liquid_feedback_core

view core.sql @ 500:c1a2954078d7

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

Impressum / About Us