liquid_feedback_core

view core.sql @ 471:124b9e7c3c23

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

Impressum / About Us