liquid_feedback_core

view core.sql @ 465:49fbad89371d

Changed table/column order
author jbe
date Sat Mar 26 00:22:13 2016 +0100 (2016-03-26)
parents 913f4d0b1e6e
children c6344e3a3c4a
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 "advertisement" (
1280 PRIMARY KEY ("time_serial", "initiative_id", "member_id"),
1281 "time_serial" SERIAL8,
1282 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1283 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1284 CREATE INDEX "advertisement_initiative_id_idx" ON "advertisement" ("initiative_id");
1285 CREATE INDEX "advertisement_member_id_idx" ON "advertisement" ("member_id");
1287 COMMENT ON TABLE "advertisement" IS 'Stores which initiatives have been advertised to a member in a mail digest';
1289 COMMENT ON COLUMN "advertisement"."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)';
1293 ----------------------------------------------
1294 -- Writing of history entries and event log --
1295 ----------------------------------------------
1298 CREATE FUNCTION "write_member_history_trigger"()
1299 RETURNS TRIGGER
1300 LANGUAGE 'plpgsql' VOLATILE AS $$
1301 BEGIN
1302 IF
1303 ( NEW."active" != OLD."active" OR
1304 NEW."name" != OLD."name" ) AND
1305 OLD."activated" NOTNULL
1306 THEN
1307 INSERT INTO "member_history"
1308 ("member_id", "active", "name")
1309 VALUES (NEW."id", OLD."active", OLD."name");
1310 END IF;
1311 RETURN NULL;
1312 END;
1313 $$;
1315 CREATE TRIGGER "write_member_history"
1316 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1317 "write_member_history_trigger"();
1319 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1320 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1323 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1324 RETURNS TRIGGER
1325 LANGUAGE 'plpgsql' VOLATILE AS $$
1326 BEGIN
1327 IF NEW."state" != OLD."state" THEN
1328 INSERT INTO "event" ("event", "issue_id", "state")
1329 VALUES ('issue_state_changed', NEW."id", NEW."state");
1330 END IF;
1331 RETURN NULL;
1332 END;
1333 $$;
1335 CREATE TRIGGER "write_event_issue_state_changed"
1336 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1337 "write_event_issue_state_changed_trigger"();
1339 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1340 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1343 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1344 RETURNS TRIGGER
1345 LANGUAGE 'plpgsql' VOLATILE AS $$
1346 DECLARE
1347 "initiative_row" "initiative"%ROWTYPE;
1348 "issue_row" "issue"%ROWTYPE;
1349 "event_v" "event_type";
1350 BEGIN
1351 SELECT * INTO "initiative_row" FROM "initiative"
1352 WHERE "id" = NEW."initiative_id";
1353 SELECT * INTO "issue_row" FROM "issue"
1354 WHERE "id" = "initiative_row"."issue_id";
1355 IF EXISTS (
1356 SELECT NULL FROM "draft"
1357 WHERE "initiative_id" = NEW."initiative_id"
1358 AND "id" != NEW."id"
1359 ) THEN
1360 "event_v" := 'new_draft_created';
1361 ELSE
1362 IF EXISTS (
1363 SELECT NULL FROM "initiative"
1364 WHERE "issue_id" = "initiative_row"."issue_id"
1365 AND "id" != "initiative_row"."id"
1366 ) THEN
1367 "event_v" := 'initiative_created_in_existing_issue';
1368 ELSE
1369 "event_v" := 'initiative_created_in_new_issue';
1370 END IF;
1371 END IF;
1372 INSERT INTO "event" (
1373 "event", "member_id",
1374 "issue_id", "state", "initiative_id", "draft_id"
1375 ) VALUES (
1376 "event_v",
1377 NEW."author_id",
1378 "initiative_row"."issue_id",
1379 "issue_row"."state",
1380 "initiative_row"."id",
1381 NEW."id" );
1382 RETURN NULL;
1383 END;
1384 $$;
1386 CREATE TRIGGER "write_event_initiative_or_draft_created"
1387 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1388 "write_event_initiative_or_draft_created_trigger"();
1390 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1391 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1394 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1395 RETURNS TRIGGER
1396 LANGUAGE 'plpgsql' VOLATILE AS $$
1397 DECLARE
1398 "issue_row" "issue"%ROWTYPE;
1399 "draft_id_v" "draft"."id"%TYPE;
1400 BEGIN
1401 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1402 SELECT * INTO "issue_row" FROM "issue"
1403 WHERE "id" = NEW."issue_id";
1404 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1405 WHERE "initiative_id" = NEW."id";
1406 INSERT INTO "event" (
1407 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1408 ) VALUES (
1409 'initiative_revoked',
1410 NEW."revoked_by_member_id",
1411 NEW."issue_id",
1412 "issue_row"."state",
1413 NEW."id",
1414 "draft_id_v");
1415 END IF;
1416 RETURN NULL;
1417 END;
1418 $$;
1420 CREATE TRIGGER "write_event_initiative_revoked"
1421 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1422 "write_event_initiative_revoked_trigger"();
1424 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1425 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1428 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1429 RETURNS TRIGGER
1430 LANGUAGE 'plpgsql' VOLATILE AS $$
1431 DECLARE
1432 "initiative_row" "initiative"%ROWTYPE;
1433 "issue_row" "issue"%ROWTYPE;
1434 BEGIN
1435 SELECT * INTO "initiative_row" FROM "initiative"
1436 WHERE "id" = NEW."initiative_id";
1437 SELECT * INTO "issue_row" FROM "issue"
1438 WHERE "id" = "initiative_row"."issue_id";
1439 INSERT INTO "event" (
1440 "event", "member_id",
1441 "issue_id", "state", "initiative_id", "suggestion_id"
1442 ) VALUES (
1443 'suggestion_created',
1444 NEW."author_id",
1445 "initiative_row"."issue_id",
1446 "issue_row"."state",
1447 "initiative_row"."id",
1448 NEW."id" );
1449 RETURN NULL;
1450 END;
1451 $$;
1453 CREATE TRIGGER "write_event_suggestion_created"
1454 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1455 "write_event_suggestion_created_trigger"();
1457 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1458 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1462 ----------------------------
1463 -- Additional constraints --
1464 ----------------------------
1467 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1468 RETURNS TRIGGER
1469 LANGUAGE 'plpgsql' VOLATILE AS $$
1470 BEGIN
1471 IF NOT EXISTS (
1472 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1473 ) THEN
1474 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
1475 ERRCODE = 'integrity_constraint_violation',
1476 HINT = 'Create issue, initiative, and draft within the same transaction.';
1477 END IF;
1478 RETURN NULL;
1479 END;
1480 $$;
1482 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1483 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1484 FOR EACH ROW EXECUTE PROCEDURE
1485 "issue_requires_first_initiative_trigger"();
1487 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1488 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1491 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1492 RETURNS TRIGGER
1493 LANGUAGE 'plpgsql' VOLATILE AS $$
1494 DECLARE
1495 "reference_lost" BOOLEAN;
1496 BEGIN
1497 IF TG_OP = 'DELETE' THEN
1498 "reference_lost" := TRUE;
1499 ELSE
1500 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1501 END IF;
1502 IF
1503 "reference_lost" AND NOT EXISTS (
1504 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1506 THEN
1507 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1508 END IF;
1509 RETURN NULL;
1510 END;
1511 $$;
1513 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1514 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1515 FOR EACH ROW EXECUTE PROCEDURE
1516 "last_initiative_deletes_issue_trigger"();
1518 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1519 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1522 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1523 RETURNS TRIGGER
1524 LANGUAGE 'plpgsql' VOLATILE AS $$
1525 BEGIN
1526 IF NOT EXISTS (
1527 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1528 ) THEN
1529 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
1530 ERRCODE = 'integrity_constraint_violation',
1531 HINT = 'Create issue, initiative and draft within the same transaction.';
1532 END IF;
1533 RETURN NULL;
1534 END;
1535 $$;
1537 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1538 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1539 FOR EACH ROW EXECUTE PROCEDURE
1540 "initiative_requires_first_draft_trigger"();
1542 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1543 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1546 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1547 RETURNS TRIGGER
1548 LANGUAGE 'plpgsql' VOLATILE AS $$
1549 DECLARE
1550 "reference_lost" BOOLEAN;
1551 BEGIN
1552 IF TG_OP = 'DELETE' THEN
1553 "reference_lost" := TRUE;
1554 ELSE
1555 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1556 END IF;
1557 IF
1558 "reference_lost" AND NOT EXISTS (
1559 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1561 THEN
1562 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1563 END IF;
1564 RETURN NULL;
1565 END;
1566 $$;
1568 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1569 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1570 FOR EACH ROW EXECUTE PROCEDURE
1571 "last_draft_deletes_initiative_trigger"();
1573 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1574 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1577 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1578 RETURNS TRIGGER
1579 LANGUAGE 'plpgsql' VOLATILE AS $$
1580 BEGIN
1581 IF NOT EXISTS (
1582 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1583 ) THEN
1584 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
1585 ERRCODE = 'integrity_constraint_violation',
1586 HINT = 'Create suggestion and opinion within the same transaction.';
1587 END IF;
1588 RETURN NULL;
1589 END;
1590 $$;
1592 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1593 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1594 FOR EACH ROW EXECUTE PROCEDURE
1595 "suggestion_requires_first_opinion_trigger"();
1597 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1598 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1601 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1602 RETURNS TRIGGER
1603 LANGUAGE 'plpgsql' VOLATILE AS $$
1604 DECLARE
1605 "reference_lost" BOOLEAN;
1606 BEGIN
1607 IF TG_OP = 'DELETE' THEN
1608 "reference_lost" := TRUE;
1609 ELSE
1610 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1611 END IF;
1612 IF
1613 "reference_lost" AND NOT EXISTS (
1614 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1616 THEN
1617 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1618 END IF;
1619 RETURN NULL;
1620 END;
1621 $$;
1623 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1624 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1625 FOR EACH ROW EXECUTE PROCEDURE
1626 "last_opinion_deletes_suggestion_trigger"();
1628 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1629 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1632 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1633 RETURNS TRIGGER
1634 LANGUAGE 'plpgsql' VOLATILE AS $$
1635 BEGIN
1636 DELETE FROM "direct_voter"
1637 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1638 RETURN NULL;
1639 END;
1640 $$;
1642 CREATE TRIGGER "non_voter_deletes_direct_voter"
1643 AFTER INSERT OR UPDATE ON "non_voter"
1644 FOR EACH ROW EXECUTE PROCEDURE
1645 "non_voter_deletes_direct_voter_trigger"();
1647 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1648 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")';
1651 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1652 RETURNS TRIGGER
1653 LANGUAGE 'plpgsql' VOLATILE AS $$
1654 BEGIN
1655 DELETE FROM "non_voter"
1656 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1657 RETURN NULL;
1658 END;
1659 $$;
1661 CREATE TRIGGER "direct_voter_deletes_non_voter"
1662 AFTER INSERT OR UPDATE ON "direct_voter"
1663 FOR EACH ROW EXECUTE PROCEDURE
1664 "direct_voter_deletes_non_voter_trigger"();
1666 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1667 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")';
1670 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1671 RETURNS TRIGGER
1672 LANGUAGE 'plpgsql' VOLATILE AS $$
1673 BEGIN
1674 IF NEW."comment" ISNULL THEN
1675 NEW."comment_changed" := NULL;
1676 NEW."formatting_engine" := NULL;
1677 END IF;
1678 RETURN NEW;
1679 END;
1680 $$;
1682 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1683 BEFORE INSERT OR UPDATE ON "direct_voter"
1684 FOR EACH ROW EXECUTE PROCEDURE
1685 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1687 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"';
1688 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.';
1691 ---------------------------------------------------------------
1692 -- Ensure that votes are not modified when issues are closed --
1693 ---------------------------------------------------------------
1695 -- NOTE: Frontends should ensure this anyway, but in case of programming
1696 -- errors the following triggers ensure data integrity.
1699 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1700 RETURNS TRIGGER
1701 LANGUAGE 'plpgsql' VOLATILE AS $$
1702 DECLARE
1703 "issue_id_v" "issue"."id"%TYPE;
1704 "issue_row" "issue"%ROWTYPE;
1705 BEGIN
1706 IF EXISTS (
1707 SELECT NULL FROM "temporary_transaction_data"
1708 WHERE "txid" = txid_current()
1709 AND "key" = 'override_protection_triggers'
1710 AND "value" = TRUE::TEXT
1711 ) THEN
1712 RETURN NULL;
1713 END IF;
1714 IF TG_OP = 'DELETE' THEN
1715 "issue_id_v" := OLD."issue_id";
1716 ELSE
1717 "issue_id_v" := NEW."issue_id";
1718 END IF;
1719 SELECT INTO "issue_row" * FROM "issue"
1720 WHERE "id" = "issue_id_v" FOR SHARE;
1721 IF (
1722 "issue_row"."closed" NOTNULL OR (
1723 "issue_row"."state" = 'voting' AND
1724 "issue_row"."phase_finished" NOTNULL
1726 ) THEN
1727 IF
1728 TG_RELID = 'direct_voter'::regclass AND
1729 TG_OP = 'UPDATE'
1730 THEN
1731 IF
1732 OLD."issue_id" = NEW."issue_id" AND
1733 OLD."member_id" = NEW."member_id" AND
1734 OLD."weight" = NEW."weight"
1735 THEN
1736 RETURN NULL; -- allows changing of voter comment
1737 END IF;
1738 END IF;
1739 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
1740 ERRCODE = 'integrity_constraint_violation';
1741 END IF;
1742 RETURN NULL;
1743 END;
1744 $$;
1746 CREATE TRIGGER "forbid_changes_on_closed_issue"
1747 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1748 FOR EACH ROW EXECUTE PROCEDURE
1749 "forbid_changes_on_closed_issue_trigger"();
1751 CREATE TRIGGER "forbid_changes_on_closed_issue"
1752 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1753 FOR EACH ROW EXECUTE PROCEDURE
1754 "forbid_changes_on_closed_issue_trigger"();
1756 CREATE TRIGGER "forbid_changes_on_closed_issue"
1757 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1758 FOR EACH ROW EXECUTE PROCEDURE
1759 "forbid_changes_on_closed_issue_trigger"();
1761 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"';
1762 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';
1763 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';
1764 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';
1768 --------------------------------------------------------------------
1769 -- Auto-retrieval of fields only needed for referential integrity --
1770 --------------------------------------------------------------------
1773 CREATE FUNCTION "autofill_issue_id_trigger"()
1774 RETURNS TRIGGER
1775 LANGUAGE 'plpgsql' VOLATILE AS $$
1776 BEGIN
1777 IF NEW."issue_id" ISNULL THEN
1778 SELECT "issue_id" INTO NEW."issue_id"
1779 FROM "initiative" WHERE "id" = NEW."initiative_id";
1780 END IF;
1781 RETURN NEW;
1782 END;
1783 $$;
1785 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1786 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1788 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1789 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1791 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1792 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1793 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1796 CREATE FUNCTION "autofill_initiative_id_trigger"()
1797 RETURNS TRIGGER
1798 LANGUAGE 'plpgsql' VOLATILE AS $$
1799 BEGIN
1800 IF NEW."initiative_id" ISNULL THEN
1801 SELECT "initiative_id" INTO NEW."initiative_id"
1802 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1803 END IF;
1804 RETURN NEW;
1805 END;
1806 $$;
1808 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1809 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1811 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1812 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1816 -----------------------------------------------------
1817 -- Automatic calculation of certain default values --
1818 -----------------------------------------------------
1821 CREATE FUNCTION "copy_timings_trigger"()
1822 RETURNS TRIGGER
1823 LANGUAGE 'plpgsql' VOLATILE AS $$
1824 DECLARE
1825 "policy_row" "policy"%ROWTYPE;
1826 BEGIN
1827 SELECT * INTO "policy_row" FROM "policy"
1828 WHERE "id" = NEW."policy_id";
1829 IF NEW."min_admission_time" ISNULL THEN
1830 NEW."min_admission_time" := "policy_row"."min_admission_time";
1831 END IF;
1832 IF NEW."max_admission_time" ISNULL THEN
1833 NEW."max_admission_time" := "policy_row"."max_admission_time";
1834 END IF;
1835 IF NEW."discussion_time" ISNULL THEN
1836 NEW."discussion_time" := "policy_row"."discussion_time";
1837 END IF;
1838 IF NEW."verification_time" ISNULL THEN
1839 NEW."verification_time" := "policy_row"."verification_time";
1840 END IF;
1841 IF NEW."voting_time" ISNULL THEN
1842 NEW."voting_time" := "policy_row"."voting_time";
1843 END IF;
1844 RETURN NEW;
1845 END;
1846 $$;
1848 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1849 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1851 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1852 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1855 CREATE FUNCTION "default_for_draft_id_trigger"()
1856 RETURNS TRIGGER
1857 LANGUAGE 'plpgsql' VOLATILE AS $$
1858 BEGIN
1859 IF NEW."draft_id" ISNULL THEN
1860 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1861 WHERE "initiative_id" = NEW."initiative_id";
1862 END IF;
1863 RETURN NEW;
1864 END;
1865 $$;
1867 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1868 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1869 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1870 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1872 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1873 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';
1874 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';
1878 ----------------------------------------
1879 -- Automatic creation of dependencies --
1880 ----------------------------------------
1883 CREATE FUNCTION "autocreate_interest_trigger"()
1884 RETURNS TRIGGER
1885 LANGUAGE 'plpgsql' VOLATILE AS $$
1886 BEGIN
1887 IF NOT EXISTS (
1888 SELECT NULL FROM "initiative" JOIN "interest"
1889 ON "initiative"."issue_id" = "interest"."issue_id"
1890 WHERE "initiative"."id" = NEW."initiative_id"
1891 AND "interest"."member_id" = NEW."member_id"
1892 ) THEN
1893 BEGIN
1894 INSERT INTO "interest" ("issue_id", "member_id")
1895 SELECT "issue_id", NEW."member_id"
1896 FROM "initiative" WHERE "id" = NEW."initiative_id";
1897 EXCEPTION WHEN unique_violation THEN END;
1898 END IF;
1899 RETURN NEW;
1900 END;
1901 $$;
1903 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1904 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1906 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1907 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';
1910 CREATE FUNCTION "autocreate_supporter_trigger"()
1911 RETURNS TRIGGER
1912 LANGUAGE 'plpgsql' VOLATILE AS $$
1913 BEGIN
1914 IF NOT EXISTS (
1915 SELECT NULL FROM "suggestion" JOIN "supporter"
1916 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1917 WHERE "suggestion"."id" = NEW."suggestion_id"
1918 AND "supporter"."member_id" = NEW."member_id"
1919 ) THEN
1920 BEGIN
1921 INSERT INTO "supporter" ("initiative_id", "member_id")
1922 SELECT "initiative_id", NEW."member_id"
1923 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1924 EXCEPTION WHEN unique_violation THEN END;
1925 END IF;
1926 RETURN NEW;
1927 END;
1928 $$;
1930 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1931 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1933 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1934 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.';
1938 ------------------------------------------
1939 -- Views and helper functions for views --
1940 ------------------------------------------
1943 CREATE VIEW "unit_delegation" AS
1944 SELECT
1945 "unit"."id" AS "unit_id",
1946 "delegation"."id",
1947 "delegation"."truster_id",
1948 "delegation"."trustee_id",
1949 "delegation"."scope"
1950 FROM "unit"
1951 JOIN "delegation"
1952 ON "delegation"."unit_id" = "unit"."id"
1953 JOIN "member"
1954 ON "delegation"."truster_id" = "member"."id"
1955 JOIN "privilege"
1956 ON "delegation"."unit_id" = "privilege"."unit_id"
1957 AND "delegation"."truster_id" = "privilege"."member_id"
1958 WHERE "member"."active" AND "privilege"."voting_right";
1960 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1963 CREATE VIEW "area_delegation" AS
1964 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1965 "area"."id" AS "area_id",
1966 "delegation"."id",
1967 "delegation"."truster_id",
1968 "delegation"."trustee_id",
1969 "delegation"."scope"
1970 FROM "area"
1971 JOIN "delegation"
1972 ON "delegation"."unit_id" = "area"."unit_id"
1973 OR "delegation"."area_id" = "area"."id"
1974 JOIN "member"
1975 ON "delegation"."truster_id" = "member"."id"
1976 JOIN "privilege"
1977 ON "area"."unit_id" = "privilege"."unit_id"
1978 AND "delegation"."truster_id" = "privilege"."member_id"
1979 WHERE "member"."active" AND "privilege"."voting_right"
1980 ORDER BY
1981 "area"."id",
1982 "delegation"."truster_id",
1983 "delegation"."scope" DESC;
1985 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1988 CREATE VIEW "issue_delegation" AS
1989 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1990 "issue"."id" AS "issue_id",
1991 "delegation"."id",
1992 "delegation"."truster_id",
1993 "delegation"."trustee_id",
1994 "delegation"."scope"
1995 FROM "issue"
1996 JOIN "area"
1997 ON "area"."id" = "issue"."area_id"
1998 JOIN "delegation"
1999 ON "delegation"."unit_id" = "area"."unit_id"
2000 OR "delegation"."area_id" = "area"."id"
2001 OR "delegation"."issue_id" = "issue"."id"
2002 JOIN "member"
2003 ON "delegation"."truster_id" = "member"."id"
2004 JOIN "privilege"
2005 ON "area"."unit_id" = "privilege"."unit_id"
2006 AND "delegation"."truster_id" = "privilege"."member_id"
2007 WHERE "member"."active" AND "privilege"."voting_right"
2008 ORDER BY
2009 "issue"."id",
2010 "delegation"."truster_id",
2011 "delegation"."scope" DESC;
2013 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
2016 CREATE FUNCTION "membership_weight_with_skipping"
2017 ( "area_id_p" "area"."id"%TYPE,
2018 "member_id_p" "member"."id"%TYPE,
2019 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
2020 RETURNS INT4
2021 LANGUAGE 'plpgsql' STABLE AS $$
2022 DECLARE
2023 "sum_v" INT4;
2024 "delegation_row" "area_delegation"%ROWTYPE;
2025 BEGIN
2026 "sum_v" := 1;
2027 FOR "delegation_row" IN
2028 SELECT "area_delegation".*
2029 FROM "area_delegation" LEFT JOIN "membership"
2030 ON "membership"."area_id" = "area_id_p"
2031 AND "membership"."member_id" = "area_delegation"."truster_id"
2032 WHERE "area_delegation"."area_id" = "area_id_p"
2033 AND "area_delegation"."trustee_id" = "member_id_p"
2034 AND "membership"."member_id" ISNULL
2035 LOOP
2036 IF NOT
2037 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
2038 THEN
2039 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
2040 "area_id_p",
2041 "delegation_row"."truster_id",
2042 "skip_member_ids_p" || "delegation_row"."truster_id"
2043 );
2044 END IF;
2045 END LOOP;
2046 RETURN "sum_v";
2047 END;
2048 $$;
2050 COMMENT ON FUNCTION "membership_weight_with_skipping"
2051 ( "area"."id"%TYPE,
2052 "member"."id"%TYPE,
2053 INT4[] )
2054 IS 'Helper function for "membership_weight" function';
2057 CREATE FUNCTION "membership_weight"
2058 ( "area_id_p" "area"."id"%TYPE,
2059 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
2060 RETURNS INT4
2061 LANGUAGE 'plpgsql' STABLE AS $$
2062 BEGIN
2063 RETURN "membership_weight_with_skipping"(
2064 "area_id_p",
2065 "member_id_p",
2066 ARRAY["member_id_p"]
2067 );
2068 END;
2069 $$;
2071 COMMENT ON FUNCTION "membership_weight"
2072 ( "area"."id"%TYPE,
2073 "member"."id"%TYPE )
2074 IS 'Calculates the potential voting weight of a member in a given area';
2077 CREATE VIEW "member_count_view" AS
2078 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
2080 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
2083 CREATE VIEW "unit_member_count" AS
2084 SELECT
2085 "unit"."id" AS "unit_id",
2086 count("member"."id") AS "member_count"
2087 FROM "unit"
2088 LEFT JOIN "privilege"
2089 ON "privilege"."unit_id" = "unit"."id"
2090 AND "privilege"."voting_right"
2091 LEFT JOIN "member"
2092 ON "member"."id" = "privilege"."member_id"
2093 AND "member"."active"
2094 GROUP BY "unit"."id";
2096 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
2099 CREATE VIEW "area_member_count" AS
2100 SELECT
2101 "area"."id" AS "area_id",
2102 count("member"."id") AS "direct_member_count",
2103 coalesce(
2104 sum(
2105 CASE WHEN "member"."id" NOTNULL THEN
2106 "membership_weight"("area"."id", "member"."id")
2107 ELSE 0 END
2109 ) AS "member_weight"
2110 FROM "area"
2111 LEFT JOIN "membership"
2112 ON "area"."id" = "membership"."area_id"
2113 LEFT JOIN "privilege"
2114 ON "privilege"."unit_id" = "area"."unit_id"
2115 AND "privilege"."member_id" = "membership"."member_id"
2116 AND "privilege"."voting_right"
2117 LEFT JOIN "member"
2118 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2119 AND "member"."active"
2120 GROUP BY "area"."id";
2122 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2125 CREATE VIEW "opening_draft" AS
2126 SELECT "draft".* FROM (
2127 SELECT
2128 "initiative"."id" AS "initiative_id",
2129 min("draft"."id") AS "draft_id"
2130 FROM "initiative" JOIN "draft"
2131 ON "initiative"."id" = "draft"."initiative_id"
2132 GROUP BY "initiative"."id"
2133 ) AS "subquery"
2134 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2136 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2139 CREATE VIEW "current_draft" AS
2140 SELECT "draft".* FROM (
2141 SELECT
2142 "initiative"."id" AS "initiative_id",
2143 max("draft"."id") AS "draft_id"
2144 FROM "initiative" JOIN "draft"
2145 ON "initiative"."id" = "draft"."initiative_id"
2146 GROUP BY "initiative"."id"
2147 ) AS "subquery"
2148 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2150 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2153 CREATE VIEW "critical_opinion" AS
2154 SELECT * FROM "opinion"
2155 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2156 OR ("degree" = -2 AND "fulfilled" = TRUE);
2158 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2161 CREATE VIEW "issue_supporter_in_admission_state" AS
2162 SELECT DISTINCT
2163 "area"."unit_id",
2164 "issue"."area_id",
2165 "issue"."id" AS "issue_id",
2166 "supporter"."member_id",
2167 "direct_interest_snapshot"."weight"
2168 FROM "issue"
2169 JOIN "area" ON "area"."id" = "issue"."area_id"
2170 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
2171 JOIN "direct_interest_snapshot"
2172 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2173 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2174 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
2175 WHERE "issue"."state" = 'admission'::"issue_state";
2177 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';
2180 CREATE VIEW "initiative_suggestion_order_calculation" AS
2181 SELECT
2182 "initiative"."id" AS "initiative_id",
2183 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
2184 FROM "initiative" JOIN "issue"
2185 ON "initiative"."issue_id" = "issue"."id"
2186 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
2187 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
2189 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
2191 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';
2194 CREATE VIEW "individual_suggestion_ranking" AS
2195 SELECT
2196 "opinion"."initiative_id",
2197 "opinion"."member_id",
2198 "direct_interest_snapshot"."weight",
2199 CASE WHEN
2200 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
2201 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
2202 THEN 1 ELSE
2203 CASE WHEN
2204 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
2205 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
2206 THEN 2 ELSE
2207 CASE WHEN
2208 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
2209 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
2210 THEN 3 ELSE 4 END
2211 END
2212 END AS "preference",
2213 "opinion"."suggestion_id"
2214 FROM "opinion"
2215 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
2216 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2217 JOIN "direct_interest_snapshot"
2218 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2219 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2220 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
2222 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
2225 CREATE VIEW "battle_participant" AS
2226 SELECT "initiative"."id", "initiative"."issue_id"
2227 FROM "issue" JOIN "initiative"
2228 ON "issue"."id" = "initiative"."issue_id"
2229 WHERE "initiative"."admitted"
2230 UNION ALL
2231 SELECT NULL, "id" AS "issue_id"
2232 FROM "issue";
2234 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2237 CREATE VIEW "battle_view" AS
2238 SELECT
2239 "issue"."id" AS "issue_id",
2240 "winning_initiative"."id" AS "winning_initiative_id",
2241 "losing_initiative"."id" AS "losing_initiative_id",
2242 sum(
2243 CASE WHEN
2244 coalesce("better_vote"."grade", 0) >
2245 coalesce("worse_vote"."grade", 0)
2246 THEN "direct_voter"."weight" ELSE 0 END
2247 ) AS "count"
2248 FROM "issue"
2249 LEFT JOIN "direct_voter"
2250 ON "issue"."id" = "direct_voter"."issue_id"
2251 JOIN "battle_participant" AS "winning_initiative"
2252 ON "issue"."id" = "winning_initiative"."issue_id"
2253 JOIN "battle_participant" AS "losing_initiative"
2254 ON "issue"."id" = "losing_initiative"."issue_id"
2255 LEFT JOIN "vote" AS "better_vote"
2256 ON "direct_voter"."member_id" = "better_vote"."member_id"
2257 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2258 LEFT JOIN "vote" AS "worse_vote"
2259 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2260 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2261 WHERE "issue"."state" = 'voting'
2262 AND "issue"."phase_finished" NOTNULL
2263 AND (
2264 "winning_initiative"."id" != "losing_initiative"."id" OR
2265 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2266 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2267 GROUP BY
2268 "issue"."id",
2269 "winning_initiative"."id",
2270 "losing_initiative"."id";
2272 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';
2275 CREATE VIEW "expired_session" AS
2276 SELECT * FROM "session" WHERE now() > "expiry";
2278 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2279 DELETE FROM "session" WHERE "ident" = OLD."ident";
2281 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2282 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2285 CREATE VIEW "open_issue" AS
2286 SELECT * FROM "issue" WHERE "closed" ISNULL;
2288 COMMENT ON VIEW "open_issue" IS 'All open issues';
2291 CREATE VIEW "member_contingent" AS
2292 SELECT
2293 "member"."id" AS "member_id",
2294 "contingent"."polling",
2295 "contingent"."time_frame",
2296 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2298 SELECT count(1) FROM "draft"
2299 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2300 WHERE "draft"."author_id" = "member"."id"
2301 AND "initiative"."polling" = "contingent"."polling"
2302 AND "draft"."created" > now() - "contingent"."time_frame"
2303 ) + (
2304 SELECT count(1) FROM "suggestion"
2305 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2306 WHERE "suggestion"."author_id" = "member"."id"
2307 AND "contingent"."polling" = FALSE
2308 AND "suggestion"."created" > now() - "contingent"."time_frame"
2310 ELSE NULL END AS "text_entry_count",
2311 "contingent"."text_entry_limit",
2312 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2313 SELECT count(1) FROM "opening_draft" AS "draft"
2314 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2315 WHERE "draft"."author_id" = "member"."id"
2316 AND "initiative"."polling" = "contingent"."polling"
2317 AND "draft"."created" > now() - "contingent"."time_frame"
2318 ) ELSE NULL END AS "initiative_count",
2319 "contingent"."initiative_limit"
2320 FROM "member" CROSS JOIN "contingent";
2322 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2324 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2325 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2328 CREATE VIEW "member_contingent_left" AS
2329 SELECT
2330 "member_id",
2331 "polling",
2332 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2333 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2334 FROM "member_contingent" GROUP BY "member_id", "polling";
2336 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.';
2339 CREATE VIEW "event_seen_by_member" AS
2340 SELECT
2341 "member"."id" AS "seen_by_member_id",
2342 CASE WHEN "event"."state" IN (
2343 'voting',
2344 'finished_without_winner',
2345 'finished_with_winner'
2346 ) THEN
2347 'voting'::"notify_level"
2348 ELSE
2349 CASE WHEN "event"."state" IN (
2350 'verification',
2351 'canceled_after_revocation_during_verification',
2352 'canceled_no_initiative_admitted'
2353 ) THEN
2354 'verification'::"notify_level"
2355 ELSE
2356 CASE WHEN "event"."state" IN (
2357 'discussion',
2358 'canceled_after_revocation_during_discussion'
2359 ) THEN
2360 'discussion'::"notify_level"
2361 ELSE
2362 'all'::"notify_level"
2363 END
2364 END
2365 END AS "notify_level",
2366 "event".*
2367 FROM "member" CROSS JOIN "event"
2368 LEFT JOIN "issue"
2369 ON "event"."issue_id" = "issue"."id"
2370 LEFT JOIN "membership"
2371 ON "member"."id" = "membership"."member_id"
2372 AND "issue"."area_id" = "membership"."area_id"
2373 LEFT JOIN "interest"
2374 ON "member"."id" = "interest"."member_id"
2375 AND "event"."issue_id" = "interest"."issue_id"
2376 LEFT JOIN "ignored_member"
2377 ON "member"."id" = "ignored_member"."member_id"
2378 AND "event"."member_id" = "ignored_member"."other_member_id"
2379 LEFT JOIN "ignored_initiative"
2380 ON "member"."id" = "ignored_initiative"."member_id"
2381 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2382 WHERE (
2383 "interest"."member_id" NOTNULL OR
2384 ( "membership"."member_id" NOTNULL AND
2385 "event"."event" IN (
2386 'issue_state_changed',
2387 'initiative_created_in_new_issue',
2388 'initiative_created_in_existing_issue',
2389 'initiative_revoked' ) ) )
2390 AND "ignored_member"."member_id" ISNULL
2391 AND "ignored_initiative"."member_id" ISNULL;
2393 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"';
2397 ------------------------------------------------------
2398 -- Row set returning function for delegation chains --
2399 ------------------------------------------------------
2402 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2403 ('first', 'intermediate', 'last', 'repetition');
2405 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2408 CREATE TYPE "delegation_chain_row" AS (
2409 "index" INT4,
2410 "member_id" INT4,
2411 "member_valid" BOOLEAN,
2412 "participation" BOOLEAN,
2413 "overridden" BOOLEAN,
2414 "scope_in" "delegation_scope",
2415 "scope_out" "delegation_scope",
2416 "disabled_out" BOOLEAN,
2417 "loop" "delegation_chain_loop_tag" );
2419 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2421 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2422 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';
2423 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2424 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2425 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2426 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2427 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2430 CREATE FUNCTION "delegation_chain_for_closed_issue"
2431 ( "member_id_p" "member"."id"%TYPE,
2432 "issue_id_p" "issue"."id"%TYPE )
2433 RETURNS SETOF "delegation_chain_row"
2434 LANGUAGE 'plpgsql' STABLE AS $$
2435 DECLARE
2436 "output_row" "delegation_chain_row";
2437 "direct_voter_row" "direct_voter"%ROWTYPE;
2438 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2439 BEGIN
2440 "output_row"."index" := 0;
2441 "output_row"."member_id" := "member_id_p";
2442 "output_row"."member_valid" := TRUE;
2443 "output_row"."participation" := FALSE;
2444 "output_row"."overridden" := FALSE;
2445 "output_row"."disabled_out" := FALSE;
2446 LOOP
2447 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2448 WHERE "issue_id" = "issue_id_p"
2449 AND "member_id" = "output_row"."member_id";
2450 IF "direct_voter_row"."member_id" NOTNULL THEN
2451 "output_row"."participation" := TRUE;
2452 "output_row"."scope_out" := NULL;
2453 "output_row"."disabled_out" := NULL;
2454 RETURN NEXT "output_row";
2455 RETURN;
2456 END IF;
2457 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2458 WHERE "issue_id" = "issue_id_p"
2459 AND "member_id" = "output_row"."member_id";
2460 IF "delegating_voter_row"."member_id" ISNULL THEN
2461 RETURN;
2462 END IF;
2463 "output_row"."scope_out" := "delegating_voter_row"."scope";
2464 RETURN NEXT "output_row";
2465 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2466 "output_row"."scope_in" := "output_row"."scope_out";
2467 END LOOP;
2468 END;
2469 $$;
2471 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2472 ( "member"."id"%TYPE,
2473 "member"."id"%TYPE )
2474 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2477 CREATE FUNCTION "delegation_chain"
2478 ( "member_id_p" "member"."id"%TYPE,
2479 "unit_id_p" "unit"."id"%TYPE,
2480 "area_id_p" "area"."id"%TYPE,
2481 "issue_id_p" "issue"."id"%TYPE,
2482 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2483 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2484 RETURNS SETOF "delegation_chain_row"
2485 LANGUAGE 'plpgsql' STABLE AS $$
2486 DECLARE
2487 "scope_v" "delegation_scope";
2488 "unit_id_v" "unit"."id"%TYPE;
2489 "area_id_v" "area"."id"%TYPE;
2490 "issue_row" "issue"%ROWTYPE;
2491 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2492 "loop_member_id_v" "member"."id"%TYPE;
2493 "output_row" "delegation_chain_row";
2494 "output_rows" "delegation_chain_row"[];
2495 "simulate_v" BOOLEAN;
2496 "simulate_here_v" BOOLEAN;
2497 "delegation_row" "delegation"%ROWTYPE;
2498 "row_count" INT4;
2499 "i" INT4;
2500 "loop_v" BOOLEAN;
2501 BEGIN
2502 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2503 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2504 END IF;
2505 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2506 "simulate_v" := TRUE;
2507 ELSE
2508 "simulate_v" := FALSE;
2509 END IF;
2510 IF
2511 "unit_id_p" NOTNULL AND
2512 "area_id_p" ISNULL AND
2513 "issue_id_p" ISNULL
2514 THEN
2515 "scope_v" := 'unit';
2516 "unit_id_v" := "unit_id_p";
2517 ELSIF
2518 "unit_id_p" ISNULL AND
2519 "area_id_p" NOTNULL AND
2520 "issue_id_p" ISNULL
2521 THEN
2522 "scope_v" := 'area';
2523 "area_id_v" := "area_id_p";
2524 SELECT "unit_id" INTO "unit_id_v"
2525 FROM "area" WHERE "id" = "area_id_v";
2526 ELSIF
2527 "unit_id_p" ISNULL AND
2528 "area_id_p" ISNULL AND
2529 "issue_id_p" NOTNULL
2530 THEN
2531 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2532 IF "issue_row"."id" ISNULL THEN
2533 RETURN;
2534 END IF;
2535 IF "issue_row"."closed" NOTNULL THEN
2536 IF "simulate_v" THEN
2537 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2538 END IF;
2539 FOR "output_row" IN
2540 SELECT * FROM
2541 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2542 LOOP
2543 RETURN NEXT "output_row";
2544 END LOOP;
2545 RETURN;
2546 END IF;
2547 "scope_v" := 'issue';
2548 SELECT "area_id" INTO "area_id_v"
2549 FROM "issue" WHERE "id" = "issue_id_p";
2550 SELECT "unit_id" INTO "unit_id_v"
2551 FROM "area" WHERE "id" = "area_id_v";
2552 ELSE
2553 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2554 END IF;
2555 "visited_member_ids" := '{}';
2556 "loop_member_id_v" := NULL;
2557 "output_rows" := '{}';
2558 "output_row"."index" := 0;
2559 "output_row"."member_id" := "member_id_p";
2560 "output_row"."member_valid" := TRUE;
2561 "output_row"."participation" := FALSE;
2562 "output_row"."overridden" := FALSE;
2563 "output_row"."disabled_out" := FALSE;
2564 "output_row"."scope_out" := NULL;
2565 LOOP
2566 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2567 "loop_member_id_v" := "output_row"."member_id";
2568 ELSE
2569 "visited_member_ids" :=
2570 "visited_member_ids" || "output_row"."member_id";
2571 END IF;
2572 IF "output_row"."participation" ISNULL THEN
2573 "output_row"."overridden" := NULL;
2574 ELSIF "output_row"."participation" THEN
2575 "output_row"."overridden" := TRUE;
2576 END IF;
2577 "output_row"."scope_in" := "output_row"."scope_out";
2578 "output_row"."member_valid" := EXISTS (
2579 SELECT NULL FROM "member" JOIN "privilege"
2580 ON "privilege"."member_id" = "member"."id"
2581 AND "privilege"."unit_id" = "unit_id_v"
2582 WHERE "id" = "output_row"."member_id"
2583 AND "member"."active" AND "privilege"."voting_right"
2584 );
2585 "simulate_here_v" := (
2586 "simulate_v" AND
2587 "output_row"."member_id" = "member_id_p"
2588 );
2589 "delegation_row" := ROW(NULL);
2590 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2591 IF "scope_v" = 'unit' THEN
2592 IF NOT "simulate_here_v" THEN
2593 SELECT * INTO "delegation_row" FROM "delegation"
2594 WHERE "truster_id" = "output_row"."member_id"
2595 AND "unit_id" = "unit_id_v";
2596 END IF;
2597 ELSIF "scope_v" = 'area' THEN
2598 "output_row"."participation" := EXISTS (
2599 SELECT NULL FROM "membership"
2600 WHERE "area_id" = "area_id_p"
2601 AND "member_id" = "output_row"."member_id"
2602 );
2603 IF "simulate_here_v" THEN
2604 IF "simulate_trustee_id_p" ISNULL THEN
2605 SELECT * INTO "delegation_row" FROM "delegation"
2606 WHERE "truster_id" = "output_row"."member_id"
2607 AND "unit_id" = "unit_id_v";
2608 END IF;
2609 ELSE
2610 SELECT * INTO "delegation_row" FROM "delegation"
2611 WHERE "truster_id" = "output_row"."member_id"
2612 AND (
2613 "unit_id" = "unit_id_v" OR
2614 "area_id" = "area_id_v"
2616 ORDER BY "scope" DESC;
2617 END IF;
2618 ELSIF "scope_v" = 'issue' THEN
2619 IF "issue_row"."fully_frozen" ISNULL THEN
2620 "output_row"."participation" := EXISTS (
2621 SELECT NULL FROM "interest"
2622 WHERE "issue_id" = "issue_id_p"
2623 AND "member_id" = "output_row"."member_id"
2624 );
2625 ELSE
2626 IF "output_row"."member_id" = "member_id_p" THEN
2627 "output_row"."participation" := EXISTS (
2628 SELECT NULL FROM "direct_voter"
2629 WHERE "issue_id" = "issue_id_p"
2630 AND "member_id" = "output_row"."member_id"
2631 );
2632 ELSE
2633 "output_row"."participation" := NULL;
2634 END IF;
2635 END IF;
2636 IF "simulate_here_v" THEN
2637 IF "simulate_trustee_id_p" ISNULL THEN
2638 SELECT * INTO "delegation_row" FROM "delegation"
2639 WHERE "truster_id" = "output_row"."member_id"
2640 AND (
2641 "unit_id" = "unit_id_v" OR
2642 "area_id" = "area_id_v"
2644 ORDER BY "scope" DESC;
2645 END IF;
2646 ELSE
2647 SELECT * INTO "delegation_row" FROM "delegation"
2648 WHERE "truster_id" = "output_row"."member_id"
2649 AND (
2650 "unit_id" = "unit_id_v" OR
2651 "area_id" = "area_id_v" OR
2652 "issue_id" = "issue_id_p"
2654 ORDER BY "scope" DESC;
2655 END IF;
2656 END IF;
2657 ELSE
2658 "output_row"."participation" := FALSE;
2659 END IF;
2660 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2661 "output_row"."scope_out" := "scope_v";
2662 "output_rows" := "output_rows" || "output_row";
2663 "output_row"."member_id" := "simulate_trustee_id_p";
2664 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2665 "output_row"."scope_out" := "delegation_row"."scope";
2666 "output_rows" := "output_rows" || "output_row";
2667 "output_row"."member_id" := "delegation_row"."trustee_id";
2668 ELSIF "delegation_row"."scope" NOTNULL THEN
2669 "output_row"."scope_out" := "delegation_row"."scope";
2670 "output_row"."disabled_out" := TRUE;
2671 "output_rows" := "output_rows" || "output_row";
2672 EXIT;
2673 ELSE
2674 "output_row"."scope_out" := NULL;
2675 "output_rows" := "output_rows" || "output_row";
2676 EXIT;
2677 END IF;
2678 EXIT WHEN "loop_member_id_v" NOTNULL;
2679 "output_row"."index" := "output_row"."index" + 1;
2680 END LOOP;
2681 "row_count" := array_upper("output_rows", 1);
2682 "i" := 1;
2683 "loop_v" := FALSE;
2684 LOOP
2685 "output_row" := "output_rows"["i"];
2686 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2687 IF "loop_v" THEN
2688 IF "i" + 1 = "row_count" THEN
2689 "output_row"."loop" := 'last';
2690 ELSIF "i" = "row_count" THEN
2691 "output_row"."loop" := 'repetition';
2692 ELSE
2693 "output_row"."loop" := 'intermediate';
2694 END IF;
2695 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2696 "output_row"."loop" := 'first';
2697 "loop_v" := TRUE;
2698 END IF;
2699 IF "scope_v" = 'unit' THEN
2700 "output_row"."participation" := NULL;
2701 END IF;
2702 RETURN NEXT "output_row";
2703 "i" := "i" + 1;
2704 END LOOP;
2705 RETURN;
2706 END;
2707 $$;
2709 COMMENT ON FUNCTION "delegation_chain"
2710 ( "member"."id"%TYPE,
2711 "unit"."id"%TYPE,
2712 "area"."id"%TYPE,
2713 "issue"."id"%TYPE,
2714 "member"."id"%TYPE,
2715 BOOLEAN )
2716 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2720 ---------------------------------------------------------
2721 -- Single row returning function for delegation chains --
2722 ---------------------------------------------------------
2725 CREATE TYPE "delegation_info_loop_type" AS ENUM
2726 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2728 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''';
2731 CREATE TYPE "delegation_info_type" AS (
2732 "own_participation" BOOLEAN,
2733 "own_delegation_scope" "delegation_scope",
2734 "first_trustee_id" INT4,
2735 "first_trustee_participation" BOOLEAN,
2736 "first_trustee_ellipsis" BOOLEAN,
2737 "other_trustee_id" INT4,
2738 "other_trustee_participation" BOOLEAN,
2739 "other_trustee_ellipsis" BOOLEAN,
2740 "delegation_loop" "delegation_info_loop_type",
2741 "participating_member_id" INT4 );
2743 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';
2745 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2746 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2747 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2748 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2749 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2750 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2751 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)';
2752 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2753 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';
2754 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2757 CREATE FUNCTION "delegation_info"
2758 ( "member_id_p" "member"."id"%TYPE,
2759 "unit_id_p" "unit"."id"%TYPE,
2760 "area_id_p" "area"."id"%TYPE,
2761 "issue_id_p" "issue"."id"%TYPE,
2762 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2763 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2764 RETURNS "delegation_info_type"
2765 LANGUAGE 'plpgsql' STABLE AS $$
2766 DECLARE
2767 "current_row" "delegation_chain_row";
2768 "result" "delegation_info_type";
2769 BEGIN
2770 "result"."own_participation" := FALSE;
2771 FOR "current_row" IN
2772 SELECT * FROM "delegation_chain"(
2773 "member_id_p",
2774 "unit_id_p", "area_id_p", "issue_id_p",
2775 "simulate_trustee_id_p", "simulate_default_p")
2776 LOOP
2777 IF
2778 "result"."participating_member_id" ISNULL AND
2779 "current_row"."participation"
2780 THEN
2781 "result"."participating_member_id" := "current_row"."member_id";
2782 END IF;
2783 IF "current_row"."member_id" = "member_id_p" THEN
2784 "result"."own_participation" := "current_row"."participation";
2785 "result"."own_delegation_scope" := "current_row"."scope_out";
2786 IF "current_row"."loop" = 'first' THEN
2787 "result"."delegation_loop" := 'own';
2788 END IF;
2789 ELSIF
2790 "current_row"."member_valid" AND
2791 ( "current_row"."loop" ISNULL OR
2792 "current_row"."loop" != 'repetition' )
2793 THEN
2794 IF "result"."first_trustee_id" ISNULL THEN
2795 "result"."first_trustee_id" := "current_row"."member_id";
2796 "result"."first_trustee_participation" := "current_row"."participation";
2797 "result"."first_trustee_ellipsis" := FALSE;
2798 IF "current_row"."loop" = 'first' THEN
2799 "result"."delegation_loop" := 'first';
2800 END IF;
2801 ELSIF "result"."other_trustee_id" ISNULL THEN
2802 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2803 "result"."other_trustee_id" := "current_row"."member_id";
2804 "result"."other_trustee_participation" := TRUE;
2805 "result"."other_trustee_ellipsis" := FALSE;
2806 IF "current_row"."loop" = 'first' THEN
2807 "result"."delegation_loop" := 'other';
2808 END IF;
2809 ELSE
2810 "result"."first_trustee_ellipsis" := TRUE;
2811 IF "current_row"."loop" = 'first' THEN
2812 "result"."delegation_loop" := 'first_ellipsis';
2813 END IF;
2814 END IF;
2815 ELSE
2816 "result"."other_trustee_ellipsis" := TRUE;
2817 IF "current_row"."loop" = 'first' THEN
2818 "result"."delegation_loop" := 'other_ellipsis';
2819 END IF;
2820 END IF;
2821 END IF;
2822 END LOOP;
2823 RETURN "result";
2824 END;
2825 $$;
2827 COMMENT ON FUNCTION "delegation_info"
2828 ( "member"."id"%TYPE,
2829 "unit"."id"%TYPE,
2830 "area"."id"%TYPE,
2831 "issue"."id"%TYPE,
2832 "member"."id"%TYPE,
2833 BOOLEAN )
2834 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2838 ---------------------------
2839 -- Transaction isolation --
2840 ---------------------------
2843 CREATE FUNCTION "require_transaction_isolation"()
2844 RETURNS VOID
2845 LANGUAGE 'plpgsql' VOLATILE AS $$
2846 BEGIN
2847 IF
2848 current_setting('transaction_isolation') NOT IN
2849 ('repeatable read', 'serializable')
2850 THEN
2851 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
2852 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
2853 END IF;
2854 RETURN;
2855 END;
2856 $$;
2858 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
2861 CREATE FUNCTION "dont_require_transaction_isolation"()
2862 RETURNS VOID
2863 LANGUAGE 'plpgsql' VOLATILE AS $$
2864 BEGIN
2865 IF
2866 current_setting('transaction_isolation') IN
2867 ('repeatable read', 'serializable')
2868 THEN
2869 RAISE WARNING 'Unneccessary transaction isolation level: %',
2870 current_setting('transaction_isolation');
2871 END IF;
2872 RETURN;
2873 END;
2874 $$;
2876 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
2880 ------------------------------------------------------------------------
2881 -- Regular tasks, except calculcation of snapshots and voting results --
2882 ------------------------------------------------------------------------
2885 CREATE FUNCTION "check_activity"()
2886 RETURNS VOID
2887 LANGUAGE 'plpgsql' VOLATILE AS $$
2888 DECLARE
2889 "system_setting_row" "system_setting"%ROWTYPE;
2890 BEGIN
2891 PERFORM "dont_require_transaction_isolation"();
2892 SELECT * INTO "system_setting_row" FROM "system_setting";
2893 IF "system_setting_row"."member_ttl" NOTNULL THEN
2894 UPDATE "member" SET "active" = FALSE
2895 WHERE "active" = TRUE
2896 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2897 END IF;
2898 RETURN;
2899 END;
2900 $$;
2902 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2905 CREATE FUNCTION "calculate_member_counts"()
2906 RETURNS VOID
2907 LANGUAGE 'plpgsql' VOLATILE AS $$
2908 BEGIN
2909 PERFORM "require_transaction_isolation"();
2910 DELETE FROM "member_count";
2911 INSERT INTO "member_count" ("total_count")
2912 SELECT "total_count" FROM "member_count_view";
2913 UPDATE "unit" SET "member_count" = "view"."member_count"
2914 FROM "unit_member_count" AS "view"
2915 WHERE "view"."unit_id" = "unit"."id";
2916 UPDATE "area" SET
2917 "direct_member_count" = "view"."direct_member_count",
2918 "member_weight" = "view"."member_weight"
2919 FROM "area_member_count" AS "view"
2920 WHERE "view"."area_id" = "area"."id";
2921 RETURN;
2922 END;
2923 $$;
2925 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"';
2929 ------------------------------------
2930 -- Calculation of harmonic weight --
2931 ------------------------------------
2934 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2935 SELECT
2936 "direct_interest_snapshot"."issue_id",
2937 "direct_interest_snapshot"."event",
2938 "direct_interest_snapshot"."member_id",
2939 "direct_interest_snapshot"."weight" AS "weight_num",
2940 count("initiative"."id") AS "weight_den"
2941 FROM "issue"
2942 JOIN "direct_interest_snapshot"
2943 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
2944 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
2945 JOIN "initiative"
2946 ON "issue"."id" = "initiative"."issue_id"
2947 AND "initiative"."harmonic_weight" ISNULL
2948 JOIN "direct_supporter_snapshot"
2949 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2950 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
2951 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
2952 AND (
2953 "direct_supporter_snapshot"."satisfied" = TRUE OR
2954 coalesce("initiative"."admitted", FALSE) = FALSE
2956 GROUP BY
2957 "direct_interest_snapshot"."issue_id",
2958 "direct_interest_snapshot"."event",
2959 "direct_interest_snapshot"."member_id",
2960 "direct_interest_snapshot"."weight";
2962 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
2965 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
2966 SELECT
2967 "initiative"."issue_id",
2968 "initiative"."id" AS "initiative_id",
2969 "initiative"."admitted",
2970 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
2971 "remaining_harmonic_supporter_weight"."weight_den"
2972 FROM "remaining_harmonic_supporter_weight"
2973 JOIN "initiative"
2974 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
2975 AND "initiative"."harmonic_weight" ISNULL
2976 JOIN "direct_supporter_snapshot"
2977 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2978 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
2979 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
2980 AND (
2981 "direct_supporter_snapshot"."satisfied" = TRUE OR
2982 coalesce("initiative"."admitted", FALSE) = FALSE
2984 GROUP BY
2985 "initiative"."issue_id",
2986 "initiative"."id",
2987 "initiative"."admitted",
2988 "remaining_harmonic_supporter_weight"."weight_den";
2990 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
2993 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
2994 SELECT
2995 "issue_id",
2996 "id" AS "initiative_id",
2997 "admitted",
2998 0 AS "weight_num",
2999 1 AS "weight_den"
3000 FROM "initiative"
3001 WHERE "harmonic_weight" ISNULL;
3003 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';
3006 CREATE FUNCTION "set_harmonic_initiative_weights"
3007 ( "issue_id_p" "issue"."id"%TYPE )
3008 RETURNS VOID
3009 LANGUAGE 'plpgsql' VOLATILE AS $$
3010 DECLARE
3011 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
3012 "i" INT4;
3013 "count_v" INT4;
3014 "summand_v" FLOAT;
3015 "id_ary" INT4[];
3016 "weight_ary" FLOAT[];
3017 "min_weight_v" FLOAT;
3018 BEGIN
3019 PERFORM "require_transaction_isolation"();
3020 UPDATE "initiative" SET "harmonic_weight" = NULL
3021 WHERE "issue_id" = "issue_id_p";
3022 LOOP
3023 "min_weight_v" := NULL;
3024 "i" := 0;
3025 "count_v" := 0;
3026 FOR "weight_row" IN
3027 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
3028 WHERE "issue_id" = "issue_id_p"
3029 AND (
3030 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3031 SELECT NULL FROM "initiative"
3032 WHERE "issue_id" = "issue_id_p"
3033 AND "harmonic_weight" ISNULL
3034 AND coalesce("admitted", FALSE) = FALSE
3037 UNION ALL -- needed for corner cases
3038 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
3039 WHERE "issue_id" = "issue_id_p"
3040 AND (
3041 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3042 SELECT NULL FROM "initiative"
3043 WHERE "issue_id" = "issue_id_p"
3044 AND "harmonic_weight" ISNULL
3045 AND coalesce("admitted", FALSE) = FALSE
3048 ORDER BY "initiative_id" DESC, "weight_den" DESC
3049 -- NOTE: non-admitted initiatives placed first (at last positions),
3050 -- latest initiatives treated worse in case of tie
3051 LOOP
3052 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
3053 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
3054 "i" := "i" + 1;
3055 "count_v" := "i";
3056 "id_ary"["i"] := "weight_row"."initiative_id";
3057 "weight_ary"["i"] := "summand_v";
3058 ELSE
3059 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
3060 END IF;
3061 END LOOP;
3062 EXIT WHEN "count_v" = 0;
3063 "i" := 1;
3064 LOOP
3065 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
3066 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
3067 "min_weight_v" := "weight_ary"["i"];
3068 END IF;
3069 "i" := "i" + 1;
3070 EXIT WHEN "i" > "count_v";
3071 END LOOP;
3072 "i" := 1;
3073 LOOP
3074 IF "weight_ary"["i"] = "min_weight_v" THEN
3075 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
3076 WHERE "id" = "id_ary"["i"];
3077 EXIT;
3078 END IF;
3079 "i" := "i" + 1;
3080 END LOOP;
3081 END LOOP;
3082 UPDATE "initiative" SET "harmonic_weight" = 0
3083 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
3084 END;
3085 $$;
3087 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
3088 ( "issue"."id"%TYPE )
3089 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
3093 ------------------------------
3094 -- Calculation of snapshots --
3095 ------------------------------
3098 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3099 ( "issue_id_p" "issue"."id"%TYPE,
3100 "member_id_p" "member"."id"%TYPE,
3101 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3102 RETURNS "direct_population_snapshot"."weight"%TYPE
3103 LANGUAGE 'plpgsql' VOLATILE AS $$
3104 DECLARE
3105 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3106 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3107 "weight_v" INT4;
3108 "sub_weight_v" INT4;
3109 BEGIN
3110 PERFORM "require_transaction_isolation"();
3111 "weight_v" := 0;
3112 FOR "issue_delegation_row" IN
3113 SELECT * FROM "issue_delegation"
3114 WHERE "trustee_id" = "member_id_p"
3115 AND "issue_id" = "issue_id_p"
3116 LOOP
3117 IF NOT EXISTS (
3118 SELECT NULL FROM "direct_population_snapshot"
3119 WHERE "issue_id" = "issue_id_p"
3120 AND "event" = 'periodic'
3121 AND "member_id" = "issue_delegation_row"."truster_id"
3122 ) AND NOT EXISTS (
3123 SELECT NULL FROM "delegating_population_snapshot"
3124 WHERE "issue_id" = "issue_id_p"
3125 AND "event" = 'periodic'
3126 AND "member_id" = "issue_delegation_row"."truster_id"
3127 ) THEN
3128 "delegate_member_ids_v" :=
3129 "member_id_p" || "delegate_member_ids_p";
3130 INSERT INTO "delegating_population_snapshot" (
3131 "issue_id",
3132 "event",
3133 "member_id",
3134 "scope",
3135 "delegate_member_ids"
3136 ) VALUES (
3137 "issue_id_p",
3138 'periodic',
3139 "issue_delegation_row"."truster_id",
3140 "issue_delegation_row"."scope",
3141 "delegate_member_ids_v"
3142 );
3143 "sub_weight_v" := 1 +
3144 "weight_of_added_delegations_for_population_snapshot"(
3145 "issue_id_p",
3146 "issue_delegation_row"."truster_id",
3147 "delegate_member_ids_v"
3148 );
3149 UPDATE "delegating_population_snapshot"
3150 SET "weight" = "sub_weight_v"
3151 WHERE "issue_id" = "issue_id_p"
3152 AND "event" = 'periodic'
3153 AND "member_id" = "issue_delegation_row"."truster_id";
3154 "weight_v" := "weight_v" + "sub_weight_v";
3155 END IF;
3156 END LOOP;
3157 RETURN "weight_v";
3158 END;
3159 $$;
3161 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3162 ( "issue"."id"%TYPE,
3163 "member"."id"%TYPE,
3164 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3165 IS 'Helper function for "create_population_snapshot" function';
3168 CREATE FUNCTION "create_population_snapshot"
3169 ( "issue_id_p" "issue"."id"%TYPE )
3170 RETURNS VOID
3171 LANGUAGE 'plpgsql' VOLATILE AS $$
3172 DECLARE
3173 "member_id_v" "member"."id"%TYPE;
3174 BEGIN
3175 PERFORM "require_transaction_isolation"();
3176 DELETE FROM "direct_population_snapshot"
3177 WHERE "issue_id" = "issue_id_p"
3178 AND "event" = 'periodic';
3179 DELETE FROM "delegating_population_snapshot"
3180 WHERE "issue_id" = "issue_id_p"
3181 AND "event" = 'periodic';
3182 INSERT INTO "direct_population_snapshot"
3183 ("issue_id", "event", "member_id")
3184 SELECT
3185 "issue_id_p" AS "issue_id",
3186 'periodic'::"snapshot_event" AS "event",
3187 "member"."id" AS "member_id"
3188 FROM "issue"
3189 JOIN "area" ON "issue"."area_id" = "area"."id"
3190 JOIN "membership" ON "area"."id" = "membership"."area_id"
3191 JOIN "member" ON "membership"."member_id" = "member"."id"
3192 JOIN "privilege"
3193 ON "privilege"."unit_id" = "area"."unit_id"
3194 AND "privilege"."member_id" = "member"."id"
3195 WHERE "issue"."id" = "issue_id_p"
3196 AND "member"."active" AND "privilege"."voting_right"
3197 UNION
3198 SELECT
3199 "issue_id_p" AS "issue_id",
3200 'periodic'::"snapshot_event" AS "event",
3201 "member"."id" AS "member_id"
3202 FROM "issue"
3203 JOIN "area" ON "issue"."area_id" = "area"."id"
3204 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3205 JOIN "member" ON "interest"."member_id" = "member"."id"
3206 JOIN "privilege"
3207 ON "privilege"."unit_id" = "area"."unit_id"
3208 AND "privilege"."member_id" = "member"."id"
3209 WHERE "issue"."id" = "issue_id_p"
3210 AND "member"."active" AND "privilege"."voting_right";
3211 FOR "member_id_v" IN
3212 SELECT "member_id" FROM "direct_population_snapshot"
3213 WHERE "issue_id" = "issue_id_p"
3214 AND "event" = 'periodic'
3215 LOOP
3216 UPDATE "direct_population_snapshot" SET
3217 "weight" = 1 +
3218 "weight_of_added_delegations_for_population_snapshot"(
3219 "issue_id_p",
3220 "member_id_v",
3221 '{}'
3223 WHERE "issue_id" = "issue_id_p"
3224 AND "event" = 'periodic'
3225 AND "member_id" = "member_id_v";
3226 END LOOP;
3227 RETURN;
3228 END;
3229 $$;
3231 COMMENT ON FUNCTION "create_population_snapshot"
3232 ( "issue"."id"%TYPE )
3233 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.';
3236 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3237 ( "issue_id_p" "issue"."id"%TYPE,
3238 "member_id_p" "member"."id"%TYPE,
3239 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3240 RETURNS "direct_interest_snapshot"."weight"%TYPE
3241 LANGUAGE 'plpgsql' VOLATILE AS $$
3242 DECLARE
3243 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3244 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3245 "weight_v" INT4;
3246 "sub_weight_v" INT4;
3247 BEGIN
3248 PERFORM "require_transaction_isolation"();
3249 "weight_v" := 0;
3250 FOR "issue_delegation_row" IN
3251 SELECT * FROM "issue_delegation"
3252 WHERE "trustee_id" = "member_id_p"
3253 AND "issue_id" = "issue_id_p"
3254 LOOP
3255 IF NOT EXISTS (
3256 SELECT NULL FROM "direct_interest_snapshot"
3257 WHERE "issue_id" = "issue_id_p"
3258 AND "event" = 'periodic'
3259 AND "member_id" = "issue_delegation_row"."truster_id"
3260 ) AND NOT EXISTS (
3261 SELECT NULL FROM "delegating_interest_snapshot"
3262 WHERE "issue_id" = "issue_id_p"
3263 AND "event" = 'periodic'
3264 AND "member_id" = "issue_delegation_row"."truster_id"
3265 ) THEN
3266 "delegate_member_ids_v" :=
3267 "member_id_p" || "delegate_member_ids_p";
3268 INSERT INTO "delegating_interest_snapshot" (
3269 "issue_id",
3270 "event",
3271 "member_id",
3272 "scope",
3273 "delegate_member_ids"
3274 ) VALUES (
3275 "issue_id_p",
3276 'periodic',
3277 "issue_delegation_row"."truster_id",
3278 "issue_delegation_row"."scope",
3279 "delegate_member_ids_v"
3280 );
3281 "sub_weight_v" := 1 +
3282 "weight_of_added_delegations_for_interest_snapshot"(
3283 "issue_id_p",
3284 "issue_delegation_row"."truster_id",
3285 "delegate_member_ids_v"
3286 );
3287 UPDATE "delegating_interest_snapshot"
3288 SET "weight" = "sub_weight_v"
3289 WHERE "issue_id" = "issue_id_p"
3290 AND "event" = 'periodic'
3291 AND "member_id" = "issue_delegation_row"."truster_id";
3292 "weight_v" := "weight_v" + "sub_weight_v";
3293 END IF;
3294 END LOOP;
3295 RETURN "weight_v";
3296 END;
3297 $$;
3299 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3300 ( "issue"."id"%TYPE,
3301 "member"."id"%TYPE,
3302 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3303 IS 'Helper function for "create_interest_snapshot" function';
3306 CREATE FUNCTION "create_interest_snapshot"
3307 ( "issue_id_p" "issue"."id"%TYPE )
3308 RETURNS VOID
3309 LANGUAGE 'plpgsql' VOLATILE AS $$
3310 DECLARE
3311 "member_id_v" "member"."id"%TYPE;
3312 BEGIN
3313 PERFORM "require_transaction_isolation"();
3314 DELETE FROM "direct_interest_snapshot"
3315 WHERE "issue_id" = "issue_id_p"
3316 AND "event" = 'periodic';
3317 DELETE FROM "delegating_interest_snapshot"
3318 WHERE "issue_id" = "issue_id_p"
3319 AND "event" = 'periodic';
3320 DELETE FROM "direct_supporter_snapshot"
3321 USING "initiative" -- NOTE: due to missing index on issue_id
3322 WHERE "initiative"."issue_id" = "issue_id_p"
3323 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3324 AND "direct_supporter_snapshot"."event" = 'periodic';
3325 INSERT INTO "direct_interest_snapshot"
3326 ("issue_id", "event", "member_id")
3327 SELECT
3328 "issue_id_p" AS "issue_id",
3329 'periodic' 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_interest_snapshot"
3342 WHERE "issue_id" = "issue_id_p"
3343 AND "event" = 'periodic'
3344 LOOP
3345 UPDATE "direct_interest_snapshot" SET
3346 "weight" = 1 +
3347 "weight_of_added_delegations_for_interest_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 INSERT INTO "direct_supporter_snapshot"
3357 ( "issue_id", "initiative_id", "event", "member_id",
3358 "draft_id", "informed", "satisfied" )
3359 SELECT
3360 "issue_id_p" AS "issue_id",
3361 "initiative"."id" AS "initiative_id",
3362 'periodic' AS "event",
3363 "supporter"."member_id" AS "member_id",
3364 "supporter"."draft_id" AS "draft_id",
3365 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3366 NOT EXISTS (
3367 SELECT NULL FROM "critical_opinion"
3368 WHERE "initiative_id" = "initiative"."id"
3369 AND "member_id" = "supporter"."member_id"
3370 ) AS "satisfied"
3371 FROM "initiative"
3372 JOIN "supporter"
3373 ON "supporter"."initiative_id" = "initiative"."id"
3374 JOIN "current_draft"
3375 ON "initiative"."id" = "current_draft"."initiative_id"
3376 JOIN "direct_interest_snapshot"
3377 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3378 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3379 AND "event" = 'periodic'
3380 WHERE "initiative"."issue_id" = "issue_id_p";
3381 RETURN;
3382 END;
3383 $$;
3385 COMMENT ON FUNCTION "create_interest_snapshot"
3386 ( "issue"."id"%TYPE )
3387 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.';
3390 CREATE FUNCTION "create_snapshot"
3391 ( "issue_id_p" "issue"."id"%TYPE )
3392 RETURNS VOID
3393 LANGUAGE 'plpgsql' VOLATILE AS $$
3394 DECLARE
3395 "initiative_id_v" "initiative"."id"%TYPE;
3396 "suggestion_id_v" "suggestion"."id"%TYPE;
3397 BEGIN
3398 PERFORM "require_transaction_isolation"();
3399 PERFORM "create_population_snapshot"("issue_id_p");
3400 PERFORM "create_interest_snapshot"("issue_id_p");
3401 UPDATE "issue" SET
3402 "snapshot" = coalesce("phase_finished", now()),
3403 "latest_snapshot_event" = 'periodic',
3404 "population" = (
3405 SELECT coalesce(sum("weight"), 0)
3406 FROM "direct_population_snapshot"
3407 WHERE "issue_id" = "issue_id_p"
3408 AND "event" = 'periodic'
3410 WHERE "id" = "issue_id_p";
3411 FOR "initiative_id_v" IN
3412 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3413 LOOP
3414 UPDATE "initiative" SET
3415 "supporter_count" = (
3416 SELECT coalesce(sum("di"."weight"), 0)
3417 FROM "direct_interest_snapshot" AS "di"
3418 JOIN "direct_supporter_snapshot" AS "ds"
3419 ON "di"."member_id" = "ds"."member_id"
3420 WHERE "di"."issue_id" = "issue_id_p"
3421 AND "di"."event" = 'periodic'
3422 AND "ds"."initiative_id" = "initiative_id_v"
3423 AND "ds"."event" = 'periodic'
3424 ),
3425 "informed_supporter_count" = (
3426 SELECT coalesce(sum("di"."weight"), 0)
3427 FROM "direct_interest_snapshot" AS "di"
3428 JOIN "direct_supporter_snapshot" AS "ds"
3429 ON "di"."member_id" = "ds"."member_id"
3430 WHERE "di"."issue_id" = "issue_id_p"
3431 AND "di"."event" = 'periodic'
3432 AND "ds"."initiative_id" = "initiative_id_v"
3433 AND "ds"."event" = 'periodic'
3434 AND "ds"."informed"
3435 ),
3436 "satisfied_supporter_count" = (
3437 SELECT coalesce(sum("di"."weight"), 0)
3438 FROM "direct_interest_snapshot" AS "di"
3439 JOIN "direct_supporter_snapshot" AS "ds"
3440 ON "di"."member_id" = "ds"."member_id"
3441 WHERE "di"."issue_id" = "issue_id_p"
3442 AND "di"."event" = 'periodic'
3443 AND "ds"."initiative_id" = "initiative_id_v"
3444 AND "ds"."event" = 'periodic'
3445 AND "ds"."satisfied"
3446 ),
3447 "satisfied_informed_supporter_count" = (
3448 SELECT coalesce(sum("di"."weight"), 0)
3449 FROM "direct_interest_snapshot" AS "di"
3450 JOIN "direct_supporter_snapshot" AS "ds"
3451 ON "di"."member_id" = "ds"."member_id"
3452 WHERE "di"."issue_id" = "issue_id_p"
3453 AND "di"."event" = 'periodic'
3454 AND "ds"."initiative_id" = "initiative_id_v"
3455 AND "ds"."event" = 'periodic'
3456 AND "ds"."informed"
3457 AND "ds"."satisfied"
3459 WHERE "id" = "initiative_id_v";
3460 FOR "suggestion_id_v" IN
3461 SELECT "id" FROM "suggestion"
3462 WHERE "initiative_id" = "initiative_id_v"
3463 LOOP
3464 UPDATE "suggestion" SET
3465 "minus2_unfulfilled_count" = (
3466 SELECT coalesce(sum("snapshot"."weight"), 0)
3467 FROM "issue" CROSS JOIN "opinion"
3468 JOIN "direct_interest_snapshot" AS "snapshot"
3469 ON "snapshot"."issue_id" = "issue"."id"
3470 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3471 AND "snapshot"."member_id" = "opinion"."member_id"
3472 WHERE "issue"."id" = "issue_id_p"
3473 AND "opinion"."suggestion_id" = "suggestion_id_v"
3474 AND "opinion"."degree" = -2
3475 AND "opinion"."fulfilled" = FALSE
3476 ),
3477 "minus2_fulfilled_count" = (
3478 SELECT coalesce(sum("snapshot"."weight"), 0)
3479 FROM "issue" CROSS JOIN "opinion"
3480 JOIN "direct_interest_snapshot" AS "snapshot"
3481 ON "snapshot"."issue_id" = "issue"."id"
3482 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3483 AND "snapshot"."member_id" = "opinion"."member_id"
3484 WHERE "issue"."id" = "issue_id_p"
3485 AND "opinion"."suggestion_id" = "suggestion_id_v"
3486 AND "opinion"."degree" = -2
3487 AND "opinion"."fulfilled" = TRUE
3488 ),
3489 "minus1_unfulfilled_count" = (
3490 SELECT coalesce(sum("snapshot"."weight"), 0)
3491 FROM "issue" CROSS JOIN "opinion"
3492 JOIN "direct_interest_snapshot" AS "snapshot"
3493 ON "snapshot"."issue_id" = "issue"."id"
3494 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3495 AND "snapshot"."member_id" = "opinion"."member_id"
3496 WHERE "issue"."id" = "issue_id_p"
3497 AND "opinion"."suggestion_id" = "suggestion_id_v"
3498 AND "opinion"."degree" = -1
3499 AND "opinion"."fulfilled" = FALSE
3500 ),
3501 "minus1_fulfilled_count" = (
3502 SELECT coalesce(sum("snapshot"."weight"), 0)
3503 FROM "issue" CROSS JOIN "opinion"
3504 JOIN "direct_interest_snapshot" AS "snapshot"
3505 ON "snapshot"."issue_id" = "issue"."id"
3506 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3507 AND "snapshot"."member_id" = "opinion"."member_id"
3508 WHERE "issue"."id" = "issue_id_p"
3509 AND "opinion"."suggestion_id" = "suggestion_id_v"
3510 AND "opinion"."degree" = -1
3511 AND "opinion"."fulfilled" = TRUE
3512 ),
3513 "plus1_unfulfilled_count" = (
3514 SELECT coalesce(sum("snapshot"."weight"), 0)
3515 FROM "issue" CROSS JOIN "opinion"
3516 JOIN "direct_interest_snapshot" AS "snapshot"
3517 ON "snapshot"."issue_id" = "issue"."id"
3518 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3519 AND "snapshot"."member_id" = "opinion"."member_id"
3520 WHERE "issue"."id" = "issue_id_p"
3521 AND "opinion"."suggestion_id" = "suggestion_id_v"
3522 AND "opinion"."degree" = 1
3523 AND "opinion"."fulfilled" = FALSE
3524 ),
3525 "plus1_fulfilled_count" = (
3526 SELECT coalesce(sum("snapshot"."weight"), 0)
3527 FROM "issue" CROSS JOIN "opinion"
3528 JOIN "direct_interest_snapshot" AS "snapshot"
3529 ON "snapshot"."issue_id" = "issue"."id"
3530 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3531 AND "snapshot"."member_id" = "opinion"."member_id"
3532 WHERE "issue"."id" = "issue_id_p"
3533 AND "opinion"."suggestion_id" = "suggestion_id_v"
3534 AND "opinion"."degree" = 1
3535 AND "opinion"."fulfilled" = TRUE
3536 ),
3537 "plus2_unfulfilled_count" = (
3538 SELECT coalesce(sum("snapshot"."weight"), 0)
3539 FROM "issue" CROSS JOIN "opinion"
3540 JOIN "direct_interest_snapshot" AS "snapshot"
3541 ON "snapshot"."issue_id" = "issue"."id"
3542 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3543 AND "snapshot"."member_id" = "opinion"."member_id"
3544 WHERE "issue"."id" = "issue_id_p"
3545 AND "opinion"."suggestion_id" = "suggestion_id_v"
3546 AND "opinion"."degree" = 2
3547 AND "opinion"."fulfilled" = FALSE
3548 ),
3549 "plus2_fulfilled_count" = (
3550 SELECT coalesce(sum("snapshot"."weight"), 0)
3551 FROM "issue" CROSS JOIN "opinion"
3552 JOIN "direct_interest_snapshot" AS "snapshot"
3553 ON "snapshot"."issue_id" = "issue"."id"
3554 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3555 AND "snapshot"."member_id" = "opinion"."member_id"
3556 WHERE "issue"."id" = "issue_id_p"
3557 AND "opinion"."suggestion_id" = "suggestion_id_v"
3558 AND "opinion"."degree" = 2
3559 AND "opinion"."fulfilled" = TRUE
3561 WHERE "suggestion"."id" = "suggestion_id_v";
3562 END LOOP;
3563 END LOOP;
3564 RETURN;
3565 END;
3566 $$;
3568 COMMENT ON FUNCTION "create_snapshot"
3569 ( "issue"."id"%TYPE )
3570 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.';
3573 CREATE FUNCTION "set_snapshot_event"
3574 ( "issue_id_p" "issue"."id"%TYPE,
3575 "event_p" "snapshot_event" )
3576 RETURNS VOID
3577 LANGUAGE 'plpgsql' VOLATILE AS $$
3578 DECLARE
3579 "event_v" "issue"."latest_snapshot_event"%TYPE;
3580 BEGIN
3581 PERFORM "require_transaction_isolation"();
3582 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3583 WHERE "id" = "issue_id_p" FOR UPDATE;
3584 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3585 WHERE "id" = "issue_id_p";
3586 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3587 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3588 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3589 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3590 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3591 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3592 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3593 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3594 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3595 FROM "initiative" -- NOTE: due to missing index on issue_id
3596 WHERE "initiative"."issue_id" = "issue_id_p"
3597 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3598 AND "direct_supporter_snapshot"."event" = "event_v";
3599 RETURN;
3600 END;
3601 $$;
3603 COMMENT ON FUNCTION "set_snapshot_event"
3604 ( "issue"."id"%TYPE,
3605 "snapshot_event" )
3606 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3610 -----------------------
3611 -- Counting of votes --
3612 -----------------------
3615 CREATE FUNCTION "weight_of_added_vote_delegations"
3616 ( "issue_id_p" "issue"."id"%TYPE,
3617 "member_id_p" "member"."id"%TYPE,
3618 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3619 RETURNS "direct_voter"."weight"%TYPE
3620 LANGUAGE 'plpgsql' VOLATILE AS $$
3621 DECLARE
3622 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3623 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3624 "weight_v" INT4;
3625 "sub_weight_v" INT4;
3626 BEGIN
3627 PERFORM "require_transaction_isolation"();
3628 "weight_v" := 0;
3629 FOR "issue_delegation_row" IN
3630 SELECT * FROM "issue_delegation"
3631 WHERE "trustee_id" = "member_id_p"
3632 AND "issue_id" = "issue_id_p"
3633 LOOP
3634 IF NOT EXISTS (
3635 SELECT NULL FROM "direct_voter"
3636 WHERE "member_id" = "issue_delegation_row"."truster_id"
3637 AND "issue_id" = "issue_id_p"
3638 ) AND NOT EXISTS (
3639 SELECT NULL FROM "delegating_voter"
3640 WHERE "member_id" = "issue_delegation_row"."truster_id"
3641 AND "issue_id" = "issue_id_p"
3642 ) THEN
3643 "delegate_member_ids_v" :=
3644 "member_id_p" || "delegate_member_ids_p";
3645 INSERT INTO "delegating_voter" (
3646 "issue_id",
3647 "member_id",
3648 "scope",
3649 "delegate_member_ids"
3650 ) VALUES (
3651 "issue_id_p",
3652 "issue_delegation_row"."truster_id",
3653 "issue_delegation_row"."scope",
3654 "delegate_member_ids_v"
3655 );
3656 "sub_weight_v" := 1 +
3657 "weight_of_added_vote_delegations"(
3658 "issue_id_p",
3659 "issue_delegation_row"."truster_id",
3660 "delegate_member_ids_v"
3661 );
3662 UPDATE "delegating_voter"
3663 SET "weight" = "sub_weight_v"
3664 WHERE "issue_id" = "issue_id_p"
3665 AND "member_id" = "issue_delegation_row"."truster_id";
3666 "weight_v" := "weight_v" + "sub_weight_v";
3667 END IF;
3668 END LOOP;
3669 RETURN "weight_v";
3670 END;
3671 $$;
3673 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3674 ( "issue"."id"%TYPE,
3675 "member"."id"%TYPE,
3676 "delegating_voter"."delegate_member_ids"%TYPE )
3677 IS 'Helper function for "add_vote_delegations" function';
3680 CREATE FUNCTION "add_vote_delegations"
3681 ( "issue_id_p" "issue"."id"%TYPE )
3682 RETURNS VOID
3683 LANGUAGE 'plpgsql' VOLATILE AS $$
3684 DECLARE
3685 "member_id_v" "member"."id"%TYPE;
3686 BEGIN
3687 PERFORM "require_transaction_isolation"();
3688 FOR "member_id_v" IN
3689 SELECT "member_id" FROM "direct_voter"
3690 WHERE "issue_id" = "issue_id_p"
3691 LOOP
3692 UPDATE "direct_voter" SET
3693 "weight" = "weight" + "weight_of_added_vote_delegations"(
3694 "issue_id_p",
3695 "member_id_v",
3696 '{}'
3698 WHERE "member_id" = "member_id_v"
3699 AND "issue_id" = "issue_id_p";
3700 END LOOP;
3701 RETURN;
3702 END;
3703 $$;
3705 COMMENT ON FUNCTION "add_vote_delegations"
3706 ( "issue_id_p" "issue"."id"%TYPE )
3707 IS 'Helper function for "close_voting" function';
3710 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3711 RETURNS VOID
3712 LANGUAGE 'plpgsql' VOLATILE AS $$
3713 DECLARE
3714 "area_id_v" "area"."id"%TYPE;
3715 "unit_id_v" "unit"."id"%TYPE;
3716 "member_id_v" "member"."id"%TYPE;
3717 BEGIN
3718 PERFORM "require_transaction_isolation"();
3719 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3720 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3721 -- override protection triggers:
3722 INSERT INTO "temporary_transaction_data" ("key", "value")
3723 VALUES ('override_protection_triggers', TRUE::TEXT);
3724 -- delete timestamp of voting comment:
3725 UPDATE "direct_voter" SET "comment_changed" = NULL
3726 WHERE "issue_id" = "issue_id_p";
3727 -- delete delegating votes (in cases of manual reset of issue state):
3728 DELETE FROM "delegating_voter"
3729 WHERE "issue_id" = "issue_id_p";
3730 -- delete votes from non-privileged voters:
3731 DELETE FROM "direct_voter"
3732 USING (
3733 SELECT
3734 "direct_voter"."member_id"
3735 FROM "direct_voter"
3736 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3737 LEFT JOIN "privilege"
3738 ON "privilege"."unit_id" = "unit_id_v"
3739 AND "privilege"."member_id" = "direct_voter"."member_id"
3740 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3741 "member"."active" = FALSE OR
3742 "privilege"."voting_right" ISNULL OR
3743 "privilege"."voting_right" = FALSE
3745 ) AS "subquery"
3746 WHERE "direct_voter"."issue_id" = "issue_id_p"
3747 AND "direct_voter"."member_id" = "subquery"."member_id";
3748 -- consider delegations:
3749 UPDATE "direct_voter" SET "weight" = 1
3750 WHERE "issue_id" = "issue_id_p";
3751 PERFORM "add_vote_delegations"("issue_id_p");
3752 -- mark first preferences:
3753 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
3754 FROM (
3755 SELECT
3756 "vote"."initiative_id",
3757 "vote"."member_id",
3758 CASE WHEN "vote"."grade" > 0 THEN
3759 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
3760 ELSE NULL
3761 END AS "first_preference"
3762 FROM "vote"
3763 JOIN "initiative" -- NOTE: due to missing index on issue_id
3764 ON "vote"."issue_id" = "initiative"."issue_id"
3765 JOIN "vote" AS "agg"
3766 ON "initiative"."id" = "agg"."initiative_id"
3767 AND "vote"."member_id" = "agg"."member_id"
3768 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
3769 ) AS "subquery"
3770 WHERE "vote"."issue_id" = "issue_id_p"
3771 AND "vote"."initiative_id" = "subquery"."initiative_id"
3772 AND "vote"."member_id" = "subquery"."member_id";
3773 -- finish overriding protection triggers (avoids garbage):
3774 DELETE FROM "temporary_transaction_data"
3775 WHERE "key" = 'override_protection_triggers';
3776 -- materialize battle_view:
3777 -- NOTE: "closed" column of issue must be set at this point
3778 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3779 INSERT INTO "battle" (
3780 "issue_id",
3781 "winning_initiative_id", "losing_initiative_id",
3782 "count"
3783 ) SELECT
3784 "issue_id",
3785 "winning_initiative_id", "losing_initiative_id",
3786 "count"
3787 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3788 -- set voter count:
3789 UPDATE "issue" SET
3790 "voter_count" = (
3791 SELECT coalesce(sum("weight"), 0)
3792 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3794 WHERE "id" = "issue_id_p";
3795 -- copy "positive_votes" and "negative_votes" from "battle" table:
3796 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
3797 UPDATE "initiative" SET
3798 "first_preference_votes" = 0,
3799 "positive_votes" = "battle_win"."count",
3800 "negative_votes" = "battle_lose"."count"
3801 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3802 WHERE
3803 "battle_win"."issue_id" = "issue_id_p" AND
3804 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3805 "battle_win"."losing_initiative_id" ISNULL AND
3806 "battle_lose"."issue_id" = "issue_id_p" AND
3807 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3808 "battle_lose"."winning_initiative_id" ISNULL;
3809 -- calculate "first_preference_votes":
3810 -- NOTE: will only set values not equal to zero
3811 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
3812 FROM (
3813 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
3814 FROM "vote" JOIN "direct_voter"
3815 ON "vote"."issue_id" = "direct_voter"."issue_id"
3816 AND "vote"."member_id" = "direct_voter"."member_id"
3817 WHERE "vote"."first_preference"
3818 GROUP BY "vote"."initiative_id"
3819 ) AS "subquery"
3820 WHERE "initiative"."issue_id" = "issue_id_p"
3821 AND "initiative"."admitted"
3822 AND "initiative"."id" = "subquery"."initiative_id";
3823 END;
3824 $$;
3826 COMMENT ON FUNCTION "close_voting"
3827 ( "issue"."id"%TYPE )
3828 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.';
3831 CREATE FUNCTION "defeat_strength"
3832 ( "positive_votes_p" INT4,
3833 "negative_votes_p" INT4,
3834 "defeat_strength_p" "defeat_strength" )
3835 RETURNS INT8
3836 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3837 BEGIN
3838 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
3839 IF "positive_votes_p" > "negative_votes_p" THEN
3840 RETURN "positive_votes_p";
3841 ELSE
3842 RETURN 0;
3843 END IF;
3844 ELSE
3845 IF "positive_votes_p" > "negative_votes_p" THEN
3846 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3847 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3848 RETURN 0;
3849 ELSE
3850 RETURN -1;
3851 END IF;
3852 END IF;
3853 END;
3854 $$;
3856 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")';
3859 CREATE FUNCTION "secondary_link_strength"
3860 ( "initiative1_ord_p" INT4,
3861 "initiative2_ord_p" INT4,
3862 "tie_breaking_p" "tie_breaking" )
3863 RETURNS INT8
3864 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3865 BEGIN
3866 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
3867 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
3868 END IF;
3869 RETURN (
3870 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
3872 ELSE
3873 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
3874 1::INT8 << 62
3875 ELSE 0 END
3877 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
3878 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
3879 ELSE
3880 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
3881 END
3882 END
3883 );
3884 END;
3885 $$;
3887 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
3890 CREATE TYPE "link_strength" AS (
3891 "primary" INT8,
3892 "secondary" INT8 );
3894 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'')';
3897 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
3898 RETURNS "link_strength"[][]
3899 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3900 DECLARE
3901 "dimension_v" INT4;
3902 "matrix_p" "link_strength"[][];
3903 "i" INT4;
3904 "j" INT4;
3905 "k" INT4;
3906 BEGIN
3907 "dimension_v" := array_upper("matrix_d", 1);
3908 "matrix_p" := "matrix_d";
3909 "i" := 1;
3910 LOOP
3911 "j" := 1;
3912 LOOP
3913 IF "i" != "j" THEN
3914 "k" := 1;
3915 LOOP
3916 IF "i" != "k" AND "j" != "k" THEN
3917 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
3918 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
3919 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
3920 END IF;
3921 ELSE
3922 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
3923 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
3924 END IF;
3925 END IF;
3926 END IF;
3927 EXIT WHEN "k" = "dimension_v";
3928 "k" := "k" + 1;
3929 END LOOP;
3930 END IF;
3931 EXIT WHEN "j" = "dimension_v";
3932 "j" := "j" + 1;
3933 END LOOP;
3934 EXIT WHEN "i" = "dimension_v";
3935 "i" := "i" + 1;
3936 END LOOP;
3937 RETURN "matrix_p";
3938 END;
3939 $$;
3941 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
3944 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3945 RETURNS VOID
3946 LANGUAGE 'plpgsql' VOLATILE AS $$
3947 DECLARE
3948 "issue_row" "issue"%ROWTYPE;
3949 "policy_row" "policy"%ROWTYPE;
3950 "dimension_v" INT4;
3951 "matrix_a" INT4[][]; -- absolute votes
3952 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
3953 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
3954 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
3955 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
3956 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
3957 "i" INT4;
3958 "j" INT4;
3959 "m" INT4;
3960 "n" INT4;
3961 "battle_row" "battle"%ROWTYPE;
3962 "rank_ary" INT4[];
3963 "rank_v" INT4;
3964 "initiative_id_v" "initiative"."id"%TYPE;
3965 BEGIN
3966 PERFORM "require_transaction_isolation"();
3967 SELECT * INTO "issue_row"
3968 FROM "issue" WHERE "id" = "issue_id_p";
3969 SELECT * INTO "policy_row"
3970 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3971 SELECT count(1) INTO "dimension_v"
3972 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3973 -- create "matrix_a" with absolute number of votes in pairwise
3974 -- comparison:
3975 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3976 "i" := 1;
3977 "j" := 2;
3978 FOR "battle_row" IN
3979 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3980 ORDER BY
3981 "winning_initiative_id" NULLS FIRST,
3982 "losing_initiative_id" NULLS FIRST
3983 LOOP
3984 "matrix_a"["i"]["j"] := "battle_row"."count";
3985 IF "j" = "dimension_v" THEN
3986 "i" := "i" + 1;
3987 "j" := 1;
3988 ELSE
3989 "j" := "j" + 1;
3990 IF "j" = "i" THEN
3991 "j" := "j" + 1;
3992 END IF;
3993 END IF;
3994 END LOOP;
3995 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3996 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3997 END IF;
3998 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
3999 -- and "secondary_link_strength" functions:
4000 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
4001 "i" := 1;
4002 LOOP
4003 "j" := 1;
4004 LOOP
4005 IF "i" != "j" THEN
4006 "matrix_d"["i"]["j"] := (
4007 "defeat_strength"(
4008 "matrix_a"["i"]["j"],
4009 "matrix_a"["j"]["i"],
4010 "policy_row"."defeat_strength"
4011 ),
4012 "secondary_link_strength"(
4013 "i",
4014 "j",
4015 "policy_row"."tie_breaking"
4017 )::"link_strength";
4018 END IF;
4019 EXIT WHEN "j" = "dimension_v";
4020 "j" := "j" + 1;
4021 END LOOP;
4022 EXIT WHEN "i" = "dimension_v";
4023 "i" := "i" + 1;
4024 END LOOP;
4025 -- find best paths:
4026 "matrix_p" := "find_best_paths"("matrix_d");
4027 -- create partial order:
4028 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
4029 "i" := 1;
4030 LOOP
4031 "j" := "i" + 1;
4032 LOOP
4033 IF "i" != "j" THEN
4034 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
4035 "matrix_b"["i"]["j"] := TRUE;
4036 "matrix_b"["j"]["i"] := FALSE;
4037 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
4038 "matrix_b"["i"]["j"] := FALSE;
4039 "matrix_b"["j"]["i"] := TRUE;
4040 END IF;
4041 END IF;
4042 EXIT WHEN "j" = "dimension_v";
4043 "j" := "j" + 1;
4044 END LOOP;
4045 EXIT WHEN "i" = "dimension_v" - 1;
4046 "i" := "i" + 1;
4047 END LOOP;
4048 -- tie-breaking by forbidding shared weakest links in beat-paths
4049 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
4050 -- is performed later by initiative id):
4051 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
4052 "m" := 1;
4053 LOOP
4054 "n" := "m" + 1;
4055 LOOP
4056 -- only process those candidates m and n, which are tied:
4057 IF "matrix_b"["m"]["n"] ISNULL THEN
4058 -- start with beat-paths prior tie-breaking:
4059 "matrix_t" := "matrix_p";
4060 -- start with all links allowed:
4061 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
4062 LOOP
4063 -- determine (and forbid) that link that is the weakest link
4064 -- in both the best path from candidate m to candidate n and
4065 -- from candidate n to candidate m:
4066 "i" := 1;
4067 <<forbid_one_link>>
4068 LOOP
4069 "j" := 1;
4070 LOOP
4071 IF "i" != "j" THEN
4072 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
4073 "matrix_f"["i"]["j"] := TRUE;
4074 -- exit for performance reasons,
4075 -- as exactly one link will be found:
4076 EXIT forbid_one_link;
4077 END IF;
4078 END IF;
4079 EXIT WHEN "j" = "dimension_v";
4080 "j" := "j" + 1;
4081 END LOOP;
4082 IF "i" = "dimension_v" THEN
4083 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
4084 END IF;
4085 "i" := "i" + 1;
4086 END LOOP;
4087 -- calculate best beat-paths while ignoring forbidden links:
4088 "i" := 1;
4089 LOOP
4090 "j" := 1;
4091 LOOP
4092 IF "i" != "j" THEN
4093 "matrix_t"["i"]["j"] := CASE
4094 WHEN "matrix_f"["i"]["j"]
4095 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
4096 ELSE "matrix_d"["i"]["j"] END;
4097 END IF;
4098 EXIT WHEN "j" = "dimension_v";
4099 "j" := "j" + 1;
4100 END LOOP;
4101 EXIT WHEN "i" = "dimension_v";
4102 "i" := "i" + 1;
4103 END LOOP;
4104 "matrix_t" := "find_best_paths"("matrix_t");
4105 -- extend partial order, if tie-breaking was successful:
4106 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
4107 "matrix_b"["m"]["n"] := TRUE;
4108 "matrix_b"["n"]["m"] := FALSE;
4109 EXIT;
4110 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
4111 "matrix_b"["m"]["n"] := FALSE;
4112 "matrix_b"["n"]["m"] := TRUE;
4113 EXIT;
4114 END IF;
4115 END LOOP;
4116 END IF;
4117 EXIT WHEN "n" = "dimension_v";
4118 "n" := "n" + 1;
4119 END LOOP;
4120 EXIT WHEN "m" = "dimension_v" - 1;
4121 "m" := "m" + 1;
4122 END LOOP;
4123 END IF;
4124 -- store a unique ranking in "rank_ary":
4125 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
4126 "rank_v" := 1;
4127 LOOP
4128 "i" := 1;
4129 <<assign_next_rank>>
4130 LOOP
4131 IF "rank_ary"["i"] ISNULL THEN
4132 "j" := 1;
4133 LOOP
4134 IF
4135 "i" != "j" AND
4136 "rank_ary"["j"] ISNULL AND
4137 ( "matrix_b"["j"]["i"] OR
4138 -- tie-breaking by "id"
4139 ( "matrix_b"["j"]["i"] ISNULL AND
4140 "j" < "i" ) )
4141 THEN
4142 -- someone else is better
4143 EXIT;
4144 END IF;
4145 IF "j" = "dimension_v" THEN
4146 -- noone is better
4147 "rank_ary"["i"] := "rank_v";
4148 EXIT assign_next_rank;
4149 END IF;
4150 "j" := "j" + 1;
4151 END LOOP;
4152 END IF;
4153 "i" := "i" + 1;
4154 IF "i" > "dimension_v" THEN
4155 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
4156 END IF;
4157 END LOOP;
4158 EXIT WHEN "rank_v" = "dimension_v";
4159 "rank_v" := "rank_v" + 1;
4160 END LOOP;
4161 -- write preliminary results:
4162 "i" := 2; -- omit status quo with "i" = 1
4163 FOR "initiative_id_v" IN
4164 SELECT "id" FROM "initiative"
4165 WHERE "issue_id" = "issue_id_p" AND "admitted"
4166 ORDER BY "id"
4167 LOOP
4168 UPDATE "initiative" SET
4169 "direct_majority" =
4170 CASE WHEN "policy_row"."direct_majority_strict" THEN
4171 "positive_votes" * "policy_row"."direct_majority_den" >
4172 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4173 ELSE
4174 "positive_votes" * "policy_row"."direct_majority_den" >=
4175 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4176 END
4177 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4178 AND "issue_row"."voter_count"-"negative_votes" >=
4179 "policy_row"."direct_majority_non_negative",
4180 "indirect_majority" =
4181 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4182 "positive_votes" * "policy_row"."indirect_majority_den" >
4183 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4184 ELSE
4185 "positive_votes" * "policy_row"."indirect_majority_den" >=
4186 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4187 END
4188 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4189 AND "issue_row"."voter_count"-"negative_votes" >=
4190 "policy_row"."indirect_majority_non_negative",
4191 "schulze_rank" = "rank_ary"["i"],
4192 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
4193 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
4194 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
4195 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
4196 THEN NULL
4197 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
4198 "eligible" = FALSE,
4199 "winner" = FALSE,
4200 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4201 WHERE "id" = "initiative_id_v";
4202 "i" := "i" + 1;
4203 END LOOP;
4204 IF "i" != "dimension_v" + 1 THEN
4205 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4206 END IF;
4207 -- take indirect majorities into account:
4208 LOOP
4209 UPDATE "initiative" SET "indirect_majority" = TRUE
4210 FROM (
4211 SELECT "new_initiative"."id" AS "initiative_id"
4212 FROM "initiative" "old_initiative"
4213 JOIN "initiative" "new_initiative"
4214 ON "new_initiative"."issue_id" = "issue_id_p"
4215 AND "new_initiative"."indirect_majority" = FALSE
4216 JOIN "battle" "battle_win"
4217 ON "battle_win"."issue_id" = "issue_id_p"
4218 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4219 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4220 JOIN "battle" "battle_lose"
4221 ON "battle_lose"."issue_id" = "issue_id_p"
4222 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4223 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4224 WHERE "old_initiative"."issue_id" = "issue_id_p"
4225 AND "old_initiative"."indirect_majority" = TRUE
4226 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4227 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4228 "policy_row"."indirect_majority_num" *
4229 ("battle_win"."count"+"battle_lose"."count")
4230 ELSE
4231 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4232 "policy_row"."indirect_majority_num" *
4233 ("battle_win"."count"+"battle_lose"."count")
4234 END
4235 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4236 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4237 "policy_row"."indirect_majority_non_negative"
4238 ) AS "subquery"
4239 WHERE "id" = "subquery"."initiative_id";
4240 EXIT WHEN NOT FOUND;
4241 END LOOP;
4242 -- set "multistage_majority" for remaining matching initiatives:
4243 UPDATE "initiative" SET "multistage_majority" = TRUE
4244 FROM (
4245 SELECT "losing_initiative"."id" AS "initiative_id"
4246 FROM "initiative" "losing_initiative"
4247 JOIN "initiative" "winning_initiative"
4248 ON "winning_initiative"."issue_id" = "issue_id_p"
4249 AND "winning_initiative"."admitted"
4250 JOIN "battle" "battle_win"
4251 ON "battle_win"."issue_id" = "issue_id_p"
4252 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4253 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4254 JOIN "battle" "battle_lose"
4255 ON "battle_lose"."issue_id" = "issue_id_p"
4256 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4257 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4258 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4259 AND "losing_initiative"."admitted"
4260 AND "winning_initiative"."schulze_rank" <
4261 "losing_initiative"."schulze_rank"
4262 AND "battle_win"."count" > "battle_lose"."count"
4263 AND (
4264 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4265 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4266 ) AS "subquery"
4267 WHERE "id" = "subquery"."initiative_id";
4268 -- mark eligible initiatives:
4269 UPDATE "initiative" SET "eligible" = TRUE
4270 WHERE "issue_id" = "issue_id_p"
4271 AND "initiative"."direct_majority"
4272 AND "initiative"."indirect_majority"
4273 AND "initiative"."better_than_status_quo"
4274 AND (
4275 "policy_row"."no_multistage_majority" = FALSE OR
4276 "initiative"."multistage_majority" = FALSE )
4277 AND (
4278 "policy_row"."no_reverse_beat_path" = FALSE OR
4279 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
4280 -- mark final winner:
4281 UPDATE "initiative" SET "winner" = TRUE
4282 FROM (
4283 SELECT "id" AS "initiative_id"
4284 FROM "initiative"
4285 WHERE "issue_id" = "issue_id_p" AND "eligible"
4286 ORDER BY
4287 "schulze_rank",
4288 "id"
4289 LIMIT 1
4290 ) AS "subquery"
4291 WHERE "id" = "subquery"."initiative_id";
4292 -- write (final) ranks:
4293 "rank_v" := 1;
4294 FOR "initiative_id_v" IN
4295 SELECT "id"
4296 FROM "initiative"
4297 WHERE "issue_id" = "issue_id_p" AND "admitted"
4298 ORDER BY
4299 "winner" DESC,
4300 "eligible" DESC,
4301 "schulze_rank",
4302 "id"
4303 LOOP
4304 UPDATE "initiative" SET "rank" = "rank_v"
4305 WHERE "id" = "initiative_id_v";
4306 "rank_v" := "rank_v" + 1;
4307 END LOOP;
4308 -- set schulze rank of status quo and mark issue as finished:
4309 UPDATE "issue" SET
4310 "status_quo_schulze_rank" = "rank_ary"[1],
4311 "state" =
4312 CASE WHEN EXISTS (
4313 SELECT NULL FROM "initiative"
4314 WHERE "issue_id" = "issue_id_p" AND "winner"
4315 ) THEN
4316 'finished_with_winner'::"issue_state"
4317 ELSE
4318 'finished_without_winner'::"issue_state"
4319 END,
4320 "closed" = "phase_finished",
4321 "phase_finished" = NULL
4322 WHERE "id" = "issue_id_p";
4323 RETURN;
4324 END;
4325 $$;
4327 COMMENT ON FUNCTION "calculate_ranks"
4328 ( "issue"."id"%TYPE )
4329 IS 'Determine ranking (Votes have to be counted first)';
4333 -----------------------------
4334 -- Automatic state changes --
4335 -----------------------------
4338 CREATE TYPE "check_issue_persistence" AS (
4339 "state" "issue_state",
4340 "phase_finished" BOOLEAN,
4341 "issue_revoked" BOOLEAN,
4342 "snapshot_created" BOOLEAN,
4343 "harmonic_weights_set" BOOLEAN,
4344 "closed_voting" BOOLEAN );
4346 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';
4349 CREATE FUNCTION "check_issue"
4350 ( "issue_id_p" "issue"."id"%TYPE,
4351 "persist" "check_issue_persistence" )
4352 RETURNS "check_issue_persistence"
4353 LANGUAGE 'plpgsql' VOLATILE AS $$
4354 DECLARE
4355 "issue_row" "issue"%ROWTYPE;
4356 "policy_row" "policy"%ROWTYPE;
4357 "initiative_row" "initiative"%ROWTYPE;
4358 "state_v" "issue_state";
4359 BEGIN
4360 PERFORM "require_transaction_isolation"();
4361 IF "persist" ISNULL THEN
4362 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4363 FOR UPDATE;
4364 IF "issue_row"."closed" NOTNULL THEN
4365 RETURN NULL;
4366 END IF;
4367 "persist"."state" := "issue_row"."state";
4368 IF
4369 ( "issue_row"."state" = 'admission' AND now() >=
4370 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
4371 ( "issue_row"."state" = 'discussion' AND now() >=
4372 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4373 ( "issue_row"."state" = 'verification' AND now() >=
4374 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4375 ( "issue_row"."state" = 'voting' AND now() >=
4376 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4377 THEN
4378 "persist"."phase_finished" := TRUE;
4379 ELSE
4380 "persist"."phase_finished" := FALSE;
4381 END IF;
4382 IF
4383 NOT EXISTS (
4384 -- all initiatives are revoked
4385 SELECT NULL FROM "initiative"
4386 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4387 ) AND (
4388 -- and issue has not been accepted yet
4389 "persist"."state" = 'admission' OR
4390 -- or verification time has elapsed
4391 ( "persist"."state" = 'verification' AND
4392 "persist"."phase_finished" ) OR
4393 -- or no initiatives have been revoked lately
4394 NOT EXISTS (
4395 SELECT NULL FROM "initiative"
4396 WHERE "issue_id" = "issue_id_p"
4397 AND now() < "revoked" + "issue_row"."verification_time"
4400 THEN
4401 "persist"."issue_revoked" := TRUE;
4402 ELSE
4403 "persist"."issue_revoked" := FALSE;
4404 END IF;
4405 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4406 UPDATE "issue" SET "phase_finished" = now()
4407 WHERE "id" = "issue_row"."id";
4408 RETURN "persist";
4409 ELSIF
4410 "persist"."state" IN ('admission', 'discussion', 'verification')
4411 THEN
4412 RETURN "persist";
4413 ELSE
4414 RETURN NULL;
4415 END IF;
4416 END IF;
4417 IF
4418 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4419 coalesce("persist"."snapshot_created", FALSE) = FALSE
4420 THEN
4421 PERFORM "create_snapshot"("issue_id_p");
4422 "persist"."snapshot_created" = TRUE;
4423 IF "persist"."phase_finished" THEN
4424 IF "persist"."state" = 'admission' THEN
4425 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4426 ELSIF "persist"."state" = 'discussion' THEN
4427 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4428 ELSIF "persist"."state" = 'verification' THEN
4429 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4430 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4431 SELECT * INTO "policy_row" FROM "policy"
4432 WHERE "id" = "issue_row"."policy_id";
4433 FOR "initiative_row" IN
4434 SELECT * FROM "initiative"
4435 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4436 FOR UPDATE
4437 LOOP
4438 IF
4439 "initiative_row"."polling" OR (
4440 "initiative_row"."satisfied_supporter_count" > 0 AND
4441 "initiative_row"."satisfied_supporter_count" *
4442 "policy_row"."initiative_quorum_den" >=
4443 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4445 THEN
4446 UPDATE "initiative" SET "admitted" = TRUE
4447 WHERE "id" = "initiative_row"."id";
4448 ELSE
4449 UPDATE "initiative" SET "admitted" = FALSE
4450 WHERE "id" = "initiative_row"."id";
4451 END IF;
4452 END LOOP;
4453 END IF;
4454 END IF;
4455 RETURN "persist";
4456 END IF;
4457 IF
4458 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4459 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4460 THEN
4461 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4462 "persist"."harmonic_weights_set" = TRUE;
4463 IF
4464 "persist"."phase_finished" OR
4465 "persist"."issue_revoked" OR
4466 "persist"."state" = 'admission'
4467 THEN
4468 RETURN "persist";
4469 ELSE
4470 RETURN NULL;
4471 END IF;
4472 END IF;
4473 IF "persist"."issue_revoked" THEN
4474 IF "persist"."state" = 'admission' THEN
4475 "state_v" := 'canceled_revoked_before_accepted';
4476 ELSIF "persist"."state" = 'discussion' THEN
4477 "state_v" := 'canceled_after_revocation_during_discussion';
4478 ELSIF "persist"."state" = 'verification' THEN
4479 "state_v" := 'canceled_after_revocation_during_verification';
4480 END IF;
4481 UPDATE "issue" SET
4482 "state" = "state_v",
4483 "closed" = "phase_finished",
4484 "phase_finished" = NULL
4485 WHERE "id" = "issue_id_p";
4486 RETURN NULL;
4487 END IF;
4488 IF "persist"."state" = 'admission' THEN
4489 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4490 FOR UPDATE;
4491 SELECT * INTO "policy_row"
4492 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4493 IF
4494 ( now() >=
4495 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
4496 EXISTS (
4497 SELECT NULL FROM "initiative"
4498 WHERE "issue_id" = "issue_id_p"
4499 AND "supporter_count" > 0
4500 AND "supporter_count" * "policy_row"."issue_quorum_den"
4501 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4503 THEN
4504 UPDATE "issue" SET
4505 "state" = 'discussion',
4506 "accepted" = coalesce("phase_finished", now()),
4507 "phase_finished" = NULL
4508 WHERE "id" = "issue_id_p";
4509 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4510 UPDATE "issue" SET
4511 "state" = 'canceled_issue_not_accepted',
4512 "closed" = "phase_finished",
4513 "phase_finished" = NULL
4514 WHERE "id" = "issue_id_p";
4515 END IF;
4516 RETURN NULL;
4517 END IF;
4518 IF "persist"."phase_finished" THEN
4519 IF "persist"."state" = 'discussion' THEN
4520 UPDATE "issue" SET
4521 "state" = 'verification',
4522 "half_frozen" = "phase_finished",
4523 "phase_finished" = NULL
4524 WHERE "id" = "issue_id_p";
4525 RETURN NULL;
4526 END IF;
4527 IF "persist"."state" = 'verification' THEN
4528 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4529 FOR UPDATE;
4530 SELECT * INTO "policy_row" FROM "policy"
4531 WHERE "id" = "issue_row"."policy_id";
4532 IF EXISTS (
4533 SELECT NULL FROM "initiative"
4534 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4535 ) THEN
4536 UPDATE "issue" SET
4537 "state" = 'voting',
4538 "fully_frozen" = "phase_finished",
4539 "phase_finished" = NULL
4540 WHERE "id" = "issue_id_p";
4541 ELSE
4542 UPDATE "issue" SET
4543 "state" = 'canceled_no_initiative_admitted',
4544 "fully_frozen" = "phase_finished",
4545 "closed" = "phase_finished",
4546 "phase_finished" = NULL
4547 WHERE "id" = "issue_id_p";
4548 -- NOTE: The following DELETE statements have effect only when
4549 -- issue state has been manipulated
4550 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4551 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4552 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4553 END IF;
4554 RETURN NULL;
4555 END IF;
4556 IF "persist"."state" = 'voting' THEN
4557 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4558 PERFORM "close_voting"("issue_id_p");
4559 "persist"."closed_voting" = TRUE;
4560 RETURN "persist";
4561 END IF;
4562 PERFORM "calculate_ranks"("issue_id_p");
4563 RETURN NULL;
4564 END IF;
4565 END IF;
4566 RAISE WARNING 'should not happen';
4567 RETURN NULL;
4568 END;
4569 $$;
4571 COMMENT ON FUNCTION "check_issue"
4572 ( "issue"."id"%TYPE,
4573 "check_issue_persistence" )
4574 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")';
4577 CREATE FUNCTION "check_everything"()
4578 RETURNS VOID
4579 LANGUAGE 'plpgsql' VOLATILE AS $$
4580 DECLARE
4581 "issue_id_v" "issue"."id"%TYPE;
4582 "persist_v" "check_issue_persistence";
4583 BEGIN
4584 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4585 DELETE FROM "expired_session";
4586 PERFORM "check_activity"();
4587 PERFORM "calculate_member_counts"();
4588 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4589 "persist_v" := NULL;
4590 LOOP
4591 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4592 EXIT WHEN "persist_v" ISNULL;
4593 END LOOP;
4594 END LOOP;
4595 RETURN;
4596 END;
4597 $$;
4599 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.';
4603 ----------------------
4604 -- Deletion of data --
4605 ----------------------
4608 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4609 RETURNS VOID
4610 LANGUAGE 'plpgsql' VOLATILE AS $$
4611 BEGIN
4612 IF EXISTS (
4613 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
4614 ) THEN
4615 -- override protection triggers:
4616 INSERT INTO "temporary_transaction_data" ("key", "value")
4617 VALUES ('override_protection_triggers', TRUE::TEXT);
4618 -- clean data:
4619 DELETE FROM "delegating_voter"
4620 WHERE "issue_id" = "issue_id_p";
4621 DELETE FROM "direct_voter"
4622 WHERE "issue_id" = "issue_id_p";
4623 DELETE FROM "delegating_interest_snapshot"
4624 WHERE "issue_id" = "issue_id_p";
4625 DELETE FROM "direct_interest_snapshot"
4626 WHERE "issue_id" = "issue_id_p";
4627 DELETE FROM "delegating_population_snapshot"
4628 WHERE "issue_id" = "issue_id_p";
4629 DELETE FROM "direct_population_snapshot"
4630 WHERE "issue_id" = "issue_id_p";
4631 DELETE FROM "non_voter"
4632 WHERE "issue_id" = "issue_id_p";
4633 DELETE FROM "delegation"
4634 WHERE "issue_id" = "issue_id_p";
4635 DELETE FROM "supporter"
4636 USING "initiative" -- NOTE: due to missing index on issue_id
4637 WHERE "initiative"."issue_id" = "issue_id_p"
4638 AND "supporter"."initiative_id" = "initiative_id";
4639 -- mark issue as cleaned:
4640 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
4641 -- finish overriding protection triggers (avoids garbage):
4642 DELETE FROM "temporary_transaction_data"
4643 WHERE "key" = 'override_protection_triggers';
4644 END IF;
4645 RETURN;
4646 END;
4647 $$;
4649 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4652 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4653 RETURNS VOID
4654 LANGUAGE 'plpgsql' VOLATILE AS $$
4655 BEGIN
4656 UPDATE "member" SET
4657 "last_login" = NULL,
4658 "last_delegation_check" = NULL,
4659 "login" = NULL,
4660 "password" = NULL,
4661 "authority" = NULL,
4662 "authority_uid" = NULL,
4663 "authority_login" = NULL,
4664 "locked" = TRUE,
4665 "active" = FALSE,
4666 "notify_email" = NULL,
4667 "notify_email_unconfirmed" = NULL,
4668 "notify_email_secret" = NULL,
4669 "notify_email_secret_expiry" = NULL,
4670 "notify_email_lock_expiry" = NULL,
4671 "login_recovery_expiry" = NULL,
4672 "password_reset_secret" = NULL,
4673 "password_reset_secret_expiry" = NULL,
4674 "organizational_unit" = NULL,
4675 "internal_posts" = NULL,
4676 "realname" = NULL,
4677 "birthday" = NULL,
4678 "address" = NULL,
4679 "email" = NULL,
4680 "xmpp_address" = NULL,
4681 "website" = NULL,
4682 "phone" = NULL,
4683 "mobile_phone" = NULL,
4684 "profession" = NULL,
4685 "external_memberships" = NULL,
4686 "external_posts" = NULL,
4687 "statement" = NULL
4688 WHERE "id" = "member_id_p";
4689 -- "text_search_data" is updated by triggers
4690 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4691 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4692 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4693 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4694 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4695 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4696 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4697 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4698 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4699 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4700 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4701 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4702 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4703 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4704 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4705 DELETE FROM "direct_voter" USING "issue"
4706 WHERE "direct_voter"."issue_id" = "issue"."id"
4707 AND "issue"."closed" ISNULL
4708 AND "member_id" = "member_id_p";
4709 RETURN;
4710 END;
4711 $$;
4713 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)';
4716 CREATE FUNCTION "delete_private_data"()
4717 RETURNS VOID
4718 LANGUAGE 'plpgsql' VOLATILE AS $$
4719 BEGIN
4720 DELETE FROM "temporary_transaction_data";
4721 DELETE FROM "member" WHERE "activated" ISNULL;
4722 UPDATE "member" SET
4723 "invite_code" = NULL,
4724 "invite_code_expiry" = NULL,
4725 "admin_comment" = NULL,
4726 "last_login" = NULL,
4727 "last_delegation_check" = NULL,
4728 "login" = NULL,
4729 "password" = NULL,
4730 "authority" = NULL,
4731 "authority_uid" = NULL,
4732 "authority_login" = NULL,
4733 "lang" = NULL,
4734 "notify_email" = NULL,
4735 "notify_email_unconfirmed" = NULL,
4736 "notify_email_secret" = NULL,
4737 "notify_email_secret_expiry" = NULL,
4738 "notify_email_lock_expiry" = NULL,
4739 "notify_level" = NULL,
4740 "login_recovery_expiry" = NULL,
4741 "password_reset_secret" = NULL,
4742 "password_reset_secret_expiry" = NULL,
4743 "organizational_unit" = NULL,
4744 "internal_posts" = NULL,
4745 "realname" = NULL,
4746 "birthday" = NULL,
4747 "address" = NULL,
4748 "email" = NULL,
4749 "xmpp_address" = NULL,
4750 "website" = NULL,
4751 "phone" = NULL,
4752 "mobile_phone" = NULL,
4753 "profession" = NULL,
4754 "external_memberships" = NULL,
4755 "external_posts" = NULL,
4756 "formatting_engine" = NULL,
4757 "statement" = NULL;
4758 -- "text_search_data" is updated by triggers
4759 DELETE FROM "setting";
4760 DELETE FROM "setting_map";
4761 DELETE FROM "member_relation_setting";
4762 DELETE FROM "member_image";
4763 DELETE FROM "contact";
4764 DELETE FROM "ignored_member";
4765 DELETE FROM "session";
4766 DELETE FROM "area_setting";
4767 DELETE FROM "issue_setting";
4768 DELETE FROM "ignored_initiative";
4769 DELETE FROM "initiative_setting";
4770 DELETE FROM "suggestion_setting";
4771 DELETE FROM "non_voter";
4772 DELETE FROM "direct_voter" USING "issue"
4773 WHERE "direct_voter"."issue_id" = "issue"."id"
4774 AND "issue"."closed" ISNULL;
4775 RETURN;
4776 END;
4777 $$;
4779 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.';
4783 COMMIT;

Impressum / About Us