liquid_feedback_core

view core.sql @ 511:48761b189274

Added comment on function "get_initiatives_for_notification"
author jbe
date Sat Apr 16 19:56:24 2016 +0200 (2016-04-16)
parents 3b684315c724
children 705097d1b1f3
line source
2 -- Execute the following command manually for PostgreSQL prior version 9.0:
3 -- CREATE LANGUAGE plpgsql;
5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
7 BEGIN;
9 CREATE VIEW "liquid_feedback_version" AS
10 SELECT * FROM (VALUES ('3.2.0', 3, 2, 0))
11 AS "subquery"("string", "major", "minor", "revision");
15 ----------------------
16 -- Full text search --
17 ----------------------
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
21 RETURNS TSQUERY
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
23 BEGIN
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
25 END;
26 $$;
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
31 CREATE FUNCTION "highlight"
32 ( "body_p" TEXT,
33 "query_text_p" TEXT )
34 RETURNS TEXT
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
36 BEGIN
37 RETURN ts_headline(
38 'pg_catalog.simple',
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
40 "text_search_query"("query_text_p"),
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
42 END;
43 $$;
45 COMMENT ON FUNCTION "highlight"
46 ( "body_p" TEXT,
47 "query_text_p" TEXT )
48 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.';
52 -------------------------
53 -- Tables and indicies --
54 -------------------------
57 CREATE TABLE "temporary_transaction_data" (
58 PRIMARY KEY ("txid", "key"),
59 "txid" INT8 DEFAULT txid_current(),
60 "key" TEXT,
61 "value" TEXT NOT NULL );
63 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
65 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';
68 CREATE TABLE "system_setting" (
69 "member_ttl" INTERVAL );
70 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
72 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
73 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
75 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.';
78 CREATE TABLE "contingent" (
79 PRIMARY KEY ("polling", "time_frame"),
80 "polling" BOOLEAN,
81 "time_frame" INTERVAL,
82 "text_entry_limit" INT4,
83 "initiative_limit" INT4 );
85 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.';
87 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
88 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';
89 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
92 CREATE TABLE "member" (
93 "id" SERIAL4 PRIMARY KEY,
94 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
95 "invite_code" TEXT UNIQUE,
96 "invite_code_expiry" TIMESTAMPTZ,
97 "admin_comment" TEXT,
98 "activated" TIMESTAMPTZ,
99 "last_activity" DATE,
100 "last_login" TIMESTAMPTZ,
101 "last_delegation_check" TIMESTAMPTZ,
102 "login" TEXT UNIQUE,
103 "password" TEXT,
104 "authority" TEXT,
105 "authority_uid" TEXT,
106 "authority_login" TEXT,
107 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
108 "active" BOOLEAN NOT NULL DEFAULT FALSE,
109 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
110 "lang" TEXT,
111 "notify_email" TEXT,
112 "notify_email_unconfirmed" TEXT,
113 "notify_email_secret" TEXT UNIQUE,
114 "notify_email_secret_expiry" TIMESTAMPTZ,
115 "notify_email_lock_expiry" TIMESTAMPTZ,
116 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
117 "notification_counter" INT4 NOT NULL DEFAULT 1,
118 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
119 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
120 "notification_hour" INT4 CHECK ("notification_hour" BETWEEN 0 AND 23),
121 "notification_sent" TIMESTAMP,
122 "login_recovery_expiry" TIMESTAMPTZ,
123 "password_reset_secret" TEXT UNIQUE,
124 "password_reset_secret_expiry" TIMESTAMPTZ,
125 "name" TEXT UNIQUE,
126 "identification" TEXT UNIQUE,
127 "authentication" TEXT,
128 "organizational_unit" TEXT,
129 "internal_posts" TEXT,
130 "realname" TEXT,
131 "birthday" DATE,
132 "address" TEXT,
133 "email" TEXT,
134 "xmpp_address" TEXT,
135 "website" TEXT,
136 "phone" TEXT,
137 "mobile_phone" TEXT,
138 "profession" TEXT,
139 "external_memberships" TEXT,
140 "external_posts" TEXT,
141 "formatting_engine" TEXT,
142 "statement" TEXT,
143 "text_search_data" TSVECTOR,
144 CONSTRAINT "active_requires_activated_and_last_activity"
145 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
146 CONSTRAINT "authority_requires_uid_and_vice_versa"
147 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
148 CONSTRAINT "authority_uid_unique_per_authority"
149 UNIQUE ("authority", "authority_uid"),
150 CONSTRAINT "authority_login_requires_authority"
151 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
152 CONSTRAINT "notification_dow_requires_notification_hour"
153 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
154 CONSTRAINT "name_not_null_if_activated"
155 CHECK ("activated" ISNULL OR "name" NOTNULL) );
156 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
157 CREATE INDEX "member_active_idx" ON "member" ("active");
158 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
159 CREATE TRIGGER "update_text_search_data"
160 BEFORE INSERT OR UPDATE ON "member"
161 FOR EACH ROW EXECUTE PROCEDURE
162 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
163 "name", "identification", "organizational_unit", "internal_posts",
164 "realname", "external_memberships", "external_posts", "statement" );
166 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
168 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
169 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
170 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
171 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
172 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';
173 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
174 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
175 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
176 COMMENT ON COLUMN "member"."login" IS 'Login name';
177 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
178 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)';
179 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)';
180 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
181 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
182 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".';
183 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
184 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
185 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
186 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
187 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
188 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
189 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
190 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
191 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
192 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
193 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
194 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
195 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
196 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
197 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
198 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';
199 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
200 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
201 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
202 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
203 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
204 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
205 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
206 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
207 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
208 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
209 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
212 CREATE TABLE "member_history" (
213 "id" SERIAL8 PRIMARY KEY,
214 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
215 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
216 "active" BOOLEAN NOT NULL,
217 "name" TEXT NOT NULL );
218 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
220 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
222 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
223 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
226 CREATE TABLE "rendered_member_statement" (
227 PRIMARY KEY ("member_id", "format"),
228 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
229 "format" TEXT,
230 "content" TEXT NOT NULL );
232 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)';
235 CREATE TABLE "setting" (
236 PRIMARY KEY ("member_id", "key"),
237 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
238 "key" TEXT NOT NULL,
239 "value" TEXT NOT NULL );
240 CREATE INDEX "setting_key_idx" ON "setting" ("key");
242 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
244 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
247 CREATE TABLE "setting_map" (
248 PRIMARY KEY ("member_id", "key", "subkey"),
249 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
250 "key" TEXT NOT NULL,
251 "subkey" TEXT NOT NULL,
252 "value" TEXT NOT NULL );
253 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
255 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
257 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
258 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
259 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
262 CREATE TABLE "member_relation_setting" (
263 PRIMARY KEY ("member_id", "key", "other_member_id"),
264 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
265 "key" TEXT NOT NULL,
266 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
267 "value" TEXT NOT NULL );
269 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
272 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
274 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
277 CREATE TABLE "member_image" (
278 PRIMARY KEY ("member_id", "image_type", "scaled"),
279 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
280 "image_type" "member_image_type",
281 "scaled" BOOLEAN,
282 "content_type" TEXT,
283 "data" BYTEA NOT NULL );
285 COMMENT ON TABLE "member_image" IS 'Images of members';
287 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
290 CREATE TABLE "member_count" (
291 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
292 "total_count" INT4 NOT NULL );
294 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';
296 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
297 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
300 CREATE TABLE "contact" (
301 PRIMARY KEY ("member_id", "other_member_id"),
302 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
303 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
304 "public" BOOLEAN NOT NULL DEFAULT FALSE,
305 CONSTRAINT "cant_save_yourself_as_contact"
306 CHECK ("member_id" != "other_member_id") );
307 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
309 COMMENT ON TABLE "contact" IS 'Contact lists';
311 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
312 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
313 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
316 CREATE TABLE "ignored_member" (
317 PRIMARY KEY ("member_id", "other_member_id"),
318 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
319 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
320 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
322 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
324 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
325 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
328 CREATE TABLE "session" (
329 "ident" TEXT PRIMARY KEY,
330 "additional_secret" TEXT,
331 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
332 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
333 "authority" TEXT,
334 "authority_uid" TEXT,
335 "authority_login" TEXT,
336 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
337 "lang" TEXT );
338 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
340 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
342 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
343 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
344 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
345 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
346 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
347 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
348 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';
349 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
352 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
354 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';
357 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
359 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';
362 CREATE TABLE "policy" (
363 "id" SERIAL4 PRIMARY KEY,
364 "index" INT4 NOT NULL,
365 "active" BOOLEAN NOT NULL DEFAULT TRUE,
366 "name" TEXT NOT NULL UNIQUE,
367 "description" TEXT NOT NULL DEFAULT '',
368 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
369 "min_admission_time" INTERVAL,
370 "max_admission_time" INTERVAL,
371 "discussion_time" INTERVAL,
372 "verification_time" INTERVAL,
373 "voting_time" INTERVAL,
374 "issue_quorum_num" INT4,
375 "issue_quorum_den" INT4,
376 "initiative_quorum_num" INT4 NOT NULL,
377 "initiative_quorum_den" INT4 NOT NULL,
378 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
379 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
380 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
381 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
382 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
383 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
384 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
385 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
386 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
387 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
388 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
389 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
390 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
391 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
392 CONSTRAINT "timing" CHECK (
393 ( "polling" = FALSE AND
394 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
395 "min_admission_time" <= "max_admission_time" AND
396 "discussion_time" NOTNULL AND
397 "verification_time" NOTNULL AND
398 "voting_time" NOTNULL ) OR
399 ( "polling" = TRUE AND
400 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
401 "discussion_time" NOTNULL AND
402 "verification_time" NOTNULL AND
403 "voting_time" NOTNULL ) OR
404 ( "polling" = TRUE AND
405 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
406 "discussion_time" ISNULL AND
407 "verification_time" ISNULL AND
408 "voting_time" ISNULL ) ),
409 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
410 "polling" = ("issue_quorum_num" ISNULL) AND
411 "polling" = ("issue_quorum_den" ISNULL) ),
412 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
413 "defeat_strength" = 'tuple'::"defeat_strength" OR
414 "no_reverse_beat_path" = FALSE ) );
415 CREATE INDEX "policy_active_idx" ON "policy" ("active");
417 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
419 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
420 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
421 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';
422 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open';
423 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
424 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
425 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"';
426 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'')';
427 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
428 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
429 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
430 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
431 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';
432 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
433 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
434 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
435 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.';
436 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
437 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';
438 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';
439 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';
440 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.';
441 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';
442 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';
443 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.';
444 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").';
447 CREATE TABLE "unit" (
448 "id" SERIAL4 PRIMARY KEY,
449 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
450 "active" BOOLEAN NOT NULL DEFAULT TRUE,
451 "name" TEXT NOT NULL,
452 "description" TEXT NOT NULL DEFAULT '',
453 "external_reference" TEXT,
454 "member_count" INT4,
455 "text_search_data" TSVECTOR );
456 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
457 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
458 CREATE INDEX "unit_active_idx" ON "unit" ("active");
459 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
460 CREATE TRIGGER "update_text_search_data"
461 BEFORE INSERT OR UPDATE ON "unit"
462 FOR EACH ROW EXECUTE PROCEDURE
463 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
464 "name", "description" );
466 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
468 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
469 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
470 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
471 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
474 CREATE TABLE "subscription" (
475 PRIMARY KEY ("member_id", "unit_id"),
476 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
477 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
478 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
480 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';
483 CREATE TABLE "unit_setting" (
484 PRIMARY KEY ("member_id", "key", "unit_id"),
485 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
486 "key" TEXT NOT NULL,
487 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
488 "value" TEXT NOT NULL );
490 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
493 CREATE TABLE "area" (
494 "id" SERIAL4 PRIMARY KEY,
495 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
496 "active" BOOLEAN NOT NULL DEFAULT TRUE,
497 "name" TEXT NOT NULL,
498 "description" TEXT NOT NULL DEFAULT '',
499 "external_reference" TEXT,
500 "direct_member_count" INT4,
501 "member_weight" INT4,
502 "text_search_data" TSVECTOR );
503 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
504 CREATE INDEX "area_active_idx" ON "area" ("active");
505 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
506 CREATE TRIGGER "update_text_search_data"
507 BEFORE INSERT OR UPDATE ON "area"
508 FOR EACH ROW EXECUTE PROCEDURE
509 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
510 "name", "description" );
512 COMMENT ON TABLE "area" IS 'Subject areas';
514 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
515 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
516 COMMENT ON COLUMN "area"."direct_member_count" IS 'Number of active members of that area (ignoring their weight), as calculated from view "area_member_count"';
517 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
520 CREATE TABLE "ignored_area" (
521 PRIMARY KEY ("member_id", "area_id"),
522 "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
523 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
524 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
526 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';
529 CREATE TABLE "area_setting" (
530 PRIMARY KEY ("member_id", "key", "area_id"),
531 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
532 "key" TEXT NOT NULL,
533 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
534 "value" TEXT NOT NULL );
536 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
539 CREATE TABLE "allowed_policy" (
540 PRIMARY KEY ("area_id", "policy_id"),
541 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
542 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
543 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
544 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
546 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
548 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
551 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
553 COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period';
556 CREATE TYPE "issue_state" AS ENUM (
557 'admission', 'discussion', 'verification', 'voting',
558 'canceled_by_admin',
559 'canceled_revoked_before_accepted',
560 'canceled_issue_not_accepted',
561 'canceled_after_revocation_during_discussion',
562 'canceled_after_revocation_during_verification',
563 'canceled_no_initiative_admitted',
564 'finished_without_winner', 'finished_with_winner');
566 COMMENT ON TYPE "issue_state" IS 'State of issues';
569 CREATE TABLE "issue" (
570 "id" SERIAL4 PRIMARY KEY,
571 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
572 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
573 "admin_notice" TEXT,
574 "external_reference" TEXT,
575 "state" "issue_state" NOT NULL DEFAULT 'admission',
576 "phase_finished" TIMESTAMPTZ,
577 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
578 "accepted" TIMESTAMPTZ,
579 "half_frozen" TIMESTAMPTZ,
580 "fully_frozen" TIMESTAMPTZ,
581 "closed" TIMESTAMPTZ,
582 "cleaned" TIMESTAMPTZ,
583 "min_admission_time" INTERVAL,
584 "max_admission_time" INTERVAL,
585 "discussion_time" INTERVAL NOT NULL,
586 "verification_time" INTERVAL NOT NULL,
587 "voting_time" INTERVAL NOT NULL,
588 "snapshot" TIMESTAMPTZ,
589 "latest_snapshot_event" "snapshot_event",
590 "population" INT4,
591 "voter_count" INT4,
592 "status_quo_schulze_rank" INT4,
593 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
594 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
595 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
596 CONSTRAINT "valid_state" CHECK (
597 (
598 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
599 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
600 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
601 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
602 ) AND (
603 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
604 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
605 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
606 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
607 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
608 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
609 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
610 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
611 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
612 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
613 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
614 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
615 )),
616 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
617 "phase_finished" ISNULL OR "closed" ISNULL ),
618 CONSTRAINT "state_change_order" CHECK (
619 "created" <= "accepted" AND
620 "accepted" <= "half_frozen" AND
621 "half_frozen" <= "fully_frozen" AND
622 "fully_frozen" <= "closed" ),
623 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
624 "cleaned" ISNULL OR "closed" NOTNULL ),
625 CONSTRAINT "last_snapshot_on_full_freeze"
626 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
627 CONSTRAINT "freeze_requires_snapshot"
628 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
629 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
630 CHECK (("snapshot" NOTNULL) = ("latest_snapshot_event" NOTNULL)) );
631 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
632 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
633 CREATE INDEX "issue_created_idx" ON "issue" ("created");
634 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
635 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
636 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
637 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
638 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
639 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
641 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
643 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
644 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
645 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';
646 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
647 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.';
648 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.';
649 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.';
650 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
651 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
652 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
653 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
654 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
655 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
656 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
657 COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables';
658 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
659 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';
660 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
663 CREATE TABLE "issue_order_in_admission_state" (
664 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
665 "order_in_area" INT4,
666 "order_in_unit" INT4 );
668 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"';
670 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';
671 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';
672 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';
675 CREATE TABLE "issue_setting" (
676 PRIMARY KEY ("member_id", "key", "issue_id"),
677 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
678 "key" TEXT NOT NULL,
679 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
680 "value" TEXT NOT NULL );
682 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
685 CREATE TABLE "initiative" (
686 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
687 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
688 "id" SERIAL4 PRIMARY KEY,
689 "name" TEXT NOT NULL,
690 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
691 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
692 "revoked" TIMESTAMPTZ,
693 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
694 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
695 "external_reference" TEXT,
696 "admitted" BOOLEAN,
697 "supporter_count" INT4,
698 "informed_supporter_count" INT4,
699 "satisfied_supporter_count" INT4,
700 "satisfied_informed_supporter_count" INT4,
701 "harmonic_weight" NUMERIC(12, 3),
702 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
703 "first_preference_votes" INT4,
704 "positive_votes" INT4,
705 "negative_votes" INT4,
706 "direct_majority" BOOLEAN,
707 "indirect_majority" BOOLEAN,
708 "schulze_rank" INT4,
709 "better_than_status_quo" BOOLEAN,
710 "worse_than_status_quo" BOOLEAN,
711 "reverse_beat_path" BOOLEAN,
712 "multistage_majority" BOOLEAN,
713 "eligible" BOOLEAN,
714 "winner" BOOLEAN,
715 "rank" INT4,
716 "text_search_data" TSVECTOR,
717 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
718 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
719 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
720 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
721 CONSTRAINT "revoked_initiatives_cant_be_admitted"
722 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
723 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
724 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
725 ( "first_preference_votes" ISNULL AND
726 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
727 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
728 "schulze_rank" ISNULL AND
729 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
730 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
731 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
732 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
733 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
734 "eligible" = FALSE OR
735 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
736 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
737 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
738 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
739 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
740 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
741 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
742 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
743 CREATE TRIGGER "update_text_search_data"
744 BEFORE INSERT OR UPDATE ON "initiative"
745 FOR EACH ROW EXECUTE PROCEDURE
746 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
748 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.';
750 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
751 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
752 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
753 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
754 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
755 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
756 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
757 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
758 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
759 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';
760 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
761 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
762 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
763 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
764 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"';
765 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
766 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
767 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
768 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)';
769 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''';
770 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';
771 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"';
772 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
773 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';
776 CREATE TABLE "battle" (
777 "issue_id" INT4 NOT NULL,
778 "winning_initiative_id" INT4,
779 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
780 "losing_initiative_id" INT4,
781 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
782 "count" INT4 NOT NULL,
783 CONSTRAINT "initiative_ids_not_equal" CHECK (
784 "winning_initiative_id" != "losing_initiative_id" OR
785 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
786 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
787 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
788 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
789 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
791 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';
794 CREATE TABLE "ignored_initiative" (
795 PRIMARY KEY ("member_id", "initiative_id"),
796 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
797 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
798 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
800 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';
803 CREATE TABLE "initiative_setting" (
804 PRIMARY KEY ("member_id", "key", "initiative_id"),
805 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
806 "key" TEXT NOT NULL,
807 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
808 "value" TEXT NOT NULL );
810 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
813 CREATE TABLE "draft" (
814 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
815 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
816 "id" SERIAL8 PRIMARY KEY,
817 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
818 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
819 "formatting_engine" TEXT,
820 "content" TEXT NOT NULL,
821 "external_reference" TEXT,
822 "text_search_data" TSVECTOR );
823 CREATE INDEX "draft_created_idx" ON "draft" ("created");
824 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
825 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
826 CREATE TRIGGER "update_text_search_data"
827 BEFORE INSERT OR UPDATE ON "draft"
828 FOR EACH ROW EXECUTE PROCEDURE
829 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
831 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.';
833 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
834 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
835 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
838 CREATE TABLE "rendered_draft" (
839 PRIMARY KEY ("draft_id", "format"),
840 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
841 "format" TEXT,
842 "content" TEXT NOT NULL );
844 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)';
847 CREATE TABLE "suggestion" (
848 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
849 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
850 "id" SERIAL8 PRIMARY KEY,
851 "draft_id" INT8 NOT NULL,
852 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
853 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
854 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
855 "name" TEXT NOT NULL,
856 "formatting_engine" TEXT,
857 "content" TEXT NOT NULL DEFAULT '',
858 "external_reference" TEXT,
859 "text_search_data" TSVECTOR,
860 "minus2_unfulfilled_count" INT4,
861 "minus2_fulfilled_count" INT4,
862 "minus1_unfulfilled_count" INT4,
863 "minus1_fulfilled_count" INT4,
864 "plus1_unfulfilled_count" INT4,
865 "plus1_fulfilled_count" INT4,
866 "plus2_unfulfilled_count" INT4,
867 "plus2_fulfilled_count" INT4,
868 "proportional_order" INT4 );
869 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
870 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
871 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
872 CREATE TRIGGER "update_text_search_data"
873 BEFORE INSERT OR UPDATE ON "suggestion"
874 FOR EACH ROW EXECUTE PROCEDURE
875 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
876 "name", "content");
878 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';
880 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")';
881 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
882 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
883 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
884 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
885 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
886 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
887 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
888 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
889 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
890 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"';
893 CREATE TABLE "rendered_suggestion" (
894 PRIMARY KEY ("suggestion_id", "format"),
895 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
896 "format" TEXT,
897 "content" TEXT NOT NULL );
899 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)';
902 CREATE TABLE "suggestion_setting" (
903 PRIMARY KEY ("member_id", "key", "suggestion_id"),
904 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
905 "key" TEXT NOT NULL,
906 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
907 "value" TEXT NOT NULL );
909 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
912 CREATE TABLE "privilege" (
913 PRIMARY KEY ("unit_id", "member_id"),
914 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
915 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
916 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
917 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
918 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
919 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
920 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
921 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
922 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
924 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
926 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
927 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
928 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
929 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
930 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
931 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
932 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';
935 CREATE TABLE "membership" (
936 PRIMARY KEY ("area_id", "member_id"),
937 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
938 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
939 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
941 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
944 CREATE TABLE "interest" (
945 PRIMARY KEY ("issue_id", "member_id"),
946 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
947 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
948 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
950 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.';
953 CREATE TABLE "initiator" (
954 PRIMARY KEY ("initiative_id", "member_id"),
955 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
956 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
957 "accepted" BOOLEAN );
958 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
960 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.';
962 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.';
965 CREATE TABLE "supporter" (
966 "issue_id" INT4 NOT NULL,
967 PRIMARY KEY ("initiative_id", "member_id"),
968 "initiative_id" INT4,
969 "member_id" INT4,
970 "draft_id" INT8 NOT NULL,
971 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
972 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
973 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
975 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.';
977 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
978 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")';
981 CREATE TABLE "opinion" (
982 "initiative_id" INT4 NOT NULL,
983 PRIMARY KEY ("suggestion_id", "member_id"),
984 "suggestion_id" INT8,
985 "member_id" INT4,
986 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
987 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
988 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
989 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
990 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
992 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.';
994 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
997 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
999 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1002 CREATE TABLE "delegation" (
1003 "id" SERIAL8 PRIMARY KEY,
1004 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1005 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1006 "scope" "delegation_scope" NOT NULL,
1007 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1008 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1009 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1010 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1011 CONSTRAINT "no_unit_delegation_to_null"
1012 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1013 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1014 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1015 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1016 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1017 UNIQUE ("unit_id", "truster_id"),
1018 UNIQUE ("area_id", "truster_id"),
1019 UNIQUE ("issue_id", "truster_id") );
1020 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1021 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1023 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1025 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1026 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1027 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1030 CREATE TABLE "direct_population_snapshot" (
1031 PRIMARY KEY ("issue_id", "event", "member_id"),
1032 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1033 "event" "snapshot_event",
1034 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1035 "weight" INT4 );
1036 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
1038 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
1040 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1041 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
1044 CREATE TABLE "delegating_population_snapshot" (
1045 PRIMARY KEY ("issue_id", "event", "member_id"),
1046 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1047 "event" "snapshot_event",
1048 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1049 "weight" INT4,
1050 "scope" "delegation_scope" NOT NULL,
1051 "delegate_member_ids" INT4[] NOT NULL );
1052 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
1054 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
1056 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1057 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
1058 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
1059 COMMENT ON COLUMN "delegating_population_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_population_snapshot"';
1062 CREATE TABLE "direct_interest_snapshot" (
1063 PRIMARY KEY ("issue_id", "event", "member_id"),
1064 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1065 "event" "snapshot_event",
1066 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1067 "weight" INT4 );
1068 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1070 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';
1072 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1073 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1076 CREATE TABLE "delegating_interest_snapshot" (
1077 PRIMARY KEY ("issue_id", "event", "member_id"),
1078 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1079 "event" "snapshot_event",
1080 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1081 "weight" INT4,
1082 "scope" "delegation_scope" NOT NULL,
1083 "delegate_member_ids" INT4[] NOT NULL );
1084 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1086 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';
1088 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1089 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1090 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1091 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"';
1094 CREATE TABLE "direct_supporter_snapshot" (
1095 "issue_id" INT4 NOT NULL,
1096 PRIMARY KEY ("initiative_id", "event", "member_id"),
1097 "initiative_id" INT4,
1098 "event" "snapshot_event",
1099 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1100 "draft_id" INT8 NOT NULL,
1101 "informed" BOOLEAN NOT NULL,
1102 "satisfied" BOOLEAN NOT NULL,
1103 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1104 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1105 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1106 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1108 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';
1110 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';
1111 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1112 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1113 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1116 CREATE TABLE "non_voter" (
1117 PRIMARY KEY ("issue_id", "member_id"),
1118 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1119 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1120 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1122 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1125 CREATE TABLE "direct_voter" (
1126 PRIMARY KEY ("issue_id", "member_id"),
1127 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1128 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1129 "weight" INT4,
1130 "comment_changed" TIMESTAMPTZ,
1131 "formatting_engine" TEXT,
1132 "comment" TEXT,
1133 "text_search_data" TSVECTOR );
1134 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1135 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1136 CREATE TRIGGER "update_text_search_data"
1137 BEFORE INSERT OR UPDATE ON "direct_voter"
1138 FOR EACH ROW EXECUTE PROCEDURE
1139 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1141 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';
1143 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1144 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';
1145 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';
1146 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.';
1149 CREATE TABLE "rendered_voter_comment" (
1150 PRIMARY KEY ("issue_id", "member_id", "format"),
1151 FOREIGN KEY ("issue_id", "member_id")
1152 REFERENCES "direct_voter" ("issue_id", "member_id")
1153 ON DELETE CASCADE ON UPDATE CASCADE,
1154 "issue_id" INT4,
1155 "member_id" INT4,
1156 "format" TEXT,
1157 "content" TEXT NOT NULL );
1159 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)';
1162 CREATE TABLE "delegating_voter" (
1163 PRIMARY KEY ("issue_id", "member_id"),
1164 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1165 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1166 "weight" INT4,
1167 "scope" "delegation_scope" NOT NULL,
1168 "delegate_member_ids" INT4[] NOT NULL );
1169 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1171 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';
1173 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1174 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1175 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"';
1178 CREATE TABLE "vote" (
1179 "issue_id" INT4 NOT NULL,
1180 PRIMARY KEY ("initiative_id", "member_id"),
1181 "initiative_id" INT4,
1182 "member_id" INT4,
1183 "grade" INT4 NOT NULL,
1184 "first_preference" BOOLEAN,
1185 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1186 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1187 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1188 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1189 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1191 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';
1193 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1194 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.';
1195 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.';
1198 CREATE TYPE "event_type" AS ENUM (
1199 'issue_state_changed',
1200 'initiative_created_in_new_issue',
1201 'initiative_created_in_existing_issue',
1202 'initiative_revoked',
1203 'new_draft_created',
1204 'suggestion_created');
1206 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1209 CREATE TABLE "event" (
1210 "id" SERIAL8 PRIMARY KEY,
1211 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1212 "event" "event_type" NOT NULL,
1213 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1214 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1215 "state" "issue_state",
1216 "initiative_id" INT4,
1217 "draft_id" INT8,
1218 "suggestion_id" INT8,
1219 FOREIGN KEY ("issue_id", "initiative_id")
1220 REFERENCES "initiative" ("issue_id", "id")
1221 ON DELETE CASCADE ON UPDATE CASCADE,
1222 FOREIGN KEY ("initiative_id", "draft_id")
1223 REFERENCES "draft" ("initiative_id", "id")
1224 ON DELETE CASCADE ON UPDATE CASCADE,
1225 FOREIGN KEY ("initiative_id", "suggestion_id")
1226 REFERENCES "suggestion" ("initiative_id", "id")
1227 ON DELETE CASCADE ON UPDATE CASCADE,
1228 CONSTRAINT "null_constr_for_issue_state_changed" CHECK (
1229 "event" != 'issue_state_changed' OR (
1230 "member_id" ISNULL AND
1231 "issue_id" NOTNULL AND
1232 "state" NOTNULL AND
1233 "initiative_id" ISNULL AND
1234 "draft_id" ISNULL AND
1235 "suggestion_id" ISNULL )),
1236 CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1237 "event" NOT IN (
1238 'initiative_created_in_new_issue',
1239 'initiative_created_in_existing_issue',
1240 'initiative_revoked',
1241 'new_draft_created'
1242 ) OR (
1243 "member_id" NOTNULL AND
1244 "issue_id" NOTNULL AND
1245 "state" NOTNULL AND
1246 "initiative_id" NOTNULL AND
1247 "draft_id" NOTNULL AND
1248 "suggestion_id" ISNULL )),
1249 CONSTRAINT "null_constr_for_suggestion_creation" CHECK (
1250 "event" != 'suggestion_created' OR (
1251 "member_id" NOTNULL AND
1252 "issue_id" NOTNULL AND
1253 "state" NOTNULL AND
1254 "initiative_id" NOTNULL AND
1255 "draft_id" ISNULL AND
1256 "suggestion_id" NOTNULL )) );
1257 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1259 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1261 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1262 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1263 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1264 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1267 CREATE TABLE "notification_event_sent" (
1268 "event_id" INT8 NOT NULL );
1269 CREATE UNIQUE INDEX "notification_event_sent_singleton_idx" ON "notification_event_sent" ((1));
1271 COMMENT ON TABLE "notification_event_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1272 COMMENT ON INDEX "notification_event_sent_singleton_idx" IS 'This index ensures that "notification_event_sent" only contains one row maximum.';
1275 CREATE TABLE "notification_initiative_sent" (
1276 PRIMARY KEY ("member_id", "initiative_id"),
1277 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1278 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1279 "last_draft_id" INT8 NOT NULL,
1280 "last_suggestion_id" INT8 );
1281 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1283 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1285 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1286 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1289 CREATE TABLE "newsletter" (
1290 "id" SERIAL4 PRIMARY KEY,
1291 "published" TIMESTAMPTZ NOT NULL,
1292 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1293 "include_all_members" BOOLEAN NOT NULL,
1294 "sent" TIMESTAMPTZ,
1295 "subject" TEXT NOT NULL,
1296 "content" TEXT NOT NULL );
1297 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1298 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1299 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1301 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1303 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1304 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1305 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1306 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1307 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1308 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1312 ----------------------------------------------
1313 -- Writing of history entries and event log --
1314 ----------------------------------------------
1317 CREATE FUNCTION "write_member_history_trigger"()
1318 RETURNS TRIGGER
1319 LANGUAGE 'plpgsql' VOLATILE AS $$
1320 BEGIN
1321 IF
1322 ( NEW."active" != OLD."active" OR
1323 NEW."name" != OLD."name" ) AND
1324 OLD."activated" NOTNULL
1325 THEN
1326 INSERT INTO "member_history"
1327 ("member_id", "active", "name")
1328 VALUES (NEW."id", OLD."active", OLD."name");
1329 END IF;
1330 RETURN NULL;
1331 END;
1332 $$;
1334 CREATE TRIGGER "write_member_history"
1335 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1336 "write_member_history_trigger"();
1338 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1339 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1342 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1343 RETURNS TRIGGER
1344 LANGUAGE 'plpgsql' VOLATILE AS $$
1345 BEGIN
1346 IF NEW."state" != OLD."state" THEN
1347 INSERT INTO "event" ("event", "issue_id", "state")
1348 VALUES ('issue_state_changed', NEW."id", NEW."state");
1349 END IF;
1350 RETURN NULL;
1351 END;
1352 $$;
1354 CREATE TRIGGER "write_event_issue_state_changed"
1355 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1356 "write_event_issue_state_changed_trigger"();
1358 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1359 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1362 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1363 RETURNS TRIGGER
1364 LANGUAGE 'plpgsql' VOLATILE AS $$
1365 DECLARE
1366 "initiative_row" "initiative"%ROWTYPE;
1367 "issue_row" "issue"%ROWTYPE;
1368 "event_v" "event_type";
1369 BEGIN
1370 SELECT * INTO "initiative_row" FROM "initiative"
1371 WHERE "id" = NEW."initiative_id";
1372 SELECT * INTO "issue_row" FROM "issue"
1373 WHERE "id" = "initiative_row"."issue_id";
1374 IF EXISTS (
1375 SELECT NULL FROM "draft"
1376 WHERE "initiative_id" = NEW."initiative_id"
1377 AND "id" != NEW."id"
1378 ) THEN
1379 "event_v" := 'new_draft_created';
1380 ELSE
1381 IF EXISTS (
1382 SELECT NULL FROM "initiative"
1383 WHERE "issue_id" = "initiative_row"."issue_id"
1384 AND "id" != "initiative_row"."id"
1385 ) THEN
1386 "event_v" := 'initiative_created_in_existing_issue';
1387 ELSE
1388 "event_v" := 'initiative_created_in_new_issue';
1389 END IF;
1390 END IF;
1391 INSERT INTO "event" (
1392 "event", "member_id",
1393 "issue_id", "state", "initiative_id", "draft_id"
1394 ) VALUES (
1395 "event_v",
1396 NEW."author_id",
1397 "initiative_row"."issue_id",
1398 "issue_row"."state",
1399 "initiative_row"."id",
1400 NEW."id" );
1401 RETURN NULL;
1402 END;
1403 $$;
1405 CREATE TRIGGER "write_event_initiative_or_draft_created"
1406 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1407 "write_event_initiative_or_draft_created_trigger"();
1409 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1410 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1413 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1414 RETURNS TRIGGER
1415 LANGUAGE 'plpgsql' VOLATILE AS $$
1416 DECLARE
1417 "issue_row" "issue"%ROWTYPE;
1418 "draft_id_v" "draft"."id"%TYPE;
1419 BEGIN
1420 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1421 SELECT * INTO "issue_row" FROM "issue"
1422 WHERE "id" = NEW."issue_id";
1423 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1424 WHERE "initiative_id" = NEW."id";
1425 INSERT INTO "event" (
1426 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1427 ) VALUES (
1428 'initiative_revoked',
1429 NEW."revoked_by_member_id",
1430 NEW."issue_id",
1431 "issue_row"."state",
1432 NEW."id",
1433 "draft_id_v");
1434 END IF;
1435 RETURN NULL;
1436 END;
1437 $$;
1439 CREATE TRIGGER "write_event_initiative_revoked"
1440 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1441 "write_event_initiative_revoked_trigger"();
1443 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1444 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1447 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1448 RETURNS TRIGGER
1449 LANGUAGE 'plpgsql' VOLATILE AS $$
1450 DECLARE
1451 "initiative_row" "initiative"%ROWTYPE;
1452 "issue_row" "issue"%ROWTYPE;
1453 BEGIN
1454 SELECT * INTO "initiative_row" FROM "initiative"
1455 WHERE "id" = NEW."initiative_id";
1456 SELECT * INTO "issue_row" FROM "issue"
1457 WHERE "id" = "initiative_row"."issue_id";
1458 INSERT INTO "event" (
1459 "event", "member_id",
1460 "issue_id", "state", "initiative_id", "suggestion_id"
1461 ) VALUES (
1462 'suggestion_created',
1463 NEW."author_id",
1464 "initiative_row"."issue_id",
1465 "issue_row"."state",
1466 "initiative_row"."id",
1467 NEW."id" );
1468 RETURN NULL;
1469 END;
1470 $$;
1472 CREATE TRIGGER "write_event_suggestion_created"
1473 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1474 "write_event_suggestion_created_trigger"();
1476 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1477 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1481 ----------------------------
1482 -- Additional constraints --
1483 ----------------------------
1486 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1487 RETURNS TRIGGER
1488 LANGUAGE 'plpgsql' VOLATILE AS $$
1489 BEGIN
1490 IF NOT EXISTS (
1491 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1492 ) THEN
1493 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
1494 ERRCODE = 'integrity_constraint_violation',
1495 HINT = 'Create issue, initiative, and draft within the same transaction.';
1496 END IF;
1497 RETURN NULL;
1498 END;
1499 $$;
1501 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1502 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1503 FOR EACH ROW EXECUTE PROCEDURE
1504 "issue_requires_first_initiative_trigger"();
1506 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1507 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1510 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1511 RETURNS TRIGGER
1512 LANGUAGE 'plpgsql' VOLATILE AS $$
1513 DECLARE
1514 "reference_lost" BOOLEAN;
1515 BEGIN
1516 IF TG_OP = 'DELETE' THEN
1517 "reference_lost" := TRUE;
1518 ELSE
1519 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1520 END IF;
1521 IF
1522 "reference_lost" AND NOT EXISTS (
1523 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1525 THEN
1526 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1527 END IF;
1528 RETURN NULL;
1529 END;
1530 $$;
1532 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1533 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1534 FOR EACH ROW EXECUTE PROCEDURE
1535 "last_initiative_deletes_issue_trigger"();
1537 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1538 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1541 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1542 RETURNS TRIGGER
1543 LANGUAGE 'plpgsql' VOLATILE AS $$
1544 BEGIN
1545 IF NOT EXISTS (
1546 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1547 ) THEN
1548 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
1549 ERRCODE = 'integrity_constraint_violation',
1550 HINT = 'Create issue, initiative and draft within the same transaction.';
1551 END IF;
1552 RETURN NULL;
1553 END;
1554 $$;
1556 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1557 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1558 FOR EACH ROW EXECUTE PROCEDURE
1559 "initiative_requires_first_draft_trigger"();
1561 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1562 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1565 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1566 RETURNS TRIGGER
1567 LANGUAGE 'plpgsql' VOLATILE AS $$
1568 DECLARE
1569 "reference_lost" BOOLEAN;
1570 BEGIN
1571 IF TG_OP = 'DELETE' THEN
1572 "reference_lost" := TRUE;
1573 ELSE
1574 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1575 END IF;
1576 IF
1577 "reference_lost" AND NOT EXISTS (
1578 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1580 THEN
1581 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1582 END IF;
1583 RETURN NULL;
1584 END;
1585 $$;
1587 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1588 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1589 FOR EACH ROW EXECUTE PROCEDURE
1590 "last_draft_deletes_initiative_trigger"();
1592 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1593 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1596 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1597 RETURNS TRIGGER
1598 LANGUAGE 'plpgsql' VOLATILE AS $$
1599 BEGIN
1600 IF NOT EXISTS (
1601 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1602 ) THEN
1603 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
1604 ERRCODE = 'integrity_constraint_violation',
1605 HINT = 'Create suggestion and opinion within the same transaction.';
1606 END IF;
1607 RETURN NULL;
1608 END;
1609 $$;
1611 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1612 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1613 FOR EACH ROW EXECUTE PROCEDURE
1614 "suggestion_requires_first_opinion_trigger"();
1616 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1617 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1620 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1621 RETURNS TRIGGER
1622 LANGUAGE 'plpgsql' VOLATILE AS $$
1623 DECLARE
1624 "reference_lost" BOOLEAN;
1625 BEGIN
1626 IF TG_OP = 'DELETE' THEN
1627 "reference_lost" := TRUE;
1628 ELSE
1629 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1630 END IF;
1631 IF
1632 "reference_lost" AND NOT EXISTS (
1633 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1635 THEN
1636 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1637 END IF;
1638 RETURN NULL;
1639 END;
1640 $$;
1642 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1643 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1644 FOR EACH ROW EXECUTE PROCEDURE
1645 "last_opinion_deletes_suggestion_trigger"();
1647 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1648 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1651 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1652 RETURNS TRIGGER
1653 LANGUAGE 'plpgsql' VOLATILE AS $$
1654 BEGIN
1655 DELETE FROM "direct_voter"
1656 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1657 RETURN NULL;
1658 END;
1659 $$;
1661 CREATE TRIGGER "non_voter_deletes_direct_voter"
1662 AFTER INSERT OR UPDATE ON "non_voter"
1663 FOR EACH ROW EXECUTE PROCEDURE
1664 "non_voter_deletes_direct_voter_trigger"();
1666 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1667 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")';
1670 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1671 RETURNS TRIGGER
1672 LANGUAGE 'plpgsql' VOLATILE AS $$
1673 BEGIN
1674 DELETE FROM "non_voter"
1675 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1676 RETURN NULL;
1677 END;
1678 $$;
1680 CREATE TRIGGER "direct_voter_deletes_non_voter"
1681 AFTER INSERT OR UPDATE ON "direct_voter"
1682 FOR EACH ROW EXECUTE PROCEDURE
1683 "direct_voter_deletes_non_voter_trigger"();
1685 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1686 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")';
1689 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1690 RETURNS TRIGGER
1691 LANGUAGE 'plpgsql' VOLATILE AS $$
1692 BEGIN
1693 IF NEW."comment" ISNULL THEN
1694 NEW."comment_changed" := NULL;
1695 NEW."formatting_engine" := NULL;
1696 END IF;
1697 RETURN NEW;
1698 END;
1699 $$;
1701 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1702 BEFORE INSERT OR UPDATE ON "direct_voter"
1703 FOR EACH ROW EXECUTE PROCEDURE
1704 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1706 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"';
1707 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.';
1710 ---------------------------------------------------------------
1711 -- Ensure that votes are not modified when issues are closed --
1712 ---------------------------------------------------------------
1714 -- NOTE: Frontends should ensure this anyway, but in case of programming
1715 -- errors the following triggers ensure data integrity.
1718 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1719 RETURNS TRIGGER
1720 LANGUAGE 'plpgsql' VOLATILE AS $$
1721 DECLARE
1722 "issue_id_v" "issue"."id"%TYPE;
1723 "issue_row" "issue"%ROWTYPE;
1724 BEGIN
1725 IF EXISTS (
1726 SELECT NULL FROM "temporary_transaction_data"
1727 WHERE "txid" = txid_current()
1728 AND "key" = 'override_protection_triggers'
1729 AND "value" = TRUE::TEXT
1730 ) THEN
1731 RETURN NULL;
1732 END IF;
1733 IF TG_OP = 'DELETE' THEN
1734 "issue_id_v" := OLD."issue_id";
1735 ELSE
1736 "issue_id_v" := NEW."issue_id";
1737 END IF;
1738 SELECT INTO "issue_row" * FROM "issue"
1739 WHERE "id" = "issue_id_v" FOR SHARE;
1740 IF (
1741 "issue_row"."closed" NOTNULL OR (
1742 "issue_row"."state" = 'voting' AND
1743 "issue_row"."phase_finished" NOTNULL
1745 ) THEN
1746 IF
1747 TG_RELID = 'direct_voter'::regclass AND
1748 TG_OP = 'UPDATE'
1749 THEN
1750 IF
1751 OLD."issue_id" = NEW."issue_id" AND
1752 OLD."member_id" = NEW."member_id" AND
1753 OLD."weight" = NEW."weight"
1754 THEN
1755 RETURN NULL; -- allows changing of voter comment
1756 END IF;
1757 END IF;
1758 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
1759 ERRCODE = 'integrity_constraint_violation';
1760 END IF;
1761 RETURN NULL;
1762 END;
1763 $$;
1765 CREATE TRIGGER "forbid_changes_on_closed_issue"
1766 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1767 FOR EACH ROW EXECUTE PROCEDURE
1768 "forbid_changes_on_closed_issue_trigger"();
1770 CREATE TRIGGER "forbid_changes_on_closed_issue"
1771 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1772 FOR EACH ROW EXECUTE PROCEDURE
1773 "forbid_changes_on_closed_issue_trigger"();
1775 CREATE TRIGGER "forbid_changes_on_closed_issue"
1776 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1777 FOR EACH ROW EXECUTE PROCEDURE
1778 "forbid_changes_on_closed_issue_trigger"();
1780 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"';
1781 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';
1782 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';
1783 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';
1787 --------------------------------------------------------------------
1788 -- Auto-retrieval of fields only needed for referential integrity --
1789 --------------------------------------------------------------------
1792 CREATE FUNCTION "autofill_issue_id_trigger"()
1793 RETURNS TRIGGER
1794 LANGUAGE 'plpgsql' VOLATILE AS $$
1795 BEGIN
1796 IF NEW."issue_id" ISNULL THEN
1797 SELECT "issue_id" INTO NEW."issue_id"
1798 FROM "initiative" WHERE "id" = NEW."initiative_id";
1799 END IF;
1800 RETURN NEW;
1801 END;
1802 $$;
1804 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1805 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1807 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1808 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1810 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1811 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1812 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1815 CREATE FUNCTION "autofill_initiative_id_trigger"()
1816 RETURNS TRIGGER
1817 LANGUAGE 'plpgsql' VOLATILE AS $$
1818 BEGIN
1819 IF NEW."initiative_id" ISNULL THEN
1820 SELECT "initiative_id" INTO NEW."initiative_id"
1821 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1822 END IF;
1823 RETURN NEW;
1824 END;
1825 $$;
1827 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1828 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1830 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1831 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1835 -----------------------------------------------------
1836 -- Automatic calculation of certain default values --
1837 -----------------------------------------------------
1840 CREATE FUNCTION "copy_timings_trigger"()
1841 RETURNS TRIGGER
1842 LANGUAGE 'plpgsql' VOLATILE AS $$
1843 DECLARE
1844 "policy_row" "policy"%ROWTYPE;
1845 BEGIN
1846 SELECT * INTO "policy_row" FROM "policy"
1847 WHERE "id" = NEW."policy_id";
1848 IF NEW."min_admission_time" ISNULL THEN
1849 NEW."min_admission_time" := "policy_row"."min_admission_time";
1850 END IF;
1851 IF NEW."max_admission_time" ISNULL THEN
1852 NEW."max_admission_time" := "policy_row"."max_admission_time";
1853 END IF;
1854 IF NEW."discussion_time" ISNULL THEN
1855 NEW."discussion_time" := "policy_row"."discussion_time";
1856 END IF;
1857 IF NEW."verification_time" ISNULL THEN
1858 NEW."verification_time" := "policy_row"."verification_time";
1859 END IF;
1860 IF NEW."voting_time" ISNULL THEN
1861 NEW."voting_time" := "policy_row"."voting_time";
1862 END IF;
1863 RETURN NEW;
1864 END;
1865 $$;
1867 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1868 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1870 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1871 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1874 CREATE FUNCTION "default_for_draft_id_trigger"()
1875 RETURNS TRIGGER
1876 LANGUAGE 'plpgsql' VOLATILE AS $$
1877 BEGIN
1878 IF NEW."draft_id" ISNULL THEN
1879 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1880 WHERE "initiative_id" = NEW."initiative_id";
1881 END IF;
1882 RETURN NEW;
1883 END;
1884 $$;
1886 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1887 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1888 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1889 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1891 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1892 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';
1893 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';
1897 ----------------------------------------
1898 -- Automatic creation of dependencies --
1899 ----------------------------------------
1902 CREATE FUNCTION "autocreate_interest_trigger"()
1903 RETURNS TRIGGER
1904 LANGUAGE 'plpgsql' VOLATILE AS $$
1905 BEGIN
1906 IF NOT EXISTS (
1907 SELECT NULL FROM "initiative" JOIN "interest"
1908 ON "initiative"."issue_id" = "interest"."issue_id"
1909 WHERE "initiative"."id" = NEW."initiative_id"
1910 AND "interest"."member_id" = NEW."member_id"
1911 ) THEN
1912 BEGIN
1913 INSERT INTO "interest" ("issue_id", "member_id")
1914 SELECT "issue_id", NEW."member_id"
1915 FROM "initiative" WHERE "id" = NEW."initiative_id";
1916 EXCEPTION WHEN unique_violation THEN END;
1917 END IF;
1918 RETURN NEW;
1919 END;
1920 $$;
1922 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1923 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1925 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1926 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';
1929 CREATE FUNCTION "autocreate_supporter_trigger"()
1930 RETURNS TRIGGER
1931 LANGUAGE 'plpgsql' VOLATILE AS $$
1932 BEGIN
1933 IF NOT EXISTS (
1934 SELECT NULL FROM "suggestion" JOIN "supporter"
1935 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1936 WHERE "suggestion"."id" = NEW."suggestion_id"
1937 AND "supporter"."member_id" = NEW."member_id"
1938 ) THEN
1939 BEGIN
1940 INSERT INTO "supporter" ("initiative_id", "member_id")
1941 SELECT "initiative_id", NEW."member_id"
1942 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1943 EXCEPTION WHEN unique_violation THEN END;
1944 END IF;
1945 RETURN NEW;
1946 END;
1947 $$;
1949 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1950 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1952 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1953 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.';
1957 ------------------------------------------
1958 -- Views and helper functions for views --
1959 ------------------------------------------
1962 CREATE VIEW "unit_delegation" AS
1963 SELECT
1964 "unit"."id" AS "unit_id",
1965 "delegation"."id",
1966 "delegation"."truster_id",
1967 "delegation"."trustee_id",
1968 "delegation"."scope"
1969 FROM "unit"
1970 JOIN "delegation"
1971 ON "delegation"."unit_id" = "unit"."id"
1972 JOIN "member"
1973 ON "delegation"."truster_id" = "member"."id"
1974 JOIN "privilege"
1975 ON "delegation"."unit_id" = "privilege"."unit_id"
1976 AND "delegation"."truster_id" = "privilege"."member_id"
1977 WHERE "member"."active" AND "privilege"."voting_right";
1979 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1982 CREATE VIEW "area_delegation" AS
1983 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1984 "area"."id" AS "area_id",
1985 "delegation"."id",
1986 "delegation"."truster_id",
1987 "delegation"."trustee_id",
1988 "delegation"."scope"
1989 FROM "area"
1990 JOIN "delegation"
1991 ON "delegation"."unit_id" = "area"."unit_id"
1992 OR "delegation"."area_id" = "area"."id"
1993 JOIN "member"
1994 ON "delegation"."truster_id" = "member"."id"
1995 JOIN "privilege"
1996 ON "area"."unit_id" = "privilege"."unit_id"
1997 AND "delegation"."truster_id" = "privilege"."member_id"
1998 WHERE "member"."active" AND "privilege"."voting_right"
1999 ORDER BY
2000 "area"."id",
2001 "delegation"."truster_id",
2002 "delegation"."scope" DESC;
2004 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
2007 CREATE VIEW "issue_delegation" AS
2008 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
2009 "issue"."id" AS "issue_id",
2010 "delegation"."id",
2011 "delegation"."truster_id",
2012 "delegation"."trustee_id",
2013 "delegation"."scope"
2014 FROM "issue"
2015 JOIN "area"
2016 ON "area"."id" = "issue"."area_id"
2017 JOIN "delegation"
2018 ON "delegation"."unit_id" = "area"."unit_id"
2019 OR "delegation"."area_id" = "area"."id"
2020 OR "delegation"."issue_id" = "issue"."id"
2021 JOIN "member"
2022 ON "delegation"."truster_id" = "member"."id"
2023 JOIN "privilege"
2024 ON "area"."unit_id" = "privilege"."unit_id"
2025 AND "delegation"."truster_id" = "privilege"."member_id"
2026 WHERE "member"."active" AND "privilege"."voting_right"
2027 ORDER BY
2028 "issue"."id",
2029 "delegation"."truster_id",
2030 "delegation"."scope" DESC;
2032 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
2035 CREATE FUNCTION "membership_weight_with_skipping"
2036 ( "area_id_p" "area"."id"%TYPE,
2037 "member_id_p" "member"."id"%TYPE,
2038 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
2039 RETURNS INT4
2040 LANGUAGE 'plpgsql' STABLE AS $$
2041 DECLARE
2042 "sum_v" INT4;
2043 "delegation_row" "area_delegation"%ROWTYPE;
2044 BEGIN
2045 "sum_v" := 1;
2046 FOR "delegation_row" IN
2047 SELECT "area_delegation".*
2048 FROM "area_delegation" LEFT JOIN "membership"
2049 ON "membership"."area_id" = "area_id_p"
2050 AND "membership"."member_id" = "area_delegation"."truster_id"
2051 WHERE "area_delegation"."area_id" = "area_id_p"
2052 AND "area_delegation"."trustee_id" = "member_id_p"
2053 AND "membership"."member_id" ISNULL
2054 LOOP
2055 IF NOT
2056 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
2057 THEN
2058 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
2059 "area_id_p",
2060 "delegation_row"."truster_id",
2061 "skip_member_ids_p" || "delegation_row"."truster_id"
2062 );
2063 END IF;
2064 END LOOP;
2065 RETURN "sum_v";
2066 END;
2067 $$;
2069 COMMENT ON FUNCTION "membership_weight_with_skipping"
2070 ( "area"."id"%TYPE,
2071 "member"."id"%TYPE,
2072 INT4[] )
2073 IS 'Helper function for "membership_weight" function';
2076 CREATE FUNCTION "membership_weight"
2077 ( "area_id_p" "area"."id"%TYPE,
2078 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
2079 RETURNS INT4
2080 LANGUAGE 'plpgsql' STABLE AS $$
2081 BEGIN
2082 RETURN "membership_weight_with_skipping"(
2083 "area_id_p",
2084 "member_id_p",
2085 ARRAY["member_id_p"]
2086 );
2087 END;
2088 $$;
2090 COMMENT ON FUNCTION "membership_weight"
2091 ( "area"."id"%TYPE,
2092 "member"."id"%TYPE )
2093 IS 'Calculates the potential voting weight of a member in a given area';
2096 CREATE VIEW "member_count_view" AS
2097 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
2099 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
2102 CREATE VIEW "unit_member_count" AS
2103 SELECT
2104 "unit"."id" AS "unit_id",
2105 count("member"."id") AS "member_count"
2106 FROM "unit"
2107 LEFT JOIN "privilege"
2108 ON "privilege"."unit_id" = "unit"."id"
2109 AND "privilege"."voting_right"
2110 LEFT JOIN "member"
2111 ON "member"."id" = "privilege"."member_id"
2112 AND "member"."active"
2113 GROUP BY "unit"."id";
2115 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
2118 CREATE VIEW "area_member_count" AS
2119 SELECT
2120 "area"."id" AS "area_id",
2121 count("member"."id") AS "direct_member_count",
2122 coalesce(
2123 sum(
2124 CASE WHEN "member"."id" NOTNULL THEN
2125 "membership_weight"("area"."id", "member"."id")
2126 ELSE 0 END
2128 ) AS "member_weight"
2129 FROM "area"
2130 LEFT JOIN "membership"
2131 ON "area"."id" = "membership"."area_id"
2132 LEFT JOIN "privilege"
2133 ON "privilege"."unit_id" = "area"."unit_id"
2134 AND "privilege"."member_id" = "membership"."member_id"
2135 AND "privilege"."voting_right"
2136 LEFT JOIN "member"
2137 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2138 AND "member"."active"
2139 GROUP BY "area"."id";
2141 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2144 CREATE VIEW "opening_draft" AS
2145 SELECT "draft".* FROM (
2146 SELECT
2147 "initiative"."id" AS "initiative_id",
2148 min("draft"."id") AS "draft_id"
2149 FROM "initiative" JOIN "draft"
2150 ON "initiative"."id" = "draft"."initiative_id"
2151 GROUP BY "initiative"."id"
2152 ) AS "subquery"
2153 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2155 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2158 CREATE VIEW "current_draft" AS
2159 SELECT "draft".* FROM (
2160 SELECT
2161 "initiative"."id" AS "initiative_id",
2162 max("draft"."id") AS "draft_id"
2163 FROM "initiative" JOIN "draft"
2164 ON "initiative"."id" = "draft"."initiative_id"
2165 GROUP BY "initiative"."id"
2166 ) AS "subquery"
2167 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2169 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2172 CREATE VIEW "critical_opinion" AS
2173 SELECT * FROM "opinion"
2174 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2175 OR ("degree" = -2 AND "fulfilled" = TRUE);
2177 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2180 CREATE VIEW "issue_supporter_in_admission_state" AS
2181 SELECT DISTINCT -- TODO: DISTINCT needed?
2182 "area"."unit_id",
2183 "issue"."area_id",
2184 "issue"."id" AS "issue_id",
2185 "supporter"."member_id",
2186 "direct_interest_snapshot"."weight"
2187 FROM "issue"
2188 JOIN "area" ON "area"."id" = "issue"."area_id"
2189 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
2190 JOIN "direct_interest_snapshot"
2191 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2192 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2193 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
2194 WHERE "issue"."state" = 'admission'::"issue_state";
2196 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';
2199 CREATE VIEW "initiative_suggestion_order_calculation" AS
2200 SELECT
2201 "initiative"."id" AS "initiative_id",
2202 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
2203 FROM "initiative" JOIN "issue"
2204 ON "initiative"."issue_id" = "issue"."id"
2205 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
2206 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
2208 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
2210 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';
2213 CREATE VIEW "individual_suggestion_ranking" AS
2214 SELECT
2215 "opinion"."initiative_id",
2216 "opinion"."member_id",
2217 "direct_interest_snapshot"."weight",
2218 CASE WHEN
2219 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
2220 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
2221 THEN 1 ELSE
2222 CASE WHEN
2223 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
2224 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
2225 THEN 2 ELSE
2226 CASE WHEN
2227 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
2228 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
2229 THEN 3 ELSE 4 END
2230 END
2231 END AS "preference",
2232 "opinion"."suggestion_id"
2233 FROM "opinion"
2234 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
2235 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2236 JOIN "direct_interest_snapshot"
2237 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2238 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2239 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
2241 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
2244 CREATE VIEW "battle_participant" AS
2245 SELECT "initiative"."id", "initiative"."issue_id"
2246 FROM "issue" JOIN "initiative"
2247 ON "issue"."id" = "initiative"."issue_id"
2248 WHERE "initiative"."admitted"
2249 UNION ALL
2250 SELECT NULL, "id" AS "issue_id"
2251 FROM "issue";
2253 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2256 CREATE VIEW "battle_view" AS
2257 SELECT
2258 "issue"."id" AS "issue_id",
2259 "winning_initiative"."id" AS "winning_initiative_id",
2260 "losing_initiative"."id" AS "losing_initiative_id",
2261 sum(
2262 CASE WHEN
2263 coalesce("better_vote"."grade", 0) >
2264 coalesce("worse_vote"."grade", 0)
2265 THEN "direct_voter"."weight" ELSE 0 END
2266 ) AS "count"
2267 FROM "issue"
2268 LEFT JOIN "direct_voter"
2269 ON "issue"."id" = "direct_voter"."issue_id"
2270 JOIN "battle_participant" AS "winning_initiative"
2271 ON "issue"."id" = "winning_initiative"."issue_id"
2272 JOIN "battle_participant" AS "losing_initiative"
2273 ON "issue"."id" = "losing_initiative"."issue_id"
2274 LEFT JOIN "vote" AS "better_vote"
2275 ON "direct_voter"."member_id" = "better_vote"."member_id"
2276 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2277 LEFT JOIN "vote" AS "worse_vote"
2278 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2279 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2280 WHERE "issue"."state" = 'voting'
2281 AND "issue"."phase_finished" NOTNULL
2282 AND (
2283 "winning_initiative"."id" != "losing_initiative"."id" OR
2284 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2285 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2286 GROUP BY
2287 "issue"."id",
2288 "winning_initiative"."id",
2289 "losing_initiative"."id";
2291 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';
2294 CREATE VIEW "expired_session" AS
2295 SELECT * FROM "session" WHERE now() > "expiry";
2297 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2298 DELETE FROM "session" WHERE "ident" = OLD."ident";
2300 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2301 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2304 CREATE VIEW "open_issue" AS
2305 SELECT * FROM "issue" WHERE "closed" ISNULL;
2307 COMMENT ON VIEW "open_issue" IS 'All open issues';
2310 CREATE VIEW "member_contingent" AS
2311 SELECT
2312 "member"."id" AS "member_id",
2313 "contingent"."polling",
2314 "contingent"."time_frame",
2315 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2317 SELECT count(1) FROM "draft"
2318 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2319 WHERE "draft"."author_id" = "member"."id"
2320 AND "initiative"."polling" = "contingent"."polling"
2321 AND "draft"."created" > now() - "contingent"."time_frame"
2322 ) + (
2323 SELECT count(1) FROM "suggestion"
2324 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2325 WHERE "suggestion"."author_id" = "member"."id"
2326 AND "contingent"."polling" = FALSE
2327 AND "suggestion"."created" > now() - "contingent"."time_frame"
2329 ELSE NULL END AS "text_entry_count",
2330 "contingent"."text_entry_limit",
2331 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2332 SELECT count(1) FROM "opening_draft" AS "draft"
2333 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2334 WHERE "draft"."author_id" = "member"."id"
2335 AND "initiative"."polling" = "contingent"."polling"
2336 AND "draft"."created" > now() - "contingent"."time_frame"
2337 ) ELSE NULL END AS "initiative_count",
2338 "contingent"."initiative_limit"
2339 FROM "member" CROSS JOIN "contingent";
2341 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2343 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2344 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2347 CREATE VIEW "member_contingent_left" AS
2348 SELECT
2349 "member_id",
2350 "polling",
2351 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2352 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2353 FROM "member_contingent" GROUP BY "member_id", "polling";
2355 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.';
2358 CREATE VIEW "event_for_notification" AS
2359 SELECT
2360 "member"."id" AS "recipient_id",
2361 "event".*
2362 FROM "member" CROSS JOIN "event"
2363 JOIN "issue" ON "issue"."id" = "event"."issue_id"
2364 JOIN "area" ON "area"."id" = "issue"."area_id"
2365 LEFT JOIN "privilege" ON
2366 "privilege"."member_id" = "member"."id" AND
2367 "privilege"."unit_id" = "area"."unit_id" AND
2368 "privilege"."voting_right" = TRUE
2369 LEFT JOIN "subscription" ON
2370 "subscription"."member_id" = "member"."id" AND
2371 "subscription"."unit_id" = "area"."unit_id"
2372 LEFT JOIN "ignored_area" ON
2373 "ignored_area"."member_id" = "member"."id" AND
2374 "ignored_area"."area_id" = "issue"."area_id"
2375 LEFT JOIN "interest" ON
2376 "interest"."member_id" = "member"."id" AND
2377 "interest"."issue_id" = "event"."issue_id"
2378 LEFT JOIN "supporter" ON
2379 "supporter"."member_id" = "member"."id" AND
2380 "supporter"."initiative_id" = "event"."initiative_id"
2381 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
2382 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
2383 AND (
2384 "event"."event" = 'issue_state_changed'::"event_type" OR
2385 ( "event"."event" = 'initiative_revoked'::"event_type" AND
2386 "supporter"."member_id" NOTNULL ) );
2388 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
2390 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
2393 CREATE VIEW "updated_initiative" AS
2394 SELECT
2395 "supporter"."member_id" AS "recipient_id",
2396 FALSE AS "featured",
2397 "supporter"."initiative_id"
2398 FROM "supporter"
2399 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
2400 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2401 LEFT JOIN "notification_initiative_sent" AS "sent" ON
2402 "sent"."member_id" = "supporter"."member_id" AND
2403 "sent"."initiative_id" = "supporter"."initiative_id"
2404 LEFT JOIN "ignored_initiative" ON
2405 "ignored_initiative"."member_id" = "supporter"."member_id" AND
2406 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
2407 WHERE "issue"."state" IN ('admission', 'discussion')
2408 AND "initiative"."revoked" ISNULL
2409 AND "ignored_initiative"."member_id" ISNULL
2410 AND (
2411 EXISTS (
2412 SELECT NULL FROM "draft"
2413 LEFT JOIN "ignored_member" ON
2414 "ignored_member"."member_id" = "supporter"."member_id" AND
2415 "ignored_member"."other_member_id" = "draft"."author_id"
2416 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
2417 AND "draft"."id" > "supporter"."draft_id"
2418 AND "ignored_member"."member_id" ISNULL
2419 ) OR EXISTS (
2420 SELECT NULL FROM "suggestion"
2421 LEFT JOIN "opinion" ON
2422 "opinion"."member_id" = "supporter"."member_id" AND
2423 "opinion"."suggestion_id" = "suggestion"."id"
2424 LEFT JOIN "ignored_member" ON
2425 "ignored_member"."member_id" = "supporter"."member_id" AND
2426 "ignored_member"."other_member_id" = "suggestion"."author_id"
2427 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
2428 AND "opinion"."member_id" ISNULL
2429 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
2430 AND "ignored_member"."member_id" ISNULL
2432 );
2434 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
2437 CREATE FUNCTION "featured_initiative"
2438 ( "recipient_id_p" "member"."id"%TYPE,
2439 "area_id_p" "area"."id"%TYPE )
2440 RETURNS SETOF "initiative"."id"%TYPE
2441 LANGUAGE 'plpgsql' STABLE AS $$
2442 DECLARE
2443 "counter_v" "member"."notification_counter"%TYPE;
2444 "sample_size_v" "member"."notification_sample_size"%TYPE;
2445 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
2446 "match_v" BOOLEAN;
2447 "member_id_v" "member"."id"%TYPE;
2448 "seed_v" TEXT;
2449 "initiative_id_v" "initiative"."id"%TYPE;
2450 BEGIN
2451 SELECT "notification_counter", "notification_sample_size"
2452 INTO "counter_v", "sample_size_v"
2453 FROM "member" WHERE "id" = "recipient_id_p";
2454 "initiative_id_ary" := '{}';
2455 LOOP
2456 "match_v" := FALSE;
2457 FOR "member_id_v", "seed_v" IN
2458 SELECT * FROM (
2459 SELECT DISTINCT
2460 "supporter"."member_id",
2461 md5(
2462 "recipient_id_p" || '-' ||
2463 "counter_v" || '-' ||
2464 "area_id_p" || '-' ||
2465 "supporter"."member_id"
2466 ) AS "seed"
2467 FROM "supporter"
2468 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
2469 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2470 WHERE "supporter"."member_id" != "recipient_id_p"
2471 AND "issue"."area_id" = "area_id_p"
2472 AND "issue"."state" IN ('admission', 'discussion', 'verification')
2473 ) AS "subquery"
2474 ORDER BY "seed"
2475 LOOP
2476 SELECT "initiative"."id" INTO "initiative_id_v"
2477 FROM "initiative"
2478 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2479 JOIN "area" ON "area"."id" = "issue"."area_id"
2480 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
2481 LEFT JOIN "supporter" AS "self_support" ON
2482 "self_support"."initiative_id" = "initiative"."id" AND
2483 "self_support"."member_id" = "recipient_id_p"
2484 LEFT JOIN "privilege" ON
2485 "privilege"."member_id" = "recipient_id_p" AND
2486 "privilege"."unit_id" = "area"."unit_id" AND
2487 "privilege"."voting_right" = TRUE
2488 LEFT JOIN "subscription" ON
2489 "subscription"."member_id" = "recipient_id_p" AND
2490 "subscription"."unit_id" = "area"."unit_id"
2491 LEFT JOIN "ignored_initiative" ON
2492 "ignored_initiative"."member_id" = "recipient_id_p" AND
2493 "ignored_initiative"."initiative_id" = "initiative"."id"
2494 WHERE "supporter"."member_id" = "member_id_v"
2495 AND "issue"."area_id" = "area_id_p"
2496 AND "issue"."state" IN ('admission', 'discussion', 'verification')
2497 AND "initiative"."revoked" ISNULL
2498 AND "self_support"."member_id" ISNULL
2499 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
2500 AND (
2501 "privilege"."member_id" NOTNULL OR
2502 "subscription"."member_id" NOTNULL )
2503 AND "ignored_initiative"."member_id" ISNULL
2504 AND NOT EXISTS (
2505 SELECT NULL FROM "draft"
2506 JOIN "ignored_member" ON
2507 "ignored_member"."member_id" = "recipient_id_p" AND
2508 "ignored_member"."other_member_id" = "draft"."author_id"
2509 WHERE "draft"."initiative_id" = "initiative"."id"
2511 ORDER BY md5("seed_v" || '-' || "initiative"."id")
2512 LIMIT 1;
2513 IF FOUND THEN
2514 "match_v" := TRUE;
2515 RETURN NEXT "initiative_id_v";
2516 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
2517 RETURN;
2518 END IF;
2519 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
2520 END IF;
2521 END LOOP;
2522 EXIT WHEN NOT "match_v";
2523 END LOOP;
2524 RETURN;
2525 END;
2526 $$;
2528 COMMENT ON FUNCTION "featured_initiative"
2529 ( "recipient_id_p" "member"."id"%TYPE,
2530 "area_id_p" "area"."id"%TYPE )
2531 IS 'Helper function for view "updated_or_featured_initiative"';
2534 CREATE VIEW "updated_or_featured_initiative" AS
2535 SELECT
2536 "subquery".*,
2537 NOT EXISTS (
2538 SELECT NULL FROM "initiative" AS "better_initiative"
2539 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
2540 AND
2541 ( COALESCE("better_initiative"."supporter_count", -1),
2542 -"better_initiative"."id" ) >
2543 ( COALESCE("initiative"."supporter_count", -1),
2544 -"initiative"."id" )
2545 ) AS "leading"
2546 FROM (
2547 SELECT * FROM "updated_initiative"
2548 UNION ALL
2549 SELECT
2550 "member"."id" AS "recipient_id",
2551 TRUE AS "featured",
2552 "featured_initiative_id" AS "initiative_id"
2553 FROM "member" CROSS JOIN "area"
2554 CROSS JOIN LATERAL
2555 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
2556 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
2557 ) AS "subquery"
2558 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
2560 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';
2562 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
2563 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")';
2564 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
2565 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
2568 CREATE VIEW "leading_complement_initiative" AS
2569 SELECT * FROM (
2570 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
2571 "uf_initiative"."recipient_id",
2572 FALSE AS "featured",
2573 "uf_initiative"."initiative_id",
2574 TRUE AS "leading"
2575 FROM "updated_or_featured_initiative" AS "uf_initiative"
2576 JOIN "initiative" AS "uf_initiative_full" ON
2577 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
2578 JOIN "initiative" ON
2579 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
2580 WHERE "initiative"."revoked" ISNULL
2581 ORDER BY
2582 "uf_initiative"."recipient_id",
2583 "initiative"."issue_id",
2584 "initiative"."supporter_count" DESC,
2585 "initiative"."id"
2586 ) AS "subquery"
2587 WHERE NOT EXISTS (
2588 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
2589 WHERE "other"."recipient_id" = "subquery"."recipient_id"
2590 AND "other"."initiative_id" = "subquery"."initiative_id"
2591 );
2593 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';
2594 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
2595 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
2596 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
2599 CREATE VIEW "unfiltered_initiative_for_notification" AS
2600 SELECT
2601 "subquery".*,
2602 "supporter"."member_id" NOTNULL AS "supported",
2603 CASE WHEN "supporter"."member_id" NOTNULL THEN
2604 EXISTS (
2605 SELECT NULL FROM "draft"
2606 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
2607 AND "draft"."id" > "supporter"."draft_id"
2609 ELSE
2610 EXISTS (
2611 SELECT NULL FROM "draft"
2612 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
2613 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
2615 END AS "new_draft",
2616 CASE WHEN "supporter"."member_id" NOTNULL THEN
2617 ( SELECT count(1) FROM "suggestion"
2618 LEFT JOIN "opinion" ON
2619 "opinion"."member_id" = "supporter"."member_id" AND
2620 "opinion"."suggestion_id" = "suggestion"."id"
2621 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
2622 AND "opinion"."member_id" ISNULL
2623 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
2625 ELSE
2626 ( SELECT count(1) FROM "suggestion"
2627 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
2628 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
2630 END AS "new_suggestion_count"
2631 FROM (
2632 SELECT * FROM "updated_or_featured_initiative"
2633 UNION ALL
2634 SELECT * FROM "leading_complement_initiative"
2635 ) AS "subquery"
2636 LEFT JOIN "supporter" ON
2637 "supporter"."member_id" = "subquery"."recipient_id" AND
2638 "supporter"."initiative_id" = "subquery"."initiative_id"
2639 LEFT JOIN "notification_initiative_sent" AS "sent" ON
2640 "sent"."member_id" = "subquery"."recipient_id" AND
2641 "sent"."initiative_id" = "subquery"."initiative_id";
2643 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';
2645 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
2646 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)';
2647 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")';
2650 CREATE VIEW "initiative_for_notification" AS
2651 SELECT "unfiltered1".*
2652 FROM "unfiltered_initiative_for_notification" "unfiltered1"
2653 JOIN "initiative" AS "initiative1" ON
2654 "initiative1"."id" = "unfiltered1"."initiative_id"
2655 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
2656 WHERE EXISTS (
2657 SELECT NULL
2658 FROM "unfiltered_initiative_for_notification" "unfiltered2"
2659 JOIN "initiative" AS "initiative2" ON
2660 "initiative2"."id" = "unfiltered2"."initiative_id"
2661 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
2662 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
2663 AND "issue1"."area_id" = "issue2"."area_id"
2664 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
2665 );
2667 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
2669 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
2670 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")';
2671 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
2672 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
2673 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
2674 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)';
2675 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")';
2678 CREATE VIEW "scheduled_notification_to_send" AS
2679 SELECT * FROM (
2680 SELECT
2681 "id" AS "recipient_id",
2682 now() - CASE WHEN "notification_dow" ISNULL THEN
2683 ( "notification_sent"::DATE + CASE
2684 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
2685 THEN 0 ELSE 1 END
2686 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
2687 ELSE
2688 ( "notification_sent"::DATE +
2689 ( 7 + "notification_dow" -
2690 EXTRACT(DOW FROM
2691 ( "notification_sent"::DATE + CASE
2692 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
2693 THEN 0 ELSE 1 END
2694 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
2695 )::INTEGER
2696 ) % 7 +
2697 CASE
2698 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
2699 THEN 0 ELSE 1
2700 END
2701 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
2702 END AS "pending"
2703 FROM (
2704 SELECT
2705 "id",
2706 COALESCE("notification_sent", "activated") AS "notification_sent",
2707 "notification_dow",
2708 "notification_hour"
2709 FROM "member"
2710 WHERE "disable_notifications" = FALSE
2711 AND "notification_hour" NOTNULL
2712 ) AS "subquery1"
2713 ) AS "subquery2"
2714 WHERE "pending" > '0'::INTERVAL;
2716 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
2718 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
2719 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
2722 CREATE VIEW "newsletter_to_send" AS
2723 SELECT
2724 "member"."id" AS "recipient_id",
2725 "newsletter"."id" AS "newsletter_id"
2726 FROM "newsletter" CROSS JOIN "member"
2727 LEFT JOIN "privilege" ON
2728 "privilege"."member_id" = "member"."id" AND
2729 "privilege"."unit_id" = "newsletter"."unit_id" AND
2730 "privilege"."voting_right" = TRUE
2731 LEFT JOIN "subscription" ON
2732 "subscription"."member_id" = "member"."id" AND
2733 "subscription"."unit_id" = "newsletter"."unit_id"
2734 WHERE "newsletter"."published" <= now()
2735 AND "newsletter"."sent" ISNULL
2736 AND "member"."locked" = FALSE
2737 AND (
2738 "member"."disable_notifications" = FALSE OR
2739 "newsletter"."include_all_members" = TRUE )
2740 AND (
2741 "newsletter"."unit_id" ISNULL OR
2742 "privilege"."member_id" NOTNULL OR
2743 "subscription"."member_id" NOTNULL );
2745 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
2749 ------------------------------------------------------
2750 -- Row set returning function for delegation chains --
2751 ------------------------------------------------------
2754 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2755 ('first', 'intermediate', 'last', 'repetition');
2757 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2760 CREATE TYPE "delegation_chain_row" AS (
2761 "index" INT4,
2762 "member_id" INT4,
2763 "member_valid" BOOLEAN,
2764 "participation" BOOLEAN,
2765 "overridden" BOOLEAN,
2766 "scope_in" "delegation_scope",
2767 "scope_out" "delegation_scope",
2768 "disabled_out" BOOLEAN,
2769 "loop" "delegation_chain_loop_tag" );
2771 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2773 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2774 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest, for areas: membership, for global delegation chains: always null';
2775 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2776 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2777 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2778 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2779 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2782 CREATE FUNCTION "delegation_chain_for_closed_issue"
2783 ( "member_id_p" "member"."id"%TYPE,
2784 "issue_id_p" "issue"."id"%TYPE )
2785 RETURNS SETOF "delegation_chain_row"
2786 LANGUAGE 'plpgsql' STABLE AS $$
2787 DECLARE
2788 "output_row" "delegation_chain_row";
2789 "direct_voter_row" "direct_voter"%ROWTYPE;
2790 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2791 BEGIN
2792 "output_row"."index" := 0;
2793 "output_row"."member_id" := "member_id_p";
2794 "output_row"."member_valid" := TRUE;
2795 "output_row"."participation" := FALSE;
2796 "output_row"."overridden" := FALSE;
2797 "output_row"."disabled_out" := FALSE;
2798 LOOP
2799 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2800 WHERE "issue_id" = "issue_id_p"
2801 AND "member_id" = "output_row"."member_id";
2802 IF "direct_voter_row"."member_id" NOTNULL THEN
2803 "output_row"."participation" := TRUE;
2804 "output_row"."scope_out" := NULL;
2805 "output_row"."disabled_out" := NULL;
2806 RETURN NEXT "output_row";
2807 RETURN;
2808 END IF;
2809 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2810 WHERE "issue_id" = "issue_id_p"
2811 AND "member_id" = "output_row"."member_id";
2812 IF "delegating_voter_row"."member_id" ISNULL THEN
2813 RETURN;
2814 END IF;
2815 "output_row"."scope_out" := "delegating_voter_row"."scope";
2816 RETURN NEXT "output_row";
2817 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2818 "output_row"."scope_in" := "output_row"."scope_out";
2819 END LOOP;
2820 END;
2821 $$;
2823 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2824 ( "member"."id"%TYPE,
2825 "member"."id"%TYPE )
2826 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2829 CREATE FUNCTION "delegation_chain"
2830 ( "member_id_p" "member"."id"%TYPE,
2831 "unit_id_p" "unit"."id"%TYPE,
2832 "area_id_p" "area"."id"%TYPE,
2833 "issue_id_p" "issue"."id"%TYPE,
2834 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2835 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2836 RETURNS SETOF "delegation_chain_row"
2837 LANGUAGE 'plpgsql' STABLE AS $$
2838 DECLARE
2839 "scope_v" "delegation_scope";
2840 "unit_id_v" "unit"."id"%TYPE;
2841 "area_id_v" "area"."id"%TYPE;
2842 "issue_row" "issue"%ROWTYPE;
2843 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2844 "loop_member_id_v" "member"."id"%TYPE;
2845 "output_row" "delegation_chain_row";
2846 "output_rows" "delegation_chain_row"[];
2847 "simulate_v" BOOLEAN;
2848 "simulate_here_v" BOOLEAN;
2849 "delegation_row" "delegation"%ROWTYPE;
2850 "row_count" INT4;
2851 "i" INT4;
2852 "loop_v" BOOLEAN;
2853 BEGIN
2854 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2855 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2856 END IF;
2857 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2858 "simulate_v" := TRUE;
2859 ELSE
2860 "simulate_v" := FALSE;
2861 END IF;
2862 IF
2863 "unit_id_p" NOTNULL AND
2864 "area_id_p" ISNULL AND
2865 "issue_id_p" ISNULL
2866 THEN
2867 "scope_v" := 'unit';
2868 "unit_id_v" := "unit_id_p";
2869 ELSIF
2870 "unit_id_p" ISNULL AND
2871 "area_id_p" NOTNULL AND
2872 "issue_id_p" ISNULL
2873 THEN
2874 "scope_v" := 'area';
2875 "area_id_v" := "area_id_p";
2876 SELECT "unit_id" INTO "unit_id_v"
2877 FROM "area" WHERE "id" = "area_id_v";
2878 ELSIF
2879 "unit_id_p" ISNULL AND
2880 "area_id_p" ISNULL AND
2881 "issue_id_p" NOTNULL
2882 THEN
2883 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2884 IF "issue_row"."id" ISNULL THEN
2885 RETURN;
2886 END IF;
2887 IF "issue_row"."closed" NOTNULL THEN
2888 IF "simulate_v" THEN
2889 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2890 END IF;
2891 FOR "output_row" IN
2892 SELECT * FROM
2893 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2894 LOOP
2895 RETURN NEXT "output_row";
2896 END LOOP;
2897 RETURN;
2898 END IF;
2899 "scope_v" := 'issue';
2900 SELECT "area_id" INTO "area_id_v"
2901 FROM "issue" WHERE "id" = "issue_id_p";
2902 SELECT "unit_id" INTO "unit_id_v"
2903 FROM "area" WHERE "id" = "area_id_v";
2904 ELSE
2905 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2906 END IF;
2907 "visited_member_ids" := '{}';
2908 "loop_member_id_v" := NULL;
2909 "output_rows" := '{}';
2910 "output_row"."index" := 0;
2911 "output_row"."member_id" := "member_id_p";
2912 "output_row"."member_valid" := TRUE;
2913 "output_row"."participation" := FALSE;
2914 "output_row"."overridden" := FALSE;
2915 "output_row"."disabled_out" := FALSE;
2916 "output_row"."scope_out" := NULL;
2917 LOOP
2918 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2919 "loop_member_id_v" := "output_row"."member_id";
2920 ELSE
2921 "visited_member_ids" :=
2922 "visited_member_ids" || "output_row"."member_id";
2923 END IF;
2924 IF "output_row"."participation" ISNULL THEN
2925 "output_row"."overridden" := NULL;
2926 ELSIF "output_row"."participation" THEN
2927 "output_row"."overridden" := TRUE;
2928 END IF;
2929 "output_row"."scope_in" := "output_row"."scope_out";
2930 "output_row"."member_valid" := EXISTS (
2931 SELECT NULL FROM "member" JOIN "privilege"
2932 ON "privilege"."member_id" = "member"."id"
2933 AND "privilege"."unit_id" = "unit_id_v"
2934 WHERE "id" = "output_row"."member_id"
2935 AND "member"."active" AND "privilege"."voting_right"
2936 );
2937 "simulate_here_v" := (
2938 "simulate_v" AND
2939 "output_row"."member_id" = "member_id_p"
2940 );
2941 "delegation_row" := ROW(NULL);
2942 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2943 IF "scope_v" = 'unit' THEN
2944 IF NOT "simulate_here_v" THEN
2945 SELECT * INTO "delegation_row" FROM "delegation"
2946 WHERE "truster_id" = "output_row"."member_id"
2947 AND "unit_id" = "unit_id_v";
2948 END IF;
2949 ELSIF "scope_v" = 'area' THEN
2950 "output_row"."participation" := EXISTS (
2951 SELECT NULL FROM "membership"
2952 WHERE "area_id" = "area_id_p"
2953 AND "member_id" = "output_row"."member_id"
2954 );
2955 IF "simulate_here_v" THEN
2956 IF "simulate_trustee_id_p" ISNULL THEN
2957 SELECT * INTO "delegation_row" FROM "delegation"
2958 WHERE "truster_id" = "output_row"."member_id"
2959 AND "unit_id" = "unit_id_v";
2960 END IF;
2961 ELSE
2962 SELECT * INTO "delegation_row" FROM "delegation"
2963 WHERE "truster_id" = "output_row"."member_id"
2964 AND (
2965 "unit_id" = "unit_id_v" OR
2966 "area_id" = "area_id_v"
2968 ORDER BY "scope" DESC;
2969 END IF;
2970 ELSIF "scope_v" = 'issue' THEN
2971 IF "issue_row"."fully_frozen" ISNULL THEN
2972 "output_row"."participation" := EXISTS (
2973 SELECT NULL FROM "interest"
2974 WHERE "issue_id" = "issue_id_p"
2975 AND "member_id" = "output_row"."member_id"
2976 );
2977 ELSE
2978 IF "output_row"."member_id" = "member_id_p" THEN
2979 "output_row"."participation" := EXISTS (
2980 SELECT NULL FROM "direct_voter"
2981 WHERE "issue_id" = "issue_id_p"
2982 AND "member_id" = "output_row"."member_id"
2983 );
2984 ELSE
2985 "output_row"."participation" := NULL;
2986 END IF;
2987 END IF;
2988 IF "simulate_here_v" THEN
2989 IF "simulate_trustee_id_p" ISNULL THEN
2990 SELECT * INTO "delegation_row" FROM "delegation"
2991 WHERE "truster_id" = "output_row"."member_id"
2992 AND (
2993 "unit_id" = "unit_id_v" OR
2994 "area_id" = "area_id_v"
2996 ORDER BY "scope" DESC;
2997 END IF;
2998 ELSE
2999 SELECT * INTO "delegation_row" FROM "delegation"
3000 WHERE "truster_id" = "output_row"."member_id"
3001 AND (
3002 "unit_id" = "unit_id_v" OR
3003 "area_id" = "area_id_v" OR
3004 "issue_id" = "issue_id_p"
3006 ORDER BY "scope" DESC;
3007 END IF;
3008 END IF;
3009 ELSE
3010 "output_row"."participation" := FALSE;
3011 END IF;
3012 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
3013 "output_row"."scope_out" := "scope_v";
3014 "output_rows" := "output_rows" || "output_row";
3015 "output_row"."member_id" := "simulate_trustee_id_p";
3016 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
3017 "output_row"."scope_out" := "delegation_row"."scope";
3018 "output_rows" := "output_rows" || "output_row";
3019 "output_row"."member_id" := "delegation_row"."trustee_id";
3020 ELSIF "delegation_row"."scope" NOTNULL THEN
3021 "output_row"."scope_out" := "delegation_row"."scope";
3022 "output_row"."disabled_out" := TRUE;
3023 "output_rows" := "output_rows" || "output_row";
3024 EXIT;
3025 ELSE
3026 "output_row"."scope_out" := NULL;
3027 "output_rows" := "output_rows" || "output_row";
3028 EXIT;
3029 END IF;
3030 EXIT WHEN "loop_member_id_v" NOTNULL;
3031 "output_row"."index" := "output_row"."index" + 1;
3032 END LOOP;
3033 "row_count" := array_upper("output_rows", 1);
3034 "i" := 1;
3035 "loop_v" := FALSE;
3036 LOOP
3037 "output_row" := "output_rows"["i"];
3038 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
3039 IF "loop_v" THEN
3040 IF "i" + 1 = "row_count" THEN
3041 "output_row"."loop" := 'last';
3042 ELSIF "i" = "row_count" THEN
3043 "output_row"."loop" := 'repetition';
3044 ELSE
3045 "output_row"."loop" := 'intermediate';
3046 END IF;
3047 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
3048 "output_row"."loop" := 'first';
3049 "loop_v" := TRUE;
3050 END IF;
3051 IF "scope_v" = 'unit' THEN
3052 "output_row"."participation" := NULL;
3053 END IF;
3054 RETURN NEXT "output_row";
3055 "i" := "i" + 1;
3056 END LOOP;
3057 RETURN;
3058 END;
3059 $$;
3061 COMMENT ON FUNCTION "delegation_chain"
3062 ( "member"."id"%TYPE,
3063 "unit"."id"%TYPE,
3064 "area"."id"%TYPE,
3065 "issue"."id"%TYPE,
3066 "member"."id"%TYPE,
3067 BOOLEAN )
3068 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
3072 ---------------------------------------------------------
3073 -- Single row returning function for delegation chains --
3074 ---------------------------------------------------------
3077 CREATE TYPE "delegation_info_loop_type" AS ENUM
3078 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
3080 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''';
3083 CREATE TYPE "delegation_info_type" AS (
3084 "own_participation" BOOLEAN,
3085 "own_delegation_scope" "delegation_scope",
3086 "first_trustee_id" INT4,
3087 "first_trustee_participation" BOOLEAN,
3088 "first_trustee_ellipsis" BOOLEAN,
3089 "other_trustee_id" INT4,
3090 "other_trustee_participation" BOOLEAN,
3091 "other_trustee_ellipsis" BOOLEAN,
3092 "delegation_loop" "delegation_info_loop_type",
3093 "participating_member_id" INT4 );
3095 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';
3097 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
3098 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
3099 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
3100 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
3101 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
3102 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
3103 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)';
3104 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
3105 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';
3106 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
3109 CREATE FUNCTION "delegation_info"
3110 ( "member_id_p" "member"."id"%TYPE,
3111 "unit_id_p" "unit"."id"%TYPE,
3112 "area_id_p" "area"."id"%TYPE,
3113 "issue_id_p" "issue"."id"%TYPE,
3114 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
3115 "simulate_default_p" BOOLEAN DEFAULT FALSE )
3116 RETURNS "delegation_info_type"
3117 LANGUAGE 'plpgsql' STABLE AS $$
3118 DECLARE
3119 "current_row" "delegation_chain_row";
3120 "result" "delegation_info_type";
3121 BEGIN
3122 "result"."own_participation" := FALSE;
3123 FOR "current_row" IN
3124 SELECT * FROM "delegation_chain"(
3125 "member_id_p",
3126 "unit_id_p", "area_id_p", "issue_id_p",
3127 "simulate_trustee_id_p", "simulate_default_p")
3128 LOOP
3129 IF
3130 "result"."participating_member_id" ISNULL AND
3131 "current_row"."participation"
3132 THEN
3133 "result"."participating_member_id" := "current_row"."member_id";
3134 END IF;
3135 IF "current_row"."member_id" = "member_id_p" THEN
3136 "result"."own_participation" := "current_row"."participation";
3137 "result"."own_delegation_scope" := "current_row"."scope_out";
3138 IF "current_row"."loop" = 'first' THEN
3139 "result"."delegation_loop" := 'own';
3140 END IF;
3141 ELSIF
3142 "current_row"."member_valid" AND
3143 ( "current_row"."loop" ISNULL OR
3144 "current_row"."loop" != 'repetition' )
3145 THEN
3146 IF "result"."first_trustee_id" ISNULL THEN
3147 "result"."first_trustee_id" := "current_row"."member_id";
3148 "result"."first_trustee_participation" := "current_row"."participation";
3149 "result"."first_trustee_ellipsis" := FALSE;
3150 IF "current_row"."loop" = 'first' THEN
3151 "result"."delegation_loop" := 'first';
3152 END IF;
3153 ELSIF "result"."other_trustee_id" ISNULL THEN
3154 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
3155 "result"."other_trustee_id" := "current_row"."member_id";
3156 "result"."other_trustee_participation" := TRUE;
3157 "result"."other_trustee_ellipsis" := FALSE;
3158 IF "current_row"."loop" = 'first' THEN
3159 "result"."delegation_loop" := 'other';
3160 END IF;
3161 ELSE
3162 "result"."first_trustee_ellipsis" := TRUE;
3163 IF "current_row"."loop" = 'first' THEN
3164 "result"."delegation_loop" := 'first_ellipsis';
3165 END IF;
3166 END IF;
3167 ELSE
3168 "result"."other_trustee_ellipsis" := TRUE;
3169 IF "current_row"."loop" = 'first' THEN
3170 "result"."delegation_loop" := 'other_ellipsis';
3171 END IF;
3172 END IF;
3173 END IF;
3174 END LOOP;
3175 RETURN "result";
3176 END;
3177 $$;
3179 COMMENT ON FUNCTION "delegation_info"
3180 ( "member"."id"%TYPE,
3181 "unit"."id"%TYPE,
3182 "area"."id"%TYPE,
3183 "issue"."id"%TYPE,
3184 "member"."id"%TYPE,
3185 BOOLEAN )
3186 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
3190 ---------------------------
3191 -- Transaction isolation --
3192 ---------------------------
3195 CREATE FUNCTION "require_transaction_isolation"()
3196 RETURNS VOID
3197 LANGUAGE 'plpgsql' VOLATILE AS $$
3198 BEGIN
3199 IF
3200 current_setting('transaction_isolation') NOT IN
3201 ('repeatable read', 'serializable')
3202 THEN
3203 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
3204 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
3205 END IF;
3206 RETURN;
3207 END;
3208 $$;
3210 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
3213 CREATE FUNCTION "dont_require_transaction_isolation"()
3214 RETURNS VOID
3215 LANGUAGE 'plpgsql' VOLATILE AS $$
3216 BEGIN
3217 IF
3218 current_setting('transaction_isolation') IN
3219 ('repeatable read', 'serializable')
3220 THEN
3221 RAISE WARNING 'Unneccessary transaction isolation level: %',
3222 current_setting('transaction_isolation');
3223 END IF;
3224 RETURN;
3225 END;
3226 $$;
3228 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
3232 -------------------------
3233 -- Notification system --
3234 -------------------------
3236 CREATE FUNCTION "get_initiatives_for_notification"
3237 ( "recipient_id_p" "member"."id"%TYPE )
3238 RETURNS SETOF "initiative_for_notification"
3239 LANGUAGE 'plpgsql' VOLATILE AS $$
3240 DECLARE
3241 "result_row" "initiative_for_notification"%ROWTYPE;
3242 "last_draft_id_v" "draft"."id"%TYPE;
3243 "last_suggestion_id_v" "suggestion"."id"%TYPE;
3244 BEGIN
3245 PERFORM "require_transaction_isolation"();
3246 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
3247 FOR "result_row" IN
3248 SELECT * FROM "initiative_for_notification"
3249 WHERE "recipient_id" = "recipient_id_p"
3250 LOOP
3251 SELECT "id" INTO "last_draft_id_v" FROM "draft"
3252 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
3253 ORDER BY "id" DESC LIMIT 1;
3254 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
3255 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
3256 ORDER BY "id" DESC LIMIT 1;
3257 INSERT INTO "notification_initiative_sent"
3258 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
3259 VALUES (
3260 "recipient_id_p",
3261 "result_row"."initiative_id",
3262 "last_draft_id_v",
3263 "last_suggestion_id_v" )
3264 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
3265 "last_draft_id" = CASE
3266 WHEN "notification_initiative_sent"."last_draft_id" > "last_draft_id_v"
3267 THEN "notification_initiative_sent"."last_draft_id"
3268 ELSE "last_draft_id_v"
3269 END,
3270 "last_suggestion_id" = CASE
3271 WHEN "notification_initiative_sent"."last_suggestion_id" > "last_suggestion_id_v"
3272 THEN "notification_initiative_sent"."last_suggestion_id"
3273 ELSE "last_suggestion_id_v"
3274 END;
3275 RETURN NEXT "result_row";
3276 END LOOP;
3277 DELETE FROM "notification_initiative_sent"
3278 USING "initiative", "issue"
3279 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
3280 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
3281 AND "issue"."id" = "initiative"."issue_id"
3282 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
3283 UPDATE "member" SET
3284 "notification_counter" = "notification_counter" + 1,
3285 "notification_sent" = now()
3286 WHERE "id" = "recipient_id_p";
3287 RETURN;
3288 END;
3289 $$;
3291 COMMENT ON FUNCTION "get_initiatives_for_notification"
3292 ( "member"."id"%TYPE )
3293 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';
3297 ------------------------------------------------------------------------
3298 -- Regular tasks, except calculcation of snapshots and voting results --
3299 ------------------------------------------------------------------------
3302 CREATE FUNCTION "check_activity"()
3303 RETURNS VOID
3304 LANGUAGE 'plpgsql' VOLATILE AS $$
3305 DECLARE
3306 "system_setting_row" "system_setting"%ROWTYPE;
3307 BEGIN
3308 PERFORM "dont_require_transaction_isolation"();
3309 SELECT * INTO "system_setting_row" FROM "system_setting";
3310 IF "system_setting_row"."member_ttl" NOTNULL THEN
3311 UPDATE "member" SET "active" = FALSE
3312 WHERE "active" = TRUE
3313 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
3314 END IF;
3315 RETURN;
3316 END;
3317 $$;
3319 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
3322 CREATE FUNCTION "calculate_member_counts"()
3323 RETURNS VOID
3324 LANGUAGE 'plpgsql' VOLATILE AS $$
3325 BEGIN
3326 PERFORM "require_transaction_isolation"();
3327 DELETE FROM "member_count";
3328 INSERT INTO "member_count" ("total_count")
3329 SELECT "total_count" FROM "member_count_view";
3330 UPDATE "unit" SET "member_count" = "view"."member_count"
3331 FROM "unit_member_count" AS "view"
3332 WHERE "view"."unit_id" = "unit"."id";
3333 UPDATE "area" SET
3334 "direct_member_count" = "view"."direct_member_count",
3335 "member_weight" = "view"."member_weight"
3336 FROM "area_member_count" AS "view"
3337 WHERE "view"."area_id" = "area"."id";
3338 RETURN;
3339 END;
3340 $$;
3342 COMMENT ON FUNCTION "calculate_member_counts"() IS 'Updates "member_count" table and "member_count" column of table "area" by materializing data from views "member_count_view" and "area_member_count"';
3346 ------------------------------------
3347 -- Calculation of harmonic weight --
3348 ------------------------------------
3351 CREATE VIEW "remaining_harmonic_supporter_weight" AS
3352 SELECT
3353 "direct_interest_snapshot"."issue_id",
3354 "direct_interest_snapshot"."event",
3355 "direct_interest_snapshot"."member_id",
3356 "direct_interest_snapshot"."weight" AS "weight_num",
3357 count("initiative"."id") AS "weight_den"
3358 FROM "issue"
3359 JOIN "direct_interest_snapshot"
3360 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
3361 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
3362 JOIN "initiative"
3363 ON "issue"."id" = "initiative"."issue_id"
3364 AND "initiative"."harmonic_weight" ISNULL
3365 JOIN "direct_supporter_snapshot"
3366 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
3367 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
3368 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
3369 AND (
3370 "direct_supporter_snapshot"."satisfied" = TRUE OR
3371 coalesce("initiative"."admitted", FALSE) = FALSE
3373 GROUP BY
3374 "direct_interest_snapshot"."issue_id",
3375 "direct_interest_snapshot"."event",
3376 "direct_interest_snapshot"."member_id",
3377 "direct_interest_snapshot"."weight";
3379 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
3382 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
3383 SELECT
3384 "initiative"."issue_id",
3385 "initiative"."id" AS "initiative_id",
3386 "initiative"."admitted",
3387 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
3388 "remaining_harmonic_supporter_weight"."weight_den"
3389 FROM "remaining_harmonic_supporter_weight"
3390 JOIN "initiative"
3391 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
3392 AND "initiative"."harmonic_weight" ISNULL
3393 JOIN "direct_supporter_snapshot"
3394 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
3395 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
3396 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
3397 AND (
3398 "direct_supporter_snapshot"."satisfied" = TRUE OR
3399 coalesce("initiative"."admitted", FALSE) = FALSE
3401 GROUP BY
3402 "initiative"."issue_id",
3403 "initiative"."id",
3404 "initiative"."admitted",
3405 "remaining_harmonic_supporter_weight"."weight_den";
3407 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
3410 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
3411 SELECT
3412 "issue_id",
3413 "id" AS "initiative_id",
3414 "admitted",
3415 0 AS "weight_num",
3416 1 AS "weight_den"
3417 FROM "initiative"
3418 WHERE "harmonic_weight" ISNULL;
3420 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';
3423 CREATE FUNCTION "set_harmonic_initiative_weights"
3424 ( "issue_id_p" "issue"."id"%TYPE )
3425 RETURNS VOID
3426 LANGUAGE 'plpgsql' VOLATILE AS $$
3427 DECLARE
3428 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
3429 "i" INT4;
3430 "count_v" INT4;
3431 "summand_v" FLOAT;
3432 "id_ary" INT4[];
3433 "weight_ary" FLOAT[];
3434 "min_weight_v" FLOAT;
3435 BEGIN
3436 PERFORM "require_transaction_isolation"();
3437 UPDATE "initiative" SET "harmonic_weight" = NULL
3438 WHERE "issue_id" = "issue_id_p";
3439 LOOP
3440 "min_weight_v" := NULL;
3441 "i" := 0;
3442 "count_v" := 0;
3443 FOR "weight_row" IN
3444 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
3445 WHERE "issue_id" = "issue_id_p"
3446 AND (
3447 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3448 SELECT NULL FROM "initiative"
3449 WHERE "issue_id" = "issue_id_p"
3450 AND "harmonic_weight" ISNULL
3451 AND coalesce("admitted", FALSE) = FALSE
3454 UNION ALL -- needed for corner cases
3455 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
3456 WHERE "issue_id" = "issue_id_p"
3457 AND (
3458 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3459 SELECT NULL FROM "initiative"
3460 WHERE "issue_id" = "issue_id_p"
3461 AND "harmonic_weight" ISNULL
3462 AND coalesce("admitted", FALSE) = FALSE
3465 ORDER BY "initiative_id" DESC, "weight_den" DESC
3466 -- NOTE: non-admitted initiatives placed first (at last positions),
3467 -- latest initiatives treated worse in case of tie
3468 LOOP
3469 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
3470 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
3471 "i" := "i" + 1;
3472 "count_v" := "i";
3473 "id_ary"["i"] := "weight_row"."initiative_id";
3474 "weight_ary"["i"] := "summand_v";
3475 ELSE
3476 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
3477 END IF;
3478 END LOOP;
3479 EXIT WHEN "count_v" = 0;
3480 "i" := 1;
3481 LOOP
3482 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
3483 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
3484 "min_weight_v" := "weight_ary"["i"];
3485 END IF;
3486 "i" := "i" + 1;
3487 EXIT WHEN "i" > "count_v";
3488 END LOOP;
3489 "i" := 1;
3490 LOOP
3491 IF "weight_ary"["i"] = "min_weight_v" THEN
3492 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
3493 WHERE "id" = "id_ary"["i"];
3494 EXIT;
3495 END IF;
3496 "i" := "i" + 1;
3497 END LOOP;
3498 END LOOP;
3499 UPDATE "initiative" SET "harmonic_weight" = 0
3500 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
3501 END;
3502 $$;
3504 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
3505 ( "issue"."id"%TYPE )
3506 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
3510 ------------------------------
3511 -- Calculation of snapshots --
3512 ------------------------------
3515 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3516 ( "issue_id_p" "issue"."id"%TYPE,
3517 "member_id_p" "member"."id"%TYPE,
3518 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3519 RETURNS "direct_population_snapshot"."weight"%TYPE
3520 LANGUAGE 'plpgsql' VOLATILE AS $$
3521 DECLARE
3522 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3523 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3524 "weight_v" INT4;
3525 "sub_weight_v" INT4;
3526 BEGIN
3527 PERFORM "require_transaction_isolation"();
3528 "weight_v" := 0;
3529 FOR "issue_delegation_row" IN
3530 SELECT * FROM "issue_delegation"
3531 WHERE "trustee_id" = "member_id_p"
3532 AND "issue_id" = "issue_id_p"
3533 LOOP
3534 IF NOT EXISTS (
3535 SELECT NULL FROM "direct_population_snapshot"
3536 WHERE "issue_id" = "issue_id_p"
3537 AND "event" = 'periodic'
3538 AND "member_id" = "issue_delegation_row"."truster_id"
3539 ) AND NOT EXISTS (
3540 SELECT NULL FROM "delegating_population_snapshot"
3541 WHERE "issue_id" = "issue_id_p"
3542 AND "event" = 'periodic'
3543 AND "member_id" = "issue_delegation_row"."truster_id"
3544 ) THEN
3545 "delegate_member_ids_v" :=
3546 "member_id_p" || "delegate_member_ids_p";
3547 INSERT INTO "delegating_population_snapshot" (
3548 "issue_id",
3549 "event",
3550 "member_id",
3551 "scope",
3552 "delegate_member_ids"
3553 ) VALUES (
3554 "issue_id_p",
3555 'periodic',
3556 "issue_delegation_row"."truster_id",
3557 "issue_delegation_row"."scope",
3558 "delegate_member_ids_v"
3559 );
3560 "sub_weight_v" := 1 +
3561 "weight_of_added_delegations_for_population_snapshot"(
3562 "issue_id_p",
3563 "issue_delegation_row"."truster_id",
3564 "delegate_member_ids_v"
3565 );
3566 UPDATE "delegating_population_snapshot"
3567 SET "weight" = "sub_weight_v"
3568 WHERE "issue_id" = "issue_id_p"
3569 AND "event" = 'periodic'
3570 AND "member_id" = "issue_delegation_row"."truster_id";
3571 "weight_v" := "weight_v" + "sub_weight_v";
3572 END IF;
3573 END LOOP;
3574 RETURN "weight_v";
3575 END;
3576 $$;
3578 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3579 ( "issue"."id"%TYPE,
3580 "member"."id"%TYPE,
3581 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3582 IS 'Helper function for "create_population_snapshot" function';
3585 CREATE FUNCTION "create_population_snapshot"
3586 ( "issue_id_p" "issue"."id"%TYPE )
3587 RETURNS VOID
3588 LANGUAGE 'plpgsql' VOLATILE AS $$
3589 DECLARE
3590 "member_id_v" "member"."id"%TYPE;
3591 BEGIN
3592 PERFORM "require_transaction_isolation"();
3593 DELETE FROM "direct_population_snapshot"
3594 WHERE "issue_id" = "issue_id_p"
3595 AND "event" = 'periodic';
3596 DELETE FROM "delegating_population_snapshot"
3597 WHERE "issue_id" = "issue_id_p"
3598 AND "event" = 'periodic';
3599 INSERT INTO "direct_population_snapshot"
3600 ("issue_id", "event", "member_id")
3601 SELECT
3602 "issue_id_p" AS "issue_id",
3603 'periodic'::"snapshot_event" AS "event",
3604 "member"."id" AS "member_id"
3605 FROM "issue"
3606 JOIN "area" ON "issue"."area_id" = "area"."id"
3607 JOIN "membership" ON "area"."id" = "membership"."area_id"
3608 JOIN "member" ON "membership"."member_id" = "member"."id"
3609 JOIN "privilege"
3610 ON "privilege"."unit_id" = "area"."unit_id"
3611 AND "privilege"."member_id" = "member"."id"
3612 WHERE "issue"."id" = "issue_id_p"
3613 AND "member"."active" AND "privilege"."voting_right"
3614 UNION
3615 SELECT
3616 "issue_id_p" AS "issue_id",
3617 'periodic'::"snapshot_event" AS "event",
3618 "member"."id" AS "member_id"
3619 FROM "issue"
3620 JOIN "area" ON "issue"."area_id" = "area"."id"
3621 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3622 JOIN "member" ON "interest"."member_id" = "member"."id"
3623 JOIN "privilege"
3624 ON "privilege"."unit_id" = "area"."unit_id"
3625 AND "privilege"."member_id" = "member"."id"
3626 WHERE "issue"."id" = "issue_id_p"
3627 AND "member"."active" AND "privilege"."voting_right";
3628 FOR "member_id_v" IN
3629 SELECT "member_id" FROM "direct_population_snapshot"
3630 WHERE "issue_id" = "issue_id_p"
3631 AND "event" = 'periodic'
3632 LOOP
3633 UPDATE "direct_population_snapshot" SET
3634 "weight" = 1 +
3635 "weight_of_added_delegations_for_population_snapshot"(
3636 "issue_id_p",
3637 "member_id_v",
3638 '{}'
3640 WHERE "issue_id" = "issue_id_p"
3641 AND "event" = 'periodic'
3642 AND "member_id" = "member_id_v";
3643 END LOOP;
3644 RETURN;
3645 END;
3646 $$;
3648 COMMENT ON FUNCTION "create_population_snapshot"
3649 ( "issue"."id"%TYPE )
3650 IS 'This function creates a new ''periodic'' population snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
3653 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3654 ( "issue_id_p" "issue"."id"%TYPE,
3655 "member_id_p" "member"."id"%TYPE,
3656 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3657 RETURNS "direct_interest_snapshot"."weight"%TYPE
3658 LANGUAGE 'plpgsql' VOLATILE AS $$
3659 DECLARE
3660 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3661 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3662 "weight_v" INT4;
3663 "sub_weight_v" INT4;
3664 BEGIN
3665 PERFORM "require_transaction_isolation"();
3666 "weight_v" := 0;
3667 FOR "issue_delegation_row" IN
3668 SELECT * FROM "issue_delegation"
3669 WHERE "trustee_id" = "member_id_p"
3670 AND "issue_id" = "issue_id_p"
3671 LOOP
3672 IF NOT EXISTS (
3673 SELECT NULL FROM "direct_interest_snapshot"
3674 WHERE "issue_id" = "issue_id_p"
3675 AND "event" = 'periodic'
3676 AND "member_id" = "issue_delegation_row"."truster_id"
3677 ) AND NOT EXISTS (
3678 SELECT NULL FROM "delegating_interest_snapshot"
3679 WHERE "issue_id" = "issue_id_p"
3680 AND "event" = 'periodic'
3681 AND "member_id" = "issue_delegation_row"."truster_id"
3682 ) THEN
3683 "delegate_member_ids_v" :=
3684 "member_id_p" || "delegate_member_ids_p";
3685 INSERT INTO "delegating_interest_snapshot" (
3686 "issue_id",
3687 "event",
3688 "member_id",
3689 "scope",
3690 "delegate_member_ids"
3691 ) VALUES (
3692 "issue_id_p",
3693 'periodic',
3694 "issue_delegation_row"."truster_id",
3695 "issue_delegation_row"."scope",
3696 "delegate_member_ids_v"
3697 );
3698 "sub_weight_v" := 1 +
3699 "weight_of_added_delegations_for_interest_snapshot"(
3700 "issue_id_p",
3701 "issue_delegation_row"."truster_id",
3702 "delegate_member_ids_v"
3703 );
3704 UPDATE "delegating_interest_snapshot"
3705 SET "weight" = "sub_weight_v"
3706 WHERE "issue_id" = "issue_id_p"
3707 AND "event" = 'periodic'
3708 AND "member_id" = "issue_delegation_row"."truster_id";
3709 "weight_v" := "weight_v" + "sub_weight_v";
3710 END IF;
3711 END LOOP;
3712 RETURN "weight_v";
3713 END;
3714 $$;
3716 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3717 ( "issue"."id"%TYPE,
3718 "member"."id"%TYPE,
3719 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3720 IS 'Helper function for "create_interest_snapshot" function';
3723 CREATE FUNCTION "create_interest_snapshot"
3724 ( "issue_id_p" "issue"."id"%TYPE )
3725 RETURNS VOID
3726 LANGUAGE 'plpgsql' VOLATILE AS $$
3727 DECLARE
3728 "member_id_v" "member"."id"%TYPE;
3729 BEGIN
3730 PERFORM "require_transaction_isolation"();
3731 DELETE FROM "direct_interest_snapshot"
3732 WHERE "issue_id" = "issue_id_p"
3733 AND "event" = 'periodic';
3734 DELETE FROM "delegating_interest_snapshot"
3735 WHERE "issue_id" = "issue_id_p"
3736 AND "event" = 'periodic';
3737 DELETE FROM "direct_supporter_snapshot"
3738 USING "initiative" -- NOTE: due to missing index on issue_id
3739 WHERE "initiative"."issue_id" = "issue_id_p"
3740 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3741 AND "direct_supporter_snapshot"."event" = 'periodic';
3742 INSERT INTO "direct_interest_snapshot"
3743 ("issue_id", "event", "member_id")
3744 SELECT
3745 "issue_id_p" AS "issue_id",
3746 'periodic' AS "event",
3747 "member"."id" AS "member_id"
3748 FROM "issue"
3749 JOIN "area" ON "issue"."area_id" = "area"."id"
3750 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3751 JOIN "member" ON "interest"."member_id" = "member"."id"
3752 JOIN "privilege"
3753 ON "privilege"."unit_id" = "area"."unit_id"
3754 AND "privilege"."member_id" = "member"."id"
3755 WHERE "issue"."id" = "issue_id_p"
3756 AND "member"."active" AND "privilege"."voting_right";
3757 FOR "member_id_v" IN
3758 SELECT "member_id" FROM "direct_interest_snapshot"
3759 WHERE "issue_id" = "issue_id_p"
3760 AND "event" = 'periodic'
3761 LOOP
3762 UPDATE "direct_interest_snapshot" SET
3763 "weight" = 1 +
3764 "weight_of_added_delegations_for_interest_snapshot"(
3765 "issue_id_p",
3766 "member_id_v",
3767 '{}'
3769 WHERE "issue_id" = "issue_id_p"
3770 AND "event" = 'periodic'
3771 AND "member_id" = "member_id_v";
3772 END LOOP;
3773 INSERT INTO "direct_supporter_snapshot"
3774 ( "issue_id", "initiative_id", "event", "member_id",
3775 "draft_id", "informed", "satisfied" )
3776 SELECT
3777 "issue_id_p" AS "issue_id",
3778 "initiative"."id" AS "initiative_id",
3779 'periodic' AS "event",
3780 "supporter"."member_id" AS "member_id",
3781 "supporter"."draft_id" AS "draft_id",
3782 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3783 NOT EXISTS (
3784 SELECT NULL FROM "critical_opinion"
3785 WHERE "initiative_id" = "initiative"."id"
3786 AND "member_id" = "supporter"."member_id"
3787 ) AS "satisfied"
3788 FROM "initiative"
3789 JOIN "supporter"
3790 ON "supporter"."initiative_id" = "initiative"."id"
3791 JOIN "current_draft"
3792 ON "initiative"."id" = "current_draft"."initiative_id"
3793 JOIN "direct_interest_snapshot"
3794 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3795 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3796 AND "event" = 'periodic'
3797 WHERE "initiative"."issue_id" = "issue_id_p";
3798 RETURN;
3799 END;
3800 $$;
3802 COMMENT ON FUNCTION "create_interest_snapshot"
3803 ( "issue"."id"%TYPE )
3804 IS 'This function creates a new ''periodic'' interest/supporter snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
3807 CREATE FUNCTION "create_snapshot"
3808 ( "issue_id_p" "issue"."id"%TYPE )
3809 RETURNS VOID
3810 LANGUAGE 'plpgsql' VOLATILE AS $$
3811 DECLARE
3812 "initiative_id_v" "initiative"."id"%TYPE;
3813 "suggestion_id_v" "suggestion"."id"%TYPE;
3814 BEGIN
3815 PERFORM "require_transaction_isolation"();
3816 PERFORM "create_population_snapshot"("issue_id_p");
3817 PERFORM "create_interest_snapshot"("issue_id_p");
3818 UPDATE "issue" SET
3819 "snapshot" = coalesce("phase_finished", now()),
3820 "latest_snapshot_event" = 'periodic',
3821 "population" = (
3822 SELECT coalesce(sum("weight"), 0)
3823 FROM "direct_population_snapshot"
3824 WHERE "issue_id" = "issue_id_p"
3825 AND "event" = 'periodic'
3827 WHERE "id" = "issue_id_p";
3828 FOR "initiative_id_v" IN
3829 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3830 LOOP
3831 UPDATE "initiative" SET
3832 "supporter_count" = (
3833 SELECT coalesce(sum("di"."weight"), 0)
3834 FROM "direct_interest_snapshot" AS "di"
3835 JOIN "direct_supporter_snapshot" AS "ds"
3836 ON "di"."member_id" = "ds"."member_id"
3837 WHERE "di"."issue_id" = "issue_id_p"
3838 AND "di"."event" = 'periodic'
3839 AND "ds"."initiative_id" = "initiative_id_v"
3840 AND "ds"."event" = 'periodic'
3841 ),
3842 "informed_supporter_count" = (
3843 SELECT coalesce(sum("di"."weight"), 0)
3844 FROM "direct_interest_snapshot" AS "di"
3845 JOIN "direct_supporter_snapshot" AS "ds"
3846 ON "di"."member_id" = "ds"."member_id"
3847 WHERE "di"."issue_id" = "issue_id_p"
3848 AND "di"."event" = 'periodic'
3849 AND "ds"."initiative_id" = "initiative_id_v"
3850 AND "ds"."event" = 'periodic'
3851 AND "ds"."informed"
3852 ),
3853 "satisfied_supporter_count" = (
3854 SELECT coalesce(sum("di"."weight"), 0)
3855 FROM "direct_interest_snapshot" AS "di"
3856 JOIN "direct_supporter_snapshot" AS "ds"
3857 ON "di"."member_id" = "ds"."member_id"
3858 WHERE "di"."issue_id" = "issue_id_p"
3859 AND "di"."event" = 'periodic'
3860 AND "ds"."initiative_id" = "initiative_id_v"
3861 AND "ds"."event" = 'periodic'
3862 AND "ds"."satisfied"
3863 ),
3864 "satisfied_informed_supporter_count" = (
3865 SELECT coalesce(sum("di"."weight"), 0)
3866 FROM "direct_interest_snapshot" AS "di"
3867 JOIN "direct_supporter_snapshot" AS "ds"
3868 ON "di"."member_id" = "ds"."member_id"
3869 WHERE "di"."issue_id" = "issue_id_p"
3870 AND "di"."event" = 'periodic'
3871 AND "ds"."initiative_id" = "initiative_id_v"
3872 AND "ds"."event" = 'periodic'
3873 AND "ds"."informed"
3874 AND "ds"."satisfied"
3876 WHERE "id" = "initiative_id_v";
3877 FOR "suggestion_id_v" IN
3878 SELECT "id" FROM "suggestion"
3879 WHERE "initiative_id" = "initiative_id_v"
3880 LOOP
3881 UPDATE "suggestion" SET
3882 "minus2_unfulfilled_count" = (
3883 SELECT coalesce(sum("snapshot"."weight"), 0)
3884 FROM "issue" CROSS JOIN "opinion"
3885 JOIN "direct_interest_snapshot" AS "snapshot"
3886 ON "snapshot"."issue_id" = "issue"."id"
3887 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3888 AND "snapshot"."member_id" = "opinion"."member_id"
3889 WHERE "issue"."id" = "issue_id_p"
3890 AND "opinion"."suggestion_id" = "suggestion_id_v"
3891 AND "opinion"."degree" = -2
3892 AND "opinion"."fulfilled" = FALSE
3893 ),
3894 "minus2_fulfilled_count" = (
3895 SELECT coalesce(sum("snapshot"."weight"), 0)
3896 FROM "issue" CROSS JOIN "opinion"
3897 JOIN "direct_interest_snapshot" AS "snapshot"
3898 ON "snapshot"."issue_id" = "issue"."id"
3899 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3900 AND "snapshot"."member_id" = "opinion"."member_id"
3901 WHERE "issue"."id" = "issue_id_p"
3902 AND "opinion"."suggestion_id" = "suggestion_id_v"
3903 AND "opinion"."degree" = -2
3904 AND "opinion"."fulfilled" = TRUE
3905 ),
3906 "minus1_unfulfilled_count" = (
3907 SELECT coalesce(sum("snapshot"."weight"), 0)
3908 FROM "issue" CROSS JOIN "opinion"
3909 JOIN "direct_interest_snapshot" AS "snapshot"
3910 ON "snapshot"."issue_id" = "issue"."id"
3911 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3912 AND "snapshot"."member_id" = "opinion"."member_id"
3913 WHERE "issue"."id" = "issue_id_p"
3914 AND "opinion"."suggestion_id" = "suggestion_id_v"
3915 AND "opinion"."degree" = -1
3916 AND "opinion"."fulfilled" = FALSE
3917 ),
3918 "minus1_fulfilled_count" = (
3919 SELECT coalesce(sum("snapshot"."weight"), 0)
3920 FROM "issue" CROSS JOIN "opinion"
3921 JOIN "direct_interest_snapshot" AS "snapshot"
3922 ON "snapshot"."issue_id" = "issue"."id"
3923 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3924 AND "snapshot"."member_id" = "opinion"."member_id"
3925 WHERE "issue"."id" = "issue_id_p"
3926 AND "opinion"."suggestion_id" = "suggestion_id_v"
3927 AND "opinion"."degree" = -1
3928 AND "opinion"."fulfilled" = TRUE
3929 ),
3930 "plus1_unfulfilled_count" = (
3931 SELECT coalesce(sum("snapshot"."weight"), 0)
3932 FROM "issue" CROSS JOIN "opinion"
3933 JOIN "direct_interest_snapshot" AS "snapshot"
3934 ON "snapshot"."issue_id" = "issue"."id"
3935 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3936 AND "snapshot"."member_id" = "opinion"."member_id"
3937 WHERE "issue"."id" = "issue_id_p"
3938 AND "opinion"."suggestion_id" = "suggestion_id_v"
3939 AND "opinion"."degree" = 1
3940 AND "opinion"."fulfilled" = FALSE
3941 ),
3942 "plus1_fulfilled_count" = (
3943 SELECT coalesce(sum("snapshot"."weight"), 0)
3944 FROM "issue" CROSS JOIN "opinion"
3945 JOIN "direct_interest_snapshot" AS "snapshot"
3946 ON "snapshot"."issue_id" = "issue"."id"
3947 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3948 AND "snapshot"."member_id" = "opinion"."member_id"
3949 WHERE "issue"."id" = "issue_id_p"
3950 AND "opinion"."suggestion_id" = "suggestion_id_v"
3951 AND "opinion"."degree" = 1
3952 AND "opinion"."fulfilled" = TRUE
3953 ),
3954 "plus2_unfulfilled_count" = (
3955 SELECT coalesce(sum("snapshot"."weight"), 0)
3956 FROM "issue" CROSS JOIN "opinion"
3957 JOIN "direct_interest_snapshot" AS "snapshot"
3958 ON "snapshot"."issue_id" = "issue"."id"
3959 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3960 AND "snapshot"."member_id" = "opinion"."member_id"
3961 WHERE "issue"."id" = "issue_id_p"
3962 AND "opinion"."suggestion_id" = "suggestion_id_v"
3963 AND "opinion"."degree" = 2
3964 AND "opinion"."fulfilled" = FALSE
3965 ),
3966 "plus2_fulfilled_count" = (
3967 SELECT coalesce(sum("snapshot"."weight"), 0)
3968 FROM "issue" CROSS JOIN "opinion"
3969 JOIN "direct_interest_snapshot" AS "snapshot"
3970 ON "snapshot"."issue_id" = "issue"."id"
3971 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3972 AND "snapshot"."member_id" = "opinion"."member_id"
3973 WHERE "issue"."id" = "issue_id_p"
3974 AND "opinion"."suggestion_id" = "suggestion_id_v"
3975 AND "opinion"."degree" = 2
3976 AND "opinion"."fulfilled" = TRUE
3978 WHERE "suggestion"."id" = "suggestion_id_v";
3979 END LOOP;
3980 END LOOP;
3981 RETURN;
3982 END;
3983 $$;
3985 COMMENT ON FUNCTION "create_snapshot"
3986 ( "issue"."id"%TYPE )
3987 IS 'This function creates a complete new ''periodic'' snapshot of population, interest and support for the given issue. All involved tables are locked, and after completion precalculated values in the source tables are updated.';
3990 CREATE FUNCTION "set_snapshot_event"
3991 ( "issue_id_p" "issue"."id"%TYPE,
3992 "event_p" "snapshot_event" )
3993 RETURNS VOID
3994 LANGUAGE 'plpgsql' VOLATILE AS $$
3995 DECLARE
3996 "event_v" "issue"."latest_snapshot_event"%TYPE;
3997 BEGIN
3998 PERFORM "require_transaction_isolation"();
3999 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
4000 WHERE "id" = "issue_id_p" FOR UPDATE;
4001 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
4002 WHERE "id" = "issue_id_p";
4003 UPDATE "direct_population_snapshot" SET "event" = "event_p"
4004 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
4005 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
4006 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
4007 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
4008 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
4009 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
4010 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
4011 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
4012 FROM "initiative" -- NOTE: due to missing index on issue_id
4013 WHERE "initiative"."issue_id" = "issue_id_p"
4014 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
4015 AND "direct_supporter_snapshot"."event" = "event_v";
4016 RETURN;
4017 END;
4018 $$;
4020 COMMENT ON FUNCTION "set_snapshot_event"
4021 ( "issue"."id"%TYPE,
4022 "snapshot_event" )
4023 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
4027 -----------------------
4028 -- Counting of votes --
4029 -----------------------
4032 CREATE FUNCTION "weight_of_added_vote_delegations"
4033 ( "issue_id_p" "issue"."id"%TYPE,
4034 "member_id_p" "member"."id"%TYPE,
4035 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
4036 RETURNS "direct_voter"."weight"%TYPE
4037 LANGUAGE 'plpgsql' VOLATILE AS $$
4038 DECLARE
4039 "issue_delegation_row" "issue_delegation"%ROWTYPE;
4040 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
4041 "weight_v" INT4;
4042 "sub_weight_v" INT4;
4043 BEGIN
4044 PERFORM "require_transaction_isolation"();
4045 "weight_v" := 0;
4046 FOR "issue_delegation_row" IN
4047 SELECT * FROM "issue_delegation"
4048 WHERE "trustee_id" = "member_id_p"
4049 AND "issue_id" = "issue_id_p"
4050 LOOP
4051 IF NOT EXISTS (
4052 SELECT NULL FROM "direct_voter"
4053 WHERE "member_id" = "issue_delegation_row"."truster_id"
4054 AND "issue_id" = "issue_id_p"
4055 ) AND NOT EXISTS (
4056 SELECT NULL FROM "delegating_voter"
4057 WHERE "member_id" = "issue_delegation_row"."truster_id"
4058 AND "issue_id" = "issue_id_p"
4059 ) THEN
4060 "delegate_member_ids_v" :=
4061 "member_id_p" || "delegate_member_ids_p";
4062 INSERT INTO "delegating_voter" (
4063 "issue_id",
4064 "member_id",
4065 "scope",
4066 "delegate_member_ids"
4067 ) VALUES (
4068 "issue_id_p",
4069 "issue_delegation_row"."truster_id",
4070 "issue_delegation_row"."scope",
4071 "delegate_member_ids_v"
4072 );
4073 "sub_weight_v" := 1 +
4074 "weight_of_added_vote_delegations"(
4075 "issue_id_p",
4076 "issue_delegation_row"."truster_id",
4077 "delegate_member_ids_v"
4078 );
4079 UPDATE "delegating_voter"
4080 SET "weight" = "sub_weight_v"
4081 WHERE "issue_id" = "issue_id_p"
4082 AND "member_id" = "issue_delegation_row"."truster_id";
4083 "weight_v" := "weight_v" + "sub_weight_v";
4084 END IF;
4085 END LOOP;
4086 RETURN "weight_v";
4087 END;
4088 $$;
4090 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
4091 ( "issue"."id"%TYPE,
4092 "member"."id"%TYPE,
4093 "delegating_voter"."delegate_member_ids"%TYPE )
4094 IS 'Helper function for "add_vote_delegations" function';
4097 CREATE FUNCTION "add_vote_delegations"
4098 ( "issue_id_p" "issue"."id"%TYPE )
4099 RETURNS VOID
4100 LANGUAGE 'plpgsql' VOLATILE AS $$
4101 DECLARE
4102 "member_id_v" "member"."id"%TYPE;
4103 BEGIN
4104 PERFORM "require_transaction_isolation"();
4105 FOR "member_id_v" IN
4106 SELECT "member_id" FROM "direct_voter"
4107 WHERE "issue_id" = "issue_id_p"
4108 LOOP
4109 UPDATE "direct_voter" SET
4110 "weight" = "weight" + "weight_of_added_vote_delegations"(
4111 "issue_id_p",
4112 "member_id_v",
4113 '{}'
4115 WHERE "member_id" = "member_id_v"
4116 AND "issue_id" = "issue_id_p";
4117 END LOOP;
4118 RETURN;
4119 END;
4120 $$;
4122 COMMENT ON FUNCTION "add_vote_delegations"
4123 ( "issue_id_p" "issue"."id"%TYPE )
4124 IS 'Helper function for "close_voting" function';
4127 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
4128 RETURNS VOID
4129 LANGUAGE 'plpgsql' VOLATILE AS $$
4130 DECLARE
4131 "area_id_v" "area"."id"%TYPE;
4132 "unit_id_v" "unit"."id"%TYPE;
4133 "member_id_v" "member"."id"%TYPE;
4134 BEGIN
4135 PERFORM "require_transaction_isolation"();
4136 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
4137 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
4138 -- override protection triggers:
4139 INSERT INTO "temporary_transaction_data" ("key", "value")
4140 VALUES ('override_protection_triggers', TRUE::TEXT);
4141 -- delete timestamp of voting comment:
4142 UPDATE "direct_voter" SET "comment_changed" = NULL
4143 WHERE "issue_id" = "issue_id_p";
4144 -- delete delegating votes (in cases of manual reset of issue state):
4145 DELETE FROM "delegating_voter"
4146 WHERE "issue_id" = "issue_id_p";
4147 -- delete votes from non-privileged voters:
4148 DELETE FROM "direct_voter"
4149 USING (
4150 SELECT
4151 "direct_voter"."member_id"
4152 FROM "direct_voter"
4153 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
4154 LEFT JOIN "privilege"
4155 ON "privilege"."unit_id" = "unit_id_v"
4156 AND "privilege"."member_id" = "direct_voter"."member_id"
4157 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
4158 "member"."active" = FALSE OR
4159 "privilege"."voting_right" ISNULL OR
4160 "privilege"."voting_right" = FALSE
4162 ) AS "subquery"
4163 WHERE "direct_voter"."issue_id" = "issue_id_p"
4164 AND "direct_voter"."member_id" = "subquery"."member_id";
4165 -- consider delegations:
4166 UPDATE "direct_voter" SET "weight" = 1
4167 WHERE "issue_id" = "issue_id_p";
4168 PERFORM "add_vote_delegations"("issue_id_p");
4169 -- mark first preferences:
4170 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
4171 FROM (
4172 SELECT
4173 "vote"."initiative_id",
4174 "vote"."member_id",
4175 CASE WHEN "vote"."grade" > 0 THEN
4176 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
4177 ELSE NULL
4178 END AS "first_preference"
4179 FROM "vote"
4180 JOIN "initiative" -- NOTE: due to missing index on issue_id
4181 ON "vote"."issue_id" = "initiative"."issue_id"
4182 JOIN "vote" AS "agg"
4183 ON "initiative"."id" = "agg"."initiative_id"
4184 AND "vote"."member_id" = "agg"."member_id"
4185 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
4186 ) AS "subquery"
4187 WHERE "vote"."issue_id" = "issue_id_p"
4188 AND "vote"."initiative_id" = "subquery"."initiative_id"
4189 AND "vote"."member_id" = "subquery"."member_id";
4190 -- finish overriding protection triggers (avoids garbage):
4191 DELETE FROM "temporary_transaction_data"
4192 WHERE "key" = 'override_protection_triggers';
4193 -- materialize battle_view:
4194 -- NOTE: "closed" column of issue must be set at this point
4195 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4196 INSERT INTO "battle" (
4197 "issue_id",
4198 "winning_initiative_id", "losing_initiative_id",
4199 "count"
4200 ) SELECT
4201 "issue_id",
4202 "winning_initiative_id", "losing_initiative_id",
4203 "count"
4204 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
4205 -- set voter count:
4206 UPDATE "issue" SET
4207 "voter_count" = (
4208 SELECT coalesce(sum("weight"), 0)
4209 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
4211 WHERE "id" = "issue_id_p";
4212 -- copy "positive_votes" and "negative_votes" from "battle" table:
4213 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
4214 UPDATE "initiative" SET
4215 "first_preference_votes" = 0,
4216 "positive_votes" = "battle_win"."count",
4217 "negative_votes" = "battle_lose"."count"
4218 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
4219 WHERE
4220 "battle_win"."issue_id" = "issue_id_p" AND
4221 "battle_win"."winning_initiative_id" = "initiative"."id" AND
4222 "battle_win"."losing_initiative_id" ISNULL AND
4223 "battle_lose"."issue_id" = "issue_id_p" AND
4224 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
4225 "battle_lose"."winning_initiative_id" ISNULL;
4226 -- calculate "first_preference_votes":
4227 -- NOTE: will only set values not equal to zero
4228 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
4229 FROM (
4230 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
4231 FROM "vote" JOIN "direct_voter"
4232 ON "vote"."issue_id" = "direct_voter"."issue_id"
4233 AND "vote"."member_id" = "direct_voter"."member_id"
4234 WHERE "vote"."first_preference"
4235 GROUP BY "vote"."initiative_id"
4236 ) AS "subquery"
4237 WHERE "initiative"."issue_id" = "issue_id_p"
4238 AND "initiative"."admitted"
4239 AND "initiative"."id" = "subquery"."initiative_id";
4240 END;
4241 $$;
4243 COMMENT ON FUNCTION "close_voting"
4244 ( "issue"."id"%TYPE )
4245 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.';
4248 CREATE FUNCTION "defeat_strength"
4249 ( "positive_votes_p" INT4,
4250 "negative_votes_p" INT4,
4251 "defeat_strength_p" "defeat_strength" )
4252 RETURNS INT8
4253 LANGUAGE 'plpgsql' IMMUTABLE AS $$
4254 BEGIN
4255 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
4256 IF "positive_votes_p" > "negative_votes_p" THEN
4257 RETURN "positive_votes_p";
4258 ELSE
4259 RETURN 0;
4260 END IF;
4261 ELSE
4262 IF "positive_votes_p" > "negative_votes_p" THEN
4263 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
4264 ELSIF "positive_votes_p" = "negative_votes_p" THEN
4265 RETURN 0;
4266 ELSE
4267 RETURN -1;
4268 END IF;
4269 END IF;
4270 END;
4271 $$;
4273 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")';
4276 CREATE FUNCTION "secondary_link_strength"
4277 ( "initiative1_ord_p" INT4,
4278 "initiative2_ord_p" INT4,
4279 "tie_breaking_p" "tie_breaking" )
4280 RETURNS INT8
4281 LANGUAGE 'plpgsql' IMMUTABLE AS $$
4282 BEGIN
4283 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
4284 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
4285 END IF;
4286 RETURN (
4287 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
4289 ELSE
4290 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
4291 1::INT8 << 62
4292 ELSE 0 END
4294 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
4295 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
4296 ELSE
4297 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
4298 END
4299 END
4300 );
4301 END;
4302 $$;
4304 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
4307 CREATE TYPE "link_strength" AS (
4308 "primary" INT8,
4309 "secondary" INT8 );
4311 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'')';
4314 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
4315 RETURNS "link_strength"[][]
4316 LANGUAGE 'plpgsql' IMMUTABLE AS $$
4317 DECLARE
4318 "dimension_v" INT4;
4319 "matrix_p" "link_strength"[][];
4320 "i" INT4;
4321 "j" INT4;
4322 "k" INT4;
4323 BEGIN
4324 "dimension_v" := array_upper("matrix_d", 1);
4325 "matrix_p" := "matrix_d";
4326 "i" := 1;
4327 LOOP
4328 "j" := 1;
4329 LOOP
4330 IF "i" != "j" THEN
4331 "k" := 1;
4332 LOOP
4333 IF "i" != "k" AND "j" != "k" THEN
4334 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
4335 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
4336 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
4337 END IF;
4338 ELSE
4339 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
4340 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
4341 END IF;
4342 END IF;
4343 END IF;
4344 EXIT WHEN "k" = "dimension_v";
4345 "k" := "k" + 1;
4346 END LOOP;
4347 END IF;
4348 EXIT WHEN "j" = "dimension_v";
4349 "j" := "j" + 1;
4350 END LOOP;
4351 EXIT WHEN "i" = "dimension_v";
4352 "i" := "i" + 1;
4353 END LOOP;
4354 RETURN "matrix_p";
4355 END;
4356 $$;
4358 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
4361 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
4362 RETURNS VOID
4363 LANGUAGE 'plpgsql' VOLATILE AS $$
4364 DECLARE
4365 "issue_row" "issue"%ROWTYPE;
4366 "policy_row" "policy"%ROWTYPE;
4367 "dimension_v" INT4;
4368 "matrix_a" INT4[][]; -- absolute votes
4369 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
4370 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
4371 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
4372 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
4373 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
4374 "i" INT4;
4375 "j" INT4;
4376 "m" INT4;
4377 "n" INT4;
4378 "battle_row" "battle"%ROWTYPE;
4379 "rank_ary" INT4[];
4380 "rank_v" INT4;
4381 "initiative_id_v" "initiative"."id"%TYPE;
4382 BEGIN
4383 PERFORM "require_transaction_isolation"();
4384 SELECT * INTO "issue_row"
4385 FROM "issue" WHERE "id" = "issue_id_p";
4386 SELECT * INTO "policy_row"
4387 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4388 SELECT count(1) INTO "dimension_v"
4389 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
4390 -- create "matrix_a" with absolute number of votes in pairwise
4391 -- comparison:
4392 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
4393 "i" := 1;
4394 "j" := 2;
4395 FOR "battle_row" IN
4396 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
4397 ORDER BY
4398 "winning_initiative_id" NULLS FIRST,
4399 "losing_initiative_id" NULLS FIRST
4400 LOOP
4401 "matrix_a"["i"]["j"] := "battle_row"."count";
4402 IF "j" = "dimension_v" THEN
4403 "i" := "i" + 1;
4404 "j" := 1;
4405 ELSE
4406 "j" := "j" + 1;
4407 IF "j" = "i" THEN
4408 "j" := "j" + 1;
4409 END IF;
4410 END IF;
4411 END LOOP;
4412 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
4413 RAISE EXCEPTION 'Wrong battle count (should not happen)';
4414 END IF;
4415 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
4416 -- and "secondary_link_strength" functions:
4417 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
4418 "i" := 1;
4419 LOOP
4420 "j" := 1;
4421 LOOP
4422 IF "i" != "j" THEN
4423 "matrix_d"["i"]["j"] := (
4424 "defeat_strength"(
4425 "matrix_a"["i"]["j"],
4426 "matrix_a"["j"]["i"],
4427 "policy_row"."defeat_strength"
4428 ),
4429 "secondary_link_strength"(
4430 "i",
4431 "j",
4432 "policy_row"."tie_breaking"
4434 )::"link_strength";
4435 END IF;
4436 EXIT WHEN "j" = "dimension_v";
4437 "j" := "j" + 1;
4438 END LOOP;
4439 EXIT WHEN "i" = "dimension_v";
4440 "i" := "i" + 1;
4441 END LOOP;
4442 -- find best paths:
4443 "matrix_p" := "find_best_paths"("matrix_d");
4444 -- create partial order:
4445 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
4446 "i" := 1;
4447 LOOP
4448 "j" := "i" + 1;
4449 LOOP
4450 IF "i" != "j" THEN
4451 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
4452 "matrix_b"["i"]["j"] := TRUE;
4453 "matrix_b"["j"]["i"] := FALSE;
4454 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
4455 "matrix_b"["i"]["j"] := FALSE;
4456 "matrix_b"["j"]["i"] := TRUE;
4457 END IF;
4458 END IF;
4459 EXIT WHEN "j" = "dimension_v";
4460 "j" := "j" + 1;
4461 END LOOP;
4462 EXIT WHEN "i" = "dimension_v" - 1;
4463 "i" := "i" + 1;
4464 END LOOP;
4465 -- tie-breaking by forbidding shared weakest links in beat-paths
4466 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
4467 -- is performed later by initiative id):
4468 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
4469 "m" := 1;
4470 LOOP
4471 "n" := "m" + 1;
4472 LOOP
4473 -- only process those candidates m and n, which are tied:
4474 IF "matrix_b"["m"]["n"] ISNULL THEN
4475 -- start with beat-paths prior tie-breaking:
4476 "matrix_t" := "matrix_p";
4477 -- start with all links allowed:
4478 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
4479 LOOP
4480 -- determine (and forbid) that link that is the weakest link
4481 -- in both the best path from candidate m to candidate n and
4482 -- from candidate n to candidate m:
4483 "i" := 1;
4484 <<forbid_one_link>>
4485 LOOP
4486 "j" := 1;
4487 LOOP
4488 IF "i" != "j" THEN
4489 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
4490 "matrix_f"["i"]["j"] := TRUE;
4491 -- exit for performance reasons,
4492 -- as exactly one link will be found:
4493 EXIT forbid_one_link;
4494 END IF;
4495 END IF;
4496 EXIT WHEN "j" = "dimension_v";
4497 "j" := "j" + 1;
4498 END LOOP;
4499 IF "i" = "dimension_v" THEN
4500 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
4501 END IF;
4502 "i" := "i" + 1;
4503 END LOOP;
4504 -- calculate best beat-paths while ignoring forbidden links:
4505 "i" := 1;
4506 LOOP
4507 "j" := 1;
4508 LOOP
4509 IF "i" != "j" THEN
4510 "matrix_t"["i"]["j"] := CASE
4511 WHEN "matrix_f"["i"]["j"]
4512 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
4513 ELSE "matrix_d"["i"]["j"] END;
4514 END IF;
4515 EXIT WHEN "j" = "dimension_v";
4516 "j" := "j" + 1;
4517 END LOOP;
4518 EXIT WHEN "i" = "dimension_v";
4519 "i" := "i" + 1;
4520 END LOOP;
4521 "matrix_t" := "find_best_paths"("matrix_t");
4522 -- extend partial order, if tie-breaking was successful:
4523 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
4524 "matrix_b"["m"]["n"] := TRUE;
4525 "matrix_b"["n"]["m"] := FALSE;
4526 EXIT;
4527 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
4528 "matrix_b"["m"]["n"] := FALSE;
4529 "matrix_b"["n"]["m"] := TRUE;
4530 EXIT;
4531 END IF;
4532 END LOOP;
4533 END IF;
4534 EXIT WHEN "n" = "dimension_v";
4535 "n" := "n" + 1;
4536 END LOOP;
4537 EXIT WHEN "m" = "dimension_v" - 1;
4538 "m" := "m" + 1;
4539 END LOOP;
4540 END IF;
4541 -- store a unique ranking in "rank_ary":
4542 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
4543 "rank_v" := 1;
4544 LOOP
4545 "i" := 1;
4546 <<assign_next_rank>>
4547 LOOP
4548 IF "rank_ary"["i"] ISNULL THEN
4549 "j" := 1;
4550 LOOP
4551 IF
4552 "i" != "j" AND
4553 "rank_ary"["j"] ISNULL AND
4554 ( "matrix_b"["j"]["i"] OR
4555 -- tie-breaking by "id"
4556 ( "matrix_b"["j"]["i"] ISNULL AND
4557 "j" < "i" ) )
4558 THEN
4559 -- someone else is better
4560 EXIT;
4561 END IF;
4562 IF "j" = "dimension_v" THEN
4563 -- noone is better
4564 "rank_ary"["i"] := "rank_v";
4565 EXIT assign_next_rank;
4566 END IF;
4567 "j" := "j" + 1;
4568 END LOOP;
4569 END IF;
4570 "i" := "i" + 1;
4571 IF "i" > "dimension_v" THEN
4572 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
4573 END IF;
4574 END LOOP;
4575 EXIT WHEN "rank_v" = "dimension_v";
4576 "rank_v" := "rank_v" + 1;
4577 END LOOP;
4578 -- write preliminary results:
4579 "i" := 2; -- omit status quo with "i" = 1
4580 FOR "initiative_id_v" IN
4581 SELECT "id" FROM "initiative"
4582 WHERE "issue_id" = "issue_id_p" AND "admitted"
4583 ORDER BY "id"
4584 LOOP
4585 UPDATE "initiative" SET
4586 "direct_majority" =
4587 CASE WHEN "policy_row"."direct_majority_strict" THEN
4588 "positive_votes" * "policy_row"."direct_majority_den" >
4589 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4590 ELSE
4591 "positive_votes" * "policy_row"."direct_majority_den" >=
4592 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4593 END
4594 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4595 AND "issue_row"."voter_count"-"negative_votes" >=
4596 "policy_row"."direct_majority_non_negative",
4597 "indirect_majority" =
4598 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4599 "positive_votes" * "policy_row"."indirect_majority_den" >
4600 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4601 ELSE
4602 "positive_votes" * "policy_row"."indirect_majority_den" >=
4603 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4604 END
4605 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4606 AND "issue_row"."voter_count"-"negative_votes" >=
4607 "policy_row"."indirect_majority_non_negative",
4608 "schulze_rank" = "rank_ary"["i"],
4609 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
4610 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
4611 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
4612 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
4613 THEN NULL
4614 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
4615 "eligible" = FALSE,
4616 "winner" = FALSE,
4617 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4618 WHERE "id" = "initiative_id_v";
4619 "i" := "i" + 1;
4620 END LOOP;
4621 IF "i" != "dimension_v" + 1 THEN
4622 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4623 END IF;
4624 -- take indirect majorities into account:
4625 LOOP
4626 UPDATE "initiative" SET "indirect_majority" = TRUE
4627 FROM (
4628 SELECT "new_initiative"."id" AS "initiative_id"
4629 FROM "initiative" "old_initiative"
4630 JOIN "initiative" "new_initiative"
4631 ON "new_initiative"."issue_id" = "issue_id_p"
4632 AND "new_initiative"."indirect_majority" = FALSE
4633 JOIN "battle" "battle_win"
4634 ON "battle_win"."issue_id" = "issue_id_p"
4635 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4636 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4637 JOIN "battle" "battle_lose"
4638 ON "battle_lose"."issue_id" = "issue_id_p"
4639 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4640 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4641 WHERE "old_initiative"."issue_id" = "issue_id_p"
4642 AND "old_initiative"."indirect_majority" = TRUE
4643 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4644 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4645 "policy_row"."indirect_majority_num" *
4646 ("battle_win"."count"+"battle_lose"."count")
4647 ELSE
4648 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4649 "policy_row"."indirect_majority_num" *
4650 ("battle_win"."count"+"battle_lose"."count")
4651 END
4652 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4653 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4654 "policy_row"."indirect_majority_non_negative"
4655 ) AS "subquery"
4656 WHERE "id" = "subquery"."initiative_id";
4657 EXIT WHEN NOT FOUND;
4658 END LOOP;
4659 -- set "multistage_majority" for remaining matching initiatives:
4660 UPDATE "initiative" SET "multistage_majority" = TRUE
4661 FROM (
4662 SELECT "losing_initiative"."id" AS "initiative_id"
4663 FROM "initiative" "losing_initiative"
4664 JOIN "initiative" "winning_initiative"
4665 ON "winning_initiative"."issue_id" = "issue_id_p"
4666 AND "winning_initiative"."admitted"
4667 JOIN "battle" "battle_win"
4668 ON "battle_win"."issue_id" = "issue_id_p"
4669 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4670 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4671 JOIN "battle" "battle_lose"
4672 ON "battle_lose"."issue_id" = "issue_id_p"
4673 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4674 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4675 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4676 AND "losing_initiative"."admitted"
4677 AND "winning_initiative"."schulze_rank" <
4678 "losing_initiative"."schulze_rank"
4679 AND "battle_win"."count" > "battle_lose"."count"
4680 AND (
4681 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4682 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4683 ) AS "subquery"
4684 WHERE "id" = "subquery"."initiative_id";
4685 -- mark eligible initiatives:
4686 UPDATE "initiative" SET "eligible" = TRUE
4687 WHERE "issue_id" = "issue_id_p"
4688 AND "initiative"."direct_majority"
4689 AND "initiative"."indirect_majority"
4690 AND "initiative"."better_than_status_quo"
4691 AND (
4692 "policy_row"."no_multistage_majority" = FALSE OR
4693 "initiative"."multistage_majority" = FALSE )
4694 AND (
4695 "policy_row"."no_reverse_beat_path" = FALSE OR
4696 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
4697 -- mark final winner:
4698 UPDATE "initiative" SET "winner" = TRUE
4699 FROM (
4700 SELECT "id" AS "initiative_id"
4701 FROM "initiative"
4702 WHERE "issue_id" = "issue_id_p" AND "eligible"
4703 ORDER BY
4704 "schulze_rank",
4705 "id"
4706 LIMIT 1
4707 ) AS "subquery"
4708 WHERE "id" = "subquery"."initiative_id";
4709 -- write (final) ranks:
4710 "rank_v" := 1;
4711 FOR "initiative_id_v" IN
4712 SELECT "id"
4713 FROM "initiative"
4714 WHERE "issue_id" = "issue_id_p" AND "admitted"
4715 ORDER BY
4716 "winner" DESC,
4717 "eligible" DESC,
4718 "schulze_rank",
4719 "id"
4720 LOOP
4721 UPDATE "initiative" SET "rank" = "rank_v"
4722 WHERE "id" = "initiative_id_v";
4723 "rank_v" := "rank_v" + 1;
4724 END LOOP;
4725 -- set schulze rank of status quo and mark issue as finished:
4726 UPDATE "issue" SET
4727 "status_quo_schulze_rank" = "rank_ary"[1],
4728 "state" =
4729 CASE WHEN EXISTS (
4730 SELECT NULL FROM "initiative"
4731 WHERE "issue_id" = "issue_id_p" AND "winner"
4732 ) THEN
4733 'finished_with_winner'::"issue_state"
4734 ELSE
4735 'finished_without_winner'::"issue_state"
4736 END,
4737 "closed" = "phase_finished",
4738 "phase_finished" = NULL
4739 WHERE "id" = "issue_id_p";
4740 RETURN;
4741 END;
4742 $$;
4744 COMMENT ON FUNCTION "calculate_ranks"
4745 ( "issue"."id"%TYPE )
4746 IS 'Determine ranking (Votes have to be counted first)';
4750 -----------------------------
4751 -- Automatic state changes --
4752 -----------------------------
4755 CREATE TYPE "check_issue_persistence" AS (
4756 "state" "issue_state",
4757 "phase_finished" BOOLEAN,
4758 "issue_revoked" BOOLEAN,
4759 "snapshot_created" BOOLEAN,
4760 "harmonic_weights_set" BOOLEAN,
4761 "closed_voting" BOOLEAN );
4763 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';
4766 CREATE FUNCTION "check_issue"
4767 ( "issue_id_p" "issue"."id"%TYPE,
4768 "persist" "check_issue_persistence" )
4769 RETURNS "check_issue_persistence"
4770 LANGUAGE 'plpgsql' VOLATILE AS $$
4771 DECLARE
4772 "issue_row" "issue"%ROWTYPE;
4773 "policy_row" "policy"%ROWTYPE;
4774 "initiative_row" "initiative"%ROWTYPE;
4775 "state_v" "issue_state";
4776 BEGIN
4777 PERFORM "require_transaction_isolation"();
4778 IF "persist" ISNULL THEN
4779 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4780 FOR UPDATE;
4781 IF "issue_row"."closed" NOTNULL THEN
4782 RETURN NULL;
4783 END IF;
4784 "persist"."state" := "issue_row"."state";
4785 IF
4786 ( "issue_row"."state" = 'admission' AND now() >=
4787 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
4788 ( "issue_row"."state" = 'discussion' AND now() >=
4789 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4790 ( "issue_row"."state" = 'verification' AND now() >=
4791 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4792 ( "issue_row"."state" = 'voting' AND now() >=
4793 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4794 THEN
4795 "persist"."phase_finished" := TRUE;
4796 ELSE
4797 "persist"."phase_finished" := FALSE;
4798 END IF;
4799 IF
4800 NOT EXISTS (
4801 -- all initiatives are revoked
4802 SELECT NULL FROM "initiative"
4803 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4804 ) AND (
4805 -- and issue has not been accepted yet
4806 "persist"."state" = 'admission' OR
4807 -- or verification time has elapsed
4808 ( "persist"."state" = 'verification' AND
4809 "persist"."phase_finished" ) OR
4810 -- or no initiatives have been revoked lately
4811 NOT EXISTS (
4812 SELECT NULL FROM "initiative"
4813 WHERE "issue_id" = "issue_id_p"
4814 AND now() < "revoked" + "issue_row"."verification_time"
4817 THEN
4818 "persist"."issue_revoked" := TRUE;
4819 ELSE
4820 "persist"."issue_revoked" := FALSE;
4821 END IF;
4822 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4823 UPDATE "issue" SET "phase_finished" = now()
4824 WHERE "id" = "issue_row"."id";
4825 RETURN "persist";
4826 ELSIF
4827 "persist"."state" IN ('admission', 'discussion', 'verification')
4828 THEN
4829 RETURN "persist";
4830 ELSE
4831 RETURN NULL;
4832 END IF;
4833 END IF;
4834 IF
4835 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4836 coalesce("persist"."snapshot_created", FALSE) = FALSE
4837 THEN
4838 PERFORM "create_snapshot"("issue_id_p");
4839 "persist"."snapshot_created" = TRUE;
4840 IF "persist"."phase_finished" THEN
4841 IF "persist"."state" = 'admission' THEN
4842 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4843 ELSIF "persist"."state" = 'discussion' THEN
4844 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4845 ELSIF "persist"."state" = 'verification' THEN
4846 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4847 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4848 SELECT * INTO "policy_row" FROM "policy"
4849 WHERE "id" = "issue_row"."policy_id";
4850 FOR "initiative_row" IN
4851 SELECT * FROM "initiative"
4852 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4853 FOR UPDATE
4854 LOOP
4855 IF
4856 "initiative_row"."polling" OR (
4857 "initiative_row"."satisfied_supporter_count" > 0 AND
4858 "initiative_row"."satisfied_supporter_count" *
4859 "policy_row"."initiative_quorum_den" >=
4860 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4862 THEN
4863 UPDATE "initiative" SET "admitted" = TRUE
4864 WHERE "id" = "initiative_row"."id";
4865 ELSE
4866 UPDATE "initiative" SET "admitted" = FALSE
4867 WHERE "id" = "initiative_row"."id";
4868 END IF;
4869 END LOOP;
4870 END IF;
4871 END IF;
4872 RETURN "persist";
4873 END IF;
4874 IF
4875 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4876 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4877 THEN
4878 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4879 "persist"."harmonic_weights_set" = TRUE;
4880 IF
4881 "persist"."phase_finished" OR
4882 "persist"."issue_revoked" OR
4883 "persist"."state" = 'admission'
4884 THEN
4885 RETURN "persist";
4886 ELSE
4887 RETURN NULL;
4888 END IF;
4889 END IF;
4890 IF "persist"."issue_revoked" THEN
4891 IF "persist"."state" = 'admission' THEN
4892 "state_v" := 'canceled_revoked_before_accepted';
4893 ELSIF "persist"."state" = 'discussion' THEN
4894 "state_v" := 'canceled_after_revocation_during_discussion';
4895 ELSIF "persist"."state" = 'verification' THEN
4896 "state_v" := 'canceled_after_revocation_during_verification';
4897 END IF;
4898 UPDATE "issue" SET
4899 "state" = "state_v",
4900 "closed" = "phase_finished",
4901 "phase_finished" = NULL
4902 WHERE "id" = "issue_id_p";
4903 RETURN NULL;
4904 END IF;
4905 IF "persist"."state" = 'admission' THEN
4906 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4907 FOR UPDATE;
4908 SELECT * INTO "policy_row"
4909 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4910 IF
4911 ( now() >=
4912 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
4913 EXISTS (
4914 SELECT NULL FROM "initiative"
4915 WHERE "issue_id" = "issue_id_p"
4916 AND "supporter_count" > 0
4917 AND "supporter_count" * "policy_row"."issue_quorum_den"
4918 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4920 THEN
4921 UPDATE "issue" SET
4922 "state" = 'discussion',
4923 "accepted" = coalesce("phase_finished", now()),
4924 "phase_finished" = NULL
4925 WHERE "id" = "issue_id_p";
4926 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4927 UPDATE "issue" SET
4928 "state" = 'canceled_issue_not_accepted',
4929 "closed" = "phase_finished",
4930 "phase_finished" = NULL
4931 WHERE "id" = "issue_id_p";
4932 END IF;
4933 RETURN NULL;
4934 END IF;
4935 IF "persist"."phase_finished" THEN
4936 IF "persist"."state" = 'discussion' THEN
4937 UPDATE "issue" SET
4938 "state" = 'verification',
4939 "half_frozen" = "phase_finished",
4940 "phase_finished" = NULL
4941 WHERE "id" = "issue_id_p";
4942 RETURN NULL;
4943 END IF;
4944 IF "persist"."state" = 'verification' THEN
4945 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4946 FOR UPDATE;
4947 SELECT * INTO "policy_row" FROM "policy"
4948 WHERE "id" = "issue_row"."policy_id";
4949 IF EXISTS (
4950 SELECT NULL FROM "initiative"
4951 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4952 ) THEN
4953 UPDATE "issue" SET
4954 "state" = 'voting',
4955 "fully_frozen" = "phase_finished",
4956 "phase_finished" = NULL
4957 WHERE "id" = "issue_id_p";
4958 ELSE
4959 UPDATE "issue" SET
4960 "state" = 'canceled_no_initiative_admitted',
4961 "fully_frozen" = "phase_finished",
4962 "closed" = "phase_finished",
4963 "phase_finished" = NULL
4964 WHERE "id" = "issue_id_p";
4965 -- NOTE: The following DELETE statements have effect only when
4966 -- issue state has been manipulated
4967 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4968 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4969 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4970 END IF;
4971 RETURN NULL;
4972 END IF;
4973 IF "persist"."state" = 'voting' THEN
4974 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4975 PERFORM "close_voting"("issue_id_p");
4976 "persist"."closed_voting" = TRUE;
4977 RETURN "persist";
4978 END IF;
4979 PERFORM "calculate_ranks"("issue_id_p");
4980 RETURN NULL;
4981 END IF;
4982 END IF;
4983 RAISE WARNING 'should not happen';
4984 RETURN NULL;
4985 END;
4986 $$;
4988 COMMENT ON FUNCTION "check_issue"
4989 ( "issue"."id"%TYPE,
4990 "check_issue_persistence" )
4991 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")';
4994 CREATE FUNCTION "check_everything"()
4995 RETURNS VOID
4996 LANGUAGE 'plpgsql' VOLATILE AS $$
4997 DECLARE
4998 "issue_id_v" "issue"."id"%TYPE;
4999 "persist_v" "check_issue_persistence";
5000 BEGIN
5001 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
5002 DELETE FROM "expired_session";
5003 PERFORM "check_activity"();
5004 PERFORM "calculate_member_counts"();
5005 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
5006 "persist_v" := NULL;
5007 LOOP
5008 "persist_v" := "check_issue"("issue_id_v", "persist_v");
5009 EXIT WHEN "persist_v" ISNULL;
5010 END LOOP;
5011 END LOOP;
5012 RETURN;
5013 END;
5014 $$;
5016 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.';
5020 ----------------------
5021 -- Deletion of data --
5022 ----------------------
5025 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
5026 RETURNS VOID
5027 LANGUAGE 'plpgsql' VOLATILE AS $$
5028 BEGIN
5029 IF EXISTS (
5030 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
5031 ) THEN
5032 -- override protection triggers:
5033 INSERT INTO "temporary_transaction_data" ("key", "value")
5034 VALUES ('override_protection_triggers', TRUE::TEXT);
5035 -- clean data:
5036 DELETE FROM "delegating_voter"
5037 WHERE "issue_id" = "issue_id_p";
5038 DELETE FROM "direct_voter"
5039 WHERE "issue_id" = "issue_id_p";
5040 DELETE FROM "delegating_interest_snapshot"
5041 WHERE "issue_id" = "issue_id_p";
5042 DELETE FROM "direct_interest_snapshot"
5043 WHERE "issue_id" = "issue_id_p";
5044 DELETE FROM "delegating_population_snapshot"
5045 WHERE "issue_id" = "issue_id_p";
5046 DELETE FROM "direct_population_snapshot"
5047 WHERE "issue_id" = "issue_id_p";
5048 DELETE FROM "non_voter"
5049 WHERE "issue_id" = "issue_id_p";
5050 DELETE FROM "delegation"
5051 WHERE "issue_id" = "issue_id_p";
5052 DELETE FROM "supporter"
5053 USING "initiative" -- NOTE: due to missing index on issue_id
5054 WHERE "initiative"."issue_id" = "issue_id_p"
5055 AND "supporter"."initiative_id" = "initiative_id";
5056 -- mark issue as cleaned:
5057 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
5058 -- finish overriding protection triggers (avoids garbage):
5059 DELETE FROM "temporary_transaction_data"
5060 WHERE "key" = 'override_protection_triggers';
5061 END IF;
5062 RETURN;
5063 END;
5064 $$;
5066 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
5069 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
5070 RETURNS VOID
5071 LANGUAGE 'plpgsql' VOLATILE AS $$
5072 BEGIN
5073 UPDATE "member" SET
5074 "last_login" = NULL,
5075 "last_delegation_check" = NULL,
5076 "login" = NULL,
5077 "password" = NULL,
5078 "authority" = NULL,
5079 "authority_uid" = NULL,
5080 "authority_login" = NULL,
5081 "locked" = TRUE,
5082 "active" = FALSE,
5083 "notify_email" = NULL,
5084 "notify_email_unconfirmed" = NULL,
5085 "notify_email_secret" = NULL,
5086 "notify_email_secret_expiry" = NULL,
5087 "notify_email_lock_expiry" = NULL,
5088 "disable_notifications" = NULL,
5089 "notification_counter" = NULL,
5090 "notification_sample_size" = NULL,
5091 "notification_dow" = NULL,
5092 "notification_hour" = NULL,
5093 "login_recovery_expiry" = NULL,
5094 "password_reset_secret" = NULL,
5095 "password_reset_secret_expiry" = NULL,
5096 "organizational_unit" = NULL,
5097 "internal_posts" = NULL,
5098 "realname" = NULL,
5099 "birthday" = NULL,
5100 "address" = NULL,
5101 "email" = NULL,
5102 "xmpp_address" = NULL,
5103 "website" = NULL,
5104 "phone" = NULL,
5105 "mobile_phone" = NULL,
5106 "profession" = NULL,
5107 "external_memberships" = NULL,
5108 "external_posts" = NULL,
5109 "statement" = NULL
5110 WHERE "id" = "member_id_p";
5111 -- "text_search_data" is updated by triggers
5112 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
5113 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
5114 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
5115 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
5116 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
5117 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
5118 DELETE FROM "session" WHERE "member_id" = "member_id_p";
5119 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
5120 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
5121 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
5122 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
5123 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
5124 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
5125 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
5126 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
5127 DELETE FROM "direct_voter" USING "issue"
5128 WHERE "direct_voter"."issue_id" = "issue"."id"
5129 AND "issue"."closed" ISNULL
5130 AND "member_id" = "member_id_p";
5131 RETURN;
5132 END;
5133 $$;
5135 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)';
5138 CREATE FUNCTION "delete_private_data"()
5139 RETURNS VOID
5140 LANGUAGE 'plpgsql' VOLATILE AS $$
5141 BEGIN
5142 DELETE FROM "temporary_transaction_data";
5143 DELETE FROM "member" WHERE "activated" ISNULL;
5144 UPDATE "member" SET
5145 "invite_code" = NULL,
5146 "invite_code_expiry" = NULL,
5147 "admin_comment" = NULL,
5148 "last_login" = NULL,
5149 "last_delegation_check" = NULL,
5150 "login" = NULL,
5151 "password" = NULL,
5152 "authority" = NULL,
5153 "authority_uid" = NULL,
5154 "authority_login" = NULL,
5155 "lang" = NULL,
5156 "notify_email" = NULL,
5157 "notify_email_unconfirmed" = NULL,
5158 "notify_email_secret" = NULL,
5159 "notify_email_secret_expiry" = NULL,
5160 "notify_email_lock_expiry" = NULL,
5161 "disable_notifications" = NULL,
5162 "notification_counter" = NULL,
5163 "notification_sample_size" = NULL,
5164 "notification_dow" = NULL,
5165 "notification_hour" = NULL,
5166 "login_recovery_expiry" = NULL,
5167 "password_reset_secret" = NULL,
5168 "password_reset_secret_expiry" = NULL,
5169 "organizational_unit" = NULL,
5170 "internal_posts" = NULL,
5171 "realname" = NULL,
5172 "birthday" = NULL,
5173 "address" = NULL,
5174 "email" = NULL,
5175 "xmpp_address" = NULL,
5176 "website" = NULL,
5177 "phone" = NULL,
5178 "mobile_phone" = NULL,
5179 "profession" = NULL,
5180 "external_memberships" = NULL,
5181 "external_posts" = NULL,
5182 "formatting_engine" = NULL,
5183 "statement" = NULL;
5184 -- "text_search_data" is updated by triggers
5185 DELETE FROM "setting";
5186 DELETE FROM "setting_map";
5187 DELETE FROM "member_relation_setting";
5188 DELETE FROM "member_image";
5189 DELETE FROM "contact";
5190 DELETE FROM "ignored_member";
5191 DELETE FROM "session";
5192 DELETE FROM "area_setting";
5193 DELETE FROM "issue_setting";
5194 DELETE FROM "ignored_initiative";
5195 DELETE FROM "initiative_setting";
5196 DELETE FROM "suggestion_setting";
5197 DELETE FROM "non_voter";
5198 DELETE FROM "direct_voter" USING "issue"
5199 WHERE "direct_voter"."issue_id" = "issue"."id"
5200 AND "issue"."closed" ISNULL;
5201 RETURN;
5202 END;
5203 $$;
5205 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.';
5209 COMMIT;

Impressum / About Us