liquid_feedback_core

view core.sql @ 609:314626831c04

Issue based privileges to override unit based privileges
author jbe
date Sat May 16 17:22:30 2020 +0200 (2020-05-16)
parents fa3c406a6775
children 22c6d1da7d78
line source
2 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
4 BEGIN;
6 CREATE EXTENSION IF NOT EXISTS btree_gist;
7 CREATE EXTENSION IF NOT EXISTS latlon;
8 CREATE EXTENSION IF NOT EXISTS conflux;
10 CREATE VIEW "liquid_feedback_version" AS
11 SELECT * FROM (VALUES ('4.2.0', 4, 2, 0))
12 AS "subquery"("string", "major", "minor", "revision");
16 -------------------------
17 -- Tables and indicies --
18 -------------------------
21 CREATE TABLE "temporary_transaction_data" (
22 PRIMARY KEY ("txid", "key"),
23 "txid" INT8 DEFAULT txid_current(),
24 "key" TEXT,
25 "value" TEXT NOT NULL );
27 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
29 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
32 CREATE TABLE "system_setting" (
33 "member_ttl" INTERVAL );
34 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
36 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
37 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
39 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
42 CREATE TABLE "contingent" (
43 PRIMARY KEY ("polling", "time_frame"),
44 "polling" BOOLEAN,
45 "time_frame" INTERVAL,
46 "text_entry_limit" INT4,
47 "initiative_limit" INT4 );
49 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
51 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
52 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
53 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
56 CREATE TABLE "file" (
57 "id" SERIAL8 PRIMARY KEY,
58 UNIQUE ("content_type", "hash"),
59 "content_type" TEXT NOT NULL,
60 "hash" TEXT NOT NULL,
61 "data" BYTEA NOT NULL,
62 "preview_content_type" TEXT,
63 "preview_data" BYTEA );
65 COMMENT ON TABLE "file" IS 'Table holding file contents for draft attachments';
67 COMMENT ON COLUMN "file"."content_type" IS 'Content type of "data"';
68 COMMENT ON COLUMN "file"."hash" IS 'Hash of "data" to avoid storing duplicates where content-type and data is identical';
69 COMMENT ON COLUMN "file"."data" IS 'Binary content';
70 COMMENT ON COLUMN "file"."preview_content_type" IS 'Content type of "preview_data"';
71 COMMENT ON COLUMN "file"."preview_data" IS 'Preview (e.g. preview image)';
74 CREATE TABLE "member" (
75 "id" SERIAL4 PRIMARY KEY,
76 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
77 "deleted" TIMESTAMPTZ,
78 "invite_code" TEXT UNIQUE,
79 "invite_code_expiry" TIMESTAMPTZ,
80 "admin_comment" TEXT,
81 "activated" TIMESTAMPTZ,
82 "last_activity" DATE,
83 "last_login" TIMESTAMPTZ,
84 "last_delegation_check" TIMESTAMPTZ,
85 "login" TEXT UNIQUE,
86 "password" TEXT,
87 "authority" TEXT,
88 "authority_uid" TEXT,
89 "authority_login" TEXT,
90 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
91 "active" BOOLEAN NOT NULL DEFAULT FALSE,
92 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
93 "lang" TEXT,
94 "notify_email" TEXT,
95 "notify_email_unconfirmed" TEXT,
96 "notify_email_secret" TEXT UNIQUE,
97 "notify_email_secret_expiry" TIMESTAMPTZ,
98 "notify_email_lock_expiry" TIMESTAMPTZ,
99 "unsubscribe_secret" TEXT,
100 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
101 "notification_counter" INT4 NOT NULL DEFAULT 1,
102 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
103 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
104 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
105 "notification_sent" TIMESTAMP,
106 "login_recovery_expiry" TIMESTAMPTZ,
107 "password_reset_secret" TEXT UNIQUE,
108 "password_reset_secret_expiry" TIMESTAMPTZ,
109 "name" TEXT UNIQUE, -- full text search
110 "identification" TEXT UNIQUE, -- full text search
111 "authentication" TEXT,
112 "role" BOOLEAN NOT NULL DEFAULT FALSE,
113 "location" JSONB,
114 CONSTRAINT "deleted_requires_locked"
115 CHECK ("deleted" ISNULL OR "locked" = TRUE),
116 CONSTRAINT "active_requires_activated_and_last_activity"
117 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
118 CONSTRAINT "authority_requires_uid_and_vice_versa"
119 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
120 CONSTRAINT "authority_uid_unique_per_authority"
121 UNIQUE ("authority", "authority_uid"),
122 CONSTRAINT "authority_login_requires_authority"
123 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
124 CONSTRAINT "notification_dow_requires_notification_hour"
125 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
126 CONSTRAINT "name_not_null_if_activated"
127 CHECK ("activated" ISNULL OR "name" NOTNULL) );
128 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
129 CREATE INDEX "member_active_idx" ON "member" ("active");
130 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
132 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
134 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
135 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
136 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
137 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
138 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
139 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
140 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
141 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
142 COMMENT ON COLUMN "member"."login" IS 'Login name';
143 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
144 COMMENT ON COLUMN "member"."authority" IS 'NULL if LiquidFeedback Core is authoritative for the member account; otherwise a string that indicates the source/authority of the external account (e.g. ''LDAP'' for an LDAP account)';
145 COMMENT ON COLUMN "member"."authority_uid" IS 'Unique identifier (unique per "authority") that allows to identify an external account (e.g. even if the login name changes)';
146 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
147 COMMENT ON COLUMN "member"."deleted" IS 'Timestamp of deletion (set by "delete_member" function)';
148 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
149 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
150 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
151 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
152 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
153 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
154 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
155 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
156 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
157 COMMENT ON COLUMN "member"."unsubscribe_secret" IS 'Secret string to be used for a List-Unsubscribe mail header';
158 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
159 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
160 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
161 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
162 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
163 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
164 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
165 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
166 COMMENT ON COLUMN "member"."password_reset_secret_expiry" IS 'Date/time until the password recovery secret is valid, and date/time after which another password recovery attempt is allowed';
167 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
168 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
169 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
170 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
173 CREATE TABLE "member_history" ( -- TODO: redundancy with new "event" table
174 "id" SERIAL8 PRIMARY KEY,
175 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
176 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
177 "active" BOOLEAN NOT NULL,
178 "name" TEXT NOT NULL );
179 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
181 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
183 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
184 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
187 CREATE TABLE "agent" (
188 PRIMARY KEY ("controlled_id", "controller_id"),
189 "controlled_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
190 "controller_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
191 "accepted" BOOLEAN,
192 CONSTRAINT "controlled_id_and_controller_id_differ" CHECK (
193 "controlled_id" != "controller_id" ) );
194 CREATE INDEX "agent_controller_id_idx" ON "agent" ("controller_id");
196 COMMENT ON TABLE "agent" IS 'Privileges for role accounts';
198 COMMENT ON COLUMN "agent"."accepted" IS 'If "accepted" is NULL, then the member was invited to be an agent, but has not reacted yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.';
201 CREATE TABLE "verification" (
202 "id" SERIAL8 PRIMARY KEY,
203 "requested" TIMESTAMPTZ,
204 "request_origin" JSONB,
205 "request_data" JSONB,
206 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
207 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
208 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
209 "verified" TIMESTAMPTZ,
210 "verification_data" JSONB,
211 "denied" TIMESTAMPTZ,
212 "comment" TEXT,
213 CONSTRAINT "verified_and_denied_conflict" CHECK (
214 "verified" ISNULL OR "denied" ISNULL ) );
215 CREATE INDEX "verification_requested_idx" ON "verification" ("requested");
216 CREATE INDEX "verification_open_request_idx" ON "verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
217 CREATE INDEX "verification_requesting_member_id_idx" ON "verification" ("requesting_member_id");
218 CREATE INDEX "verification_verified_member_id_idx" ON "verification" ("verified_member_id");
219 CREATE INDEX "verification_verified_idx" ON "verification" ("verified");
220 CREATE INDEX "verification_denied_idx" ON "verification" ("denied");
222 COMMENT ON TABLE "verification" IS 'Request to verify a participant';
224 COMMENT ON COLUMN "verification"."requested" IS 'Timestamp when request for verification has been submitted';
225 COMMENT ON COLUMN "verification"."request_origin" IS 'JSON data containing information about the origin of the request (e.g. IP address or hostname)';
226 COMMENT ON COLUMN "verification"."request_data" IS 'JSON data containing information about the entity to be verified (e.g. real name, address, etc.)';
227 COMMENT ON COLUMN "verification"."requesting_member_id" IS 'Member who requested verification';
228 COMMENT ON COLUMN "verification"."verifying_member_id" IS 'Member who processed the verification request (i.e. who accepted or denied the request)';
229 COMMENT ON COLUMN "verification"."verified_member_id" IS 'Member entry containing verified information (not necessarily equal to "requesting_member_id" but may be merged with requesting member later)';
230 COMMENT ON COLUMN "verification"."verified" IS 'Timestamp when request for verification has been accepted by authority';
231 COMMENT ON COLUMN "verification"."verification_data" IS 'JSON data containing additional verified data or information about the authority or operator who accepted or denied the request, but all public information shall be copied to "member"."identification", "member"."verification" and/or "member"."name" if applicable for setup';
232 COMMENT ON COLUMN "verification"."denied" IS 'Timestamp when request for verification has been denied by authority';
233 COMMENT ON COLUMN "verification"."comment" IS 'Administrative comment';
236 -- TODO: merge tables "verification" and "role_verification"
238 CREATE TABLE "role_verification" (
239 "id" SERIAL8 PRIMARY KEY,
240 "requested" TIMESTAMPTZ,
241 "request_origin" JSONB,
242 "request_data" JSONB,
243 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
244 "requesting_real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
245 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
246 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
247 "verified" TIMESTAMPTZ,
248 "verification_data" JSONB,
249 "denied" TIMESTAMPTZ,
250 "comment" TEXT,
251 CONSTRAINT "verified_and_denied_conflict" CHECK (
252 "verified" ISNULL OR "denied" ISNULL ) );
253 CREATE INDEX "role_verification_requested_idx" ON "role_verification" ("requested");
254 CREATE INDEX "role_verification_open_request_idx" ON "role_verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
255 CREATE INDEX "role_verification_requesting_member_id_idx" ON "role_verification" ("requesting_member_id");
256 CREATE INDEX "role_verification_verified_member_id_idx" ON "role_verification" ("verified_member_id");
257 CREATE INDEX "role_verification_verified_idx" ON "role_verification" ("verified");
258 CREATE INDEX "role_verification_denied_idx" ON "role_verification" ("denied");
260 COMMENT ON TABLE "role_verification" IS 'Request to verify a role account (see table "verification" for documentation of columns not documented for this table)';
262 COMMENT ON COLUMN "role_verification"."requesting_member_id" IS 'Member role account to verify';
263 COMMENT ON COLUMN "role_verification"."requesting_real_member_id" IS 'Member account of real person who requested verification';
266 CREATE TABLE "member_settings" (
267 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
268 "settings" JSONB NOT NULL CHECK (jsonb_typeof("settings") = 'object') );
270 COMMENT ON TABLE "member_settings" IS 'Stores a JSON document for each member containing optional (additional) settings for the respective member';
273 CREATE TABLE "member_useterms" (
274 "id" SERIAL8 PRIMARY KEY,
275 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
276 "accepted" TIMESTAMPTZ NOT NULL DEFAULT now(),
277 "contract_identifier" TEXT NOT NULL );
278 CREATE INDEX "member_useterms_member_id_contract_identifier" ON "member_useterms" ("member_id", "contract_identifier");
280 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
282 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
283 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
286 CREATE TABLE "member_profile" (
287 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
288 "formatting_engine" TEXT,
289 "statement" TEXT, -- full text search
290 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
291 "profile_text_data" TEXT ); -- full text search
293 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
294 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
295 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
296 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
299 CREATE TABLE "rendered_member_statement" (
300 PRIMARY KEY ("member_id", "format"),
301 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
302 "format" TEXT,
303 "content" TEXT NOT NULL );
305 COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)';
308 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
310 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
313 CREATE TABLE "member_image" (
314 PRIMARY KEY ("member_id", "image_type", "scaled"),
315 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
316 "image_type" "member_image_type",
317 "scaled" BOOLEAN,
318 "content_type" TEXT, -- TODO: NOT NULL?
319 "data" BYTEA NOT NULL );
321 COMMENT ON TABLE "member_image" IS 'Images of members';
323 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
326 CREATE TABLE "member_count" (
327 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
328 "total_count" INT4 NOT NULL );
330 COMMENT ON TABLE "member_count" IS 'Contains one row which contains the total count of active(!) members and a timestamp indicating when the total member count and area member counts were calculated';
332 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
333 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
336 CREATE TABLE "contact" (
337 PRIMARY KEY ("member_id", "other_member_id"),
338 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
339 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
340 "public" BOOLEAN NOT NULL DEFAULT FALSE,
341 "following" BOOLEAN NOT NULL DEFAULT TRUE,
342 CONSTRAINT "cant_save_yourself_as_contact"
343 CHECK ("member_id" != "other_member_id") );
344 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
346 COMMENT ON TABLE "contact" IS 'Contact lists';
348 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
349 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
350 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
351 COMMENT ON COLUMN "contact"."following" IS 'TRUE = actions of contact are shown in personal timeline';
354 CREATE TABLE "ignored_member" (
355 PRIMARY KEY ("member_id", "other_member_id"),
356 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
357 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
358 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
360 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
362 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
363 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
366 CREATE TABLE "session" (
367 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
368 "id" SERIAL8 PRIMARY KEY,
369 "ident" TEXT NOT NULL UNIQUE,
370 "additional_secret" TEXT,
371 "logout_token" TEXT,
372 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
373 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
374 "real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
375 "authority" TEXT,
376 "authority_uid" TEXT,
377 "authority_login" TEXT,
378 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
379 "lang" TEXT );
380 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
382 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
384 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
385 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
386 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
387 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in, or role account in use';
388 COMMENT ON COLUMN "session"."real_member_id" IS 'Reference to member, who is really logged in (real person rather than role account)';
389 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
390 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
391 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
392 COMMENT ON COLUMN "session"."needs_delegation_check" IS 'Set to TRUE, if member must perform a delegation check to proceed with login; see column "last_delegation_check" in "member" table';
393 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
396 CREATE TYPE "authflow" AS ENUM ('code', 'token');
398 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
401 CREATE TABLE "system_application" (
402 "id" SERIAL4 PRIMARY KEY,
403 "name" TEXT NOT NULL,
404 "base_url" TEXT,
405 "manifest_url" TEXT,
406 "client_id" TEXT NOT NULL UNIQUE,
407 "default_redirect_uri" TEXT NOT NULL,
408 "cert_common_name" TEXT,
409 "client_cred_scope" TEXT,
410 "flow" "authflow",
411 "automatic_scope" TEXT,
412 "permitted_scope" TEXT,
413 "forbidden_scope" TEXT );
415 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
417 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
418 COMMENT ON COLUMN "system_application"."base_url" IS 'Base URL for users';
419 COMMENT ON COLUMN "system_application"."manifest_url" IS 'URL referring to a manifest that can be used for application (type/version) discovery';
420 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
421 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
422 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
423 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
424 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
425 COMMENT ON COLUMN "system_application"."permitted_scope" IS 'Space-separated list of scopes; If set, scope that members may grant to the application is limited to the given value';
426 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
429 CREATE TABLE "system_application_redirect_uri" (
430 PRIMARY KEY ("system_application_id", "redirect_uri"),
431 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
432 "redirect_uri" TEXT );
434 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
437 CREATE TABLE "dynamic_application_scope" (
438 PRIMARY KEY ("redirect_uri", "flow", "scope"),
439 "redirect_uri" TEXT,
440 "flow" TEXT,
441 "scope" TEXT,
442 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
443 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
444 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
446 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
448 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
449 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
450 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
451 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
454 CREATE TABLE "member_application" (
455 "id" SERIAL4 PRIMARY KEY,
456 UNIQUE ("system_application_id", "member_id"),
457 UNIQUE ("domain", "member_id"),
458 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
459 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
460 "domain" TEXT,
461 "session_id" INT8,
462 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
463 "scope" TEXT NOT NULL,
464 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
465 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
466 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
467 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
469 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
471 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
472 COMMENT ON COLUMN "member_application"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
473 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
474 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
477 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
479 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
482 CREATE TABLE "token" (
483 "id" SERIAL8 PRIMARY KEY,
484 "token" TEXT NOT NULL UNIQUE,
485 "token_type" "token_type" NOT NULL,
486 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
487 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
488 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
489 "domain" TEXT,
490 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
491 "session_id" INT8,
492 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE, -- NOTE: deletion through "detach_token_from_session" trigger on table "session"
493 "redirect_uri" TEXT,
494 "redirect_uri_explicit" BOOLEAN,
495 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
496 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
497 "used" BOOLEAN NOT NULL DEFAULT FALSE,
498 "scope" TEXT NOT NULL,
499 CONSTRAINT "access_token_needs_expiry"
500 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
501 CONSTRAINT "authorization_token_needs_redirect_uri"
502 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
503 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
504 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
505 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
507 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
509 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
510 COMMENT ON COLUMN "token"."authorization_token_id" IS 'Reference to authorization token if tokens were originally created by Authorization Code flow (allows deletion if code is used twice)';
511 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
512 COMMENT ON COLUMN "token"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
513 COMMENT ON COLUMN "token"."session_id" IS 'If set, then token is tied to a session; Deletion of session sets value to NULL (via trigger) and removes all scopes without suffix ''_detached''';
514 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
515 COMMENT ON COLUMN "token"."redirect_uri_explicit" IS 'True if ''redirect_uri'' parameter was explicitly specified during authorization request of the Authorization Code flow (since RFC 6749 requires it to be included in the access token request in this case)';
516 COMMENT ON COLUMN "token"."expiry" IS 'Point in time when code or token expired; In case of "used" authorization codes, authorization code must not be deleted as long as tokens exist which refer to the authorization code';
517 COMMENT ON COLUMN "token"."used" IS 'Can be set to TRUE for authorization codes that have been used (enables deletion of authorization codes that were used twice)';
518 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
521 CREATE TABLE "token_scope" (
522 PRIMARY KEY ("token_id", "index"),
523 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
524 "index" INT4,
525 "scope" TEXT NOT NULL );
527 COMMENT ON TABLE "token_scope" IS 'Additional scopes for an authorization code if ''scope1'', ''scope2'', etc. parameters were used during Authorization Code flow to request several access and refresh tokens at once';
530 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
532 COMMENT ON TYPE "defeat_strength" IS 'How pairwise defeats are measured for the Schulze method: ''simple'' = only the number of winning votes, ''tuple'' = primarily the number of winning votes, secondarily the number of losing votes';
535 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
537 COMMENT ON TYPE "tie_breaking" IS 'Tie-breaker for the Schulze method: ''simple'' = only initiative ids are used, ''variant1'' = use initiative ids in variant 1 for tie breaking of the links (TBRL) and sequentially forbid shared links, ''variant2'' = use initiative ids in variant 2 for tie breaking of the links (TBRL) and sequentially forbid shared links';
540 CREATE TABLE "policy" (
541 "id" SERIAL4 PRIMARY KEY,
542 "index" INT4 NOT NULL,
543 "active" BOOLEAN NOT NULL DEFAULT TRUE,
544 "name" TEXT NOT NULL UNIQUE,
545 "description" TEXT NOT NULL DEFAULT '',
546 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
547 "min_admission_time" INTERVAL,
548 "max_admission_time" INTERVAL,
549 "discussion_time" INTERVAL,
550 "verification_time" INTERVAL,
551 "voting_time" INTERVAL,
552 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
553 "issue_quorum_num" INT4,
554 "issue_quorum_den" INT4,
555 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
556 "initiative_quorum_num" INT4 NOT NULL,
557 "initiative_quorum_den" INT4 NOT NULL,
558 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
559 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
560 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
561 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
562 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
563 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
564 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
565 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
566 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
567 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
568 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
569 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
570 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
571 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
572 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
573 "polling" = ("issue_quorum" ISNULL) AND
574 "polling" = ("issue_quorum_num" ISNULL) AND
575 "polling" = ("issue_quorum_den" ISNULL) ),
576 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
577 "min_admission_time" < "max_admission_time" ),
578 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
579 ( "polling" = FALSE AND
580 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
581 "discussion_time" NOTNULL AND
582 "verification_time" NOTNULL AND
583 "voting_time" NOTNULL ) OR
584 ( "polling" = TRUE AND
585 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
586 "discussion_time" NOTNULL AND
587 "verification_time" NOTNULL AND
588 "voting_time" NOTNULL ) OR
589 ( "polling" = TRUE AND
590 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
591 "discussion_time" ISNULL AND
592 "verification_time" ISNULL AND
593 "voting_time" ISNULL ) ),
594 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
595 "defeat_strength" = 'tuple'::"defeat_strength" OR
596 "no_reverse_beat_path" = FALSE ) );
597 CREATE INDEX "policy_active_idx" ON "policy" ("active");
599 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
601 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
602 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
603 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "min_admission_time" and "max_admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
604 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open; Note: should be considerably smaller than "max_admission_time"';
605 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
606 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
607 COMMENT ON COLUMN "policy"."verification_time" IS 'Duration of issue state ''verification''; Regular time until an issue is "fully_frozen" (e.g. entering issue state ''voting'') after being "half_frozen"';
608 COMMENT ON COLUMN "policy"."voting_time" IS 'Duration of issue state ''voting''; Time after an issue is "fully_frozen" but not "closed" (duration of issue state ''voting'')';
609 COMMENT ON COLUMN "policy"."issue_quorum" IS 'Absolute number of supporters needed by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
610 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
611 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
612 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
613 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
614 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
615 COMMENT ON COLUMN "policy"."defeat_strength" IS 'How pairwise defeats are measured for the Schulze method; see type "defeat_strength"; ''tuple'' is the recommended setting';
616 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
617 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
618 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
619 COMMENT ON COLUMN "policy"."direct_majority_strict" IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.';
620 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
621 COMMENT ON COLUMN "policy"."direct_majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner';
622 COMMENT ON COLUMN "policy"."indirect_majority_num" IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
623 COMMENT ON COLUMN "policy"."indirect_majority_den" IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
624 COMMENT ON COLUMN "policy"."indirect_majority_strict" IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.';
625 COMMENT ON COLUMN "policy"."indirect_majority_positive" IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner';
626 COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner';
627 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
628 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
631 CREATE TABLE "unit" (
632 "id" SERIAL4 PRIMARY KEY,
633 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
634 "active" BOOLEAN NOT NULL DEFAULT TRUE,
635 "name" TEXT NOT NULL, -- full text search
636 "description" TEXT NOT NULL DEFAULT '', -- full text search
637 "external_reference" TEXT,
638 "member_count" INT4,
639 "member_weight" INT4,
640 "location" JSONB );
641 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
642 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
643 CREATE INDEX "unit_active_idx" ON "unit" ("active");
644 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
646 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
648 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
649 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
650 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
651 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
652 COMMENT ON COLUMN "unit"."member_weight" IS 'Sum of active member''s voting weight';
653 COMMENT ON COLUMN "unit"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
656 CREATE TABLE "subscription" (
657 PRIMARY KEY ("member_id", "unit_id"),
658 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
659 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
660 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
662 COMMENT ON TABLE "subscription" IS 'An entry in this table denotes that the member wishes to receive notifications regardless of his/her privileges in the given unit';
665 CREATE TABLE "area" (
666 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "event"
667 "id" SERIAL4 PRIMARY KEY,
668 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
669 "active" BOOLEAN NOT NULL DEFAULT TRUE,
670 "name" TEXT NOT NULL, -- full text search
671 "description" TEXT NOT NULL DEFAULT '', -- full text search
672 "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0),
673 "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0),
674 "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL),
675 "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1),
676 "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1),
677 "quorum_den" INT4 CHECK ("quorum_den" > 0),
678 "issue_quorum" INT4,
679 "external_reference" TEXT,
680 "location" JSONB );
681 CREATE INDEX "area_active_idx" ON "area" ("active");
682 CREATE INDEX "area_location_idx" ON "area" USING gist ((GeoJSON_to_ecluster("location")));
684 COMMENT ON TABLE "area" IS 'Subject areas';
686 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
687 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
688 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
689 COMMENT ON COLUMN "area"."quorum_time" IS 'Parameter for dynamic issue quorum: discussion, verification, and voting time of open issues to result in the given default quorum (open issues with shorter time will increase quorum and open issues with longer time will reduce quorum if "quorum_exponent" is greater than zero)';
690 COMMENT ON COLUMN "area"."quorum_exponent" IS 'Parameter for dynamic issue quorum: set to zero to ignore duration of open issues, set to one to fully take duration of open issues into account; defaults to 0.5';
691 COMMENT ON COLUMN "area"."quorum_factor" IS 'Parameter for dynamic issue quorum: factor to increase dynamic quorum when a number of "quorum_issues" issues with "quorum_time" duration of discussion, verification, and voting phase are added to the number of open admitted issues';
692 COMMENT ON COLUMN "area"."quorum_den" IS 'Parameter for dynamic issue quorum: when set, dynamic quorum is multiplied with "issue"."population" and divided by "quorum_den" (and then rounded up)';
693 COMMENT ON COLUMN "area"."issue_quorum" IS 'Additional dynamic issue quorum based on the number of open accepted issues; automatically calculated by function "issue_admission"';
694 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
695 COMMENT ON COLUMN "area"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
698 CREATE TABLE "ignored_area" (
699 PRIMARY KEY ("member_id", "area_id"),
700 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
701 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
702 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
704 COMMENT ON TABLE "ignored_area" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given subject area unless he/she declared interested in a particular issue';
707 CREATE TABLE "allowed_policy" (
708 PRIMARY KEY ("area_id", "policy_id"),
709 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
710 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
711 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
712 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
714 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
716 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
719 CREATE TABLE "snapshot" (
720 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
721 "id" SERIAL8 PRIMARY KEY,
722 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
723 "population" INT4,
724 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
725 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
727 COMMENT ON TABLE "snapshot" IS 'Point in time when a snapshot of one or more issues (see table "snapshot_issue") and their supporter situation is taken';
730 CREATE TABLE "snapshot_population" (
731 PRIMARY KEY ("snapshot_id", "member_id"),
732 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
733 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
734 "weight" INT4 NOT NULL );
736 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
739 CREATE TYPE "issue_state" AS ENUM (
740 'admission', 'discussion', 'verification', 'voting',
741 'canceled_by_admin',
742 'canceled_revoked_before_accepted',
743 'canceled_issue_not_accepted',
744 'canceled_after_revocation_during_discussion',
745 'canceled_after_revocation_during_verification',
746 'canceled_no_initiative_admitted',
747 'finished_without_winner', 'finished_with_winner');
749 COMMENT ON TYPE "issue_state" IS 'State of issues';
752 CREATE TABLE "issue" (
753 UNIQUE ("area_id", "id"), -- index needed for foreign-key on table "event"
754 UNIQUE ("policy_id", "id"), -- index needed for foreign-key on table "event"
755 "id" SERIAL4 PRIMARY KEY,
756 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
757 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
758 "admin_notice" TEXT,
759 "external_reference" TEXT,
760 "state" "issue_state" NOT NULL DEFAULT 'admission',
761 "phase_finished" TIMESTAMPTZ,
762 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
763 "accepted" TIMESTAMPTZ,
764 "half_frozen" TIMESTAMPTZ,
765 "fully_frozen" TIMESTAMPTZ,
766 "closed" TIMESTAMPTZ,
767 "cleaned" TIMESTAMPTZ,
768 "min_admission_time" INTERVAL,
769 "max_admission_time" INTERVAL,
770 "discussion_time" INTERVAL NOT NULL,
771 "verification_time" INTERVAL NOT NULL,
772 "voting_time" INTERVAL NOT NULL,
773 "calculated" TIMESTAMPTZ, -- NOTE: copy of "calculated" column of latest snapshot, but no referential integrity to avoid overhead
774 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
775 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
776 "half_freeze_snapshot_id" INT8,
777 FOREIGN KEY ("id", "half_freeze_snapshot_id")
778 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
779 "full_freeze_snapshot_id" INT8,
780 FOREIGN KEY ("id", "full_freeze_snapshot_id")
781 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
782 "issue_quorum" INT4,
783 "initiative_quorum" INT4,
784 "population" INT4,
785 "voter_count" INT4,
786 "status_quo_schulze_rank" INT4,
787 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
788 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
789 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
790 CONSTRAINT "valid_state" CHECK (
791 (
792 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
793 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
794 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
795 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
796 ) AND (
797 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
798 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
799 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
800 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
801 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
802 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
803 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
804 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
805 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
806 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
807 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
808 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
809 )),
810 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
811 "phase_finished" ISNULL OR "closed" ISNULL ),
812 CONSTRAINT "state_change_order" CHECK (
813 "created" <= "accepted" AND
814 "accepted" <= "half_frozen" AND
815 "half_frozen" <= "fully_frozen" AND
816 "fully_frozen" <= "closed" ),
817 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
818 "cleaned" ISNULL OR "closed" NOTNULL ),
819 CONSTRAINT "snapshot_required" CHECK (
820 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
821 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
822 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
823 CREATE INDEX "issue_state_idx" ON "issue" ("state");
824 CREATE INDEX "issue_created_idx" ON "issue" ("created");
825 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
826 CREATE INDEX "issue_open_created_idx" ON "issue" ("created") WHERE "closed" ISNULL;
827 CREATE INDEX "issue_latest_snapshot_id_idx" ON "issue" ("latest_snapshot_id");
828 CREATE INDEX "issue_admission_snapshot_id_idx" ON "issue" ("admission_snapshot_id");
829 CREATE INDEX "issue_half_freeze_snapshot_id_idx" ON "issue" ("half_freeze_snapshot_id");
830 CREATE INDEX "issue_full_freeze_snapshot_id_idx" ON "issue" ("full_freeze_snapshot_id");
832 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
834 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
835 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
836 COMMENT ON COLUMN "issue"."phase_finished" IS 'Set to a value NOTNULL, if the current phase has finished, but calculations are pending; No changes in this issue shall be made by the frontend or API when this value is set';
837 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when the issue was accepted for further discussion (see columns "issue_quorum_num" and "issue_quorum_den" of table "policy" and quorum columns of table "area")';
838 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
839 COMMENT ON COLUMN "issue"."fully_frozen" IS 'Point in time, when "verification_time" has elapsed and voting has started; Frontends must ensure that for fully_frozen issues additionally to the restrictions for half_frozen issues a) initiatives are not created, b) no interest is created or removed, c) no supporters are added or removed, d) no opinions are created, changed or deleted.';
840 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "max_admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.';
841 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
842 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
843 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
844 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
845 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
846 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
847 COMMENT ON COLUMN "issue"."calculated" IS 'Point in time, when most recent snapshot and "population" and *_count values were calculated (NOTE: value is equal to "snapshot"."calculated" of snapshot with "id"="issue"."latest_snapshot_id")';
848 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
849 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
850 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
851 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
852 COMMENT ON COLUMN "issue"."issue_quorum" IS 'Calculated number of supporters needed by an initiative of the issue to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
853 COMMENT ON COLUMN "issue"."initiative_quorum" IS 'Calculated number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
854 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
855 COMMENT ON COLUMN "issue"."voter_count" IS 'Total number of direct and delegating voters; This value is related to the final voting, while "population" is related to snapshots before the final voting';
856 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
859 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
862 CREATE TABLE "issue_order_in_admission_state" (
863 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
864 "order_in_area" INT4,
865 "order_in_unit" INT4 );
867 COMMENT ON TABLE "issue_order_in_admission_state" IS 'Ordering information for issues that are not stored in the "issue" table to avoid locking of multiple issues at once; Filled/updated by "lf_update_issue_order"';
869 COMMENT ON COLUMN "issue_order_in_admission_state"."id" IS 'References "issue" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
870 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_area" IS 'Order of issues in admission state within a single area; NULL values sort last';
871 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_unit" IS 'Order of issues in admission state within all areas of a unit; NULL values sort last';
874 CREATE TABLE "initiative" (
875 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
876 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
877 "id" SERIAL4 PRIMARY KEY,
878 "name" TEXT NOT NULL, -- full text index
879 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
880 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
881 "revoked" TIMESTAMPTZ,
882 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
883 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
884 "location" JSONB,
885 "content" TEXT, -- full text search
886 "external_reference" TEXT,
887 "admitted" BOOLEAN,
888 "supporter_count" INT4,
889 "informed_supporter_count" INT4,
890 "satisfied_supporter_count" INT4,
891 "satisfied_informed_supporter_count" INT4,
892 "harmonic_weight" NUMERIC(12, 3),
893 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
894 "first_preference_votes" INT4,
895 "positive_votes" INT4,
896 "negative_votes" INT4,
897 "direct_majority" BOOLEAN,
898 "indirect_majority" BOOLEAN,
899 "schulze_rank" INT4,
900 "better_than_status_quo" BOOLEAN,
901 "worse_than_status_quo" BOOLEAN,
902 "reverse_beat_path" BOOLEAN,
903 "multistage_majority" BOOLEAN,
904 "eligible" BOOLEAN,
905 "winner" BOOLEAN,
906 "rank" INT4,
907 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
908 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
909 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
910 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
911 CONSTRAINT "revoked_initiatives_cant_be_admitted"
912 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
913 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
914 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
915 ( "first_preference_votes" ISNULL AND
916 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
917 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
918 "schulze_rank" ISNULL AND
919 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
920 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
921 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
922 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
923 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
924 "eligible" = FALSE OR
925 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
926 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
927 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
928 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
929 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
930 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
931 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
933 COMMENT ON TABLE "initiative" IS 'Group of members publishing drafts for resolutions to be passed; Frontends must ensure that initiatives of half_frozen issues are not revoked, and that initiatives of fully_frozen or closed issues are neither revoked nor created.';
935 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
936 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
937 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
938 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
939 COMMENT ON COLUMN "initiative"."content" IS 'Initiative text (automatically copied from most recent draft)';
940 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
941 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
942 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
943 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
944 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
945 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
946 COMMENT ON COLUMN "initiative"."harmonic_weight" IS 'Indicates the relevancy of the initiative, calculated from the potential supporters weighted with the harmonic series to avoid a large number of clones affecting other initiative''s sorting positions too much; shall be used as secondary sorting key after "admitted" as primary sorting key';
947 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
948 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
949 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
950 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
951 COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
952 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
953 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
954 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
955 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (DEPRECATED, since schulze-ranking is unique per issue; use "better_than_status_quo"=FALSE)';
956 COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties) from this initiative to the status quo; set to NULL if "policy"."defeat_strength" is set to ''simple''';
957 COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
958 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative has a "direct_majority" and an "indirect_majority", is "better_than_status_quo" and depending on selected policy the initiative has no "reverse_beat_path" or "multistage_majority"';
959 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
960 COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
963 CREATE TABLE "battle" (
964 "issue_id" INT4 NOT NULL,
965 "winning_initiative_id" INT4,
966 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
967 "losing_initiative_id" INT4,
968 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
969 "count" INT4 NOT NULL,
970 CONSTRAINT "initiative_ids_not_equal" CHECK (
971 "winning_initiative_id" != "losing_initiative_id" AND
972 ("winning_initiative_id" NOTNULL OR "losing_initiative_id" NOTNULL) ) );
973 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
974 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
975 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
977 COMMENT ON TABLE "battle" IS 'Number of members preferring one initiative to another; Filled by "battle_view" when closing an issue; NULL as initiative_id denotes virtual "status-quo" initiative';
980 CREATE TABLE "ignored_initiative" (
981 PRIMARY KEY ("member_id", "initiative_id"),
982 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
983 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
984 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
986 COMMENT ON TABLE "ignored_initiative" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given initiative';
989 CREATE TABLE "draft" (
990 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
991 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
992 "id" SERIAL8 PRIMARY KEY,
993 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
994 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
995 "formatting_engine" TEXT,
996 "content" TEXT NOT NULL, -- full text search
997 "location" JSONB,
998 "external_reference" TEXT );
999 CREATE INDEX "draft_created_idx" ON "draft" ("created");
1000 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1001 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1003 COMMENT ON TABLE "draft" IS 'Drafts of initiatives to solve issues; Frontends must ensure that new drafts for initiatives of half_frozen, fully_frozen or closed issues can''t be created.';
1005 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1006 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1007 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1008 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1011 CREATE TABLE "rendered_draft" (
1012 PRIMARY KEY ("draft_id", "format"),
1013 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1014 "format" TEXT,
1015 "content" TEXT NOT NULL );
1017 COMMENT ON TABLE "rendered_draft" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
1020 CREATE TABLE "draft_attachment" (
1021 "id" SERIAL8 PRIMARY KEY,
1022 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1023 "file_id" INT8 REFERENCES "file" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1024 "title" TEXT,
1025 "description" TEXT );
1027 COMMENT ON TABLE "draft_attachment" IS 'Binary attachments for a draft (images, PDF file, etc.); Implicitly ordered through ''id'' column';
1030 CREATE TABLE "suggestion" (
1031 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1032 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1033 "id" SERIAL8 PRIMARY KEY,
1034 "draft_id" INT8 NOT NULL,
1035 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1036 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1037 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1038 "name" TEXT NOT NULL, -- full text search
1039 "formatting_engine" TEXT,
1040 "content" TEXT NOT NULL DEFAULT '', -- full text search
1041 "location" JSONB,
1042 "external_reference" TEXT,
1043 "minus2_unfulfilled_count" INT4,
1044 "minus2_fulfilled_count" INT4,
1045 "minus1_unfulfilled_count" INT4,
1046 "minus1_fulfilled_count" INT4,
1047 "plus1_unfulfilled_count" INT4,
1048 "plus1_fulfilled_count" INT4,
1049 "plus2_unfulfilled_count" INT4,
1050 "plus2_fulfilled_count" INT4,
1051 "proportional_order" INT4 );
1052 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1053 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1054 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1056 COMMENT ON TABLE "suggestion" IS 'Suggestions to initiators, to change the current draft; must not be deleted explicitly, as they vanish automatically if the last opinion is deleted';
1058 COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
1059 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1060 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1061 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1062 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1063 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1064 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1065 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1066 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1067 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1068 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1069 COMMENT ON COLUMN "suggestion"."proportional_order" IS 'To be used for sorting suggestions within an initiative; NULL values sort last; updated by "lf_update_suggestion_order"';
1072 CREATE TABLE "rendered_suggestion" (
1073 PRIMARY KEY ("suggestion_id", "format"),
1074 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1075 "format" TEXT,
1076 "content" TEXT NOT NULL );
1078 COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
1081 CREATE TABLE "temporary_suggestion_counts" (
1082 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1083 "minus2_unfulfilled_count" INT4 NOT NULL,
1084 "minus2_fulfilled_count" INT4 NOT NULL,
1085 "minus1_unfulfilled_count" INT4 NOT NULL,
1086 "minus1_fulfilled_count" INT4 NOT NULL,
1087 "plus1_unfulfilled_count" INT4 NOT NULL,
1088 "plus1_fulfilled_count" INT4 NOT NULL,
1089 "plus2_unfulfilled_count" INT4 NOT NULL,
1090 "plus2_fulfilled_count" INT4 NOT NULL );
1092 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1094 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1097 CREATE TABLE "privilege" (
1098 PRIMARY KEY ("unit_id", "member_id"),
1099 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1100 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1101 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1102 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1103 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1104 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1105 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1106 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1107 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE,
1108 "weight" INT4 NOT NULL DEFAULT 1 CHECK ("weight" >= 0) );
1110 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1112 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1113 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1114 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1115 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1116 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1117 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1118 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues';
1119 COMMENT ON COLUMN "privilege"."weight" IS 'Voting weight of member in unit';
1122 CREATE TABLE "issue_privilege" (
1123 PRIMARY KEY ("issue_id", "member_id"),
1124 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1125 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1126 "initiative_right" BOOLEAN,
1127 "voting_right" BOOLEAN,
1128 "polling_right" BOOLEAN,
1129 "weight" INT4 CHECK ("weight" >= 0) );
1130 CREATE INDEX "issue_privilege_idx" ON "issue_privilege" ("member_id");
1132 COMMENT ON TABLE "issue_privilege" IS 'Override of "privilege" table for rights of members in certain issues';
1135 CREATE TABLE "interest" (
1136 PRIMARY KEY ("issue_id", "member_id"),
1137 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1138 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1139 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1141 COMMENT ON TABLE "interest" IS 'Interest of members in a particular issue; Frontends must ensure that interest for fully_frozen or closed issues is not added or removed.';
1144 CREATE TABLE "initiator" (
1145 PRIMARY KEY ("initiative_id", "member_id"),
1146 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1147 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1148 "accepted" BOOLEAN );
1149 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1151 COMMENT ON TABLE "initiator" IS 'Members who are allowed to post new drafts; Frontends must ensure that initiators are not added or removed from half_frozen, fully_frozen or closed initiatives.';
1153 COMMENT ON COLUMN "initiator"."accepted" IS 'If "accepted" is NULL, then the member was invited to be a co-initiator, but has not answered yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.';
1156 CREATE TABLE "supporter" (
1157 "issue_id" INT4 NOT NULL,
1158 PRIMARY KEY ("initiative_id", "member_id"),
1159 "initiative_id" INT4,
1160 "member_id" INT4,
1161 "draft_id" INT8 NOT NULL,
1162 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1163 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1164 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1166 COMMENT ON TABLE "supporter" IS 'Members who support an initiative (conditionally); Frontends must ensure that supporters are not added or removed from fully_frozen or closed initiatives.';
1168 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1169 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
1172 CREATE TABLE "opinion" (
1173 "initiative_id" INT4 NOT NULL,
1174 PRIMARY KEY ("suggestion_id", "member_id"),
1175 "suggestion_id" INT8,
1176 "member_id" INT4,
1177 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1178 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1179 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1180 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1181 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1183 COMMENT ON TABLE "opinion" IS 'Opinion on suggestions (criticism related to initiatives); Frontends must ensure that opinions are not created modified or deleted when related to fully_frozen or closed issues.';
1185 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1188 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1190 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1193 CREATE TABLE "delegation" (
1194 "id" SERIAL8 PRIMARY KEY,
1195 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1196 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1197 "scope" "delegation_scope" NOT NULL,
1198 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1199 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1200 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1201 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1202 CONSTRAINT "no_unit_delegation_to_null"
1203 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1204 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1205 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1206 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1207 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1208 UNIQUE ("unit_id", "truster_id"),
1209 UNIQUE ("area_id", "truster_id"),
1210 UNIQUE ("issue_id", "truster_id") );
1211 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1212 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1214 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1216 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1217 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1218 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1221 CREATE TABLE "snapshot_issue" (
1222 PRIMARY KEY ("snapshot_id", "issue_id"),
1223 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1224 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1225 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1227 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1229 COMMENT ON COLUMN "snapshot_issue"."issue_id" IS 'Issue being part of the snapshot; Trigger "delete_snapshot_on_partial_delete" on "snapshot_issue" table will delete snapshot if an issue of the snapshot is deleted.';
1232 CREATE TABLE "direct_interest_snapshot" (
1233 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1234 "snapshot_id" INT8,
1235 "issue_id" INT4,
1236 FOREIGN KEY ("snapshot_id", "issue_id")
1237 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1238 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1239 "ownweight" INT4 NOT NULL,
1240 "weight" INT4 );
1241 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1243 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
1245 COMMENT ON COLUMN "direct_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations';
1246 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"';
1249 CREATE TABLE "delegating_interest_snapshot" (
1250 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1251 "snapshot_id" INT8,
1252 "issue_id" INT4,
1253 FOREIGN KEY ("snapshot_id", "issue_id")
1254 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1255 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1256 "ownweight" INT4 NOT NULL,
1257 "weight" INT4,
1258 "scope" "delegation_scope" NOT NULL,
1259 "delegate_member_ids" INT4[] NOT NULL );
1260 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1262 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
1264 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1265 COMMENT ON COLUMN "delegating_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations';
1266 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate voting weight considering incoming delegations';
1267 COMMENT ON COLUMN "delegating_interest_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_interest_snapshot"';
1270 CREATE TABLE "direct_supporter_snapshot" (
1271 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1272 "snapshot_id" INT8,
1273 "issue_id" INT4 NOT NULL,
1274 FOREIGN KEY ("snapshot_id", "issue_id")
1275 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1276 "initiative_id" INT4,
1277 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1278 "draft_id" INT8 NOT NULL,
1279 "informed" BOOLEAN NOT NULL,
1280 "satisfied" BOOLEAN NOT NULL,
1281 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1282 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1283 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1284 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1286 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot"); for corrections refer to column "issue_notice" of "issue" table';
1288 COMMENT ON COLUMN "direct_supporter_snapshot"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1289 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1290 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1293 CREATE TABLE "non_voter" (
1294 PRIMARY KEY ("member_id", "issue_id"),
1295 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1296 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1297 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1299 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1302 CREATE TABLE "direct_voter" (
1303 PRIMARY KEY ("issue_id", "member_id"),
1304 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1305 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1306 "ownweight" INT4,
1307 "weight" INT4,
1308 "comment_changed" TIMESTAMPTZ,
1309 "formatting_engine" TEXT,
1310 "comment" TEXT ); -- full text index
1311 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1313 COMMENT ON TABLE "direct_voter" IS 'Members having directly voted for/against initiatives of an issue; frontends must ensure that no voters are added or removed to/from this table when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table';
1315 COMMENT ON COLUMN "direct_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations';
1316 COMMENT ON COLUMN "direct_voter"."weight" IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"';
1317 COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL';
1318 COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL';
1319 COMMENT ON COLUMN "direct_voter"."comment" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
1322 CREATE TABLE "rendered_voter_comment" (
1323 PRIMARY KEY ("issue_id", "member_id", "format"),
1324 FOREIGN KEY ("issue_id", "member_id")
1325 REFERENCES "direct_voter" ("issue_id", "member_id")
1326 ON DELETE CASCADE ON UPDATE CASCADE,
1327 "issue_id" INT4,
1328 "member_id" INT4,
1329 "format" TEXT,
1330 "content" TEXT NOT NULL );
1332 COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)';
1335 CREATE TABLE "delegating_voter" (
1336 PRIMARY KEY ("issue_id", "member_id"),
1337 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1338 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1339 "ownweight" INT4 NOT NULL,
1340 "weight" INT4,
1341 "scope" "delegation_scope" NOT NULL,
1342 "delegate_member_ids" INT4[] NOT NULL );
1343 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1345 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table; for corrections refer to column "issue_notice" of "issue" table';
1347 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1348 COMMENT ON COLUMN "delegating_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations';
1349 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate voting weight considering incoming delegations';
1350 COMMENT ON COLUMN "delegating_voter"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_voter"';
1353 CREATE TABLE "vote" (
1354 "issue_id" INT4 NOT NULL,
1355 PRIMARY KEY ("initiative_id", "member_id"),
1356 "initiative_id" INT4,
1357 "member_id" INT4,
1358 "grade" INT4 NOT NULL,
1359 "first_preference" BOOLEAN,
1360 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1361 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1362 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1363 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1364 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1366 COMMENT ON TABLE "vote" IS 'Manual and delegated votes without abstentions; frontends must ensure that no votes are added modified or removed when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table';
1368 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1369 COMMENT ON COLUMN "vote"."grade" IS 'Values smaller than zero mean reject, values greater than zero mean acceptance, zero or missing row means abstention. Preferences are expressed by different positive or negative numbers.';
1370 COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.';
1373 CREATE TABLE "posting" (
1374 UNIQUE ("author_id", "id"), -- index needed for foreign-key on table "posting_lexeme"
1375 "id" SERIAL8 PRIMARY KEY,
1376 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1377 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1378 "message" TEXT NOT NULL,
1379 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1380 "area_id" INT4,
1381 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1382 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1383 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1384 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1385 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1386 "initiative_id" INT4,
1387 "suggestion_id" INT8,
1388 -- NOTE: no referential integrity for suggestions because those are
1389 -- actually deleted
1390 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1391 -- REFERENCES "suggestion" ("initiative_id", "id")
1392 -- ON DELETE CASCADE ON UPDATE CASCADE,
1393 CONSTRAINT "area_requires_unit" CHECK (
1394 "area_id" ISNULL OR "unit_id" NOTNULL ),
1395 CONSTRAINT "policy_set_when_issue_set" CHECK (
1396 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
1397 CONSTRAINT "issue_requires_area" CHECK (
1398 "issue_id" ISNULL OR "area_id" NOTNULL ),
1399 CONSTRAINT "initiative_requires_issue" CHECK (
1400 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
1401 CONSTRAINT "suggestion_requires_initiative" CHECK (
1402 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
1403 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
1404 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
1405 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
1406 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
1407 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
1408 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
1409 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
1411 COMMENT ON TABLE "posting" IS 'Text postings of members; a text posting may optionally be associated to a unit, area, policy, issue, initiative, or suggestion';
1414 CREATE TABLE "posting_lexeme" (
1415 PRIMARY KEY ("posting_id", "lexeme"),
1416 FOREIGN KEY ("posting_id", "author_id") REFERENCES "posting" ("id", "author_id") ON DELETE CASCADE ON UPDATE CASCADE,
1417 "posting_id" INT8,
1418 "lexeme" TEXT,
1419 "author_id" INT4 );
1420 CREATE INDEX "posting_lexeme_idx" ON "posting_lexeme" USING gist ("lexeme", (pstamp("author_id", "posting_id")));
1422 COMMENT ON TABLE "posting_lexeme" IS 'Helper table to allow searches for hashtags.';
1425 CREATE TYPE "event_type" AS ENUM (
1426 'unit_created',
1427 'unit_updated',
1428 'area_created',
1429 'area_updated',
1430 'policy_created',
1431 'policy_updated',
1432 'issue_state_changed',
1433 'initiative_created_in_new_issue',
1434 'initiative_created_in_existing_issue',
1435 'initiative_revoked',
1436 'new_draft_created',
1437 'suggestion_created',
1438 'suggestion_deleted',
1439 'member_activated',
1440 'member_deleted',
1441 'member_active',
1442 'member_name_updated',
1443 'member_profile_updated',
1444 'member_image_updated',
1445 'interest',
1446 'initiator',
1447 'support',
1448 'support_updated',
1449 'suggestion_rated',
1450 'delegation',
1451 'contact',
1452 'posting_created' );
1454 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1457 CREATE TABLE "event" (
1458 "id" SERIAL8 PRIMARY KEY,
1459 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1460 "event" "event_type" NOT NULL,
1461 "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1462 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1463 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1464 "scope" "delegation_scope",
1465 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1466 "area_id" INT4,
1467 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1468 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1469 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1470 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1471 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1472 "state" "issue_state",
1473 "initiative_id" INT4,
1474 "draft_id" INT8,
1475 "suggestion_id" INT8,
1476 "boolean_value" BOOLEAN,
1477 "numeric_value" INT4,
1478 "text_value" TEXT,
1479 "old_text_value" TEXT,
1480 FOREIGN KEY ("issue_id", "initiative_id")
1481 REFERENCES "initiative" ("issue_id", "id")
1482 ON DELETE CASCADE ON UPDATE CASCADE,
1483 FOREIGN KEY ("initiative_id", "draft_id")
1484 REFERENCES "draft" ("initiative_id", "id")
1485 ON DELETE CASCADE ON UPDATE CASCADE,
1486 -- NOTE: no referential integrity for suggestions because those are
1487 -- actually deleted
1488 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1489 -- REFERENCES "suggestion" ("initiative_id", "id")
1490 -- ON DELETE CASCADE ON UPDATE CASCADE,
1491 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1492 "event" != 'issue_state_changed' OR (
1493 "posting_id" ISNULL AND
1494 "member_id" ISNULL AND
1495 "other_member_id" ISNULL AND
1496 "scope" ISNULL AND
1497 "unit_id" NOTNULL AND
1498 "area_id" NOTNULL AND
1499 "policy_id" NOTNULL AND
1500 "issue_id" NOTNULL AND
1501 "state" NOTNULL AND
1502 "initiative_id" ISNULL AND
1503 "draft_id" ISNULL AND
1504 "suggestion_id" ISNULL AND
1505 "boolean_value" ISNULL AND
1506 "numeric_value" ISNULL AND
1507 "text_value" ISNULL AND
1508 "old_text_value" ISNULL )),
1509 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1510 "event" NOT IN (
1511 'initiative_created_in_new_issue',
1512 'initiative_created_in_existing_issue',
1513 'initiative_revoked',
1514 'new_draft_created'
1515 ) OR (
1516 "posting_id" ISNULL AND
1517 "member_id" NOTNULL AND
1518 "other_member_id" ISNULL AND
1519 "scope" ISNULL AND
1520 "unit_id" NOTNULL AND
1521 "area_id" NOTNULL AND
1522 "policy_id" NOTNULL AND
1523 "issue_id" NOTNULL AND
1524 "state" NOTNULL AND
1525 "initiative_id" NOTNULL AND
1526 "draft_id" NOTNULL AND
1527 "suggestion_id" ISNULL AND
1528 "boolean_value" ISNULL AND
1529 "numeric_value" ISNULL AND
1530 "text_value" ISNULL AND
1531 "old_text_value" ISNULL )),
1532 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1533 "event" != 'suggestion_created' OR (
1534 "posting_id" ISNULL AND
1535 "member_id" NOTNULL AND
1536 "other_member_id" ISNULL AND
1537 "scope" ISNULL AND
1538 "unit_id" NOTNULL AND
1539 "area_id" NOTNULL AND
1540 "policy_id" NOTNULL AND
1541 "issue_id" NOTNULL AND
1542 "state" NOTNULL AND
1543 "initiative_id" NOTNULL AND
1544 "draft_id" ISNULL AND
1545 "suggestion_id" NOTNULL AND
1546 "boolean_value" ISNULL AND
1547 "numeric_value" ISNULL AND
1548 "text_value" ISNULL AND
1549 "old_text_value" ISNULL )),
1550 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1551 "event" != 'suggestion_deleted' OR (
1552 "posting_id" ISNULL AND
1553 "member_id" ISNULL AND
1554 "other_member_id" ISNULL AND
1555 "scope" ISNULL AND
1556 "unit_id" NOTNULL AND
1557 "area_id" NOTNULL AND
1558 "policy_id" NOTNULL AND
1559 "issue_id" NOTNULL AND
1560 "state" NOTNULL AND
1561 "initiative_id" NOTNULL AND
1562 "draft_id" ISNULL AND
1563 "suggestion_id" NOTNULL AND
1564 "boolean_value" ISNULL AND
1565 "numeric_value" ISNULL AND
1566 "text_value" ISNULL AND
1567 "old_text_value" ISNULL )),
1568 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1569 "event" NOT IN (
1570 'member_activated',
1571 'member_deleted',
1572 'member_profile_updated',
1573 'member_image_updated'
1574 ) OR (
1575 "posting_id" ISNULL AND
1576 "member_id" NOTNULL AND
1577 "other_member_id" ISNULL AND
1578 "scope" ISNULL AND
1579 "unit_id" ISNULL AND
1580 "area_id" ISNULL AND
1581 "policy_id" ISNULL AND
1582 "issue_id" ISNULL AND
1583 "state" ISNULL AND
1584 "initiative_id" ISNULL AND
1585 "draft_id" ISNULL AND
1586 "suggestion_id" ISNULL AND
1587 "boolean_value" ISNULL AND
1588 "numeric_value" ISNULL AND
1589 "text_value" ISNULL AND
1590 "old_text_value" ISNULL )),
1591 CONSTRAINT "constr_for_member_active" CHECK (
1592 "event" != 'member_active' OR (
1593 "posting_id" ISNULL AND
1594 "member_id" NOTNULL AND
1595 "other_member_id" ISNULL AND
1596 "scope" ISNULL AND
1597 "unit_id" ISNULL AND
1598 "area_id" ISNULL AND
1599 "policy_id" ISNULL AND
1600 "issue_id" ISNULL AND
1601 "state" ISNULL AND
1602 "initiative_id" ISNULL AND
1603 "draft_id" ISNULL AND
1604 "suggestion_id" ISNULL AND
1605 "boolean_value" NOTNULL AND
1606 "numeric_value" ISNULL AND
1607 "text_value" ISNULL AND
1608 "old_text_value" ISNULL )),
1609 CONSTRAINT "constr_for_member_name_updated" CHECK (
1610 "event" != 'member_name_updated' OR (
1611 "posting_id" ISNULL AND
1612 "member_id" NOTNULL AND
1613 "other_member_id" ISNULL AND
1614 "scope" ISNULL AND
1615 "unit_id" ISNULL AND
1616 "area_id" ISNULL AND
1617 "policy_id" ISNULL AND
1618 "issue_id" ISNULL AND
1619 "state" ISNULL AND
1620 "initiative_id" ISNULL AND
1621 "draft_id" ISNULL AND
1622 "suggestion_id" ISNULL AND
1623 "boolean_value" ISNULL AND
1624 "numeric_value" ISNULL AND
1625 "text_value" NOTNULL AND
1626 "old_text_value" NOTNULL )),
1627 CONSTRAINT "constr_for_interest" CHECK (
1628 "event" != 'interest' OR (
1629 "posting_id" ISNULL AND
1630 "member_id" NOTNULL AND
1631 "other_member_id" ISNULL AND
1632 "scope" ISNULL AND
1633 "unit_id" NOTNULL AND
1634 "area_id" NOTNULL AND
1635 "policy_id" NOTNULL AND
1636 "issue_id" NOTNULL AND
1637 "state" NOTNULL AND
1638 "initiative_id" ISNULL AND
1639 "draft_id" ISNULL AND
1640 "suggestion_id" ISNULL AND
1641 "boolean_value" NOTNULL AND
1642 "numeric_value" ISNULL AND
1643 "text_value" ISNULL AND
1644 "old_text_value" ISNULL )),
1645 CONSTRAINT "constr_for_initiator" CHECK (
1646 "event" != 'initiator' OR (
1647 "posting_id" ISNULL AND
1648 "member_id" NOTNULL AND
1649 "other_member_id" ISNULL AND
1650 "scope" ISNULL AND
1651 "unit_id" NOTNULL AND
1652 "area_id" NOTNULL AND
1653 "policy_id" NOTNULL AND
1654 "issue_id" NOTNULL AND
1655 "state" NOTNULL AND
1656 "initiative_id" NOTNULL AND
1657 "draft_id" ISNULL AND
1658 "suggestion_id" ISNULL AND
1659 "boolean_value" NOTNULL AND
1660 "numeric_value" ISNULL AND
1661 "text_value" ISNULL AND
1662 "old_text_value" ISNULL )),
1663 CONSTRAINT "constr_for_support" CHECK (
1664 "event" != 'support' OR (
1665 "posting_id" ISNULL AND
1666 "member_id" NOTNULL AND
1667 "other_member_id" ISNULL AND
1668 "scope" ISNULL AND
1669 "unit_id" NOTNULL AND
1670 "area_id" NOTNULL AND
1671 "policy_id" NOTNULL AND
1672 "issue_id" NOTNULL AND
1673 "state" NOTNULL AND
1674 "initiative_id" NOTNULL AND
1675 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1676 "suggestion_id" ISNULL AND
1677 "boolean_value" NOTNULL AND
1678 "numeric_value" ISNULL AND
1679 "text_value" ISNULL AND
1680 "old_text_value" ISNULL )),
1681 CONSTRAINT "constr_for_support_updated" CHECK (
1682 "event" != 'support_updated' OR (
1683 "posting_id" ISNULL AND
1684 "member_id" NOTNULL AND
1685 "other_member_id" ISNULL AND
1686 "scope" ISNULL AND
1687 "unit_id" NOTNULL AND
1688 "area_id" NOTNULL AND
1689 "policy_id" NOTNULL AND
1690 "issue_id" NOTNULL AND
1691 "state" NOTNULL AND
1692 "initiative_id" NOTNULL AND
1693 "draft_id" NOTNULL AND
1694 "suggestion_id" ISNULL AND
1695 "boolean_value" ISNULL AND
1696 "numeric_value" ISNULL AND
1697 "text_value" ISNULL AND
1698 "old_text_value" ISNULL )),
1699 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1700 "event" != 'suggestion_rated' OR (
1701 "posting_id" ISNULL AND
1702 "member_id" NOTNULL AND
1703 "other_member_id" ISNULL AND
1704 "scope" ISNULL AND
1705 "unit_id" NOTNULL AND
1706 "area_id" NOTNULL AND
1707 "policy_id" NOTNULL AND
1708 "issue_id" NOTNULL AND
1709 "state" NOTNULL AND
1710 "initiative_id" NOTNULL AND
1711 "draft_id" ISNULL AND
1712 "suggestion_id" NOTNULL AND
1713 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1714 "numeric_value" NOTNULL AND
1715 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1716 "text_value" ISNULL AND
1717 "old_text_value" ISNULL )),
1718 CONSTRAINT "constr_for_delegation" CHECK (
1719 "event" != 'delegation' OR (
1720 "posting_id" ISNULL AND
1721 "member_id" NOTNULL AND
1722 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1723 "scope" NOTNULL AND
1724 "unit_id" NOTNULL AND
1725 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1726 "policy_id" ISNULL AND
1727 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1728 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1729 "initiative_id" ISNULL AND
1730 "draft_id" ISNULL AND
1731 "suggestion_id" ISNULL AND
1732 "boolean_value" NOTNULL AND
1733 "numeric_value" ISNULL AND
1734 "text_value" ISNULL AND
1735 "old_text_value" ISNULL )),
1736 CONSTRAINT "constr_for_contact" CHECK (
1737 "event" != 'contact' OR (
1738 "posting_id" ISNULL AND
1739 "member_id" NOTNULL AND
1740 "other_member_id" NOTNULL AND
1741 "scope" ISNULL AND
1742 "unit_id" ISNULL AND
1743 "area_id" ISNULL AND
1744 "policy_id" ISNULL AND
1745 "issue_id" ISNULL AND
1746 "state" ISNULL AND
1747 "initiative_id" ISNULL AND
1748 "draft_id" ISNULL AND
1749 "suggestion_id" ISNULL AND
1750 "boolean_value" NOTNULL AND
1751 "numeric_value" ISNULL AND
1752 "text_value" ISNULL AND
1753 "old_text_value" ISNULL )),
1754 CONSTRAINT "constr_for_posting_created" CHECK (
1755 "event" != 'posting_created' OR (
1756 "posting_id" NOTNULL AND
1757 "member_id" NOTNULL AND
1758 "other_member_id" ISNULL AND
1759 "scope" ISNULL AND
1760 "state" ISNULL AND
1761 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
1762 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
1763 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
1764 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
1765 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
1766 "draft_id" ISNULL AND
1767 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
1768 "boolean_value" ISNULL AND
1769 "numeric_value" ISNULL AND
1770 "text_value" ISNULL AND
1771 "old_text_value" ISNULL )) );
1772 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1773 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
1774 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
1775 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
1776 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
1777 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
1778 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
1779 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
1782 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1784 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1785 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1786 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1787 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1790 CREATE TABLE "event_processed" (
1791 "event_id" INT8 NOT NULL );
1792 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1794 COMMENT ON TABLE "event_processed" IS 'This table stores one row with the last event_id, for which event handlers have been executed (e.g. notifications having been sent out)';
1795 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1798 CREATE TABLE "notification_initiative_sent" (
1799 PRIMARY KEY ("member_id", "initiative_id"),
1800 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1801 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1802 "last_draft_id" INT8 NOT NULL,
1803 "last_suggestion_id" INT8 );
1804 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1806 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1808 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1809 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1812 CREATE TABLE "newsletter" (
1813 "id" SERIAL4 PRIMARY KEY,
1814 "published" TIMESTAMPTZ NOT NULL,
1815 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1816 "include_all_members" BOOLEAN NOT NULL,
1817 "sent" TIMESTAMPTZ,
1818 "subject" TEXT NOT NULL,
1819 "content" TEXT NOT NULL );
1820 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1821 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1822 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1824 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1826 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1827 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1828 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1829 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1830 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1831 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1835 ----------------------
1836 -- Full text search --
1837 ----------------------
1840 CREATE FUNCTION "highlight"
1841 ( "body_p" TEXT,
1842 "query_text_p" TEXT )
1843 RETURNS TEXT
1844 LANGUAGE 'plpgsql' IMMUTABLE AS $$
1845 BEGIN
1846 RETURN ts_headline(
1847 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
1848 "plainto_tsquery"("query_text_p"),
1849 'StartSel=* StopSel=* HighlightAll=TRUE' );
1850 END;
1851 $$;
1853 COMMENT ON FUNCTION "highlight"
1854 ( "body_p" TEXT,
1855 "query_text_p" TEXT )
1856 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
1859 CREATE FUNCTION "to_tsvector"("member") RETURNS TSVECTOR
1860 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1861 $1."name",
1862 $1."identification"
1863 )) $$;
1864 CREATE INDEX "member_to_tsvector_idx" ON "member" USING gin
1865 (("to_tsvector"("member".*)));
1867 CREATE FUNCTION "to_tsvector"("member_profile") RETURNS TSVECTOR
1868 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1869 $1."statement",
1870 $1."profile_text_data"
1871 )) $$;
1872 CREATE INDEX "member_profile_to_tsvector_idx" ON "member_profile" USING gin
1873 (("to_tsvector"("member_profile".*)));
1875 CREATE FUNCTION "to_tsvector"("unit") RETURNS TSVECTOR
1876 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1877 $1."name",
1878 $1."description"
1879 )) $$;
1880 CREATE INDEX "unit_to_tsvector_idx" ON "unit" USING gin
1881 (("to_tsvector"("unit".*)));
1883 CREATE FUNCTION "to_tsvector"("area") RETURNS TSVECTOR
1884 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1885 $1."name",
1886 $1."description"
1887 )) $$;
1888 CREATE INDEX "area_to_tsvector_idx" ON "area" USING gin
1889 (("to_tsvector"("area".*)));
1891 CREATE FUNCTION "to_tsvector"("initiative") RETURNS TSVECTOR
1892 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1893 $1."name",
1894 $1."content"
1895 )) $$;
1896 CREATE INDEX "initiative_to_tsvector_idx" ON "initiative" USING gin
1897 (("to_tsvector"("initiative".*)));
1899 CREATE FUNCTION "to_tsvector"("draft") RETURNS TSVECTOR
1900 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1901 $1."content"
1902 )) $$;
1903 CREATE INDEX "draft_to_tsvector_idx" ON "draft" USING gin
1904 (("to_tsvector"("draft".*)));
1906 CREATE FUNCTION "to_tsvector"("suggestion") RETURNS TSVECTOR
1907 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1908 $1."name",
1909 $1."content"
1910 )) $$;
1911 CREATE INDEX "suggestion_to_tsvector_idx" ON "suggestion" USING gin
1912 (("to_tsvector"("suggestion".*)));
1914 CREATE FUNCTION "to_tsvector"("direct_voter") RETURNS TSVECTOR
1915 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
1916 $1."comment"
1917 )) $$;
1918 CREATE INDEX "direct_voter_to_tsvector_idx" ON "direct_voter" USING gin
1919 (("to_tsvector"("direct_voter".*)));
1922 CREATE FUNCTION "update_posting_lexeme_trigger"()
1923 RETURNS TRIGGER
1924 LANGUAGE 'plpgsql' VOLATILE AS $$
1925 DECLARE
1926 "lexeme_v" TEXT;
1927 BEGIN
1928 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
1929 DELETE FROM "posting_lexeme" WHERE "posting_id" = OLD."id";
1930 END IF;
1931 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
1932 FOR "lexeme_v" IN
1933 SELECT regexp_matches[1]
1934 FROM regexp_matches(NEW."message", '#[^\s.,;:]+')
1935 LOOP
1936 INSERT INTO "posting_lexeme" ("posting_id", "author_id", "lexeme")
1937 VALUES (
1938 NEW."id",
1939 NEW."author_id",
1940 "lexeme_v" )
1941 ON CONFLICT ("posting_id", "lexeme") DO NOTHING;
1942 END LOOP;
1943 END IF;
1944 RETURN NULL;
1945 END;
1946 $$;
1948 CREATE TRIGGER "update_posting_lexeme"
1949 AFTER INSERT OR UPDATE OR DELETE ON "posting"
1950 FOR EACH ROW EXECUTE PROCEDURE "update_posting_lexeme_trigger"();
1952 COMMENT ON FUNCTION "update_posting_lexeme_trigger"() IS 'Implementation of trigger "update_posting_lexeme" on table "posting"';
1953 COMMENT ON TRIGGER "update_posting_lexeme" ON "posting" IS 'Keeps table "posting_lexeme" up to date';
1957 ----------------------------------------------
1958 -- Writing of history entries and event log --
1959 ----------------------------------------------
1962 CREATE FUNCTION "write_member_history_trigger"()
1963 RETURNS TRIGGER
1964 LANGUAGE 'plpgsql' VOLATILE AS $$
1965 BEGIN
1966 IF
1967 ( NEW."active" != OLD."active" OR
1968 NEW."name" != OLD."name" ) AND
1969 OLD."activated" NOTNULL
1970 THEN
1971 INSERT INTO "member_history"
1972 ("member_id", "active", "name")
1973 VALUES (NEW."id", OLD."active", OLD."name");
1974 END IF;
1975 RETURN NULL;
1976 END;
1977 $$;
1979 CREATE TRIGGER "write_member_history"
1980 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1981 "write_member_history_trigger"();
1983 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1984 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1987 CREATE FUNCTION "write_event_unit_trigger"()
1988 RETURNS TRIGGER
1989 LANGUAGE 'plpgsql' VOLATILE AS $$
1990 DECLARE
1991 "event_v" "event_type";
1992 BEGIN
1993 IF TG_OP = 'UPDATE' THEN
1994 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1995 RETURN NULL;
1996 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1997 -- "event_v" := 'unit_created';
1998 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1999 -- "event_v" := 'unit_deleted';
2000 ELSIF OLD != NEW THEN
2001 "event_v" := 'unit_updated';
2002 ELSE
2003 RETURN NULL;
2004 END IF;
2005 ELSE
2006 "event_v" := 'unit_created';
2007 END IF;
2008 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
2009 RETURN NULL;
2010 END;
2011 $$;
2013 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
2014 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
2016 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
2017 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
2020 CREATE FUNCTION "write_event_area_trigger"()
2021 RETURNS TRIGGER
2022 LANGUAGE 'plpgsql' VOLATILE AS $$
2023 DECLARE
2024 "event_v" "event_type";
2025 BEGIN
2026 IF TG_OP = 'UPDATE' THEN
2027 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
2028 RETURN NULL;
2029 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
2030 -- "event_v" := 'area_created';
2031 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
2032 -- "event_v" := 'area_deleted';
2033 ELSIF OLD != NEW THEN
2034 "event_v" := 'area_updated';
2035 ELSE
2036 RETURN NULL;
2037 END IF;
2038 ELSE
2039 "event_v" := 'area_created';
2040 END IF;
2041 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
2042 RETURN NULL;
2043 END;
2044 $$;
2046 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
2047 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
2049 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
2050 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
2053 CREATE FUNCTION "write_event_policy_trigger"()
2054 RETURNS TRIGGER
2055 LANGUAGE 'plpgsql' VOLATILE AS $$
2056 DECLARE
2057 "event_v" "event_type";
2058 BEGIN
2059 IF TG_OP = 'UPDATE' THEN
2060 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
2061 RETURN NULL;
2062 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
2063 -- "event_v" := 'policy_created';
2064 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
2065 -- "event_v" := 'policy_deleted';
2066 ELSIF OLD != NEW THEN
2067 "event_v" := 'policy_updated';
2068 ELSE
2069 RETURN NULL;
2070 END IF;
2071 ELSE
2072 "event_v" := 'policy_created';
2073 END IF;
2074 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
2075 RETURN NULL;
2076 END;
2077 $$;
2079 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
2080 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
2082 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
2083 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
2086 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
2087 RETURNS TRIGGER
2088 LANGUAGE 'plpgsql' VOLATILE AS $$
2089 DECLARE
2090 "area_row" "area"%ROWTYPE;
2091 BEGIN
2092 IF NEW."state" != OLD."state" THEN
2093 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
2094 FOR SHARE;
2095 INSERT INTO "event" (
2096 "event",
2097 "unit_id", "area_id", "policy_id", "issue_id", "state"
2098 ) VALUES (
2099 'issue_state_changed',
2100 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
2101 NEW."id", NEW."state"
2102 );
2103 END IF;
2104 RETURN NULL;
2105 END;
2106 $$;
2108 CREATE TRIGGER "write_event_issue_state_changed"
2109 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
2110 "write_event_issue_state_changed_trigger"();
2112 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
2113 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
2116 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
2117 RETURNS TRIGGER
2118 LANGUAGE 'plpgsql' VOLATILE AS $$
2119 DECLARE
2120 "initiative_row" "initiative"%ROWTYPE;
2121 "issue_row" "issue"%ROWTYPE;
2122 "area_row" "area"%ROWTYPE;
2123 "event_v" "event_type";
2124 BEGIN
2125 SELECT * INTO "initiative_row" FROM "initiative"
2126 WHERE "id" = NEW."initiative_id" FOR SHARE;
2127 SELECT * INTO "issue_row" FROM "issue"
2128 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2129 SELECT * INTO "area_row" FROM "area"
2130 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2131 IF EXISTS (
2132 SELECT NULL FROM "draft"
2133 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
2134 FOR SHARE
2135 ) THEN
2136 "event_v" := 'new_draft_created';
2137 ELSE
2138 IF EXISTS (
2139 SELECT NULL FROM "initiative"
2140 WHERE "issue_id" = "initiative_row"."issue_id"
2141 AND "id" != "initiative_row"."id"
2142 FOR SHARE
2143 ) THEN
2144 "event_v" := 'initiative_created_in_existing_issue';
2145 ELSE
2146 "event_v" := 'initiative_created_in_new_issue';
2147 END IF;
2148 END IF;
2149 INSERT INTO "event" (
2150 "event", "member_id",
2151 "unit_id", "area_id", "policy_id", "issue_id", "state",
2152 "initiative_id", "draft_id"
2153 ) VALUES (
2154 "event_v", NEW."author_id",
2155 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2156 "initiative_row"."issue_id", "issue_row"."state",
2157 NEW."initiative_id", NEW."id"
2158 );
2159 RETURN NULL;
2160 END;
2161 $$;
2163 CREATE TRIGGER "write_event_initiative_or_draft_created"
2164 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
2165 "write_event_initiative_or_draft_created_trigger"();
2167 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
2168 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
2171 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
2172 RETURNS TRIGGER
2173 LANGUAGE 'plpgsql' VOLATILE AS $$
2174 DECLARE
2175 "issue_row" "issue"%ROWTYPE;
2176 "area_row" "area"%ROWTYPE;
2177 "draft_id_v" "draft"."id"%TYPE;
2178 BEGIN
2179 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
2180 -- NOTE: lock for primary key update to avoid new drafts
2181 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2182 SELECT * INTO "issue_row" FROM "issue"
2183 WHERE "id" = NEW."issue_id" FOR SHARE;
2184 SELECT * INTO "area_row" FROM "area"
2185 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2186 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2187 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2188 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2189 WHERE "initiative_id" = NEW."id";
2190 INSERT INTO "event" (
2191 "event", "member_id",
2192 "unit_id", "area_id", "policy_id", "issue_id", "state",
2193 "initiative_id", "draft_id"
2194 ) VALUES (
2195 'initiative_revoked', NEW."revoked_by_member_id",
2196 "area_row"."unit_id", "issue_row"."area_id",
2197 "issue_row"."policy_id",
2198 NEW."issue_id", "issue_row"."state",
2199 NEW."id", "draft_id_v"
2200 );
2201 END IF;
2202 RETURN NULL;
2203 END;
2204 $$;
2206 CREATE TRIGGER "write_event_initiative_revoked"
2207 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2208 "write_event_initiative_revoked_trigger"();
2210 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2211 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2214 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2215 RETURNS TRIGGER
2216 LANGUAGE 'plpgsql' VOLATILE AS $$
2217 DECLARE
2218 "initiative_row" "initiative"%ROWTYPE;
2219 "issue_row" "issue"%ROWTYPE;
2220 "area_row" "area"%ROWTYPE;
2221 BEGIN
2222 SELECT * INTO "initiative_row" FROM "initiative"
2223 WHERE "id" = NEW."initiative_id" FOR SHARE;
2224 SELECT * INTO "issue_row" FROM "issue"
2225 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2226 SELECT * INTO "area_row" FROM "area"
2227 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2228 INSERT INTO "event" (
2229 "event", "member_id",
2230 "unit_id", "area_id", "policy_id", "issue_id", "state",
2231 "initiative_id", "suggestion_id"
2232 ) VALUES (
2233 'suggestion_created', NEW."author_id",
2234 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2235 "initiative_row"."issue_id", "issue_row"."state",
2236 NEW."initiative_id", NEW."id"
2237 );
2238 RETURN NULL;
2239 END;
2240 $$;
2242 CREATE TRIGGER "write_event_suggestion_created"
2243 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2244 "write_event_suggestion_created_trigger"();
2246 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2247 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2250 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2251 RETURNS TRIGGER
2252 LANGUAGE 'plpgsql' VOLATILE AS $$
2253 DECLARE
2254 "initiative_row" "initiative"%ROWTYPE;
2255 "issue_row" "issue"%ROWTYPE;
2256 "area_row" "area"%ROWTYPE;
2257 BEGIN
2258 SELECT * INTO "initiative_row" FROM "initiative"
2259 WHERE "id" = OLD."initiative_id" FOR SHARE;
2260 IF "initiative_row"."id" NOTNULL THEN
2261 SELECT * INTO "issue_row" FROM "issue"
2262 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2263 SELECT * INTO "area_row" FROM "area"
2264 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2265 INSERT INTO "event" (
2266 "event",
2267 "unit_id", "area_id", "policy_id", "issue_id", "state",
2268 "initiative_id", "suggestion_id"
2269 ) VALUES (
2270 'suggestion_deleted',
2271 "area_row"."unit_id", "issue_row"."area_id",
2272 "issue_row"."policy_id",
2273 "initiative_row"."issue_id", "issue_row"."state",
2274 OLD."initiative_id", OLD."id"
2275 );
2276 END IF;
2277 RETURN NULL;
2278 END;
2279 $$;
2281 CREATE TRIGGER "write_event_suggestion_removed"
2282 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2283 "write_event_suggestion_removed_trigger"();
2285 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2286 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2289 CREATE FUNCTION "write_event_member_trigger"()
2290 RETURNS TRIGGER
2291 LANGUAGE 'plpgsql' VOLATILE AS $$
2292 BEGIN
2293 IF TG_OP = 'INSERT' THEN
2294 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2295 INSERT INTO "event" ("event", "member_id")
2296 VALUES ('member_activated', NEW."id");
2297 END IF;
2298 IF NEW."active" THEN
2299 INSERT INTO "event" ("event", "member_id", "boolean_value")
2300 VALUES ('member_active', NEW."id", TRUE);
2301 END IF;
2302 ELSIF TG_OP = 'UPDATE' THEN
2303 IF OLD."id" != NEW."id" THEN
2304 RAISE EXCEPTION 'Cannot change member ID';
2305 END IF;
2306 IF
2307 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2308 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2309 THEN
2310 INSERT INTO "event" ("event", "member_id")
2311 VALUES ('member_activated', NEW."id");
2312 END IF;
2313 IF OLD."active" != NEW."active" THEN
2314 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2315 'member_active', NEW."id", NEW."active"
2316 );
2317 END IF;
2318 IF OLD."name" != NEW."name" THEN
2319 INSERT INTO "event" (
2320 "event", "member_id", "text_value", "old_text_value"
2321 ) VALUES (
2322 'member_name_updated', NEW."id", NEW."name", OLD."name"
2323 );
2324 END IF;
2325 IF
2326 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2327 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2328 THEN
2329 INSERT INTO "event" ("event", "member_id")
2330 VALUES ('member_deleted', NEW."id");
2331 END IF;
2332 END IF;
2333 RETURN NULL;
2334 END;
2335 $$;
2337 CREATE TRIGGER "write_event_member"
2338 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2339 "write_event_member_trigger"();
2341 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2342 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2345 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2346 RETURNS TRIGGER
2347 LANGUAGE 'plpgsql' VOLATILE AS $$
2348 BEGIN
2349 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2350 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2351 INSERT INTO "event" ("event", "member_id") VALUES (
2352 'member_profile_updated', OLD."member_id"
2353 );
2354 END IF;
2355 END IF;
2356 IF TG_OP = 'UPDATE' THEN
2357 IF OLD."member_id" = NEW."member_id" THEN
2358 RETURN NULL;
2359 END IF;
2360 END IF;
2361 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2362 INSERT INTO "event" ("event", "member_id") VALUES (
2363 'member_profile_updated', NEW."member_id"
2364 );
2365 END IF;
2366 RETURN NULL;
2367 END;
2368 $$;
2370 CREATE TRIGGER "write_event_member_profile_updated"
2371 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2372 FOR EACH ROW EXECUTE PROCEDURE
2373 "write_event_member_profile_updated_trigger"();
2375 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2376 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2379 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2380 RETURNS TRIGGER
2381 LANGUAGE 'plpgsql' VOLATILE AS $$
2382 BEGIN
2383 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2384 IF NOT OLD."scaled" THEN
2385 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2386 INSERT INTO "event" ("event", "member_id") VALUES (
2387 'member_image_updated', OLD."member_id"
2388 );
2389 END IF;
2390 END IF;
2391 END IF;
2392 IF TG_OP = 'UPDATE' THEN
2393 IF
2394 OLD."member_id" = NEW."member_id" AND
2395 OLD."scaled" = NEW."scaled"
2396 THEN
2397 RETURN NULL;
2398 END IF;
2399 END IF;
2400 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2401 IF NOT NEW."scaled" THEN
2402 INSERT INTO "event" ("event", "member_id") VALUES (
2403 'member_image_updated', NEW."member_id"
2404 );
2405 END IF;
2406 END IF;
2407 RETURN NULL;
2408 END;
2409 $$;
2411 CREATE TRIGGER "write_event_member_image_updated"
2412 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2413 FOR EACH ROW EXECUTE PROCEDURE
2414 "write_event_member_image_updated_trigger"();
2416 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2417 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2420 CREATE FUNCTION "write_event_interest_trigger"()
2421 RETURNS TRIGGER
2422 LANGUAGE 'plpgsql' VOLATILE AS $$
2423 DECLARE
2424 "issue_row" "issue"%ROWTYPE;
2425 "area_row" "area"%ROWTYPE;
2426 BEGIN
2427 IF TG_OP = 'UPDATE' THEN
2428 IF OLD = NEW THEN
2429 RETURN NULL;
2430 END IF;
2431 END IF;
2432 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2433 SELECT * INTO "issue_row" FROM "issue"
2434 WHERE "id" = OLD."issue_id" FOR SHARE;
2435 SELECT * INTO "area_row" FROM "area"
2436 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2437 IF "issue_row"."id" NOTNULL THEN
2438 INSERT INTO "event" (
2439 "event", "member_id",
2440 "unit_id", "area_id", "policy_id", "issue_id", "state",
2441 "boolean_value"
2442 ) VALUES (
2443 'interest', OLD."member_id",
2444 "area_row"."unit_id", "issue_row"."area_id",
2445 "issue_row"."policy_id",
2446 OLD."issue_id", "issue_row"."state",
2447 FALSE
2448 );
2449 END IF;
2450 END IF;
2451 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2452 SELECT * INTO "issue_row" FROM "issue"
2453 WHERE "id" = NEW."issue_id" FOR SHARE;
2454 SELECT * INTO "area_row" FROM "area"
2455 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2456 INSERT INTO "event" (
2457 "event", "member_id",
2458 "unit_id", "area_id", "policy_id", "issue_id", "state",
2459 "boolean_value"
2460 ) VALUES (
2461 'interest', NEW."member_id",
2462 "area_row"."unit_id", "issue_row"."area_id",
2463 "issue_row"."policy_id",
2464 NEW."issue_id", "issue_row"."state",
2465 TRUE
2466 );
2467 END IF;
2468 RETURN NULL;
2469 END;
2470 $$;
2472 CREATE TRIGGER "write_event_interest"
2473 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2474 "write_event_interest_trigger"();
2476 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2477 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2480 CREATE FUNCTION "write_event_initiator_trigger"()
2481 RETURNS TRIGGER
2482 LANGUAGE 'plpgsql' VOLATILE AS $$
2483 DECLARE
2484 "initiative_row" "initiative"%ROWTYPE;
2485 "issue_row" "issue"%ROWTYPE;
2486 "area_row" "area"%ROWTYPE;
2487 "accepted_v" BOOLEAN = FALSE;
2488 "rejected_v" BOOLEAN = FALSE;
2489 BEGIN
2490 IF TG_OP = 'UPDATE' THEN
2491 IF
2492 OLD."initiative_id" = NEW."initiative_id" AND
2493 OLD."member_id" = NEW."member_id"
2494 THEN
2495 IF
2496 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2497 THEN
2498 RETURN NULL;
2499 END IF;
2500 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2501 "accepted_v" := TRUE;
2502 ELSE
2503 "rejected_v" := TRUE;
2504 END IF;
2505 END IF;
2506 END IF;
2507 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2508 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2509 SELECT * INTO "initiative_row" FROM "initiative"
2510 WHERE "id" = OLD."initiative_id" FOR SHARE;
2511 IF "initiative_row"."id" NOTNULL THEN
2512 SELECT * INTO "issue_row" FROM "issue"
2513 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2514 SELECT * INTO "area_row" FROM "area"
2515 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2516 INSERT INTO "event" (
2517 "event", "member_id",
2518 "unit_id", "area_id", "policy_id", "issue_id", "state",
2519 "initiative_id", "boolean_value"
2520 ) VALUES (
2521 'initiator', OLD."member_id",
2522 "area_row"."unit_id", "issue_row"."area_id",
2523 "issue_row"."policy_id",
2524 "issue_row"."id", "issue_row"."state",
2525 OLD."initiative_id", FALSE
2526 );
2527 END IF;
2528 END IF;
2529 END IF;
2530 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2531 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2532 SELECT * INTO "initiative_row" FROM "initiative"
2533 WHERE "id" = NEW."initiative_id" FOR SHARE;
2534 SELECT * INTO "issue_row" FROM "issue"
2535 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2536 SELECT * INTO "area_row" FROM "area"
2537 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2538 INSERT INTO "event" (
2539 "event", "member_id",
2540 "unit_id", "area_id", "policy_id", "issue_id", "state",
2541 "initiative_id", "boolean_value"
2542 ) VALUES (
2543 'initiator', NEW."member_id",
2544 "area_row"."unit_id", "issue_row"."area_id",
2545 "issue_row"."policy_id",
2546 "issue_row"."id", "issue_row"."state",
2547 NEW."initiative_id", TRUE
2548 );
2549 END IF;
2550 END IF;
2551 RETURN NULL;
2552 END;
2553 $$;
2555 CREATE TRIGGER "write_event_initiator"
2556 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2557 "write_event_initiator_trigger"();
2559 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2560 COMMENT ON TRIGGER "write_event_initiator" ON "initiator" IS 'Create entry in "event" table when accepting or removing initiatorship (NOTE: trigger does not fire on INSERT to avoid events on initiative creation)';
2563 CREATE FUNCTION "write_event_support_trigger"()
2564 RETURNS TRIGGER
2565 LANGUAGE 'plpgsql' VOLATILE AS $$
2566 DECLARE
2567 "issue_row" "issue"%ROWTYPE;
2568 "area_row" "area"%ROWTYPE;
2569 BEGIN
2570 IF TG_OP = 'UPDATE' THEN
2571 IF
2572 OLD."initiative_id" = NEW."initiative_id" AND
2573 OLD."member_id" = NEW."member_id"
2574 THEN
2575 IF OLD."draft_id" != NEW."draft_id" THEN
2576 SELECT * INTO "issue_row" FROM "issue"
2577 WHERE "id" = NEW."issue_id" FOR SHARE;
2578 SELECT * INTO "area_row" FROM "area"
2579 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2580 INSERT INTO "event" (
2581 "event", "member_id",
2582 "unit_id", "area_id", "policy_id", "issue_id", "state",
2583 "initiative_id", "draft_id"
2584 ) VALUES (
2585 'support_updated', NEW."member_id",
2586 "area_row"."unit_id", "issue_row"."area_id",
2587 "issue_row"."policy_id",
2588 "issue_row"."id", "issue_row"."state",
2589 NEW."initiative_id", NEW."draft_id"
2590 );
2591 END IF;
2592 RETURN NULL;
2593 END IF;
2594 END IF;
2595 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2596 IF EXISTS (
2597 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2598 FOR SHARE
2599 ) THEN
2600 SELECT * INTO "issue_row" FROM "issue"
2601 WHERE "id" = OLD."issue_id" FOR SHARE;
2602 SELECT * INTO "area_row" FROM "area"
2603 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2604 INSERT INTO "event" (
2605 "event", "member_id",
2606 "unit_id", "area_id", "policy_id", "issue_id", "state",
2607 "initiative_id", "boolean_value"
2608 ) VALUES (
2609 'support', OLD."member_id",
2610 "area_row"."unit_id", "issue_row"."area_id",
2611 "issue_row"."policy_id",
2612 "issue_row"."id", "issue_row"."state",
2613 OLD."initiative_id", FALSE
2614 );
2615 END IF;
2616 END IF;
2617 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2618 SELECT * INTO "issue_row" FROM "issue"
2619 WHERE "id" = NEW."issue_id" FOR SHARE;
2620 SELECT * INTO "area_row" FROM "area"
2621 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2622 INSERT INTO "event" (
2623 "event", "member_id",
2624 "unit_id", "area_id", "policy_id", "issue_id", "state",
2625 "initiative_id", "draft_id", "boolean_value"
2626 ) VALUES (
2627 'support', NEW."member_id",
2628 "area_row"."unit_id", "issue_row"."area_id",
2629 "issue_row"."policy_id",
2630 "issue_row"."id", "issue_row"."state",
2631 NEW."initiative_id", NEW."draft_id", TRUE
2632 );
2633 END IF;
2634 RETURN NULL;
2635 END;
2636 $$;
2638 CREATE TRIGGER "write_event_support"
2639 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2640 "write_event_support_trigger"();
2642 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2643 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2646 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2647 RETURNS TRIGGER
2648 LANGUAGE 'plpgsql' VOLATILE AS $$
2649 DECLARE
2650 "same_pkey_v" BOOLEAN = FALSE;
2651 "initiative_row" "initiative"%ROWTYPE;
2652 "issue_row" "issue"%ROWTYPE;
2653 "area_row" "area"%ROWTYPE;
2654 BEGIN
2655 IF TG_OP = 'UPDATE' THEN
2656 IF
2657 OLD."suggestion_id" = NEW."suggestion_id" AND
2658 OLD."member_id" = NEW."member_id"
2659 THEN
2660 IF
2661 OLD."degree" = NEW."degree" AND
2662 OLD."fulfilled" = NEW."fulfilled"
2663 THEN
2664 RETURN NULL;
2665 END IF;
2666 "same_pkey_v" := TRUE;
2667 END IF;
2668 END IF;
2669 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2670 IF EXISTS (
2671 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2672 FOR SHARE
2673 ) THEN
2674 SELECT * INTO "initiative_row" FROM "initiative"
2675 WHERE "id" = OLD."initiative_id" FOR SHARE;
2676 SELECT * INTO "issue_row" FROM "issue"
2677 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2678 SELECT * INTO "area_row" FROM "area"
2679 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2680 INSERT INTO "event" (
2681 "event", "member_id",
2682 "unit_id", "area_id", "policy_id", "issue_id", "state",
2683 "initiative_id", "suggestion_id",
2684 "boolean_value", "numeric_value"
2685 ) VALUES (
2686 'suggestion_rated', OLD."member_id",
2687 "area_row"."unit_id", "issue_row"."area_id",
2688 "issue_row"."policy_id",
2689 "initiative_row"."issue_id", "issue_row"."state",
2690 OLD."initiative_id", OLD."suggestion_id",
2691 NULL, 0
2692 );
2693 END IF;
2694 END IF;
2695 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2696 SELECT * INTO "initiative_row" FROM "initiative"
2697 WHERE "id" = NEW."initiative_id" FOR SHARE;
2698 SELECT * INTO "issue_row" FROM "issue"
2699 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2700 SELECT * INTO "area_row" FROM "area"
2701 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2702 INSERT INTO "event" (
2703 "event", "member_id",
2704 "unit_id", "area_id", "policy_id", "issue_id", "state",
2705 "initiative_id", "suggestion_id",
2706 "boolean_value", "numeric_value"
2707 ) VALUES (
2708 'suggestion_rated', NEW."member_id",
2709 "area_row"."unit_id", "issue_row"."area_id",
2710 "issue_row"."policy_id",
2711 "initiative_row"."issue_id", "issue_row"."state",
2712 NEW."initiative_id", NEW."suggestion_id",
2713 NEW."fulfilled", NEW."degree"
2714 );
2715 END IF;
2716 RETURN NULL;
2717 END;
2718 $$;
2720 CREATE TRIGGER "write_event_suggestion_rated"
2721 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2722 "write_event_suggestion_rated_trigger"();
2724 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2725 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2728 CREATE FUNCTION "write_event_delegation_trigger"()
2729 RETURNS TRIGGER
2730 LANGUAGE 'plpgsql' VOLATILE AS $$
2731 DECLARE
2732 "issue_row" "issue"%ROWTYPE;
2733 "area_row" "area"%ROWTYPE;
2734 BEGIN
2735 IF TG_OP = 'DELETE' THEN
2736 IF EXISTS (
2737 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2738 ) AND (CASE OLD."scope"
2739 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2740 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2742 WHEN 'area'::"delegation_scope" THEN EXISTS (
2743 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2745 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2746 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2748 END) THEN
2749 SELECT * INTO "issue_row" FROM "issue"
2750 WHERE "id" = OLD."issue_id" FOR SHARE;
2751 SELECT * INTO "area_row" FROM "area"
2752 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2753 FOR SHARE;
2754 INSERT INTO "event" (
2755 "event", "member_id", "scope",
2756 "unit_id", "area_id", "issue_id", "state",
2757 "boolean_value"
2758 ) VALUES (
2759 'delegation', OLD."truster_id", OLD."scope",
2760 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2761 OLD."issue_id", "issue_row"."state",
2762 FALSE
2763 );
2764 END IF;
2765 ELSE
2766 SELECT * INTO "issue_row" FROM "issue"
2767 WHERE "id" = NEW."issue_id" FOR SHARE;
2768 SELECT * INTO "area_row" FROM "area"
2769 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2770 FOR SHARE;
2771 INSERT INTO "event" (
2772 "event", "member_id", "other_member_id", "scope",
2773 "unit_id", "area_id", "issue_id", "state",
2774 "boolean_value"
2775 ) VALUES (
2776 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2777 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2778 NEW."issue_id", "issue_row"."state",
2779 TRUE
2780 );
2781 END IF;
2782 RETURN NULL;
2783 END;
2784 $$;
2786 CREATE TRIGGER "write_event_delegation"
2787 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2788 "write_event_delegation_trigger"();
2790 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2791 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2794 CREATE FUNCTION "write_event_contact_trigger"()
2795 RETURNS TRIGGER
2796 LANGUAGE 'plpgsql' VOLATILE AS $$
2797 BEGIN
2798 IF TG_OP = 'UPDATE' THEN
2799 IF
2800 OLD."member_id" = NEW."member_id" AND
2801 OLD."other_member_id" = NEW."other_member_id" AND
2802 OLD."public" = NEW."public"
2803 THEN
2804 RETURN NULL;
2805 END IF;
2806 END IF;
2807 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2808 IF OLD."public" THEN
2809 IF EXISTS (
2810 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2811 FOR SHARE
2812 ) AND EXISTS (
2813 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2814 FOR SHARE
2815 ) THEN
2816 INSERT INTO "event" (
2817 "event", "member_id", "other_member_id", "boolean_value"
2818 ) VALUES (
2819 'contact', OLD."member_id", OLD."other_member_id", FALSE
2820 );
2821 END IF;
2822 END IF;
2823 END IF;
2824 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2825 IF NEW."public" THEN
2826 INSERT INTO "event" (
2827 "event", "member_id", "other_member_id", "boolean_value"
2828 ) VALUES (
2829 'contact', NEW."member_id", NEW."other_member_id", TRUE
2830 );
2831 END IF;
2832 END IF;
2833 RETURN NULL;
2834 END;
2835 $$;
2837 CREATE TRIGGER "write_event_contact"
2838 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2839 "write_event_contact_trigger"();
2841 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2842 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2845 CREATE FUNCTION "write_event_posting_trigger"()
2846 RETURNS TRIGGER
2847 LANGUAGE 'plpgsql' VOLATILE AS $$
2848 BEGIN
2849 INSERT INTO "event" (
2850 "event", "posting_id", "member_id",
2851 "unit_id", "area_id", "policy_id",
2852 "issue_id", "initiative_id", "suggestion_id"
2853 ) VALUES (
2854 'posting_created', NEW."id", NEW."author_id",
2855 NEW."unit_id", NEW."area_id", NEW."policy_id",
2856 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
2857 );
2858 RETURN NULL;
2859 END;
2860 $$;
2862 CREATE TRIGGER "write_event_posting"
2863 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
2864 "write_event_posting_trigger"();
2866 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
2867 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
2870 CREATE FUNCTION "send_event_notify_trigger"()
2871 RETURNS TRIGGER
2872 LANGUAGE 'plpgsql' VOLATILE AS $$
2873 BEGIN
2874 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2875 RETURN NULL;
2876 END;
2877 $$;
2879 CREATE TRIGGER "send_notify"
2880 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2881 "send_event_notify_trigger"();
2885 ----------------------------
2886 -- Additional constraints --
2887 ----------------------------
2890 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2891 RETURNS TRIGGER
2892 LANGUAGE 'plpgsql' VOLATILE AS $$
2893 DECLARE
2894 "system_application_row" "system_application"%ROWTYPE;
2895 BEGIN
2896 IF OLD."system_application_id" NOTNULL THEN
2897 SELECT * FROM "system_application" INTO "system_application_row"
2898 WHERE "id" = OLD."system_application_id";
2899 DELETE FROM "token"
2900 WHERE "member_id" = OLD."member_id"
2901 AND "system_application_id" = OLD."system_application_id"
2902 AND NOT COALESCE(
2903 regexp_split_to_array("scope", E'\\s+') <@
2904 regexp_split_to_array(
2905 "system_application_row"."automatic_scope", E'\\s+'
2906 ),
2907 FALSE
2908 );
2909 END IF;
2910 RETURN OLD;
2911 END;
2912 $$;
2914 CREATE TRIGGER "delete_extended_scope_tokens"
2915 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2916 "delete_extended_scope_tokens_trigger"();
2919 CREATE FUNCTION "detach_token_from_session_trigger"()
2920 RETURNS TRIGGER
2921 LANGUAGE 'plpgsql' VOLATILE AS $$
2922 BEGIN
2923 UPDATE "token" SET "session_id" = NULL
2924 WHERE "session_id" = OLD."id";
2925 RETURN OLD;
2926 END;
2927 $$;
2929 CREATE TRIGGER "detach_token_from_session"
2930 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2931 "detach_token_from_session_trigger"();
2934 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2935 RETURNS TRIGGER
2936 LANGUAGE 'plpgsql' VOLATILE AS $$
2937 BEGIN
2938 IF NEW."session_id" ISNULL THEN
2939 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2940 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2941 WHERE "element" LIKE '%_detached';
2942 END IF;
2943 RETURN NEW;
2944 END;
2945 $$;
2947 CREATE TRIGGER "delete_non_detached_scope_with_session"
2948 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2949 "delete_non_detached_scope_with_session_trigger"();
2952 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2953 RETURNS TRIGGER
2954 LANGUAGE 'plpgsql' VOLATILE AS $$
2955 BEGIN
2956 IF NEW."scope" = '' THEN
2957 DELETE FROM "token" WHERE "id" = NEW."id";
2958 END IF;
2959 RETURN NULL;
2960 END;
2961 $$;
2963 CREATE TRIGGER "delete_token_with_empty_scope"
2964 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2965 "delete_token_with_empty_scope_trigger"();
2968 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2969 RETURNS TRIGGER
2970 LANGUAGE 'plpgsql' VOLATILE AS $$
2971 BEGIN
2972 IF NOT EXISTS (
2973 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2974 ) THEN
2975 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2976 ERRCODE = 'integrity_constraint_violation',
2977 HINT = 'Create issue, initiative, and draft within the same transaction.';
2978 END IF;
2979 RETURN NULL;
2980 END;
2981 $$;
2983 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2984 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2985 FOR EACH ROW EXECUTE PROCEDURE
2986 "issue_requires_first_initiative_trigger"();
2988 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2989 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2992 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2993 RETURNS TRIGGER
2994 LANGUAGE 'plpgsql' VOLATILE AS $$
2995 DECLARE
2996 "reference_lost" BOOLEAN;
2997 BEGIN
2998 IF TG_OP = 'DELETE' THEN
2999 "reference_lost" := TRUE;
3000 ELSE
3001 "reference_lost" := NEW."issue_id" != OLD."issue_id";
3002 END IF;
3003 IF
3004 "reference_lost" AND NOT EXISTS (
3005 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
3007 THEN
3008 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
3009 END IF;
3010 RETURN NULL;
3011 END;
3012 $$;
3014 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
3015 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
3016 FOR EACH ROW EXECUTE PROCEDURE
3017 "last_initiative_deletes_issue_trigger"();
3019 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
3020 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
3023 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
3024 RETURNS TRIGGER
3025 LANGUAGE 'plpgsql' VOLATILE AS $$
3026 BEGIN
3027 IF NOT EXISTS (
3028 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
3029 ) THEN
3030 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
3031 ERRCODE = 'integrity_constraint_violation',
3032 HINT = 'Create issue, initiative and draft within the same transaction.';
3033 END IF;
3034 RETURN NULL;
3035 END;
3036 $$;
3038 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
3039 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
3040 FOR EACH ROW EXECUTE PROCEDURE
3041 "initiative_requires_first_draft_trigger"();
3043 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
3044 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
3047 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
3048 RETURNS TRIGGER
3049 LANGUAGE 'plpgsql' VOLATILE AS $$
3050 DECLARE
3051 "reference_lost" BOOLEAN;
3052 BEGIN
3053 IF TG_OP = 'DELETE' THEN
3054 "reference_lost" := TRUE;
3055 ELSE
3056 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
3057 END IF;
3058 IF
3059 "reference_lost" AND NOT EXISTS (
3060 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
3062 THEN
3063 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
3064 END IF;
3065 RETURN NULL;
3066 END;
3067 $$;
3069 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
3070 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
3071 FOR EACH ROW EXECUTE PROCEDURE
3072 "last_draft_deletes_initiative_trigger"();
3074 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
3075 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
3078 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
3079 RETURNS TRIGGER
3080 LANGUAGE 'plpgsql' VOLATILE AS $$
3081 BEGIN
3082 IF NOT EXISTS (
3083 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
3084 ) THEN
3085 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
3086 ERRCODE = 'integrity_constraint_violation',
3087 HINT = 'Create suggestion and opinion within the same transaction.';
3088 END IF;
3089 RETURN NULL;
3090 END;
3091 $$;
3093 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
3094 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
3095 FOR EACH ROW EXECUTE PROCEDURE
3096 "suggestion_requires_first_opinion_trigger"();
3098 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
3099 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
3102 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
3103 RETURNS TRIGGER
3104 LANGUAGE 'plpgsql' VOLATILE AS $$
3105 DECLARE
3106 "reference_lost" BOOLEAN;
3107 BEGIN
3108 IF TG_OP = 'DELETE' THEN
3109 "reference_lost" := TRUE;
3110 ELSE
3111 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
3112 END IF;
3113 IF
3114 "reference_lost" AND NOT EXISTS (
3115 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
3117 THEN
3118 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
3119 END IF;
3120 RETURN NULL;
3121 END;
3122 $$;
3124 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
3125 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
3126 FOR EACH ROW EXECUTE PROCEDURE
3127 "last_opinion_deletes_suggestion_trigger"();
3129 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
3130 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
3133 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
3134 RETURNS TRIGGER
3135 LANGUAGE 'plpgsql' VOLATILE AS $$
3136 BEGIN
3137 DELETE FROM "direct_voter"
3138 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3139 RETURN NULL;
3140 END;
3141 $$;
3143 CREATE TRIGGER "non_voter_deletes_direct_voter"
3144 AFTER INSERT OR UPDATE ON "non_voter"
3145 FOR EACH ROW EXECUTE PROCEDURE
3146 "non_voter_deletes_direct_voter_trigger"();
3148 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
3149 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
3152 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
3153 RETURNS TRIGGER
3154 LANGUAGE 'plpgsql' VOLATILE AS $$
3155 BEGIN
3156 DELETE FROM "non_voter"
3157 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3158 RETURN NULL;
3159 END;
3160 $$;
3162 CREATE TRIGGER "direct_voter_deletes_non_voter"
3163 AFTER INSERT OR UPDATE ON "direct_voter"
3164 FOR EACH ROW EXECUTE PROCEDURE
3165 "direct_voter_deletes_non_voter_trigger"();
3167 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
3168 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
3171 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
3172 RETURNS TRIGGER
3173 LANGUAGE 'plpgsql' VOLATILE AS $$
3174 BEGIN
3175 IF NEW."comment" ISNULL THEN
3176 NEW."comment_changed" := NULL;
3177 NEW."formatting_engine" := NULL;
3178 END IF;
3179 RETURN NEW;
3180 END;
3181 $$;
3183 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
3184 BEFORE INSERT OR UPDATE ON "direct_voter"
3185 FOR EACH ROW EXECUTE PROCEDURE
3186 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
3188 COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"';
3189 COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.';
3192 CREATE FUNCTION "file_requires_reference_trigger"()
3193 RETURNS TRIGGER
3194 LANGUAGE 'plpgsql' VOLATILE AS $$
3195 BEGIN
3196 IF NOT EXISTS (
3197 SELECT NULL FROM "draft_attachment" WHERE "file_id" = NEW."id"
3198 ) THEN
3199 RAISE EXCEPTION 'Cannot create an unreferenced file.' USING
3200 ERRCODE = 'integrity_constraint_violation',
3201 HINT = 'Create file and its reference in another table within the same transaction.';
3202 END IF;
3203 RETURN NULL;
3204 END;
3205 $$;
3207 CREATE CONSTRAINT TRIGGER "file_requires_reference"
3208 AFTER INSERT OR UPDATE ON "file" DEFERRABLE INITIALLY DEFERRED
3209 FOR EACH ROW EXECUTE PROCEDURE
3210 "file_requires_reference_trigger"();
3212 COMMENT ON FUNCTION "file_requires_reference_trigger"() IS 'Implementation of trigger "file_requires_reference" on table "file"';
3213 COMMENT ON TRIGGER "file_requires_reference" ON "file" IS 'Ensure that files are always referenced';
3216 CREATE FUNCTION "last_reference_deletes_file_trigger"()
3217 RETURNS TRIGGER
3218 LANGUAGE 'plpgsql' VOLATILE AS $$
3219 DECLARE
3220 "reference_lost" BOOLEAN;
3221 BEGIN
3222 IF TG_OP = 'DELETE' THEN
3223 "reference_lost" := TRUE;
3224 ELSE
3225 "reference_lost" := NEW."file_id" != OLD."file_id";
3226 END IF;
3227 IF
3228 "reference_lost" AND NOT EXISTS (
3229 SELECT NULL FROM "draft_attachment" WHERE "file_id" = OLD."file_id"
3231 THEN
3232 DELETE FROM "file" WHERE "id" = OLD."file_id";
3233 END IF;
3234 RETURN NULL;
3235 END;
3236 $$;
3238 CREATE CONSTRAINT TRIGGER "last_reference_deletes_file"
3239 AFTER UPDATE OR DELETE ON "draft_attachment" DEFERRABLE INITIALLY DEFERRED
3240 FOR EACH ROW EXECUTE PROCEDURE
3241 "last_reference_deletes_file_trigger"();
3243 COMMENT ON FUNCTION "last_reference_deletes_file_trigger"() IS 'Implementation of trigger "last_reference_deletes_file" on table "draft_attachment"';
3244 COMMENT ON TRIGGER "last_reference_deletes_file" ON "draft_attachment" IS 'Removing the last reference to a file deletes the file';
3248 ---------------------------------
3249 -- Delete incomplete snapshots --
3250 ---------------------------------
3253 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
3254 RETURNS TRIGGER
3255 LANGUAGE 'plpgsql' VOLATILE AS $$
3256 BEGIN
3257 IF TG_OP = 'UPDATE' THEN
3258 IF
3259 OLD."snapshot_id" = NEW."snapshot_id" AND
3260 OLD."issue_id" = NEW."issue_id"
3261 THEN
3262 RETURN NULL;
3263 END IF;
3264 END IF;
3265 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3266 RETURN NULL;
3267 END;
3268 $$;
3270 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3271 AFTER UPDATE OR DELETE ON "snapshot_issue"
3272 FOR EACH ROW EXECUTE PROCEDURE
3273 "delete_snapshot_on_partial_delete_trigger"();
3275 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3276 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3280 ---------------------------------------------------------------
3281 -- Ensure that votes are not modified when issues are closed --
3282 ---------------------------------------------------------------
3284 -- NOTE: Frontends should ensure this anyway, but in case of programming
3285 -- errors the following triggers ensure data integrity.
3288 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3289 RETURNS TRIGGER
3290 LANGUAGE 'plpgsql' VOLATILE AS $$
3291 DECLARE
3292 "issue_id_v" "issue"."id"%TYPE;
3293 "issue_row" "issue"%ROWTYPE;
3294 BEGIN
3295 IF EXISTS (
3296 SELECT NULL FROM "temporary_transaction_data"
3297 WHERE "txid" = txid_current()
3298 AND "key" = 'override_protection_triggers'
3299 AND "value" = TRUE::TEXT
3300 ) THEN
3301 RETURN NULL;
3302 END IF;
3303 IF TG_OP = 'DELETE' THEN
3304 "issue_id_v" := OLD."issue_id";
3305 ELSE
3306 "issue_id_v" := NEW."issue_id";
3307 END IF;
3308 SELECT INTO "issue_row" * FROM "issue"
3309 WHERE "id" = "issue_id_v" FOR SHARE;
3310 IF (
3311 "issue_row"."closed" NOTNULL OR (
3312 "issue_row"."state" = 'voting' AND
3313 "issue_row"."phase_finished" NOTNULL
3315 ) THEN
3316 IF
3317 TG_RELID = 'direct_voter'::regclass AND
3318 TG_OP = 'UPDATE'
3319 THEN
3320 IF
3321 OLD."issue_id" = NEW."issue_id" AND
3322 OLD."member_id" = NEW."member_id" AND
3323 OLD."weight" = NEW."weight"
3324 THEN
3325 RETURN NULL; -- allows changing of voter comment
3326 END IF;
3327 END IF;
3328 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3329 ERRCODE = 'integrity_constraint_violation';
3330 END IF;
3331 RETURN NULL;
3332 END;
3333 $$;
3335 CREATE TRIGGER "forbid_changes_on_closed_issue"
3336 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3337 FOR EACH ROW EXECUTE PROCEDURE
3338 "forbid_changes_on_closed_issue_trigger"();
3340 CREATE TRIGGER "forbid_changes_on_closed_issue"
3341 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3342 FOR EACH ROW EXECUTE PROCEDURE
3343 "forbid_changes_on_closed_issue_trigger"();
3345 CREATE TRIGGER "forbid_changes_on_closed_issue"
3346 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3347 FOR EACH ROW EXECUTE PROCEDURE
3348 "forbid_changes_on_closed_issue_trigger"();
3350 COMMENT ON FUNCTION "forbid_changes_on_closed_issue_trigger"() IS 'Implementation of triggers "forbid_changes_on_closed_issue" on tables "direct_voter", "delegating_voter" and "vote"';
3351 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "direct_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
3352 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "delegating_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
3353 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "vote" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
3357 --------------------------------------------------------------------
3358 -- Auto-retrieval of fields only needed for referential integrity --
3359 --------------------------------------------------------------------
3362 CREATE FUNCTION "autofill_issue_id_trigger"()
3363 RETURNS TRIGGER
3364 LANGUAGE 'plpgsql' VOLATILE AS $$
3365 BEGIN
3366 IF NEW."issue_id" ISNULL THEN
3367 SELECT "issue_id" INTO NEW."issue_id"
3368 FROM "initiative" WHERE "id" = NEW."initiative_id";
3369 END IF;
3370 RETURN NEW;
3371 END;
3372 $$;
3374 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3375 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3377 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3378 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3380 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3381 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3382 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3385 CREATE FUNCTION "autofill_initiative_id_trigger"()
3386 RETURNS TRIGGER
3387 LANGUAGE 'plpgsql' VOLATILE AS $$
3388 BEGIN
3389 IF NEW."initiative_id" ISNULL THEN
3390 SELECT "initiative_id" INTO NEW."initiative_id"
3391 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3392 END IF;
3393 RETURN NEW;
3394 END;
3395 $$;
3397 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3398 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3400 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3401 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3405 -------------------------------------------------------
3406 -- Automatic copying of values for indexing purposes --
3407 -------------------------------------------------------
3410 CREATE FUNCTION "copy_current_draft_data"
3411 ("initiative_id_p" "initiative"."id"%TYPE )
3412 RETURNS VOID
3413 LANGUAGE 'plpgsql' VOLATILE AS $$
3414 BEGIN
3415 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3416 FOR UPDATE;
3417 UPDATE "initiative" SET
3418 "location" = "draft"."location",
3419 "content" = "draft"."content"
3420 FROM "current_draft" AS "draft"
3421 WHERE "initiative"."id" = "initiative_id_p"
3422 AND "draft"."initiative_id" = "initiative_id_p";
3423 END;
3424 $$;
3426 COMMENT ON FUNCTION "copy_current_draft_data"
3427 ( "initiative"."id"%TYPE )
3428 IS 'Helper function for function "copy_current_draft_data_trigger"';
3431 CREATE FUNCTION "copy_current_draft_data_trigger"()
3432 RETURNS TRIGGER
3433 LANGUAGE 'plpgsql' VOLATILE AS $$
3434 BEGIN
3435 IF TG_OP='DELETE' THEN
3436 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3437 ELSE
3438 IF TG_OP='UPDATE' THEN
3439 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3440 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3441 END IF;
3442 END IF;
3443 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3444 END IF;
3445 RETURN NULL;
3446 END;
3447 $$;
3449 CREATE TRIGGER "copy_current_draft_data"
3450 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3451 FOR EACH ROW EXECUTE PROCEDURE
3452 "copy_current_draft_data_trigger"();
3454 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3455 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3459 -----------------------------------------------------
3460 -- Automatic calculation of certain default values --
3461 -----------------------------------------------------
3464 CREATE FUNCTION "copy_timings_trigger"()
3465 RETURNS TRIGGER
3466 LANGUAGE 'plpgsql' VOLATILE AS $$
3467 DECLARE
3468 "policy_row" "policy"%ROWTYPE;
3469 BEGIN
3470 SELECT * INTO "policy_row" FROM "policy"
3471 WHERE "id" = NEW."policy_id";
3472 IF NEW."min_admission_time" ISNULL THEN
3473 NEW."min_admission_time" := "policy_row"."min_admission_time";
3474 END IF;
3475 IF NEW."max_admission_time" ISNULL THEN
3476 NEW."max_admission_time" := "policy_row"."max_admission_time";
3477 END IF;
3478 IF NEW."discussion_time" ISNULL THEN
3479 NEW."discussion_time" := "policy_row"."discussion_time";
3480 END IF;
3481 IF NEW."verification_time" ISNULL THEN
3482 NEW."verification_time" := "policy_row"."verification_time";
3483 END IF;
3484 IF NEW."voting_time" ISNULL THEN
3485 NEW."voting_time" := "policy_row"."voting_time";
3486 END IF;
3487 RETURN NEW;
3488 END;
3489 $$;
3491 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3492 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3494 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3495 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3498 CREATE FUNCTION "default_for_draft_id_trigger"()
3499 RETURNS TRIGGER
3500 LANGUAGE 'plpgsql' VOLATILE AS $$
3501 BEGIN
3502 IF NEW."draft_id" ISNULL THEN
3503 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3504 WHERE "initiative_id" = NEW."initiative_id";
3505 END IF;
3506 RETURN NEW;
3507 END;
3508 $$;
3510 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3511 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3512 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3513 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3515 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3516 COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
3517 COMMENT ON TRIGGER "default_for_draft_id" ON "supporter" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
3521 ----------------------------------------
3522 -- Automatic creation of dependencies --
3523 ----------------------------------------
3526 CREATE FUNCTION "autocreate_interest_trigger"()
3527 RETURNS TRIGGER
3528 LANGUAGE 'plpgsql' VOLATILE AS $$
3529 BEGIN
3530 IF NOT EXISTS (
3531 SELECT NULL FROM "initiative" JOIN "interest"
3532 ON "initiative"."issue_id" = "interest"."issue_id"
3533 WHERE "initiative"."id" = NEW."initiative_id"
3534 AND "interest"."member_id" = NEW."member_id"
3535 ) THEN
3536 BEGIN
3537 INSERT INTO "interest" ("issue_id", "member_id")
3538 SELECT "issue_id", NEW."member_id"
3539 FROM "initiative" WHERE "id" = NEW."initiative_id";
3540 EXCEPTION WHEN unique_violation THEN END;
3541 END IF;
3542 RETURN NEW;
3543 END;
3544 $$;
3546 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3547 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3549 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3550 COMMENT ON TRIGGER "autocreate_interest" ON "supporter" IS 'Supporting an initiative implies interest in the issue, thus automatically creates an entry in the "interest" table';
3553 CREATE FUNCTION "autocreate_supporter_trigger"()
3554 RETURNS TRIGGER
3555 LANGUAGE 'plpgsql' VOLATILE AS $$
3556 BEGIN
3557 IF NOT EXISTS (
3558 SELECT NULL FROM "suggestion" JOIN "supporter"
3559 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3560 WHERE "suggestion"."id" = NEW."suggestion_id"
3561 AND "supporter"."member_id" = NEW."member_id"
3562 ) THEN
3563 BEGIN
3564 INSERT INTO "supporter" ("initiative_id", "member_id")
3565 SELECT "initiative_id", NEW."member_id"
3566 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3567 EXCEPTION WHEN unique_violation THEN END;
3568 END IF;
3569 RETURN NEW;
3570 END;
3571 $$;
3573 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3574 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3576 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3577 COMMENT ON TRIGGER "autocreate_supporter" ON "opinion" IS 'Opinions can only be added for supported initiatives. This trigger automatrically creates an entry in the "supporter" table, if not existent yet.';
3581 ------------------------------------------
3582 -- Views and helper functions for views --
3583 ------------------------------------------
3586 CREATE VIEW "member_eligible_to_be_notified" AS
3587 SELECT * FROM "member"
3588 WHERE "activated" NOTNULL AND "locked" = FALSE;
3590 COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")';
3593 CREATE VIEW "member_to_notify" AS
3594 SELECT * FROM "member_eligible_to_be_notified"
3595 WHERE "disable_notifications" = FALSE;
3597 COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)';
3600 CREATE VIEW "follower" AS
3601 SELECT
3602 "id" AS "follower_id",
3603 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
3604 FROM "contact"
3605 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
3606 AS "following_ids"
3607 FROM "member";
3609 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
3612 CREATE VIEW "area_quorum" AS
3613 SELECT
3614 "area"."id" AS "area_id",
3615 ceil(
3616 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3617 coalesce(
3618 ( SELECT sum(
3619 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3620 extract(epoch from
3621 ("issue"."accepted"-"issue"."created") +
3622 "issue"."discussion_time" +
3623 "issue"."verification_time" +
3624 "issue"."voting_time"
3625 )::FLOAT8
3626 ) ^ "area"."quorum_exponent"::FLOAT8
3628 FROM "issue" JOIN "policy"
3629 ON "issue"."policy_id" = "policy"."id"
3630 WHERE "issue"."area_id" = "area"."id"
3631 AND "issue"."accepted" NOTNULL
3632 AND "issue"."closed" ISNULL
3633 AND "policy"."polling" = FALSE
3634 )::FLOAT8, 0::FLOAT8
3635 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3636 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3637 SELECT "snapshot"."population"
3638 FROM "snapshot"
3639 WHERE "snapshot"."area_id" = "area"."id"
3640 AND "snapshot"."issue_id" ISNULL
3641 ORDER BY "snapshot"."id" DESC
3642 LIMIT 1
3643 ) END / coalesce("area"."quorum_den", 1)
3645 )::INT4 AS "issue_quorum"
3646 FROM "area";
3648 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3651 CREATE VIEW "issue_quorum" AS
3652 SELECT DISTINCT ON ("issue_id")
3653 "issue"."id" AS "issue_id",
3654 "subquery"."issue_quorum"
3655 FROM "issue"
3656 CROSS JOIN LATERAL (
3657 SELECT "area_quorum"."issue_quorum"
3658 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3659 UNION ALL
3660 SELECT "policy"."issue_quorum"
3661 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3662 UNION ALL
3663 SELECT
3664 ceil(
3665 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3666 "policy"."issue_quorum_den"::FLOAT8
3667 )::INT4
3668 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3669 ) AS "subquery"
3670 ORDER BY "issue_id", "issue_quorum" DESC;
3672 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3675 CREATE VIEW "area_with_unaccepted_issues" AS
3676 SELECT DISTINCT ON ("area"."id") "area".*
3677 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3678 WHERE "issue"."state" = 'admission';
3680 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3683 CREATE VIEW "issue_for_admission" AS
3684 SELECT DISTINCT ON ("issue"."area_id")
3685 "issue".*,
3686 max("initiative"."supporter_count") AS "max_supporter_count"
3687 FROM "issue"
3688 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3689 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3690 JOIN "area" ON "issue"."area_id" = "area"."id"
3691 WHERE "issue"."state" = 'admission'::"issue_state"
3692 AND now() >= "issue"."created" + "issue"."min_admission_time"
3693 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3694 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3695 "issue"."population" * "policy"."issue_quorum_num"
3696 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3697 AND "initiative"."revoked" ISNULL
3698 GROUP BY "issue"."id"
3699 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3701 COMMENT ON VIEW "issue_for_admission" IS 'Contains up to 1 issue per area eligible to pass from ''admission'' to ''discussion'' state; needs to be recalculated after admitting the issue in this view';
3704 CREATE VIEW "unit_delegation" AS
3705 SELECT
3706 "unit"."id" AS "unit_id",
3707 "delegation"."id",
3708 "delegation"."truster_id",
3709 "delegation"."trustee_id",
3710 "delegation"."scope"
3711 FROM "unit"
3712 JOIN "delegation"
3713 ON "delegation"."unit_id" = "unit"."id"
3714 JOIN "member"
3715 ON "delegation"."truster_id" = "member"."id"
3716 JOIN "privilege"
3717 ON "delegation"."unit_id" = "privilege"."unit_id"
3718 AND "delegation"."truster_id" = "privilege"."member_id"
3719 WHERE "member"."active" AND "privilege"."voting_right";
3721 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3724 CREATE VIEW "area_delegation" AS
3725 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3726 "area"."id" AS "area_id",
3727 "delegation"."id",
3728 "delegation"."truster_id",
3729 "delegation"."trustee_id",
3730 "delegation"."scope"
3731 FROM "area"
3732 JOIN "delegation"
3733 ON "delegation"."unit_id" = "area"."unit_id"
3734 OR "delegation"."area_id" = "area"."id"
3735 JOIN "member"
3736 ON "delegation"."truster_id" = "member"."id"
3737 JOIN "privilege"
3738 ON "area"."unit_id" = "privilege"."unit_id"
3739 AND "delegation"."truster_id" = "privilege"."member_id"
3740 WHERE "member"."active" AND "privilege"."voting_right"
3741 ORDER BY
3742 "area"."id",
3743 "delegation"."truster_id",
3744 "delegation"."scope" DESC;
3746 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3749 CREATE VIEW "issue_delegation" AS
3750 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3751 "issue"."id" AS "issue_id",
3752 "delegation"."id",
3753 "delegation"."truster_id",
3754 "delegation"."trustee_id",
3755 COALESCE("issue_privilege"."weight", "privilege"."weight") AS "weight",
3756 "delegation"."scope"
3757 FROM "issue"
3758 JOIN "area"
3759 ON "area"."id" = "issue"."area_id"
3760 JOIN "delegation"
3761 ON "delegation"."unit_id" = "area"."unit_id"
3762 OR "delegation"."area_id" = "area"."id"
3763 OR "delegation"."issue_id" = "issue"."id"
3764 JOIN "member"
3765 ON "delegation"."truster_id" = "member"."id"
3766 LEFT JOIN "privilege"
3767 ON "area"."unit_id" = "privilege"."unit_id"
3768 AND "delegation"."truster_id" = "privilege"."member_id"
3769 LEFT JOIN "issue_privilege"
3770 ON "issue"."id" = "issue_privilege"."issue_id"
3771 AND "delegation"."truster_id" = "issue_privilege"."member_id"
3772 WHERE "member"."active"
3773 AND COALESCE("issue_privilege"."voting_right", "privilege"."voting_right")
3774 ORDER BY
3775 "issue"."id",
3776 "delegation"."truster_id",
3777 "delegation"."scope" DESC;
3779 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3782 CREATE VIEW "member_count_view" AS
3783 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3785 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3788 CREATE VIEW "unit_member" AS
3789 SELECT
3790 "privilege"."unit_id" AS "unit_id",
3791 "member"."id" AS "member_id",
3792 "privilege"."weight"
3793 FROM "privilege" JOIN "member" ON "member"."id" = "privilege"."member_id"
3794 WHERE "privilege"."voting_right" AND "member"."active";
3796 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3799 CREATE VIEW "unit_member_count" AS
3800 SELECT
3801 "unit"."id" AS "unit_id",
3802 count("unit_member"."member_id") AS "member_count",
3803 sum("unit_member"."weight") AS "member_weight"
3804 FROM "unit" LEFT JOIN "unit_member"
3805 ON "unit"."id" = "unit_member"."unit_id"
3806 GROUP BY "unit"."id";
3808 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3811 CREATE VIEW "opening_draft" AS
3812 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3813 ORDER BY "initiative_id", "id";
3815 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3818 CREATE VIEW "current_draft" AS
3819 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3820 ORDER BY "initiative_id", "id" DESC;
3822 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3825 CREATE VIEW "critical_opinion" AS
3826 SELECT * FROM "opinion"
3827 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3828 OR ("degree" = -2 AND "fulfilled" = TRUE);
3830 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3833 CREATE VIEW "issue_supporter_in_admission_state" AS
3834 SELECT
3835 "area"."unit_id",
3836 "issue"."area_id",
3837 "issue"."id" AS "issue_id",
3838 "supporter"."member_id",
3839 "direct_interest_snapshot"."weight"
3840 FROM "issue"
3841 JOIN "area" ON "area"."id" = "issue"."area_id"
3842 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3843 JOIN "direct_interest_snapshot"
3844 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3845 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3846 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3847 WHERE "issue"."state" = 'admission'::"issue_state";
3849 COMMENT ON VIEW "issue_supporter_in_admission_state" IS 'Helper view for "lf_update_issue_order" to allow a (proportional) ordering of issues within an area';
3852 CREATE VIEW "initiative_suggestion_order_calculation" AS
3853 SELECT
3854 "initiative"."id" AS "initiative_id",
3855 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3856 FROM "initiative" JOIN "issue"
3857 ON "initiative"."issue_id" = "issue"."id"
3858 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3859 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3861 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3863 COMMENT ON COLUMN "initiative_suggestion_order_calculation"."final" IS 'Set to TRUE, if the issue is fully frozen or closed, and the calculation has to be done only once for one last time';
3866 CREATE VIEW "individual_suggestion_ranking" AS
3867 SELECT
3868 "opinion"."initiative_id",
3869 "opinion"."member_id",
3870 "direct_interest_snapshot"."weight",
3871 CASE WHEN
3872 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3873 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3874 THEN 1 ELSE
3875 CASE WHEN
3876 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3877 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3878 THEN 2 ELSE
3879 CASE WHEN
3880 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3881 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3882 THEN 3 ELSE 4 END
3883 END
3884 END AS "preference",
3885 "opinion"."suggestion_id"
3886 FROM "opinion"
3887 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3888 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3889 JOIN "direct_interest_snapshot"
3890 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3891 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3892 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3894 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3897 CREATE VIEW "battle_participant" AS
3898 SELECT "initiative"."id", "initiative"."issue_id"
3899 FROM "issue" JOIN "initiative"
3900 ON "issue"."id" = "initiative"."issue_id"
3901 WHERE "initiative"."admitted"
3902 UNION ALL
3903 SELECT NULL, "id" AS "issue_id"
3904 FROM "issue";
3906 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3909 CREATE VIEW "battle_view" AS
3910 SELECT
3911 "issue"."id" AS "issue_id",
3912 "winning_initiative"."id" AS "winning_initiative_id",
3913 "losing_initiative"."id" AS "losing_initiative_id",
3914 sum(
3915 CASE WHEN
3916 coalesce("better_vote"."grade", 0) >
3917 coalesce("worse_vote"."grade", 0)
3918 THEN "direct_voter"."weight" ELSE 0 END
3919 ) AS "count"
3920 FROM "issue"
3921 LEFT JOIN "direct_voter"
3922 ON "issue"."id" = "direct_voter"."issue_id"
3923 JOIN "battle_participant" AS "winning_initiative"
3924 ON "issue"."id" = "winning_initiative"."issue_id"
3925 JOIN "battle_participant" AS "losing_initiative"
3926 ON "issue"."id" = "losing_initiative"."issue_id"
3927 LEFT JOIN "vote" AS "better_vote"
3928 ON "direct_voter"."member_id" = "better_vote"."member_id"
3929 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3930 LEFT JOIN "vote" AS "worse_vote"
3931 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3932 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3933 WHERE "issue"."state" = 'voting'
3934 AND "issue"."phase_finished" NOTNULL
3935 AND (
3936 "winning_initiative"."id" != "losing_initiative"."id" OR
3937 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3938 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3939 GROUP BY
3940 "issue"."id",
3941 "winning_initiative"."id",
3942 "losing_initiative"."id";
3944 COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative (or status-quo) to another initiative (or status-quo); Used to fill "battle" table';
3947 CREATE VIEW "expired_session" AS
3948 SELECT * FROM "session" WHERE now() > "expiry";
3950 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3951 DELETE FROM "session" WHERE "id" = OLD."id";
3953 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3954 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3957 CREATE VIEW "expired_token" AS
3958 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3959 "token_type" = 'authorization' AND "used" AND EXISTS (
3960 SELECT NULL FROM "token" AS "other"
3961 WHERE "other"."authorization_token_id" = "token"."id" ) );
3963 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3964 DELETE FROM "token" WHERE "id" = OLD."id";
3966 COMMENT ON VIEW "expired_token" IS 'View containing all expired tokens where DELETE is possible; Note that used authorization codes must not be deleted if still referred to by other tokens';
3969 CREATE VIEW "unused_snapshot" AS
3970 SELECT "snapshot".* FROM "snapshot"
3971 LEFT JOIN "issue"
3972 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3973 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3974 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3975 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3976 WHERE "issue"."id" ISNULL;
3978 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3979 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3981 COMMENT ON VIEW "unused_snapshot" IS 'Snapshots that are not referenced by any issue (either as latest snapshot or as snapshot at phase/state change)';
3984 CREATE VIEW "open_issue" AS
3985 SELECT * FROM "issue" WHERE "closed" ISNULL;
3987 COMMENT ON VIEW "open_issue" IS 'All open issues';
3990 CREATE VIEW "member_contingent" AS
3991 SELECT
3992 "member"."id" AS "member_id",
3993 "contingent"."polling",
3994 "contingent"."time_frame",
3995 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3997 SELECT count(1) FROM "draft"
3998 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3999 WHERE "draft"."author_id" = "member"."id"
4000 AND "initiative"."polling" = "contingent"."polling"
4001 AND "draft"."created" > now() - "contingent"."time_frame"
4002 ) + (
4003 SELECT count(1) FROM "suggestion"
4004 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
4005 WHERE "suggestion"."author_id" = "member"."id"
4006 AND "contingent"."polling" = FALSE
4007 AND "suggestion"."created" > now() - "contingent"."time_frame"
4009 ELSE NULL END AS "text_entry_count",
4010 "contingent"."text_entry_limit",
4011 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
4012 SELECT count(1) FROM "opening_draft" AS "draft"
4013 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
4014 WHERE "draft"."author_id" = "member"."id"
4015 AND "initiative"."polling" = "contingent"."polling"
4016 AND "draft"."created" > now() - "contingent"."time_frame"
4017 ) ELSE NULL END AS "initiative_count",
4018 "contingent"."initiative_limit"
4019 FROM "member" CROSS JOIN "contingent";
4021 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
4023 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
4024 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
4027 CREATE VIEW "member_contingent_left" AS
4028 SELECT
4029 "member_id",
4030 "polling",
4031 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
4032 max("initiative_limit" - "initiative_count") AS "initiatives_left"
4033 FROM "member_contingent" GROUP BY "member_id", "polling";
4035 COMMENT ON VIEW "member_contingent_left" IS 'Amount of text entries or initiatives which can be posted now instantly by a member. This view should be used by a frontend to determine, if the contingent for posting is exhausted.';
4038 CREATE VIEW "event_for_notification" AS
4039 SELECT
4040 "member"."id" AS "recipient_id",
4041 "event".*
4042 FROM "member" CROSS JOIN "event"
4043 JOIN "issue" ON "issue"."id" = "event"."issue_id"
4044 JOIN "area" ON "area"."id" = "issue"."area_id"
4045 LEFT JOIN "privilege" ON
4046 "privilege"."member_id" = "member"."id" AND
4047 "privilege"."unit_id" = "area"."unit_id"
4048 LEFT JOIN "issue_privilege" ON
4049 "issue_privilege"."member_id" = "member"."id" AND
4050 "issue_privilege"."issue_id" = "event"."issue_id"
4051 LEFT JOIN "subscription" ON
4052 "subscription"."member_id" = "member"."id" AND
4053 "subscription"."unit_id" = "area"."unit_id"
4054 LEFT JOIN "ignored_area" ON
4055 "ignored_area"."member_id" = "member"."id" AND
4056 "ignored_area"."area_id" = "issue"."area_id"
4057 LEFT JOIN "interest" ON
4058 "interest"."member_id" = "member"."id" AND
4059 "interest"."issue_id" = "event"."issue_id"
4060 LEFT JOIN "supporter" ON
4061 "supporter"."member_id" = "member"."id" AND
4062 "supporter"."initiative_id" = "event"."initiative_id"
4063 WHERE (
4064 COALESCE("issue_privilege"."voting_right", "privilege"."voting_right") OR
4065 "subscription"."member_id" NOTNULL
4066 ) AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
4067 AND (
4068 "event"."event" = 'issue_state_changed'::"event_type" OR
4069 ( "event"."event" = 'initiative_revoked'::"event_type" AND
4070 "supporter"."member_id" NOTNULL ) );
4072 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
4074 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
4077 CREATE VIEW "updated_initiative" AS
4078 SELECT
4079 "supporter"."member_id" AS "recipient_id",
4080 FALSE AS "featured",
4081 "supporter"."initiative_id"
4082 FROM "supporter"
4083 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
4084 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4085 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4086 "sent"."member_id" = "supporter"."member_id" AND
4087 "sent"."initiative_id" = "supporter"."initiative_id"
4088 LEFT JOIN "ignored_initiative" ON
4089 "ignored_initiative"."member_id" = "supporter"."member_id" AND
4090 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
4091 WHERE "issue"."state" IN ('admission', 'discussion')
4092 AND "initiative"."revoked" ISNULL
4093 AND "ignored_initiative"."member_id" ISNULL
4094 AND (
4095 EXISTS (
4096 SELECT NULL FROM "draft"
4097 LEFT JOIN "ignored_member" ON
4098 "ignored_member"."member_id" = "supporter"."member_id" AND
4099 "ignored_member"."other_member_id" = "draft"."author_id"
4100 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
4101 AND "draft"."id" > "supporter"."draft_id"
4102 AND "ignored_member"."member_id" ISNULL
4103 ) OR EXISTS (
4104 SELECT NULL FROM "suggestion"
4105 LEFT JOIN "opinion" ON
4106 "opinion"."member_id" = "supporter"."member_id" AND
4107 "opinion"."suggestion_id" = "suggestion"."id"
4108 LEFT JOIN "ignored_member" ON
4109 "ignored_member"."member_id" = "supporter"."member_id" AND
4110 "ignored_member"."other_member_id" = "suggestion"."author_id"
4111 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
4112 AND "opinion"."member_id" ISNULL
4113 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4114 AND "ignored_member"."member_id" ISNULL
4116 );
4118 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
4121 CREATE FUNCTION "featured_initiative"
4122 ( "recipient_id_p" "member"."id"%TYPE,
4123 "area_id_p" "area"."id"%TYPE )
4124 RETURNS SETOF "initiative"."id"%TYPE
4125 LANGUAGE 'plpgsql' STABLE AS $$
4126 DECLARE
4127 "counter_v" "member"."notification_counter"%TYPE;
4128 "sample_size_v" "member"."notification_sample_size"%TYPE;
4129 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
4130 "match_v" BOOLEAN;
4131 "member_id_v" "member"."id"%TYPE;
4132 "seed_v" TEXT;
4133 "initiative_id_v" "initiative"."id"%TYPE;
4134 BEGIN
4135 SELECT "notification_counter", "notification_sample_size"
4136 INTO "counter_v", "sample_size_v"
4137 FROM "member" WHERE "id" = "recipient_id_p";
4138 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
4139 RETURN;
4140 END IF;
4141 "initiative_id_ary" := '{}';
4142 LOOP
4143 "match_v" := FALSE;
4144 FOR "member_id_v", "seed_v" IN
4145 SELECT * FROM (
4146 SELECT DISTINCT
4147 "supporter"."member_id",
4148 md5(
4149 "recipient_id_p" || '-' ||
4150 "counter_v" || '-' ||
4151 "area_id_p" || '-' ||
4152 "supporter"."member_id"
4153 ) AS "seed"
4154 FROM "supporter"
4155 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
4156 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4157 WHERE "supporter"."member_id" != "recipient_id_p"
4158 AND "issue"."area_id" = "area_id_p"
4159 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4160 ) AS "subquery"
4161 ORDER BY "seed"
4162 LOOP
4163 SELECT "initiative"."id" INTO "initiative_id_v"
4164 FROM "initiative"
4165 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4166 JOIN "area" ON "area"."id" = "issue"."area_id"
4167 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
4168 LEFT JOIN "supporter" AS "self_support" ON
4169 "self_support"."initiative_id" = "initiative"."id" AND
4170 "self_support"."member_id" = "recipient_id_p"
4171 LEFT JOIN "privilege" ON
4172 "privilege"."member_id" = "recipient_id_p" AND
4173 "privilege"."unit_id" = "area"."unit_id"
4174 LEFT JOIN "issue_privilege" ON
4175 "privilege"."member_id" = "recipient_id_p" AND
4176 "privilege"."issue_id" = "initiative"."issue_id"
4177 LEFT JOIN "subscription" ON
4178 "subscription"."member_id" = "recipient_id_p" AND
4179 "subscription"."unit_id" = "area"."unit_id"
4180 LEFT JOIN "ignored_initiative" ON
4181 "ignored_initiative"."member_id" = "recipient_id_p" AND
4182 "ignored_initiative"."initiative_id" = "initiative"."id"
4183 WHERE "supporter"."member_id" = "member_id_v"
4184 AND "issue"."area_id" = "area_id_p"
4185 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4186 AND "initiative"."revoked" ISNULL
4187 AND "self_support"."member_id" ISNULL
4188 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
4189 AND (
4190 COALESCE(
4191 "issue_privilege"."voting_right", "privilege"."voting_right"
4192 ) OR "subscription"."member_id" NOTNULL )
4193 AND "ignored_initiative"."member_id" ISNULL
4194 AND NOT EXISTS (
4195 SELECT NULL FROM "draft"
4196 JOIN "ignored_member" ON
4197 "ignored_member"."member_id" = "recipient_id_p" AND
4198 "ignored_member"."other_member_id" = "draft"."author_id"
4199 WHERE "draft"."initiative_id" = "initiative"."id"
4201 ORDER BY md5("seed_v" || '-' || "initiative"."id")
4202 LIMIT 1;
4203 IF FOUND THEN
4204 "match_v" := TRUE;
4205 RETURN NEXT "initiative_id_v";
4206 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
4207 RETURN;
4208 END IF;
4209 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
4210 END IF;
4211 END LOOP;
4212 EXIT WHEN NOT "match_v";
4213 END LOOP;
4214 RETURN;
4215 END;
4216 $$;
4218 COMMENT ON FUNCTION "featured_initiative"
4219 ( "recipient_id_p" "member"."id"%TYPE,
4220 "area_id_p" "area"."id"%TYPE )
4221 IS 'Helper function for view "updated_or_featured_initiative"';
4224 CREATE VIEW "updated_or_featured_initiative" AS
4225 SELECT
4226 "subquery".*,
4227 NOT EXISTS (
4228 SELECT NULL FROM "initiative" AS "better_initiative"
4229 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
4230 AND
4231 ( COALESCE("better_initiative"."supporter_count", -1),
4232 -"better_initiative"."id" ) >
4233 ( COALESCE("initiative"."supporter_count", -1),
4234 -"initiative"."id" )
4235 ) AS "leading"
4236 FROM (
4237 SELECT * FROM "updated_initiative"
4238 UNION ALL
4239 SELECT
4240 "member"."id" AS "recipient_id",
4241 TRUE AS "featured",
4242 "featured_initiative_id" AS "initiative_id"
4243 FROM "member" CROSS JOIN "area"
4244 CROSS JOIN LATERAL
4245 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
4246 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
4247 ) AS "subquery"
4248 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
4250 COMMENT ON VIEW "updated_or_featured_initiative" IS 'Initiatives to be included in a scheduled notification mail because (a) they have been updated or (b) they are featured';
4252 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
4253 COMMENT ON COLUMN "updated_or_featured_initiative"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
4254 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4255 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4258 CREATE VIEW "leading_complement_initiative" AS
4259 SELECT * FROM (
4260 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
4261 "uf_initiative"."recipient_id",
4262 FALSE AS "featured",
4263 "uf_initiative"."initiative_id",
4264 TRUE AS "leading"
4265 FROM "updated_or_featured_initiative" AS "uf_initiative"
4266 JOIN "initiative" AS "uf_initiative_full" ON
4267 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
4268 JOIN "initiative" ON
4269 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4270 WHERE "initiative"."revoked" ISNULL
4271 ORDER BY
4272 "uf_initiative"."recipient_id",
4273 "initiative"."issue_id",
4274 "initiative"."supporter_count" DESC,
4275 "initiative"."id"
4276 ) AS "subquery"
4277 WHERE NOT EXISTS (
4278 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4279 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4280 AND "other"."initiative_id" = "subquery"."initiative_id"
4281 );
4283 COMMENT ON VIEW "leading_complement_initiative" IS 'Helper view for view "unfiltered_initiative_for_notification" in order to always include the most supported initiative of an issue';
4284 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4285 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4286 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4289 CREATE VIEW "unfiltered_initiative_for_notification" AS
4290 SELECT
4291 "subquery".*,
4292 "supporter"."member_id" NOTNULL AS "supported",
4293 CASE WHEN "supporter"."member_id" NOTNULL THEN
4294 EXISTS (
4295 SELECT NULL FROM "draft"
4296 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4297 AND "draft"."id" > "supporter"."draft_id"
4299 ELSE
4300 EXISTS (
4301 SELECT NULL FROM "draft"
4302 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4303 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4305 END AS "new_draft",
4306 CASE WHEN "supporter"."member_id" NOTNULL THEN
4307 ( SELECT count(1) FROM "suggestion"
4308 LEFT JOIN "opinion" ON
4309 "opinion"."member_id" = "supporter"."member_id" AND
4310 "opinion"."suggestion_id" = "suggestion"."id"
4311 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4312 AND "opinion"."member_id" ISNULL
4313 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4315 ELSE
4316 ( SELECT count(1) FROM "suggestion"
4317 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4318 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4320 END AS "new_suggestion_count"
4321 FROM (
4322 SELECT * FROM "updated_or_featured_initiative"
4323 UNION ALL
4324 SELECT * FROM "leading_complement_initiative"
4325 ) AS "subquery"
4326 LEFT JOIN "supporter" ON
4327 "supporter"."member_id" = "subquery"."recipient_id" AND
4328 "supporter"."initiative_id" = "subquery"."initiative_id"
4329 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4330 "sent"."member_id" = "subquery"."recipient_id" AND
4331 "sent"."initiative_id" = "subquery"."initiative_id";
4333 COMMENT ON VIEW "unfiltered_initiative_for_notification" IS 'Helper view which simply combines the views "updated_or_featured_initiative" and "leading_complement_initiative" and adds columns "supported", "new_draft", and "new_suggestion_count';
4335 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4336 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
4337 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
4340 CREATE VIEW "initiative_for_notification" AS
4341 SELECT "unfiltered1".*
4342 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4343 JOIN "initiative" AS "initiative1" ON
4344 "initiative1"."id" = "unfiltered1"."initiative_id"
4345 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4346 WHERE EXISTS (
4347 SELECT NULL
4348 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4349 JOIN "initiative" AS "initiative2" ON
4350 "initiative2"."id" = "unfiltered2"."initiative_id"
4351 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4352 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4353 AND "issue1"."area_id" = "issue2"."area_id"
4354 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4355 );
4357 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4359 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4360 COMMENT ON COLUMN "initiative_for_notification"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
4361 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4362 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4363 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4364 COMMENT ON COLUMN "initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
4365 COMMENT ON COLUMN "initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
4368 CREATE VIEW "scheduled_notification_to_send" AS
4369 SELECT * FROM (
4370 SELECT
4371 "id" AS "recipient_id",
4372 now() - CASE WHEN "notification_dow" ISNULL THEN
4373 ( "notification_sent"::DATE + CASE
4374 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4375 THEN 0 ELSE 1 END
4376 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4377 ELSE
4378 ( "notification_sent"::DATE +
4379 ( 7 + "notification_dow" -
4380 EXTRACT(DOW FROM
4381 ( "notification_sent"::DATE + CASE
4382 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4383 THEN 0 ELSE 1 END
4384 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4385 )::INTEGER
4386 ) % 7 +
4387 CASE
4388 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4389 THEN 0 ELSE 1
4390 END
4391 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4392 END AS "pending"
4393 FROM (
4394 SELECT
4395 "id",
4396 COALESCE("notification_sent", "activated") AS "notification_sent",
4397 "notification_dow",
4398 "notification_hour"
4399 FROM "member_to_notify"
4400 WHERE "notification_hour" NOTNULL
4401 ) AS "subquery1"
4402 ) AS "subquery2"
4403 WHERE "pending" > '0'::INTERVAL;
4405 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4407 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4408 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4411 CREATE VIEW "newsletter_to_send" AS
4412 SELECT
4413 "member"."id" AS "recipient_id",
4414 "newsletter"."id" AS "newsletter_id",
4415 "newsletter"."published"
4416 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4417 LEFT JOIN "privilege" ON
4418 "privilege"."member_id" = "member"."id" AND
4419 "privilege"."unit_id" = "newsletter"."unit_id" AND
4420 "privilege"."voting_right" = TRUE
4421 LEFT JOIN "subscription" ON
4422 "subscription"."member_id" = "member"."id" AND
4423 "subscription"."unit_id" = "newsletter"."unit_id"
4424 WHERE "newsletter"."published" <= now()
4425 AND "newsletter"."sent" ISNULL
4426 AND (
4427 "member"."disable_notifications" = FALSE OR
4428 "newsletter"."include_all_members" = TRUE )
4429 AND (
4430 "newsletter"."unit_id" ISNULL OR
4431 "privilege"."member_id" NOTNULL OR
4432 "subscription"."member_id" NOTNULL );
4434 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4436 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4440 ------------------------------------------------------
4441 -- Row set returning function for delegation chains --
4442 ------------------------------------------------------
4445 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4446 ('first', 'intermediate', 'last', 'repetition');
4448 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4451 CREATE TYPE "delegation_chain_row" AS (
4452 "index" INT4,
4453 "member_id" INT4,
4454 "member_valid" BOOLEAN,
4455 "participation" BOOLEAN,
4456 "overridden" BOOLEAN,
4457 "scope_in" "delegation_scope",
4458 "scope_out" "delegation_scope",
4459 "disabled_out" BOOLEAN,
4460 "loop" "delegation_chain_loop_tag" );
4462 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4464 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4465 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4466 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4467 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4468 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4469 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4470 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4473 CREATE FUNCTION "delegation_chain_for_closed_issue"
4474 ( "member_id_p" "member"."id"%TYPE,
4475 "issue_id_p" "issue"."id"%TYPE )
4476 RETURNS SETOF "delegation_chain_row"
4477 LANGUAGE 'plpgsql' STABLE AS $$
4478 DECLARE
4479 "output_row" "delegation_chain_row";
4480 "direct_voter_row" "direct_voter"%ROWTYPE;
4481 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4482 BEGIN
4483 "output_row"."index" := 0;
4484 "output_row"."member_id" := "member_id_p";
4485 "output_row"."member_valid" := TRUE;
4486 "output_row"."participation" := FALSE;
4487 "output_row"."overridden" := FALSE;
4488 "output_row"."disabled_out" := FALSE;
4489 LOOP
4490 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4491 WHERE "issue_id" = "issue_id_p"
4492 AND "member_id" = "output_row"."member_id";
4493 IF "direct_voter_row"."member_id" NOTNULL THEN
4494 "output_row"."participation" := TRUE;
4495 "output_row"."scope_out" := NULL;
4496 "output_row"."disabled_out" := NULL;
4497 RETURN NEXT "output_row";
4498 RETURN;
4499 END IF;
4500 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4501 WHERE "issue_id" = "issue_id_p"
4502 AND "member_id" = "output_row"."member_id";
4503 IF "delegating_voter_row"."member_id" ISNULL THEN
4504 RETURN;
4505 END IF;
4506 "output_row"."scope_out" := "delegating_voter_row"."scope";
4507 RETURN NEXT "output_row";
4508 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4509 "output_row"."scope_in" := "output_row"."scope_out";
4510 END LOOP;
4511 END;
4512 $$;
4514 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4515 ( "member"."id"%TYPE,
4516 "member"."id"%TYPE )
4517 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4520 CREATE FUNCTION "delegation_chain"
4521 ( "member_id_p" "member"."id"%TYPE,
4522 "unit_id_p" "unit"."id"%TYPE,
4523 "area_id_p" "area"."id"%TYPE,
4524 "issue_id_p" "issue"."id"%TYPE,
4525 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4526 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4527 RETURNS SETOF "delegation_chain_row"
4528 LANGUAGE 'plpgsql' STABLE AS $$
4529 DECLARE
4530 "scope_v" "delegation_scope";
4531 "unit_id_v" "unit"."id"%TYPE;
4532 "area_id_v" "area"."id"%TYPE;
4533 "issue_row" "issue"%ROWTYPE;
4534 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4535 "loop_member_id_v" "member"."id"%TYPE;
4536 "output_row" "delegation_chain_row";
4537 "output_rows" "delegation_chain_row"[];
4538 "simulate_v" BOOLEAN;
4539 "simulate_here_v" BOOLEAN;
4540 "delegation_row" "delegation"%ROWTYPE;
4541 "row_count" INT4;
4542 "i" INT4;
4543 "loop_v" BOOLEAN;
4544 BEGIN
4545 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4546 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4547 END IF;
4548 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4549 "simulate_v" := TRUE;
4550 ELSE
4551 "simulate_v" := FALSE;
4552 END IF;
4553 IF
4554 "unit_id_p" NOTNULL AND
4555 "area_id_p" ISNULL AND
4556 "issue_id_p" ISNULL
4557 THEN
4558 "scope_v" := 'unit';
4559 "unit_id_v" := "unit_id_p";
4560 ELSIF
4561 "unit_id_p" ISNULL AND
4562 "area_id_p" NOTNULL AND
4563 "issue_id_p" ISNULL
4564 THEN
4565 "scope_v" := 'area';
4566 "area_id_v" := "area_id_p";
4567 SELECT "unit_id" INTO "unit_id_v"
4568 FROM "area" WHERE "id" = "area_id_v";
4569 ELSIF
4570 "unit_id_p" ISNULL AND
4571 "area_id_p" ISNULL AND
4572 "issue_id_p" NOTNULL
4573 THEN
4574 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4575 IF "issue_row"."id" ISNULL THEN
4576 RETURN;
4577 END IF;
4578 IF "issue_row"."closed" NOTNULL THEN
4579 IF "simulate_v" THEN
4580 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4581 END IF;
4582 FOR "output_row" IN
4583 SELECT * FROM
4584 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4585 LOOP
4586 RETURN NEXT "output_row";
4587 END LOOP;
4588 RETURN;
4589 END IF;
4590 "scope_v" := 'issue';
4591 SELECT "area_id" INTO "area_id_v"
4592 FROM "issue" WHERE "id" = "issue_id_p";
4593 SELECT "unit_id" INTO "unit_id_v"
4594 FROM "area" WHERE "id" = "area_id_v";
4595 ELSE
4596 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4597 END IF;
4598 "visited_member_ids" := '{}';
4599 "loop_member_id_v" := NULL;
4600 "output_rows" := '{}';
4601 "output_row"."index" := 0;
4602 "output_row"."member_id" := "member_id_p";
4603 "output_row"."member_valid" := TRUE;
4604 "output_row"."participation" := FALSE;
4605 "output_row"."overridden" := FALSE;
4606 "output_row"."disabled_out" := FALSE;
4607 "output_row"."scope_out" := NULL;
4608 LOOP
4609 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4610 "loop_member_id_v" := "output_row"."member_id";
4611 ELSE
4612 "visited_member_ids" :=
4613 "visited_member_ids" || "output_row"."member_id";
4614 END IF;
4615 IF "output_row"."participation" ISNULL THEN
4616 "output_row"."overridden" := NULL;
4617 ELSIF "output_row"."participation" THEN
4618 "output_row"."overridden" := TRUE;
4619 END IF;
4620 "output_row"."scope_in" := "output_row"."scope_out";
4621 "output_row"."member_valid" := EXISTS (
4622 SELECT NULL FROM "member"
4623 LEFT JOIN "privilege"
4624 ON "privilege"."member_id" = "member"."id"
4625 AND "privilege"."unit_id" = "unit_id_v"
4626 LEFT JOIN "issue_privilege"
4627 ON "issue_privilege"."member_id" = "member"."id"
4628 AND "issue_privilege"."issue_id" = "issue_id_p"
4629 WHERE "id" = "output_row"."member_id"
4630 AND "member"."active"
4631 AND COALESCE(
4632 "issue_privilege"."voting_weight", "privilege"."voting_right")
4633 );
4634 "simulate_here_v" := (
4635 "simulate_v" AND
4636 "output_row"."member_id" = "member_id_p"
4637 );
4638 "delegation_row" := ROW(NULL);
4639 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4640 IF "scope_v" = 'unit' THEN
4641 IF NOT "simulate_here_v" THEN
4642 SELECT * INTO "delegation_row" FROM "delegation"
4643 WHERE "truster_id" = "output_row"."member_id"
4644 AND "unit_id" = "unit_id_v";
4645 END IF;
4646 ELSIF "scope_v" = 'area' THEN
4647 IF "simulate_here_v" THEN
4648 IF "simulate_trustee_id_p" ISNULL THEN
4649 SELECT * INTO "delegation_row" FROM "delegation"
4650 WHERE "truster_id" = "output_row"."member_id"
4651 AND "unit_id" = "unit_id_v";
4652 END IF;
4653 ELSE
4654 SELECT * INTO "delegation_row" FROM "delegation"
4655 WHERE "truster_id" = "output_row"."member_id"
4656 AND (
4657 "unit_id" = "unit_id_v" OR
4658 "area_id" = "area_id_v"
4660 ORDER BY "scope" DESC;
4661 END IF;
4662 ELSIF "scope_v" = 'issue' THEN
4663 IF "issue_row"."fully_frozen" ISNULL THEN
4664 "output_row"."participation" := EXISTS (
4665 SELECT NULL FROM "interest"
4666 WHERE "issue_id" = "issue_id_p"
4667 AND "member_id" = "output_row"."member_id"
4668 );
4669 ELSE
4670 IF "output_row"."member_id" = "member_id_p" THEN
4671 "output_row"."participation" := EXISTS (
4672 SELECT NULL FROM "direct_voter"
4673 WHERE "issue_id" = "issue_id_p"
4674 AND "member_id" = "output_row"."member_id"
4675 );
4676 ELSE
4677 "output_row"."participation" := NULL;
4678 END IF;
4679 END IF;
4680 IF "simulate_here_v" THEN
4681 IF "simulate_trustee_id_p" ISNULL THEN
4682 SELECT * INTO "delegation_row" FROM "delegation"
4683 WHERE "truster_id" = "output_row"."member_id"
4684 AND (
4685 "unit_id" = "unit_id_v" OR
4686 "area_id" = "area_id_v"
4688 ORDER BY "scope" DESC;
4689 END IF;
4690 ELSE
4691 SELECT * INTO "delegation_row" FROM "delegation"
4692 WHERE "truster_id" = "output_row"."member_id"
4693 AND (
4694 "unit_id" = "unit_id_v" OR
4695 "area_id" = "area_id_v" OR
4696 "issue_id" = "issue_id_p"
4698 ORDER BY "scope" DESC;
4699 END IF;
4700 END IF;
4701 ELSE
4702 "output_row"."participation" := FALSE;
4703 END IF;
4704 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4705 "output_row"."scope_out" := "scope_v";
4706 "output_rows" := "output_rows" || "output_row";
4707 "output_row"."member_id" := "simulate_trustee_id_p";
4708 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4709 "output_row"."scope_out" := "delegation_row"."scope";
4710 "output_rows" := "output_rows" || "output_row";
4711 "output_row"."member_id" := "delegation_row"."trustee_id";
4712 ELSIF "delegation_row"."scope" NOTNULL THEN
4713 "output_row"."scope_out" := "delegation_row"."scope";
4714 "output_row"."disabled_out" := TRUE;
4715 "output_rows" := "output_rows" || "output_row";
4716 EXIT;
4717 ELSE
4718 "output_row"."scope_out" := NULL;
4719 "output_rows" := "output_rows" || "output_row";
4720 EXIT;
4721 END IF;
4722 EXIT WHEN "loop_member_id_v" NOTNULL;
4723 "output_row"."index" := "output_row"."index" + 1;
4724 END LOOP;
4725 "row_count" := array_upper("output_rows", 1);
4726 "i" := 1;
4727 "loop_v" := FALSE;
4728 LOOP
4729 "output_row" := "output_rows"["i"];
4730 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4731 IF "loop_v" THEN
4732 IF "i" + 1 = "row_count" THEN
4733 "output_row"."loop" := 'last';
4734 ELSIF "i" = "row_count" THEN
4735 "output_row"."loop" := 'repetition';
4736 ELSE
4737 "output_row"."loop" := 'intermediate';
4738 END IF;
4739 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4740 "output_row"."loop" := 'first';
4741 "loop_v" := TRUE;
4742 END IF;
4743 IF "scope_v" = 'unit' THEN
4744 "output_row"."participation" := NULL;
4745 END IF;
4746 RETURN NEXT "output_row";
4747 "i" := "i" + 1;
4748 END LOOP;
4749 RETURN;
4750 END;
4751 $$;
4753 COMMENT ON FUNCTION "delegation_chain"
4754 ( "member"."id"%TYPE,
4755 "unit"."id"%TYPE,
4756 "area"."id"%TYPE,
4757 "issue"."id"%TYPE,
4758 "member"."id"%TYPE,
4759 BOOLEAN )
4760 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4764 ---------------------------------------------------------
4765 -- Single row returning function for delegation chains --
4766 ---------------------------------------------------------
4769 CREATE TYPE "delegation_info_loop_type" AS ENUM
4770 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4772 COMMENT ON TYPE "delegation_info_loop_type" IS 'Type of "delegation_loop" in "delegation_info_type"; ''own'' means loop to self, ''first'' means loop to first trustee, ''first_ellipsis'' means loop to ellipsis after first trustee, ''other'' means loop to other trustee, ''other_ellipsis'' means loop to ellipsis after other trustee''';
4775 CREATE TYPE "delegation_info_type" AS (
4776 "own_participation" BOOLEAN,
4777 "own_delegation_scope" "delegation_scope",
4778 "first_trustee_id" INT4,
4779 "first_trustee_participation" BOOLEAN,
4780 "first_trustee_ellipsis" BOOLEAN,
4781 "other_trustee_id" INT4,
4782 "other_trustee_participation" BOOLEAN,
4783 "other_trustee_ellipsis" BOOLEAN,
4784 "delegation_loop" "delegation_info_loop_type",
4785 "participating_member_id" INT4 );
4787 COMMENT ON TYPE "delegation_info_type" IS 'Type of result returned by "delegation_info" function; For meaning of "participation" check comment on "delegation_chain_row" type';
4789 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4790 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4791 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4792 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4793 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4794 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4795 COMMENT ON COLUMN "delegation_info_type"."other_trustee_participation" IS 'Another trustee is participating (redundant field: if "other_trustee_id" is set, then "other_trustee_participation" is always TRUE, else "other_trustee_participation" is NULL)';
4796 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4797 COMMENT ON COLUMN "delegation_info_type"."delegation_loop" IS 'Non-NULL value, if delegation chain contains a circle; See comment on "delegation_info_loop_type" for details';
4798 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4801 CREATE FUNCTION "delegation_info"
4802 ( "member_id_p" "member"."id"%TYPE,
4803 "unit_id_p" "unit"."id"%TYPE,
4804 "area_id_p" "area"."id"%TYPE,
4805 "issue_id_p" "issue"."id"%TYPE,
4806 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4807 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4808 RETURNS "delegation_info_type"
4809 LANGUAGE 'plpgsql' STABLE AS $$
4810 DECLARE
4811 "current_row" "delegation_chain_row";
4812 "result" "delegation_info_type";
4813 BEGIN
4814 "result"."own_participation" := FALSE;
4815 FOR "current_row" IN
4816 SELECT * FROM "delegation_chain"(
4817 "member_id_p",
4818 "unit_id_p", "area_id_p", "issue_id_p",
4819 "simulate_trustee_id_p", "simulate_default_p")
4820 LOOP
4821 IF
4822 "result"."participating_member_id" ISNULL AND
4823 "current_row"."participation"
4824 THEN
4825 "result"."participating_member_id" := "current_row"."member_id";
4826 END IF;
4827 IF "current_row"."member_id" = "member_id_p" THEN
4828 "result"."own_participation" := "current_row"."participation";
4829 "result"."own_delegation_scope" := "current_row"."scope_out";
4830 IF "current_row"."loop" = 'first' THEN
4831 "result"."delegation_loop" := 'own';
4832 END IF;
4833 ELSIF
4834 "current_row"."member_valid" AND
4835 ( "current_row"."loop" ISNULL OR
4836 "current_row"."loop" != 'repetition' )
4837 THEN
4838 IF "result"."first_trustee_id" ISNULL THEN
4839 "result"."first_trustee_id" := "current_row"."member_id";
4840 "result"."first_trustee_participation" := "current_row"."participation";
4841 "result"."first_trustee_ellipsis" := FALSE;
4842 IF "current_row"."loop" = 'first' THEN
4843 "result"."delegation_loop" := 'first';
4844 END IF;
4845 ELSIF "result"."other_trustee_id" ISNULL THEN
4846 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4847 "result"."other_trustee_id" := "current_row"."member_id";
4848 "result"."other_trustee_participation" := TRUE;
4849 "result"."other_trustee_ellipsis" := FALSE;
4850 IF "current_row"."loop" = 'first' THEN
4851 "result"."delegation_loop" := 'other';
4852 END IF;
4853 ELSE
4854 "result"."first_trustee_ellipsis" := TRUE;
4855 IF "current_row"."loop" = 'first' THEN
4856 "result"."delegation_loop" := 'first_ellipsis';
4857 END IF;
4858 END IF;
4859 ELSE
4860 "result"."other_trustee_ellipsis" := TRUE;
4861 IF "current_row"."loop" = 'first' THEN
4862 "result"."delegation_loop" := 'other_ellipsis';
4863 END IF;
4864 END IF;
4865 END IF;
4866 END LOOP;
4867 RETURN "result";
4868 END;
4869 $$;
4871 COMMENT ON FUNCTION "delegation_info"
4872 ( "member"."id"%TYPE,
4873 "unit"."id"%TYPE,
4874 "area"."id"%TYPE,
4875 "issue"."id"%TYPE,
4876 "member"."id"%TYPE,
4877 BOOLEAN )
4878 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4882 ------------------------
4883 -- Geospatial lookups --
4884 ------------------------
4886 /*
4887 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4888 ( "bounding_box_p" EBOX,
4889 "limit_p" INT4 )
4890 RETURNS SETOF "initiative"
4891 LANGUAGE 'plpgsql' STABLE AS $$
4892 DECLARE
4893 "limit_v" INT4;
4894 "count_v" INT4;
4895 BEGIN
4896 "limit_v" := "limit_p" + 1;
4897 LOOP
4898 SELECT count(1) INTO "count_v"
4899 FROM "initiative"
4900 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4901 WHERE "issue"."closed" NOTNULL
4902 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4903 LIMIT "limit_v";
4904 IF "count_v" < "limit_v" THEN
4905 RETURN QUERY SELECT "initiative".*
4906 FROM (
4907 SELECT
4908 "initiative"."id" AS "initiative_id",
4909 "issue"."closed"
4910 FROM "initiative"
4911 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4912 WHERE "issue"."closed" NOTNULL
4913 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4914 ) AS "subquery"
4915 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4916 ORDER BY "subquery"."closed" DESC
4917 LIMIT "limit_p";
4918 RETURN;
4919 END IF;
4920 SELECT count(1) INTO "count_v"
4921 FROM (
4922 SELECT "initiative"."id" AS "initiative_id"
4923 FROM "initiative"
4924 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4925 WHERE "issue"."closed" NOTNULL
4926 ORDER BY "closed" DESC
4927 LIMIT "limit_v"
4928 ) AS "subquery"
4929 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4930 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4931 LIMIT "limit_p";
4932 IF "count_v" >= "limit_p" THEN
4933 RETURN QUERY SELECT "initiative".*
4934 FROM (
4935 SELECT
4936 "initiative"."id" AS "initiative_id",
4937 "issue"."closed"
4938 FROM "initiative"
4939 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4940 WHERE "issue"."closed" NOTNULL
4941 ORDER BY "closed" DESC
4942 LIMIT "limit_v"
4943 ) AS "subquery"
4944 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4945 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4946 ORDER BY "subquery"."closed" DESC
4947 LIMIT "limit_p";
4948 RETURN;
4949 END IF;
4950 "limit_v" := "limit_v" * 2;
4951 END LOOP;
4952 END;
4953 $$;
4955 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4956 ( EBOX, INT4 )
4957 IS 'TODO';
4958 */
4962 ---------------------------
4963 -- Transaction isolation --
4964 ---------------------------
4967 CREATE FUNCTION "require_transaction_isolation"()
4968 RETURNS VOID
4969 LANGUAGE 'plpgsql' VOLATILE AS $$
4970 BEGIN
4971 IF
4972 current_setting('transaction_isolation') NOT IN
4973 ('repeatable read', 'serializable')
4974 THEN
4975 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4976 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4977 END IF;
4978 RETURN;
4979 END;
4980 $$;
4982 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4985 CREATE FUNCTION "dont_require_transaction_isolation"()
4986 RETURNS VOID
4987 LANGUAGE 'plpgsql' VOLATILE AS $$
4988 BEGIN
4989 IF
4990 current_setting('transaction_isolation') IN
4991 ('repeatable read', 'serializable')
4992 THEN
4993 RAISE WARNING 'Unneccessary transaction isolation level: %',
4994 current_setting('transaction_isolation');
4995 END IF;
4996 RETURN;
4997 END;
4998 $$;
5000 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
5004 -------------------------
5005 -- Notification system --
5006 -------------------------
5008 CREATE FUNCTION "get_initiatives_for_notification"
5009 ( "recipient_id_p" "member"."id"%TYPE )
5010 RETURNS SETOF "initiative_for_notification"
5011 LANGUAGE 'plpgsql' VOLATILE AS $$
5012 DECLARE
5013 "result_row" "initiative_for_notification"%ROWTYPE;
5014 "last_draft_id_v" "draft"."id"%TYPE;
5015 "last_suggestion_id_v" "suggestion"."id"%TYPE;
5016 BEGIN
5017 PERFORM "require_transaction_isolation"();
5018 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
5019 FOR "result_row" IN
5020 SELECT * FROM "initiative_for_notification"
5021 WHERE "recipient_id" = "recipient_id_p"
5022 LOOP
5023 SELECT "id" INTO "last_draft_id_v" FROM "draft"
5024 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
5025 ORDER BY "id" DESC LIMIT 1;
5026 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
5027 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
5028 ORDER BY "id" DESC LIMIT 1;
5029 INSERT INTO "notification_initiative_sent"
5030 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
5031 VALUES (
5032 "recipient_id_p",
5033 "result_row"."initiative_id",
5034 "last_draft_id_v",
5035 "last_suggestion_id_v" )
5036 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
5037 "last_draft_id" = "last_draft_id_v",
5038 "last_suggestion_id" = "last_suggestion_id_v";
5039 RETURN NEXT "result_row";
5040 END LOOP;
5041 DELETE FROM "notification_initiative_sent"
5042 USING "initiative", "issue"
5043 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
5044 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
5045 AND "issue"."id" = "initiative"."issue_id"
5046 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
5047 UPDATE "member" SET
5048 "notification_counter" = "notification_counter" + 1,
5049 "notification_sent" = now()
5050 WHERE "id" = "recipient_id_p";
5051 RETURN;
5052 END;
5053 $$;
5055 COMMENT ON FUNCTION "get_initiatives_for_notification"
5056 ( "member"."id"%TYPE )
5057 IS 'Returns rows from view "initiative_for_notification" for a given recipient while updating table "notification_initiative_sent" and columns "notification_counter" and "notification_sent" of "member" table';
5061 ------------------------------------------------------------------------
5062 -- Regular tasks, except calculcation of snapshots and voting results --
5063 ------------------------------------------------------------------------
5066 CREATE FUNCTION "check_activity"()
5067 RETURNS VOID
5068 LANGUAGE 'plpgsql' VOLATILE AS $$
5069 DECLARE
5070 "system_setting_row" "system_setting"%ROWTYPE;
5071 BEGIN
5072 PERFORM "dont_require_transaction_isolation"();
5073 SELECT * INTO "system_setting_row" FROM "system_setting";
5074 IF "system_setting_row"."member_ttl" NOTNULL THEN
5075 UPDATE "member" SET "active" = FALSE
5076 WHERE "active" = TRUE
5077 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
5078 END IF;
5079 RETURN;
5080 END;
5081 $$;
5083 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
5086 CREATE FUNCTION "calculate_member_counts"()
5087 RETURNS VOID
5088 LANGUAGE 'plpgsql' VOLATILE AS $$
5089 BEGIN
5090 PERFORM "require_transaction_isolation"();
5091 DELETE FROM "member_count";
5092 INSERT INTO "member_count" ("total_count")
5093 SELECT "total_count" FROM "member_count_view";
5094 UPDATE "unit" SET
5095 "member_count" = "view"."member_count",
5096 "member_weight" = "view"."member_weight"
5097 FROM "unit_member_count" AS "view"
5098 WHERE "view"."unit_id" = "unit"."id";
5099 RETURN;
5100 END;
5101 $$;
5103 COMMENT ON FUNCTION "calculate_member_counts"() IS 'Updates "member_count" table and "member_count" and "member_weight" columns of table "area" by materializing data from views "member_count_view" and "unit_member_count"';
5107 ------------------------------------
5108 -- Calculation of harmonic weight --
5109 ------------------------------------
5112 CREATE VIEW "remaining_harmonic_supporter_weight" AS
5113 SELECT
5114 "direct_interest_snapshot"."snapshot_id",
5115 "direct_interest_snapshot"."issue_id",
5116 "direct_interest_snapshot"."member_id",
5117 "direct_interest_snapshot"."weight" AS "weight_num",
5118 count("initiative"."id") AS "weight_den"
5119 FROM "issue"
5120 JOIN "direct_interest_snapshot"
5121 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
5122 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
5123 JOIN "initiative"
5124 ON "issue"."id" = "initiative"."issue_id"
5125 AND "initiative"."harmonic_weight" ISNULL
5126 JOIN "direct_supporter_snapshot"
5127 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5128 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5129 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
5130 AND (
5131 "direct_supporter_snapshot"."satisfied" = TRUE OR
5132 coalesce("initiative"."admitted", FALSE) = FALSE
5134 GROUP BY
5135 "direct_interest_snapshot"."snapshot_id",
5136 "direct_interest_snapshot"."issue_id",
5137 "direct_interest_snapshot"."member_id",
5138 "direct_interest_snapshot"."weight";
5140 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
5143 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
5144 SELECT
5145 "initiative"."issue_id",
5146 "initiative"."id" AS "initiative_id",
5147 "initiative"."admitted",
5148 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
5149 "remaining_harmonic_supporter_weight"."weight_den"
5150 FROM "remaining_harmonic_supporter_weight"
5151 JOIN "initiative"
5152 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
5153 AND "initiative"."harmonic_weight" ISNULL
5154 JOIN "direct_supporter_snapshot"
5155 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
5156 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
5157 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
5158 AND (
5159 "direct_supporter_snapshot"."satisfied" = TRUE OR
5160 coalesce("initiative"."admitted", FALSE) = FALSE
5162 GROUP BY
5163 "initiative"."issue_id",
5164 "initiative"."id",
5165 "initiative"."admitted",
5166 "remaining_harmonic_supporter_weight"."weight_den";
5168 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
5171 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
5172 SELECT
5173 "issue_id",
5174 "id" AS "initiative_id",
5175 "admitted",
5176 0 AS "weight_num",
5177 1 AS "weight_den"
5178 FROM "initiative"
5179 WHERE "harmonic_weight" ISNULL;
5181 COMMENT ON VIEW "remaining_harmonic_initiative_weight_dummies" IS 'Helper view for function "set_harmonic_initiative_weights" providing dummy weights of zero value, which are needed for corner cases where there are no supporters for an initiative at all';
5184 CREATE FUNCTION "set_harmonic_initiative_weights"
5185 ( "issue_id_p" "issue"."id"%TYPE )
5186 RETURNS VOID
5187 LANGUAGE 'plpgsql' VOLATILE AS $$
5188 DECLARE
5189 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
5190 "i" INT4;
5191 "count_v" INT4;
5192 "summand_v" FLOAT;
5193 "id_ary" INT4[];
5194 "weight_ary" FLOAT[];
5195 "min_weight_v" FLOAT;
5196 BEGIN
5197 PERFORM "require_transaction_isolation"();
5198 UPDATE "initiative" SET "harmonic_weight" = NULL
5199 WHERE "issue_id" = "issue_id_p";
5200 LOOP
5201 "min_weight_v" := NULL;
5202 "i" := 0;
5203 "count_v" := 0;
5204 FOR "weight_row" IN
5205 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
5206 WHERE "issue_id" = "issue_id_p"
5207 AND (
5208 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5209 SELECT NULL FROM "initiative"
5210 WHERE "issue_id" = "issue_id_p"
5211 AND "harmonic_weight" ISNULL
5212 AND coalesce("admitted", FALSE) = FALSE
5215 UNION ALL -- needed for corner cases
5216 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
5217 WHERE "issue_id" = "issue_id_p"
5218 AND (
5219 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5220 SELECT NULL FROM "initiative"
5221 WHERE "issue_id" = "issue_id_p"
5222 AND "harmonic_weight" ISNULL
5223 AND coalesce("admitted", FALSE) = FALSE
5226 ORDER BY "initiative_id" DESC, "weight_den" DESC
5227 -- NOTE: non-admitted initiatives placed first (at last positions),
5228 -- latest initiatives treated worse in case of tie
5229 LOOP
5230 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
5231 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
5232 "i" := "i" + 1;
5233 "count_v" := "i";
5234 "id_ary"["i"] := "weight_row"."initiative_id";
5235 "weight_ary"["i"] := "summand_v";
5236 ELSE
5237 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
5238 END IF;
5239 END LOOP;
5240 EXIT WHEN "count_v" = 0;
5241 "i" := 1;
5242 LOOP
5243 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
5244 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
5245 "min_weight_v" := "weight_ary"["i"];
5246 END IF;
5247 "i" := "i" + 1;
5248 EXIT WHEN "i" > "count_v";
5249 END LOOP;
5250 "i" := 1;
5251 LOOP
5252 IF "weight_ary"["i"] = "min_weight_v" THEN
5253 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
5254 WHERE "id" = "id_ary"["i"];
5255 EXIT;
5256 END IF;
5257 "i" := "i" + 1;
5258 END LOOP;
5259 END LOOP;
5260 UPDATE "initiative" SET "harmonic_weight" = 0
5261 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
5262 END;
5263 $$;
5265 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
5266 ( "issue"."id"%TYPE )
5267 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
5271 ------------------------------
5272 -- Calculation of snapshots --
5273 ------------------------------
5276 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
5277 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5278 "issue_id_p" "issue"."id"%TYPE,
5279 "member_id_p" "member"."id"%TYPE,
5280 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5281 RETURNS "direct_interest_snapshot"."weight"%TYPE
5282 LANGUAGE 'plpgsql' VOLATILE AS $$
5283 DECLARE
5284 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5285 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5286 "weight_v" INT4;
5287 "sub_weight_v" INT4;
5288 BEGIN
5289 PERFORM "require_transaction_isolation"();
5290 "weight_v" := 0;
5291 FOR "issue_delegation_row" IN
5292 SELECT * FROM "issue_delegation"
5293 WHERE "trustee_id" = "member_id_p"
5294 AND "issue_id" = "issue_id_p"
5295 LOOP
5296 IF NOT EXISTS (
5297 SELECT NULL FROM "direct_interest_snapshot"
5298 WHERE "snapshot_id" = "snapshot_id_p"
5299 AND "issue_id" = "issue_id_p"
5300 AND "member_id" = "issue_delegation_row"."truster_id"
5301 ) AND NOT EXISTS (
5302 SELECT NULL FROM "delegating_interest_snapshot"
5303 WHERE "snapshot_id" = "snapshot_id_p"
5304 AND "issue_id" = "issue_id_p"
5305 AND "member_id" = "issue_delegation_row"."truster_id"
5306 ) THEN
5307 "delegate_member_ids_v" :=
5308 "member_id_p" || "delegate_member_ids_p";
5309 INSERT INTO "delegating_interest_snapshot" (
5310 "snapshot_id",
5311 "issue_id",
5312 "member_id",
5313 "ownweight",
5314 "scope",
5315 "delegate_member_ids"
5316 ) VALUES (
5317 "snapshot_id_p",
5318 "issue_id_p",
5319 "issue_delegation_row"."truster_id",
5320 "issue_delegation_row"."weight",
5321 "issue_delegation_row"."scope",
5322 "delegate_member_ids_v"
5323 );
5324 "sub_weight_v" := "issue_delegation_row"."weight" +
5325 "weight_of_added_delegations_for_snapshot"(
5326 "snapshot_id_p",
5327 "issue_id_p",
5328 "issue_delegation_row"."truster_id",
5329 "delegate_member_ids_v"
5330 );
5331 UPDATE "delegating_interest_snapshot"
5332 SET "weight" = "sub_weight_v"
5333 WHERE "snapshot_id" = "snapshot_id_p"
5334 AND "issue_id" = "issue_id_p"
5335 AND "member_id" = "issue_delegation_row"."truster_id";
5336 "weight_v" := "weight_v" + "sub_weight_v";
5337 END IF;
5338 END LOOP;
5339 RETURN "weight_v";
5340 END;
5341 $$;
5343 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5344 ( "snapshot"."id"%TYPE,
5345 "issue"."id"%TYPE,
5346 "member"."id"%TYPE,
5347 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5348 IS 'Helper function for "fill_snapshot" function';
5351 CREATE FUNCTION "take_snapshot"
5352 ( "issue_id_p" "issue"."id"%TYPE,
5353 "area_id_p" "area"."id"%TYPE = NULL )
5354 RETURNS "snapshot"."id"%TYPE
5355 LANGUAGE 'plpgsql' VOLATILE AS $$
5356 DECLARE
5357 "area_id_v" "area"."id"%TYPE;
5358 "unit_id_v" "unit"."id"%TYPE;
5359 "snapshot_id_v" "snapshot"."id"%TYPE;
5360 "issue_id_v" "issue"."id"%TYPE;
5361 "member_id_v" "member"."id"%TYPE;
5362 BEGIN
5363 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5364 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5365 END IF;
5366 PERFORM "require_transaction_isolation"();
5367 IF "issue_id_p" ISNULL THEN
5368 "area_id_v" := "area_id_p";
5369 ELSE
5370 SELECT "area_id" INTO "area_id_v"
5371 FROM "issue" WHERE "id" = "issue_id_p";
5372 END IF;
5373 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5374 INSERT INTO "snapshot" ("area_id", "issue_id")
5375 VALUES ("area_id_v", "issue_id_p")
5376 RETURNING "id" INTO "snapshot_id_v";
5377 INSERT INTO "snapshot_population" ("snapshot_id", "member_id", "weight")
5378 SELECT
5379 "snapshot_id_v",
5380 "member"."id",
5381 COALESCE("issue_privilege"."weight", "privilege"."weight")
5382 FROM "member"
5383 LEFT JOIN "privilege"
5384 ON "privilege"."unit_id" = "unit_id_v"
5385 AND "privilege"."member_id" = "member"."id"
5386 LEFT JOIN "issue_privilege"
5387 ON "issue_privilege"."issue_id" = "issue_id_v"
5388 AND "issue_privilege"."member_id" = "member"."id"
5389 WHERE "member"."active" AND COALESCE(
5390 "issue_privilege"."voting_right", "privilege"."voting_right");
5391 UPDATE "snapshot" SET
5392 "population" = (
5393 SELECT sum("weight") FROM "snapshot_population"
5394 WHERE "snapshot_id" = "snapshot_id_v"
5395 ) WHERE "id" = "snapshot_id_v";
5396 FOR "issue_id_v" IN
5397 SELECT "id" FROM "issue"
5398 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5399 "area_id" = "area_id_p" AND
5400 "state" = 'admission'
5401 ELSE
5402 "id" = "issue_id_p"
5403 END
5404 LOOP
5405 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5406 VALUES ("snapshot_id_v", "issue_id_v");
5407 INSERT INTO "direct_interest_snapshot"
5408 ("snapshot_id", "issue_id", "member_id", "ownweight")
5409 SELECT
5410 "snapshot_id_v" AS "snapshot_id",
5411 "issue_id_v" AS "issue_id",
5412 "member"."id" AS "member_id",
5413 COALESCE(
5414 "issue_privilege"."weight", "privilege"."weight"
5415 ) AS "ownweight"
5416 FROM "issue"
5417 JOIN "area" ON "issue"."area_id" = "area"."id"
5418 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5419 JOIN "member" ON "interest"."member_id" = "member"."id"
5420 LEFT JOIN "privilege"
5421 ON "privilege"."unit_id" = "area"."unit_id"
5422 AND "privilege"."member_id" = "member"."id"
5423 LEFT JOIN "issue_privilege"
5424 ON "issue_privilege"."issue_id" = "issue_id_v"
5425 AND "issue_privilege"."member_id" = "member"."id"
5426 WHERE "issue"."id" = "issue_id_v"
5427 AND "member"."active" AND COALESCE(
5428 "issue_privilege"."voting_right", "privilege"."voting_right");
5429 FOR "member_id_v" IN
5430 SELECT "member_id" FROM "direct_interest_snapshot"
5431 WHERE "snapshot_id" = "snapshot_id_v"
5432 AND "issue_id" = "issue_id_v"
5433 LOOP
5434 UPDATE "direct_interest_snapshot" SET
5435 "weight" = "ownweight" +
5436 "weight_of_added_delegations_for_snapshot"(
5437 "snapshot_id_v",
5438 "issue_id_v",
5439 "member_id_v",
5440 '{}'
5442 WHERE "snapshot_id" = "snapshot_id_v"
5443 AND "issue_id" = "issue_id_v"
5444 AND "member_id" = "member_id_v";
5445 END LOOP;
5446 INSERT INTO "direct_supporter_snapshot"
5447 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5448 "draft_id", "informed", "satisfied" )
5449 SELECT
5450 "snapshot_id_v" AS "snapshot_id",
5451 "issue_id_v" AS "issue_id",
5452 "initiative"."id" AS "initiative_id",
5453 "supporter"."member_id" AS "member_id",
5454 "supporter"."draft_id" AS "draft_id",
5455 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5456 NOT EXISTS (
5457 SELECT NULL FROM "critical_opinion"
5458 WHERE "initiative_id" = "initiative"."id"
5459 AND "member_id" = "supporter"."member_id"
5460 ) AS "satisfied"
5461 FROM "initiative"
5462 JOIN "supporter"
5463 ON "supporter"."initiative_id" = "initiative"."id"
5464 JOIN "current_draft"
5465 ON "initiative"."id" = "current_draft"."initiative_id"
5466 JOIN "direct_interest_snapshot"
5467 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5468 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5469 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5470 WHERE "initiative"."issue_id" = "issue_id_v";
5471 DELETE FROM "temporary_suggestion_counts";
5472 INSERT INTO "temporary_suggestion_counts"
5473 ( "id",
5474 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5475 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5476 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5477 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5478 SELECT
5479 "suggestion"."id",
5480 ( SELECT coalesce(sum("di"."weight"), 0)
5481 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5482 ON "di"."snapshot_id" = "snapshot_id_v"
5483 AND "di"."issue_id" = "issue_id_v"
5484 AND "di"."member_id" = "opinion"."member_id"
5485 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5486 AND "opinion"."degree" = -2
5487 AND "opinion"."fulfilled" = FALSE
5488 ) AS "minus2_unfulfilled_count",
5489 ( SELECT coalesce(sum("di"."weight"), 0)
5490 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5491 ON "di"."snapshot_id" = "snapshot_id_v"
5492 AND "di"."issue_id" = "issue_id_v"
5493 AND "di"."member_id" = "opinion"."member_id"
5494 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5495 AND "opinion"."degree" = -2
5496 AND "opinion"."fulfilled" = TRUE
5497 ) AS "minus2_fulfilled_count",
5498 ( SELECT coalesce(sum("di"."weight"), 0)
5499 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5500 ON "di"."snapshot_id" = "snapshot_id_v"
5501 AND "di"."issue_id" = "issue_id_v"
5502 AND "di"."member_id" = "opinion"."member_id"
5503 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5504 AND "opinion"."degree" = -1
5505 AND "opinion"."fulfilled" = FALSE
5506 ) AS "minus1_unfulfilled_count",
5507 ( SELECT coalesce(sum("di"."weight"), 0)
5508 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5509 ON "di"."snapshot_id" = "snapshot_id_v"
5510 AND "di"."issue_id" = "issue_id_v"
5511 AND "di"."member_id" = "opinion"."member_id"
5512 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5513 AND "opinion"."degree" = -1
5514 AND "opinion"."fulfilled" = TRUE
5515 ) AS "minus1_fulfilled_count",
5516 ( SELECT coalesce(sum("di"."weight"), 0)
5517 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5518 ON "di"."snapshot_id" = "snapshot_id_v"
5519 AND "di"."issue_id" = "issue_id_v"
5520 AND "di"."member_id" = "opinion"."member_id"
5521 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5522 AND "opinion"."degree" = 1
5523 AND "opinion"."fulfilled" = FALSE
5524 ) AS "plus1_unfulfilled_count",
5525 ( SELECT coalesce(sum("di"."weight"), 0)
5526 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5527 ON "di"."snapshot_id" = "snapshot_id_v"
5528 AND "di"."issue_id" = "issue_id_v"
5529 AND "di"."member_id" = "opinion"."member_id"
5530 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5531 AND "opinion"."degree" = 1
5532 AND "opinion"."fulfilled" = TRUE
5533 ) AS "plus1_fulfilled_count",
5534 ( SELECT coalesce(sum("di"."weight"), 0)
5535 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5536 ON "di"."snapshot_id" = "snapshot_id_v"
5537 AND "di"."issue_id" = "issue_id_v"
5538 AND "di"."member_id" = "opinion"."member_id"
5539 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5540 AND "opinion"."degree" = 2
5541 AND "opinion"."fulfilled" = FALSE
5542 ) AS "plus2_unfulfilled_count",
5543 ( SELECT coalesce(sum("di"."weight"), 0)
5544 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5545 ON "di"."snapshot_id" = "snapshot_id_v"
5546 AND "di"."issue_id" = "issue_id_v"
5547 AND "di"."member_id" = "opinion"."member_id"
5548 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5549 AND "opinion"."degree" = 2
5550 AND "opinion"."fulfilled" = TRUE
5551 ) AS "plus2_fulfilled_count"
5552 FROM "suggestion" JOIN "initiative"
5553 ON "suggestion"."initiative_id" = "initiative"."id"
5554 WHERE "initiative"."issue_id" = "issue_id_v";
5555 END LOOP;
5556 RETURN "snapshot_id_v";
5557 END;
5558 $$;
5560 COMMENT ON FUNCTION "take_snapshot"
5561 ( "issue"."id"%TYPE,
5562 "area"."id"%TYPE )
5563 IS 'This function creates a new interest/supporter snapshot of a particular issue, or, if the first argument is NULL, for all issues in ''admission'' phase of the area given as second argument. It must be executed with TRANSACTION ISOLATION LEVEL REPEATABLE READ. The snapshot must later be finished by calling "finish_snapshot" for every issue.';
5566 CREATE FUNCTION "finish_snapshot"
5567 ( "issue_id_p" "issue"."id"%TYPE )
5568 RETURNS VOID
5569 LANGUAGE 'plpgsql' VOLATILE AS $$
5570 DECLARE
5571 "snapshot_id_v" "snapshot"."id"%TYPE;
5572 BEGIN
5573 -- NOTE: function does not require snapshot isolation but we don't call
5574 -- "dont_require_snapshot_isolation" here because this function is
5575 -- also invoked by "check_issue"
5576 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5577 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5578 ORDER BY "id" DESC LIMIT 1;
5579 UPDATE "issue" SET
5580 "calculated" = "snapshot"."calculated",
5581 "latest_snapshot_id" = "snapshot_id_v",
5582 "population" = "snapshot"."population",
5583 "initiative_quorum" = CASE WHEN
5584 "policy"."initiative_quorum" > ceil(
5585 ( "issue"."population"::INT8 *
5586 "policy"."initiative_quorum_num"::INT8 ) /
5587 "policy"."initiative_quorum_den"::FLOAT8
5588 )::INT4
5589 THEN
5590 "policy"."initiative_quorum"
5591 ELSE
5592 ceil(
5593 ( "issue"."population"::INT8 *
5594 "policy"."initiative_quorum_num"::INT8 ) /
5595 "policy"."initiative_quorum_den"::FLOAT8
5596 )::INT4
5597 END
5598 FROM "snapshot", "policy"
5599 WHERE "issue"."id" = "issue_id_p"
5600 AND "snapshot"."id" = "snapshot_id_v"
5601 AND "policy"."id" = "issue"."policy_id";
5602 UPDATE "initiative" SET
5603 "supporter_count" = (
5604 SELECT coalesce(sum("di"."weight"), 0)
5605 FROM "direct_interest_snapshot" AS "di"
5606 JOIN "direct_supporter_snapshot" AS "ds"
5607 ON "di"."member_id" = "ds"."member_id"
5608 WHERE "di"."snapshot_id" = "snapshot_id_v"
5609 AND "di"."issue_id" = "issue_id_p"
5610 AND "ds"."snapshot_id" = "snapshot_id_v"
5611 AND "ds"."initiative_id" = "initiative"."id"
5612 ),
5613 "informed_supporter_count" = (
5614 SELECT coalesce(sum("di"."weight"), 0)
5615 FROM "direct_interest_snapshot" AS "di"
5616 JOIN "direct_supporter_snapshot" AS "ds"
5617 ON "di"."member_id" = "ds"."member_id"
5618 WHERE "di"."snapshot_id" = "snapshot_id_v"
5619 AND "di"."issue_id" = "issue_id_p"
5620 AND "ds"."snapshot_id" = "snapshot_id_v"
5621 AND "ds"."initiative_id" = "initiative"."id"
5622 AND "ds"."informed"
5623 ),
5624 "satisfied_supporter_count" = (
5625 SELECT coalesce(sum("di"."weight"), 0)
5626 FROM "direct_interest_snapshot" AS "di"
5627 JOIN "direct_supporter_snapshot" AS "ds"
5628 ON "di"."member_id" = "ds"."member_id"
5629 WHERE "di"."snapshot_id" = "snapshot_id_v"
5630 AND "di"."issue_id" = "issue_id_p"
5631 AND "ds"."snapshot_id" = "snapshot_id_v"
5632 AND "ds"."initiative_id" = "initiative"."id"
5633 AND "ds"."satisfied"
5634 ),
5635 "satisfied_informed_supporter_count" = (
5636 SELECT coalesce(sum("di"."weight"), 0)
5637 FROM "direct_interest_snapshot" AS "di"
5638 JOIN "direct_supporter_snapshot" AS "ds"
5639 ON "di"."member_id" = "ds"."member_id"
5640 WHERE "di"."snapshot_id" = "snapshot_id_v"
5641 AND "di"."issue_id" = "issue_id_p"
5642 AND "ds"."snapshot_id" = "snapshot_id_v"
5643 AND "ds"."initiative_id" = "initiative"."id"
5644 AND "ds"."informed"
5645 AND "ds"."satisfied"
5647 WHERE "issue_id" = "issue_id_p";
5648 UPDATE "suggestion" SET
5649 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5650 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5651 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5652 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5653 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5654 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5655 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5656 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5657 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5658 WHERE "temp"."id" = "suggestion"."id"
5659 AND "initiative"."issue_id" = "issue_id_p"
5660 AND "suggestion"."initiative_id" = "initiative"."id";
5661 DELETE FROM "temporary_suggestion_counts";
5662 RETURN;
5663 END;
5664 $$;
5666 COMMENT ON FUNCTION "finish_snapshot"
5667 ( "issue"."id"%TYPE )
5668 IS 'After calling "take_snapshot", this function "finish_snapshot" needs to be called for every issue in the snapshot (separate function calls keep locking time minimal)';
5672 -----------------------
5673 -- Counting of votes --
5674 -----------------------
5677 CREATE FUNCTION "weight_of_added_vote_delegations"
5678 ( "issue_id_p" "issue"."id"%TYPE,
5679 "member_id_p" "member"."id"%TYPE,
5680 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5681 RETURNS "direct_voter"."weight"%TYPE
5682 LANGUAGE 'plpgsql' VOLATILE AS $$
5683 DECLARE
5684 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5685 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5686 "weight_v" INT4;
5687 "sub_weight_v" INT4;
5688 BEGIN
5689 PERFORM "require_transaction_isolation"();
5690 "weight_v" := 0;
5691 FOR "issue_delegation_row" IN
5692 SELECT * FROM "issue_delegation"
5693 WHERE "trustee_id" = "member_id_p"
5694 AND "issue_id" = "issue_id_p"
5695 LOOP
5696 IF NOT EXISTS (
5697 SELECT NULL FROM "direct_voter"
5698 WHERE "member_id" = "issue_delegation_row"."truster_id"
5699 AND "issue_id" = "issue_id_p"
5700 ) AND NOT EXISTS (
5701 SELECT NULL FROM "delegating_voter"
5702 WHERE "member_id" = "issue_delegation_row"."truster_id"
5703 AND "issue_id" = "issue_id_p"
5704 ) THEN
5705 "delegate_member_ids_v" :=
5706 "member_id_p" || "delegate_member_ids_p";
5707 INSERT INTO "delegating_voter" (
5708 "issue_id",
5709 "member_id",
5710 "ownweight",
5711 "scope",
5712 "delegate_member_ids"
5713 ) VALUES (
5714 "issue_id_p",
5715 "issue_delegation_row"."truster_id",
5716 "issue_delegation_row"."weight",
5717 "issue_delegation_row"."scope",
5718 "delegate_member_ids_v"
5719 );
5720 "sub_weight_v" := "issue_delegation_row"."weight" +
5721 "weight_of_added_vote_delegations"(
5722 "issue_id_p",
5723 "issue_delegation_row"."truster_id",
5724 "delegate_member_ids_v"
5725 );
5726 UPDATE "delegating_voter"
5727 SET "weight" = "sub_weight_v"
5728 WHERE "issue_id" = "issue_id_p"
5729 AND "member_id" = "issue_delegation_row"."truster_id";
5730 "weight_v" := "weight_v" + "sub_weight_v";
5731 END IF;
5732 END LOOP;
5733 RETURN "weight_v";
5734 END;
5735 $$;
5737 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5738 ( "issue"."id"%TYPE,
5739 "member"."id"%TYPE,
5740 "delegating_voter"."delegate_member_ids"%TYPE )
5741 IS 'Helper function for "add_vote_delegations" function';
5744 CREATE FUNCTION "add_vote_delegations"
5745 ( "issue_id_p" "issue"."id"%TYPE )
5746 RETURNS VOID
5747 LANGUAGE 'plpgsql' VOLATILE AS $$
5748 DECLARE
5749 "member_id_v" "member"."id"%TYPE;
5750 BEGIN
5751 PERFORM "require_transaction_isolation"();
5752 FOR "member_id_v" IN
5753 SELECT "member_id" FROM "direct_voter"
5754 WHERE "issue_id" = "issue_id_p"
5755 LOOP
5756 UPDATE "direct_voter" SET
5757 "weight" = "ownweight" + "weight_of_added_vote_delegations"(
5758 "issue_id_p",
5759 "member_id_v",
5760 '{}'
5762 WHERE "member_id" = "member_id_v"
5763 AND "issue_id" = "issue_id_p";
5764 END LOOP;
5765 RETURN;
5766 END;
5767 $$;
5769 COMMENT ON FUNCTION "add_vote_delegations"
5770 ( "issue_id_p" "issue"."id"%TYPE )
5771 IS 'Helper function for "close_voting" function';
5774 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5775 RETURNS VOID
5776 LANGUAGE 'plpgsql' VOLATILE AS $$
5777 DECLARE
5778 "area_id_v" "area"."id"%TYPE;
5779 "unit_id_v" "unit"."id"%TYPE;
5780 "member_id_v" "member"."id"%TYPE;
5781 BEGIN
5782 PERFORM "require_transaction_isolation"();
5783 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5784 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5785 -- override protection triggers:
5786 INSERT INTO "temporary_transaction_data" ("key", "value")
5787 VALUES ('override_protection_triggers', TRUE::TEXT);
5788 -- delete timestamp of voting comment:
5789 UPDATE "direct_voter" SET "comment_changed" = NULL
5790 WHERE "issue_id" = "issue_id_p";
5791 -- delete delegating votes (in cases of manual reset of issue state):
5792 DELETE FROM "delegating_voter"
5793 WHERE "issue_id" = "issue_id_p";
5794 -- delete votes from non-privileged voters:
5795 DELETE FROM "direct_voter"
5796 USING (
5797 SELECT "direct_voter"."member_id"
5798 FROM "direct_voter"
5799 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5800 LEFT JOIN "privilege"
5801 ON "privilege"."unit_id" = "unit_id_v"
5802 AND "privilege"."member_id" = "direct_voter"."member_id"
5803 LEFT JOIN "issue_privilege"
5804 ON "issue_privilege"."issue_id" = "issue_id_p"
5805 AND "issue_privilege"."member_id" = "direct_voter"."member_id"
5806 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5807 "member"."active" = FALSE OR
5808 COALESCE(
5809 "issue_privilege"."voting_right",
5810 "privilege"."voting_right",
5811 FALSE
5812 ) = FALSE
5814 ) AS "subquery"
5815 WHERE "direct_voter"."issue_id" = "issue_id_p"
5816 AND "direct_voter"."member_id" = "subquery"."member_id";
5817 -- consider voting weight and delegations:
5818 UPDATE "direct_voter" SET "ownweight" = "privilege"."weight"
5819 FROM "privilege"
5820 WHERE "issue_id" = "issue_id_p"
5821 AND "privilege"."unit_id" = "unit_id_v"
5822 AND "privilege"."member_id" = "direct_voter"."member_id";
5823 UPDATE "direct_voter" SET "ownweight" = "issue_privilege"."weight"
5824 FROM "issue_privilege"
5825 WHERE "direct_voter"."issue_id" = "issue_id_p"
5826 AND "issue_privilege"."issue_id" = "issue_id_p"
5827 AND "issue_privilege"."member_id" = "direct_voter"."member_id";
5828 PERFORM "add_vote_delegations"("issue_id_p");
5829 -- mark first preferences:
5830 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5831 FROM (
5832 SELECT
5833 "vote"."initiative_id",
5834 "vote"."member_id",
5835 CASE WHEN "vote"."grade" > 0 THEN
5836 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5837 ELSE NULL
5838 END AS "first_preference"
5839 FROM "vote"
5840 JOIN "initiative" -- NOTE: due to missing index on issue_id
5841 ON "vote"."issue_id" = "initiative"."issue_id"
5842 JOIN "vote" AS "agg"
5843 ON "initiative"."id" = "agg"."initiative_id"
5844 AND "vote"."member_id" = "agg"."member_id"
5845 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5846 ) AS "subquery"
5847 WHERE "vote"."issue_id" = "issue_id_p"
5848 AND "vote"."initiative_id" = "subquery"."initiative_id"
5849 AND "vote"."member_id" = "subquery"."member_id";
5850 -- finish overriding protection triggers (avoids garbage):
5851 DELETE FROM "temporary_transaction_data"
5852 WHERE "key" = 'override_protection_triggers';
5853 -- materialize battle_view:
5854 -- NOTE: "closed" column of issue must be set at this point
5855 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5856 INSERT INTO "battle" (
5857 "issue_id",
5858 "winning_initiative_id", "losing_initiative_id",
5859 "count"
5860 ) SELECT
5861 "issue_id",
5862 "winning_initiative_id", "losing_initiative_id",
5863 "count"
5864 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5865 -- set voter count:
5866 UPDATE "issue" SET
5867 "voter_count" = (
5868 SELECT coalesce(sum("weight"), 0)
5869 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5871 WHERE "id" = "issue_id_p";
5872 -- copy "positive_votes" and "negative_votes" from "battle" table:
5873 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5874 UPDATE "initiative" SET
5875 "first_preference_votes" = 0,
5876 "positive_votes" = "battle_win"."count",
5877 "negative_votes" = "battle_lose"."count"
5878 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5879 WHERE
5880 "battle_win"."issue_id" = "issue_id_p" AND
5881 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5882 "battle_win"."losing_initiative_id" ISNULL AND
5883 "battle_lose"."issue_id" = "issue_id_p" AND
5884 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5885 "battle_lose"."winning_initiative_id" ISNULL;
5886 -- calculate "first_preference_votes":
5887 -- NOTE: will only set values not equal to zero
5888 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5889 FROM (
5890 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5891 FROM "vote" JOIN "direct_voter"
5892 ON "vote"."issue_id" = "direct_voter"."issue_id"
5893 AND "vote"."member_id" = "direct_voter"."member_id"
5894 WHERE "vote"."first_preference"
5895 GROUP BY "vote"."initiative_id"
5896 ) AS "subquery"
5897 WHERE "initiative"."issue_id" = "issue_id_p"
5898 AND "initiative"."admitted"
5899 AND "initiative"."id" = "subquery"."initiative_id";
5900 END;
5901 $$;
5903 COMMENT ON FUNCTION "close_voting"
5904 ( "issue"."id"%TYPE )
5905 IS 'Closes the voting on an issue, and calculates positive and negative votes for each initiative; The ranking is not calculated yet, to keep the (locking) transaction short.';
5908 CREATE FUNCTION "defeat_strength"
5909 ( "positive_votes_p" INT4,
5910 "negative_votes_p" INT4,
5911 "defeat_strength_p" "defeat_strength" )
5912 RETURNS INT8
5913 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5914 BEGIN
5915 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5916 IF "positive_votes_p" > "negative_votes_p" THEN
5917 RETURN "positive_votes_p";
5918 ELSE
5919 RETURN 0;
5920 END IF;
5921 ELSE
5922 IF "positive_votes_p" > "negative_votes_p" THEN
5923 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5924 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5925 RETURN 0;
5926 ELSE
5927 RETURN -1;
5928 END IF;
5929 END IF;
5930 END;
5931 $$;
5933 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4, "defeat_strength") IS 'Calculates defeat strength (INT8!) according to the "defeat_strength" option (see comment on type "defeat_strength")';
5936 CREATE FUNCTION "secondary_link_strength"
5937 ( "initiative1_ord_p" INT4,
5938 "initiative2_ord_p" INT4,
5939 "tie_breaking_p" "tie_breaking" )
5940 RETURNS INT8
5941 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5942 BEGIN
5943 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5944 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5945 END IF;
5946 RETURN (
5947 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5949 ELSE
5950 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5951 1::INT8 << 62
5952 ELSE 0 END
5954 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5955 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5956 ELSE
5957 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5958 END
5959 END
5960 );
5961 END;
5962 $$;
5964 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5967 CREATE TYPE "link_strength" AS (
5968 "primary" INT8,
5969 "secondary" INT8 );
5971 COMMENT ON TYPE "link_strength" IS 'Type to store the defeat strength of a link between two candidates plus a secondary criterion to create unique link strengths between the candidates (needed for tie-breaking ''variant1'' and ''variant2'')';
5974 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5975 RETURNS "link_strength"[][]
5976 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5977 DECLARE
5978 "dimension_v" INT4;
5979 "matrix_p" "link_strength"[][];
5980 "i" INT4;
5981 "j" INT4;
5982 "k" INT4;
5983 BEGIN
5984 "dimension_v" := array_upper("matrix_d", 1);
5985 "matrix_p" := "matrix_d";
5986 "i" := 1;
5987 LOOP
5988 "j" := 1;
5989 LOOP
5990 IF "i" != "j" THEN
5991 "k" := 1;
5992 LOOP
5993 IF "i" != "k" AND "j" != "k" THEN
5994 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5995 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5996 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5997 END IF;
5998 ELSE
5999 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
6000 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
6001 END IF;
6002 END IF;
6003 END IF;
6004 EXIT WHEN "k" = "dimension_v";
6005 "k" := "k" + 1;
6006 END LOOP;
6007 END IF;
6008 EXIT WHEN "j" = "dimension_v";
6009 "j" := "j" + 1;
6010 END LOOP;
6011 EXIT WHEN "i" = "dimension_v";
6012 "i" := "i" + 1;
6013 END LOOP;
6014 RETURN "matrix_p";
6015 END;
6016 $$;
6018 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
6021 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
6022 RETURNS VOID
6023 LANGUAGE 'plpgsql' VOLATILE AS $$
6024 DECLARE
6025 "issue_row" "issue"%ROWTYPE;
6026 "policy_row" "policy"%ROWTYPE;
6027 "dimension_v" INT4;
6028 "matrix_a" INT4[][]; -- absolute votes
6029 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
6030 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
6031 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
6032 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
6033 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
6034 "i" INT4;
6035 "j" INT4;
6036 "m" INT4;
6037 "n" INT4;
6038 "battle_row" "battle"%ROWTYPE;
6039 "rank_ary" INT4[];
6040 "rank_v" INT4;
6041 "initiative_id_v" "initiative"."id"%TYPE;
6042 BEGIN
6043 PERFORM "require_transaction_isolation"();
6044 SELECT * INTO "issue_row"
6045 FROM "issue" WHERE "id" = "issue_id_p";
6046 SELECT * INTO "policy_row"
6047 FROM "policy" WHERE "id" = "issue_row"."policy_id";
6048 SELECT count(1) INTO "dimension_v"
6049 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
6050 -- create "matrix_a" with absolute number of votes in pairwise
6051 -- comparison:
6052 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
6053 "i" := 1;
6054 "j" := 2;
6055 FOR "battle_row" IN
6056 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
6057 ORDER BY
6058 "winning_initiative_id" NULLS FIRST,
6059 "losing_initiative_id" NULLS FIRST
6060 LOOP
6061 "matrix_a"["i"]["j"] := "battle_row"."count";
6062 IF "j" = "dimension_v" THEN
6063 "i" := "i" + 1;
6064 "j" := 1;
6065 ELSE
6066 "j" := "j" + 1;
6067 IF "j" = "i" THEN
6068 "j" := "j" + 1;
6069 END IF;
6070 END IF;
6071 END LOOP;
6072 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
6073 RAISE EXCEPTION 'Wrong battle count (should not happen)';
6074 END IF;
6075 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
6076 -- and "secondary_link_strength" functions:
6077 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
6078 "i" := 1;
6079 LOOP
6080 "j" := 1;
6081 LOOP
6082 IF "i" != "j" THEN
6083 "matrix_d"["i"]["j"] := (
6084 "defeat_strength"(
6085 "matrix_a"["i"]["j"],
6086 "matrix_a"["j"]["i"],
6087 "policy_row"."defeat_strength"
6088 ),
6089 "secondary_link_strength"(
6090 "i",
6091 "j",
6092 "policy_row"."tie_breaking"
6094 )::"link_strength";
6095 END IF;
6096 EXIT WHEN "j" = "dimension_v";
6097 "j" := "j" + 1;
6098 END LOOP;
6099 EXIT WHEN "i" = "dimension_v";
6100 "i" := "i" + 1;
6101 END LOOP;
6102 -- find best paths:
6103 "matrix_p" := "find_best_paths"("matrix_d");
6104 -- create partial order:
6105 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
6106 "i" := 1;
6107 LOOP
6108 "j" := "i" + 1;
6109 LOOP
6110 IF "i" != "j" THEN
6111 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
6112 "matrix_b"["i"]["j"] := TRUE;
6113 "matrix_b"["j"]["i"] := FALSE;
6114 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
6115 "matrix_b"["i"]["j"] := FALSE;
6116 "matrix_b"["j"]["i"] := TRUE;
6117 END IF;
6118 END IF;
6119 EXIT WHEN "j" = "dimension_v";
6120 "j" := "j" + 1;
6121 END LOOP;
6122 EXIT WHEN "i" = "dimension_v" - 1;
6123 "i" := "i" + 1;
6124 END LOOP;
6125 -- tie-breaking by forbidding shared weakest links in beat-paths
6126 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
6127 -- is performed later by initiative id):
6128 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
6129 "m" := 1;
6130 LOOP
6131 "n" := "m" + 1;
6132 LOOP
6133 -- only process those candidates m and n, which are tied:
6134 IF "matrix_b"["m"]["n"] ISNULL THEN
6135 -- start with beat-paths prior tie-breaking:
6136 "matrix_t" := "matrix_p";
6137 -- start with all links allowed:
6138 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
6139 LOOP
6140 -- determine (and forbid) that link that is the weakest link
6141 -- in both the best path from candidate m to candidate n and
6142 -- from candidate n to candidate m:
6143 "i" := 1;
6144 <<forbid_one_link>>
6145 LOOP
6146 "j" := 1;
6147 LOOP
6148 IF "i" != "j" THEN
6149 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
6150 "matrix_f"["i"]["j"] := TRUE;
6151 -- exit for performance reasons,
6152 -- as exactly one link will be found:
6153 EXIT forbid_one_link;
6154 END IF;
6155 END IF;
6156 EXIT WHEN "j" = "dimension_v";
6157 "j" := "j" + 1;
6158 END LOOP;
6159 IF "i" = "dimension_v" THEN
6160 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
6161 END IF;
6162 "i" := "i" + 1;
6163 END LOOP;
6164 -- calculate best beat-paths while ignoring forbidden links:
6165 "i" := 1;
6166 LOOP
6167 "j" := 1;
6168 LOOP
6169 IF "i" != "j" THEN
6170 "matrix_t"["i"]["j"] := CASE
6171 WHEN "matrix_f"["i"]["j"]
6172 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
6173 ELSE "matrix_d"["i"]["j"] END;
6174 END IF;
6175 EXIT WHEN "j" = "dimension_v";
6176 "j" := "j" + 1;
6177 END LOOP;
6178 EXIT WHEN "i" = "dimension_v";
6179 "i" := "i" + 1;
6180 END LOOP;
6181 "matrix_t" := "find_best_paths"("matrix_t");
6182 -- extend partial order, if tie-breaking was successful:
6183 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
6184 "matrix_b"["m"]["n"] := TRUE;
6185 "matrix_b"["n"]["m"] := FALSE;
6186 EXIT;
6187 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
6188 "matrix_b"["m"]["n"] := FALSE;
6189 "matrix_b"["n"]["m"] := TRUE;
6190 EXIT;
6191 END IF;
6192 END LOOP;
6193 END IF;
6194 EXIT WHEN "n" = "dimension_v";
6195 "n" := "n" + 1;
6196 END LOOP;
6197 EXIT WHEN "m" = "dimension_v" - 1;
6198 "m" := "m" + 1;
6199 END LOOP;
6200 END IF;
6201 -- store a unique ranking in "rank_ary":
6202 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
6203 "rank_v" := 1;
6204 LOOP
6205 "i" := 1;
6206 <<assign_next_rank>>
6207 LOOP
6208 IF "rank_ary"["i"] ISNULL THEN
6209 "j" := 1;
6210 LOOP
6211 IF
6212 "i" != "j" AND
6213 "rank_ary"["j"] ISNULL AND
6214 ( "matrix_b"["j"]["i"] OR
6215 -- tie-breaking by "id"
6216 ( "matrix_b"["j"]["i"] ISNULL AND
6217 "j" < "i" ) )
6218 THEN
6219 -- someone else is better
6220 EXIT;
6221 END IF;
6222 IF "j" = "dimension_v" THEN
6223 -- noone is better
6224 "rank_ary"["i"] := "rank_v";
6225 EXIT assign_next_rank;
6226 END IF;
6227 "j" := "j" + 1;
6228 END LOOP;
6229 END IF;
6230 "i" := "i" + 1;
6231 IF "i" > "dimension_v" THEN
6232 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
6233 END IF;
6234 END LOOP;
6235 EXIT WHEN "rank_v" = "dimension_v";
6236 "rank_v" := "rank_v" + 1;
6237 END LOOP;
6238 -- write preliminary results:
6239 "i" := 2; -- omit status quo with "i" = 1
6240 FOR "initiative_id_v" IN
6241 SELECT "id" FROM "initiative"
6242 WHERE "issue_id" = "issue_id_p" AND "admitted"
6243 ORDER BY "id"
6244 LOOP
6245 UPDATE "initiative" SET
6246 "direct_majority" =
6247 CASE WHEN "policy_row"."direct_majority_strict" THEN
6248 "positive_votes" * "policy_row"."direct_majority_den" >
6249 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6250 ELSE
6251 "positive_votes" * "policy_row"."direct_majority_den" >=
6252 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6253 END
6254 AND "positive_votes" >= "policy_row"."direct_majority_positive"
6255 AND "issue_row"."voter_count"-"negative_votes" >=
6256 "policy_row"."direct_majority_non_negative",
6257 "indirect_majority" =
6258 CASE WHEN "policy_row"."indirect_majority_strict" THEN
6259 "positive_votes" * "policy_row"."indirect_majority_den" >
6260 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6261 ELSE
6262 "positive_votes" * "policy_row"."indirect_majority_den" >=
6263 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6264 END
6265 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
6266 AND "issue_row"."voter_count"-"negative_votes" >=
6267 "policy_row"."indirect_majority_non_negative",
6268 "schulze_rank" = "rank_ary"["i"],
6269 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
6270 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
6271 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
6272 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
6273 THEN NULL
6274 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
6275 "eligible" = FALSE,
6276 "winner" = FALSE,
6277 "rank" = NULL -- NOTE: in cases of manual reset of issue state
6278 WHERE "id" = "initiative_id_v";
6279 "i" := "i" + 1;
6280 END LOOP;
6281 IF "i" != "dimension_v" + 1 THEN
6282 RAISE EXCEPTION 'Wrong winner count (should not happen)';
6283 END IF;
6284 -- take indirect majorities into account:
6285 LOOP
6286 UPDATE "initiative" SET "indirect_majority" = TRUE
6287 FROM (
6288 SELECT "new_initiative"."id" AS "initiative_id"
6289 FROM "initiative" "old_initiative"
6290 JOIN "initiative" "new_initiative"
6291 ON "new_initiative"."issue_id" = "issue_id_p"
6292 AND "new_initiative"."indirect_majority" = FALSE
6293 JOIN "battle" "battle_win"
6294 ON "battle_win"."issue_id" = "issue_id_p"
6295 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
6296 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
6297 JOIN "battle" "battle_lose"
6298 ON "battle_lose"."issue_id" = "issue_id_p"
6299 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
6300 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
6301 WHERE "old_initiative"."issue_id" = "issue_id_p"
6302 AND "old_initiative"."indirect_majority" = TRUE
6303 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
6304 "battle_win"."count" * "policy_row"."indirect_majority_den" >
6305 "policy_row"."indirect_majority_num" *
6306 ("battle_win"."count"+"battle_lose"."count")
6307 ELSE
6308 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
6309 "policy_row"."indirect_majority_num" *
6310 ("battle_win"."count"+"battle_lose"."count")
6311 END
6312 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6313 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6314 "policy_row"."indirect_majority_non_negative"
6315 ) AS "subquery"
6316 WHERE "id" = "subquery"."initiative_id";
6317 EXIT WHEN NOT FOUND;
6318 END LOOP;
6319 -- set "multistage_majority" for remaining matching initiatives:
6320 UPDATE "initiative" SET "multistage_majority" = TRUE
6321 FROM (
6322 SELECT "losing_initiative"."id" AS "initiative_id"
6323 FROM "initiative" "losing_initiative"
6324 JOIN "initiative" "winning_initiative"
6325 ON "winning_initiative"."issue_id" = "issue_id_p"
6326 AND "winning_initiative"."admitted"
6327 JOIN "battle" "battle_win"
6328 ON "battle_win"."issue_id" = "issue_id_p"
6329 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6330 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6331 JOIN "battle" "battle_lose"
6332 ON "battle_lose"."issue_id" = "issue_id_p"
6333 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6334 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6335 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6336 AND "losing_initiative"."admitted"
6337 AND "winning_initiative"."schulze_rank" <
6338 "losing_initiative"."schulze_rank"
6339 AND "battle_win"."count" > "battle_lose"."count"
6340 AND (
6341 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6342 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6343 ) AS "subquery"
6344 WHERE "id" = "subquery"."initiative_id";
6345 -- mark eligible initiatives:
6346 UPDATE "initiative" SET "eligible" = TRUE
6347 WHERE "issue_id" = "issue_id_p"
6348 AND "initiative"."direct_majority"
6349 AND "initiative"."indirect_majority"
6350 AND "initiative"."better_than_status_quo"
6351 AND (
6352 "policy_row"."no_multistage_majority" = FALSE OR
6353 "initiative"."multistage_majority" = FALSE )
6354 AND (
6355 "policy_row"."no_reverse_beat_path" = FALSE OR
6356 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6357 -- mark final winner:
6358 UPDATE "initiative" SET "winner" = TRUE
6359 FROM (
6360 SELECT "id" AS "initiative_id"
6361 FROM "initiative"
6362 WHERE "issue_id" = "issue_id_p" AND "eligible"
6363 ORDER BY
6364 "schulze_rank",
6365 "id"
6366 LIMIT 1
6367 ) AS "subquery"
6368 WHERE "id" = "subquery"."initiative_id";
6369 -- write (final) ranks:
6370 "rank_v" := 1;
6371 FOR "initiative_id_v" IN
6372 SELECT "id"
6373 FROM "initiative"
6374 WHERE "issue_id" = "issue_id_p" AND "admitted"
6375 ORDER BY
6376 "winner" DESC,
6377 "eligible" DESC,
6378 "schulze_rank",
6379 "id"
6380 LOOP
6381 UPDATE "initiative" SET "rank" = "rank_v"
6382 WHERE "id" = "initiative_id_v";
6383 "rank_v" := "rank_v" + 1;
6384 END LOOP;
6385 -- set schulze rank of status quo and mark issue as finished:
6386 UPDATE "issue" SET
6387 "status_quo_schulze_rank" = "rank_ary"[1],
6388 "state" =
6389 CASE WHEN EXISTS (
6390 SELECT NULL FROM "initiative"
6391 WHERE "issue_id" = "issue_id_p" AND "winner"
6392 ) THEN
6393 'finished_with_winner'::"issue_state"
6394 ELSE
6395 'finished_without_winner'::"issue_state"
6396 END,
6397 "closed" = "phase_finished",
6398 "phase_finished" = NULL
6399 WHERE "id" = "issue_id_p";
6400 RETURN;
6401 END;
6402 $$;
6404 COMMENT ON FUNCTION "calculate_ranks"
6405 ( "issue"."id"%TYPE )
6406 IS 'Determine ranking (Votes have to be counted first)';
6410 -----------------------------
6411 -- Automatic state changes --
6412 -----------------------------
6415 CREATE FUNCTION "issue_admission"
6416 ( "area_id_p" "area"."id"%TYPE )
6417 RETURNS BOOLEAN
6418 LANGUAGE 'plpgsql' VOLATILE AS $$
6419 DECLARE
6420 "issue_id_v" "issue"."id"%TYPE;
6421 BEGIN
6422 PERFORM "dont_require_transaction_isolation"();
6423 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6424 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6425 FROM "area_quorum" AS "view"
6426 WHERE "area"."id" = "view"."area_id"
6427 AND "area"."id" = "area_id_p";
6428 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6429 WHERE "area_id" = "area_id_p";
6430 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6431 UPDATE "issue" SET
6432 "admission_snapshot_id" = "latest_snapshot_id",
6433 "state" = 'discussion',
6434 "accepted" = now(),
6435 "phase_finished" = NULL,
6436 "issue_quorum" = "issue_quorum"."issue_quorum"
6437 FROM "issue_quorum"
6438 WHERE "id" = "issue_id_v"
6439 AND "issue_quorum"."issue_id" = "issue_id_v";
6440 RETURN TRUE;
6441 END;
6442 $$;
6444 COMMENT ON FUNCTION "issue_admission"
6445 ( "area"."id"%TYPE )
6446 IS 'Checks if an issue in the area can be admitted for further discussion; returns TRUE on success in which case the function must be called again until it returns FALSE';
6449 CREATE TYPE "check_issue_persistence" AS (
6450 "state" "issue_state",
6451 "phase_finished" BOOLEAN,
6452 "issue_revoked" BOOLEAN,
6453 "snapshot_created" BOOLEAN,
6454 "harmonic_weights_set" BOOLEAN,
6455 "closed_voting" BOOLEAN );
6457 COMMENT ON TYPE "check_issue_persistence" IS 'Type of data returned by "check_issue" function, to be passed to subsequent calls of the same function';
6460 CREATE FUNCTION "check_issue"
6461 ( "issue_id_p" "issue"."id"%TYPE,
6462 "persist" "check_issue_persistence" )
6463 RETURNS "check_issue_persistence"
6464 LANGUAGE 'plpgsql' VOLATILE AS $$
6465 DECLARE
6466 "issue_row" "issue"%ROWTYPE;
6467 "last_calculated_v" "snapshot"."calculated"%TYPE;
6468 "policy_row" "policy"%ROWTYPE;
6469 "initiative_row" "initiative"%ROWTYPE;
6470 "state_v" "issue_state";
6471 BEGIN
6472 PERFORM "require_transaction_isolation"();
6473 IF "persist" ISNULL THEN
6474 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6475 FOR UPDATE;
6476 SELECT "calculated" INTO "last_calculated_v"
6477 FROM "snapshot" JOIN "snapshot_issue"
6478 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6479 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
6480 ORDER BY "snapshot"."id" DESC;
6481 IF "issue_row"."closed" NOTNULL THEN
6482 RETURN NULL;
6483 END IF;
6484 "persist"."state" := "issue_row"."state";
6485 IF
6486 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6487 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6488 ( "issue_row"."state" = 'discussion' AND now() >=
6489 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6490 ( "issue_row"."state" = 'verification' AND now() >=
6491 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6492 ( "issue_row"."state" = 'voting' AND now() >=
6493 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6494 THEN
6495 "persist"."phase_finished" := TRUE;
6496 ELSE
6497 "persist"."phase_finished" := FALSE;
6498 END IF;
6499 IF
6500 NOT EXISTS (
6501 -- all initiatives are revoked
6502 SELECT NULL FROM "initiative"
6503 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6504 ) AND (
6505 -- and issue has not been accepted yet
6506 "persist"."state" = 'admission' OR
6507 -- or verification time has elapsed
6508 ( "persist"."state" = 'verification' AND
6509 "persist"."phase_finished" ) OR
6510 -- or no initiatives have been revoked lately
6511 NOT EXISTS (
6512 SELECT NULL FROM "initiative"
6513 WHERE "issue_id" = "issue_id_p"
6514 AND now() < "revoked" + "issue_row"."verification_time"
6517 THEN
6518 "persist"."issue_revoked" := TRUE;
6519 ELSE
6520 "persist"."issue_revoked" := FALSE;
6521 END IF;
6522 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6523 UPDATE "issue" SET "phase_finished" = now()
6524 WHERE "id" = "issue_row"."id";
6525 RETURN "persist";
6526 ELSIF
6527 "persist"."state" IN ('admission', 'discussion', 'verification')
6528 THEN
6529 RETURN "persist";
6530 ELSE
6531 RETURN NULL;
6532 END IF;
6533 END IF;
6534 IF
6535 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6536 coalesce("persist"."snapshot_created", FALSE) = FALSE
6537 THEN
6538 IF "persist"."state" != 'admission' THEN
6539 PERFORM "take_snapshot"("issue_id_p");
6540 PERFORM "finish_snapshot"("issue_id_p");
6541 ELSE
6542 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6543 FROM "issue_quorum"
6544 WHERE "id" = "issue_id_p"
6545 AND "issue_quorum"."issue_id" = "issue_id_p";
6546 END IF;
6547 "persist"."snapshot_created" = TRUE;
6548 IF "persist"."phase_finished" THEN
6549 IF "persist"."state" = 'admission' THEN
6550 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6551 WHERE "id" = "issue_id_p";
6552 ELSIF "persist"."state" = 'discussion' THEN
6553 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6554 WHERE "id" = "issue_id_p";
6555 ELSIF "persist"."state" = 'verification' THEN
6556 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6557 WHERE "id" = "issue_id_p";
6558 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6559 FOR "initiative_row" IN
6560 SELECT * FROM "initiative"
6561 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6562 FOR UPDATE
6563 LOOP
6564 IF
6565 "initiative_row"."polling" OR
6566 "initiative_row"."satisfied_supporter_count" >=
6567 "issue_row"."initiative_quorum"
6568 THEN
6569 UPDATE "initiative" SET "admitted" = TRUE
6570 WHERE "id" = "initiative_row"."id";
6571 ELSE
6572 UPDATE "initiative" SET "admitted" = FALSE
6573 WHERE "id" = "initiative_row"."id";
6574 END IF;
6575 END LOOP;
6576 END IF;
6577 END IF;
6578 RETURN "persist";
6579 END IF;
6580 IF
6581 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6582 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6583 THEN
6584 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6585 "persist"."harmonic_weights_set" = TRUE;
6586 IF
6587 "persist"."phase_finished" OR
6588 "persist"."issue_revoked" OR
6589 "persist"."state" = 'admission'
6590 THEN
6591 RETURN "persist";
6592 ELSE
6593 RETURN NULL;
6594 END IF;
6595 END IF;
6596 IF "persist"."issue_revoked" THEN
6597 IF "persist"."state" = 'admission' THEN
6598 "state_v" := 'canceled_revoked_before_accepted';
6599 ELSIF "persist"."state" = 'discussion' THEN
6600 "state_v" := 'canceled_after_revocation_during_discussion';
6601 ELSIF "persist"."state" = 'verification' THEN
6602 "state_v" := 'canceled_after_revocation_during_verification';
6603 END IF;
6604 UPDATE "issue" SET
6605 "state" = "state_v",
6606 "closed" = "phase_finished",
6607 "phase_finished" = NULL
6608 WHERE "id" = "issue_id_p";
6609 RETURN NULL;
6610 END IF;
6611 IF "persist"."state" = 'admission' THEN
6612 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6613 FOR UPDATE;
6614 IF "issue_row"."phase_finished" NOTNULL THEN
6615 UPDATE "issue" SET
6616 "state" = 'canceled_issue_not_accepted',
6617 "closed" = "phase_finished",
6618 "phase_finished" = NULL
6619 WHERE "id" = "issue_id_p";
6620 END IF;
6621 RETURN NULL;
6622 END IF;
6623 IF "persist"."phase_finished" THEN
6624 IF "persist"."state" = 'discussion' THEN
6625 UPDATE "issue" SET
6626 "state" = 'verification',
6627 "half_frozen" = "phase_finished",
6628 "phase_finished" = NULL
6629 WHERE "id" = "issue_id_p";
6630 RETURN NULL;
6631 END IF;
6632 IF "persist"."state" = 'verification' THEN
6633 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6634 FOR UPDATE;
6635 SELECT * INTO "policy_row" FROM "policy"
6636 WHERE "id" = "issue_row"."policy_id";
6637 IF EXISTS (
6638 SELECT NULL FROM "initiative"
6639 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6640 ) THEN
6641 UPDATE "issue" SET
6642 "state" = 'voting',
6643 "fully_frozen" = "phase_finished",
6644 "phase_finished" = NULL
6645 WHERE "id" = "issue_id_p";
6646 ELSE
6647 UPDATE "issue" SET
6648 "state" = 'canceled_no_initiative_admitted',
6649 "fully_frozen" = "phase_finished",
6650 "closed" = "phase_finished",
6651 "phase_finished" = NULL
6652 WHERE "id" = "issue_id_p";
6653 -- NOTE: The following DELETE statements have effect only when
6654 -- issue state has been manipulated
6655 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6656 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6657 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6658 END IF;
6659 RETURN NULL;
6660 END IF;
6661 IF "persist"."state" = 'voting' THEN
6662 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6663 PERFORM "close_voting"("issue_id_p");
6664 "persist"."closed_voting" = TRUE;
6665 RETURN "persist";
6666 END IF;
6667 PERFORM "calculate_ranks"("issue_id_p");
6668 RETURN NULL;
6669 END IF;
6670 END IF;
6671 RAISE WARNING 'should not happen';
6672 RETURN NULL;
6673 END;
6674 $$;
6676 COMMENT ON FUNCTION "check_issue"
6677 ( "issue"."id"%TYPE,
6678 "check_issue_persistence" )
6679 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required, and perform the status change when necessary; Function must be called multiple times with the previous result as second parameter, until the result is NULL (see source code of function "check_everything")';
6682 CREATE FUNCTION "check_everything"()
6683 RETURNS VOID
6684 LANGUAGE 'plpgsql' VOLATILE AS $$
6685 DECLARE
6686 "area_id_v" "area"."id"%TYPE;
6687 "snapshot_id_v" "snapshot"."id"%TYPE;
6688 "issue_id_v" "issue"."id"%TYPE;
6689 "persist_v" "check_issue_persistence";
6690 BEGIN
6691 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6692 DELETE FROM "expired_session";
6693 DELETE FROM "expired_token";
6694 DELETE FROM "unused_snapshot";
6695 PERFORM "check_activity"();
6696 PERFORM "calculate_member_counts"();
6697 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6698 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6699 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6700 WHERE "snapshot_id" = "snapshot_id_v";
6701 LOOP
6702 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6703 END LOOP;
6704 END LOOP;
6705 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6706 "persist_v" := NULL;
6707 LOOP
6708 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6709 EXIT WHEN "persist_v" ISNULL;
6710 END LOOP;
6711 END LOOP;
6712 DELETE FROM "unused_snapshot";
6713 RETURN;
6714 END;
6715 $$;
6717 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks, this function performs "check_issue" for every open issue. Use this function only for development and debugging purposes, as you may run into locking and/or serialization problems in productive environments. For production, use lf_update binary instead';
6721 ----------------------
6722 -- Deletion of data --
6723 ----------------------
6726 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6727 RETURNS VOID
6728 LANGUAGE 'plpgsql' VOLATILE AS $$
6729 BEGIN
6730 IF EXISTS (
6731 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6732 ) THEN
6733 -- override protection triggers:
6734 INSERT INTO "temporary_transaction_data" ("key", "value")
6735 VALUES ('override_protection_triggers', TRUE::TEXT);
6736 -- clean data:
6737 DELETE FROM "delegating_voter"
6738 WHERE "issue_id" = "issue_id_p";
6739 DELETE FROM "direct_voter"
6740 WHERE "issue_id" = "issue_id_p";
6741 DELETE FROM "delegating_interest_snapshot"
6742 WHERE "issue_id" = "issue_id_p";
6743 DELETE FROM "direct_interest_snapshot"
6744 WHERE "issue_id" = "issue_id_p";
6745 DELETE FROM "non_voter"
6746 WHERE "issue_id" = "issue_id_p";
6747 DELETE FROM "delegation"
6748 WHERE "issue_id" = "issue_id_p";
6749 DELETE FROM "supporter"
6750 USING "initiative" -- NOTE: due to missing index on issue_id
6751 WHERE "initiative"."issue_id" = "issue_id_p"
6752 AND "supporter"."initiative_id" = "initiative_id";
6753 -- mark issue as cleaned:
6754 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6755 -- finish overriding protection triggers (avoids garbage):
6756 DELETE FROM "temporary_transaction_data"
6757 WHERE "key" = 'override_protection_triggers';
6758 END IF;
6759 RETURN;
6760 END;
6761 $$;
6763 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6766 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6767 RETURNS VOID
6768 LANGUAGE 'plpgsql' VOLATILE AS $$
6769 BEGIN
6770 UPDATE "member" SET
6771 "last_login" = NULL,
6772 "last_delegation_check" = NULL,
6773 "login" = NULL,
6774 "password" = NULL,
6775 "authority" = NULL,
6776 "authority_uid" = NULL,
6777 "authority_login" = NULL,
6778 "deleted" = coalesce("deleted", now()),
6779 "locked" = TRUE,
6780 "active" = FALSE,
6781 "notify_email" = NULL,
6782 "notify_email_unconfirmed" = NULL,
6783 "notify_email_secret" = NULL,
6784 "notify_email_secret_expiry" = NULL,
6785 "notify_email_lock_expiry" = NULL,
6786 "disable_notifications" = TRUE,
6787 "notification_counter" = DEFAULT,
6788 "notification_sample_size" = 0,
6789 "notification_dow" = NULL,
6790 "notification_hour" = NULL,
6791 "notification_sent" = NULL,
6792 "login_recovery_expiry" = NULL,
6793 "password_reset_secret" = NULL,
6794 "password_reset_secret_expiry" = NULL,
6795 "location" = NULL
6796 WHERE "id" = "member_id_p";
6797 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6798 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6799 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6800 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6801 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6802 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6803 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6804 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6805 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6806 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6807 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6808 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6809 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6810 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6811 DELETE FROM "direct_voter" USING "issue"
6812 WHERE "direct_voter"."issue_id" = "issue"."id"
6813 AND "issue"."closed" ISNULL
6814 AND "member_id" = "member_id_p";
6815 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6816 RETURN;
6817 END;
6818 $$;
6820 COMMENT ON FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) IS 'Deactivate member and clear certain settings and data of this member (data protection)';
6823 CREATE FUNCTION "delete_private_data"()
6824 RETURNS VOID
6825 LANGUAGE 'plpgsql' VOLATILE AS $$
6826 BEGIN
6827 DELETE FROM "temporary_transaction_data";
6828 DELETE FROM "temporary_suggestion_counts";
6829 DELETE FROM "member" WHERE "activated" ISNULL;
6830 UPDATE "member" SET
6831 "invite_code" = NULL,
6832 "invite_code_expiry" = NULL,
6833 "admin_comment" = NULL,
6834 "last_login" = NULL,
6835 "last_delegation_check" = NULL,
6836 "login" = NULL,
6837 "password" = NULL,
6838 "authority" = NULL,
6839 "authority_uid" = NULL,
6840 "authority_login" = NULL,
6841 "lang" = NULL,
6842 "notify_email" = NULL,
6843 "notify_email_unconfirmed" = NULL,
6844 "notify_email_secret" = NULL,
6845 "notify_email_secret_expiry" = NULL,
6846 "notify_email_lock_expiry" = NULL,
6847 "disable_notifications" = TRUE,
6848 "notification_counter" = DEFAULT,
6849 "notification_sample_size" = 0,
6850 "notification_dow" = NULL,
6851 "notification_hour" = NULL,
6852 "notification_sent" = NULL,
6853 "login_recovery_expiry" = NULL,
6854 "password_reset_secret" = NULL,
6855 "password_reset_secret_expiry" = NULL,
6856 "location" = NULL;
6857 DELETE FROM "verification";
6858 DELETE FROM "member_settings";
6859 DELETE FROM "member_useterms";
6860 DELETE FROM "member_profile";
6861 DELETE FROM "rendered_member_statement";
6862 DELETE FROM "member_image";
6863 DELETE FROM "contact";
6864 DELETE FROM "ignored_member";
6865 DELETE FROM "session";
6866 DELETE FROM "system_application";
6867 DELETE FROM "system_application_redirect_uri";
6868 DELETE FROM "dynamic_application_scope";
6869 DELETE FROM "member_application";
6870 DELETE FROM "token";
6871 DELETE FROM "subscription";
6872 DELETE FROM "ignored_area";
6873 DELETE FROM "ignored_initiative";
6874 DELETE FROM "non_voter";
6875 DELETE FROM "direct_voter" USING "issue"
6876 WHERE "direct_voter"."issue_id" = "issue"."id"
6877 AND "issue"."closed" ISNULL;
6878 DELETE FROM "event_processed";
6879 DELETE FROM "notification_initiative_sent";
6880 DELETE FROM "newsletter";
6881 RETURN;
6882 END;
6883 $$;
6885 COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
6889 COMMIT;

Impressum / About Us