liquid_feedback_core

view core.sql @ 467:1e7e8b025346

Stub VIEW that selects issues which are to be included in notifications
author jbe
date Sat Mar 26 02:13:42 2016 +0100 (2016-03-26)
parents c6344e3a3c4a
children c39ff9540f4d
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" ( -- TODO: two tables: one for initiatives, one for suggestions
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 -- TODO: DISTINCT needed?
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"';
2396 CREATE VIEW "issues_for_notification" AS
2397 SELECT
2398 "member"."id" AS "member_id",
2399 "issue"."id" AS "issue_id"
2400 FROM "member" CROSS JOIN "issue"
2401 JOIN "area" ON "area"."id" = "issue"."area_id"
2402 LEFT JOIN "privilege"
2403 ON "privilege"."member_id" = "member"."id"
2404 AND "privilege"."unit_id" = "area"."unit_id"
2405 LEFT JOIN "subscription"
2406 ON "subscription"."member_id" = "member"."id"
2407 AND "subscription"."unit_id" = "area"."unit_id"
2408 WHERE
2409 ( "privilege"."initiative_right" OR "privilege"."voting_right" OR
2410 "subscription"."member_id" NOTNULL ); -- TODO: add further conditions
2412 COMMENT ON VIEW "issues_for_notification" IS 'Issues that are considered in notifications sent to the member';
2416 ------------------------------------------------------
2417 -- Row set returning function for delegation chains --
2418 ------------------------------------------------------
2421 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2422 ('first', 'intermediate', 'last', 'repetition');
2424 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2427 CREATE TYPE "delegation_chain_row" AS (
2428 "index" INT4,
2429 "member_id" INT4,
2430 "member_valid" BOOLEAN,
2431 "participation" BOOLEAN,
2432 "overridden" BOOLEAN,
2433 "scope_in" "delegation_scope",
2434 "scope_out" "delegation_scope",
2435 "disabled_out" BOOLEAN,
2436 "loop" "delegation_chain_loop_tag" );
2438 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2440 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2441 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';
2442 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2443 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2444 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2445 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2446 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2449 CREATE FUNCTION "delegation_chain_for_closed_issue"
2450 ( "member_id_p" "member"."id"%TYPE,
2451 "issue_id_p" "issue"."id"%TYPE )
2452 RETURNS SETOF "delegation_chain_row"
2453 LANGUAGE 'plpgsql' STABLE AS $$
2454 DECLARE
2455 "output_row" "delegation_chain_row";
2456 "direct_voter_row" "direct_voter"%ROWTYPE;
2457 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2458 BEGIN
2459 "output_row"."index" := 0;
2460 "output_row"."member_id" := "member_id_p";
2461 "output_row"."member_valid" := TRUE;
2462 "output_row"."participation" := FALSE;
2463 "output_row"."overridden" := FALSE;
2464 "output_row"."disabled_out" := FALSE;
2465 LOOP
2466 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2467 WHERE "issue_id" = "issue_id_p"
2468 AND "member_id" = "output_row"."member_id";
2469 IF "direct_voter_row"."member_id" NOTNULL THEN
2470 "output_row"."participation" := TRUE;
2471 "output_row"."scope_out" := NULL;
2472 "output_row"."disabled_out" := NULL;
2473 RETURN NEXT "output_row";
2474 RETURN;
2475 END IF;
2476 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2477 WHERE "issue_id" = "issue_id_p"
2478 AND "member_id" = "output_row"."member_id";
2479 IF "delegating_voter_row"."member_id" ISNULL THEN
2480 RETURN;
2481 END IF;
2482 "output_row"."scope_out" := "delegating_voter_row"."scope";
2483 RETURN NEXT "output_row";
2484 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2485 "output_row"."scope_in" := "output_row"."scope_out";
2486 END LOOP;
2487 END;
2488 $$;
2490 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2491 ( "member"."id"%TYPE,
2492 "member"."id"%TYPE )
2493 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2496 CREATE FUNCTION "delegation_chain"
2497 ( "member_id_p" "member"."id"%TYPE,
2498 "unit_id_p" "unit"."id"%TYPE,
2499 "area_id_p" "area"."id"%TYPE,
2500 "issue_id_p" "issue"."id"%TYPE,
2501 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2502 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2503 RETURNS SETOF "delegation_chain_row"
2504 LANGUAGE 'plpgsql' STABLE AS $$
2505 DECLARE
2506 "scope_v" "delegation_scope";
2507 "unit_id_v" "unit"."id"%TYPE;
2508 "area_id_v" "area"."id"%TYPE;
2509 "issue_row" "issue"%ROWTYPE;
2510 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2511 "loop_member_id_v" "member"."id"%TYPE;
2512 "output_row" "delegation_chain_row";
2513 "output_rows" "delegation_chain_row"[];
2514 "simulate_v" BOOLEAN;
2515 "simulate_here_v" BOOLEAN;
2516 "delegation_row" "delegation"%ROWTYPE;
2517 "row_count" INT4;
2518 "i" INT4;
2519 "loop_v" BOOLEAN;
2520 BEGIN
2521 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2522 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2523 END IF;
2524 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2525 "simulate_v" := TRUE;
2526 ELSE
2527 "simulate_v" := FALSE;
2528 END IF;
2529 IF
2530 "unit_id_p" NOTNULL AND
2531 "area_id_p" ISNULL AND
2532 "issue_id_p" ISNULL
2533 THEN
2534 "scope_v" := 'unit';
2535 "unit_id_v" := "unit_id_p";
2536 ELSIF
2537 "unit_id_p" ISNULL AND
2538 "area_id_p" NOTNULL AND
2539 "issue_id_p" ISNULL
2540 THEN
2541 "scope_v" := 'area';
2542 "area_id_v" := "area_id_p";
2543 SELECT "unit_id" INTO "unit_id_v"
2544 FROM "area" WHERE "id" = "area_id_v";
2545 ELSIF
2546 "unit_id_p" ISNULL AND
2547 "area_id_p" ISNULL AND
2548 "issue_id_p" NOTNULL
2549 THEN
2550 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2551 IF "issue_row"."id" ISNULL THEN
2552 RETURN;
2553 END IF;
2554 IF "issue_row"."closed" NOTNULL THEN
2555 IF "simulate_v" THEN
2556 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2557 END IF;
2558 FOR "output_row" IN
2559 SELECT * FROM
2560 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2561 LOOP
2562 RETURN NEXT "output_row";
2563 END LOOP;
2564 RETURN;
2565 END IF;
2566 "scope_v" := 'issue';
2567 SELECT "area_id" INTO "area_id_v"
2568 FROM "issue" WHERE "id" = "issue_id_p";
2569 SELECT "unit_id" INTO "unit_id_v"
2570 FROM "area" WHERE "id" = "area_id_v";
2571 ELSE
2572 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2573 END IF;
2574 "visited_member_ids" := '{}';
2575 "loop_member_id_v" := NULL;
2576 "output_rows" := '{}';
2577 "output_row"."index" := 0;
2578 "output_row"."member_id" := "member_id_p";
2579 "output_row"."member_valid" := TRUE;
2580 "output_row"."participation" := FALSE;
2581 "output_row"."overridden" := FALSE;
2582 "output_row"."disabled_out" := FALSE;
2583 "output_row"."scope_out" := NULL;
2584 LOOP
2585 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2586 "loop_member_id_v" := "output_row"."member_id";
2587 ELSE
2588 "visited_member_ids" :=
2589 "visited_member_ids" || "output_row"."member_id";
2590 END IF;
2591 IF "output_row"."participation" ISNULL THEN
2592 "output_row"."overridden" := NULL;
2593 ELSIF "output_row"."participation" THEN
2594 "output_row"."overridden" := TRUE;
2595 END IF;
2596 "output_row"."scope_in" := "output_row"."scope_out";
2597 "output_row"."member_valid" := EXISTS (
2598 SELECT NULL FROM "member" JOIN "privilege"
2599 ON "privilege"."member_id" = "member"."id"
2600 AND "privilege"."unit_id" = "unit_id_v"
2601 WHERE "id" = "output_row"."member_id"
2602 AND "member"."active" AND "privilege"."voting_right"
2603 );
2604 "simulate_here_v" := (
2605 "simulate_v" AND
2606 "output_row"."member_id" = "member_id_p"
2607 );
2608 "delegation_row" := ROW(NULL);
2609 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2610 IF "scope_v" = 'unit' THEN
2611 IF NOT "simulate_here_v" THEN
2612 SELECT * INTO "delegation_row" FROM "delegation"
2613 WHERE "truster_id" = "output_row"."member_id"
2614 AND "unit_id" = "unit_id_v";
2615 END IF;
2616 ELSIF "scope_v" = 'area' THEN
2617 "output_row"."participation" := EXISTS (
2618 SELECT NULL FROM "membership"
2619 WHERE "area_id" = "area_id_p"
2620 AND "member_id" = "output_row"."member_id"
2621 );
2622 IF "simulate_here_v" THEN
2623 IF "simulate_trustee_id_p" ISNULL THEN
2624 SELECT * INTO "delegation_row" FROM "delegation"
2625 WHERE "truster_id" = "output_row"."member_id"
2626 AND "unit_id" = "unit_id_v";
2627 END IF;
2628 ELSE
2629 SELECT * INTO "delegation_row" FROM "delegation"
2630 WHERE "truster_id" = "output_row"."member_id"
2631 AND (
2632 "unit_id" = "unit_id_v" OR
2633 "area_id" = "area_id_v"
2635 ORDER BY "scope" DESC;
2636 END IF;
2637 ELSIF "scope_v" = 'issue' THEN
2638 IF "issue_row"."fully_frozen" ISNULL THEN
2639 "output_row"."participation" := EXISTS (
2640 SELECT NULL FROM "interest"
2641 WHERE "issue_id" = "issue_id_p"
2642 AND "member_id" = "output_row"."member_id"
2643 );
2644 ELSE
2645 IF "output_row"."member_id" = "member_id_p" THEN
2646 "output_row"."participation" := EXISTS (
2647 SELECT NULL FROM "direct_voter"
2648 WHERE "issue_id" = "issue_id_p"
2649 AND "member_id" = "output_row"."member_id"
2650 );
2651 ELSE
2652 "output_row"."participation" := NULL;
2653 END IF;
2654 END IF;
2655 IF "simulate_here_v" THEN
2656 IF "simulate_trustee_id_p" ISNULL THEN
2657 SELECT * INTO "delegation_row" FROM "delegation"
2658 WHERE "truster_id" = "output_row"."member_id"
2659 AND (
2660 "unit_id" = "unit_id_v" OR
2661 "area_id" = "area_id_v"
2663 ORDER BY "scope" DESC;
2664 END IF;
2665 ELSE
2666 SELECT * INTO "delegation_row" FROM "delegation"
2667 WHERE "truster_id" = "output_row"."member_id"
2668 AND (
2669 "unit_id" = "unit_id_v" OR
2670 "area_id" = "area_id_v" OR
2671 "issue_id" = "issue_id_p"
2673 ORDER BY "scope" DESC;
2674 END IF;
2675 END IF;
2676 ELSE
2677 "output_row"."participation" := FALSE;
2678 END IF;
2679 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2680 "output_row"."scope_out" := "scope_v";
2681 "output_rows" := "output_rows" || "output_row";
2682 "output_row"."member_id" := "simulate_trustee_id_p";
2683 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2684 "output_row"."scope_out" := "delegation_row"."scope";
2685 "output_rows" := "output_rows" || "output_row";
2686 "output_row"."member_id" := "delegation_row"."trustee_id";
2687 ELSIF "delegation_row"."scope" NOTNULL THEN
2688 "output_row"."scope_out" := "delegation_row"."scope";
2689 "output_row"."disabled_out" := TRUE;
2690 "output_rows" := "output_rows" || "output_row";
2691 EXIT;
2692 ELSE
2693 "output_row"."scope_out" := NULL;
2694 "output_rows" := "output_rows" || "output_row";
2695 EXIT;
2696 END IF;
2697 EXIT WHEN "loop_member_id_v" NOTNULL;
2698 "output_row"."index" := "output_row"."index" + 1;
2699 END LOOP;
2700 "row_count" := array_upper("output_rows", 1);
2701 "i" := 1;
2702 "loop_v" := FALSE;
2703 LOOP
2704 "output_row" := "output_rows"["i"];
2705 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2706 IF "loop_v" THEN
2707 IF "i" + 1 = "row_count" THEN
2708 "output_row"."loop" := 'last';
2709 ELSIF "i" = "row_count" THEN
2710 "output_row"."loop" := 'repetition';
2711 ELSE
2712 "output_row"."loop" := 'intermediate';
2713 END IF;
2714 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2715 "output_row"."loop" := 'first';
2716 "loop_v" := TRUE;
2717 END IF;
2718 IF "scope_v" = 'unit' THEN
2719 "output_row"."participation" := NULL;
2720 END IF;
2721 RETURN NEXT "output_row";
2722 "i" := "i" + 1;
2723 END LOOP;
2724 RETURN;
2725 END;
2726 $$;
2728 COMMENT ON FUNCTION "delegation_chain"
2729 ( "member"."id"%TYPE,
2730 "unit"."id"%TYPE,
2731 "area"."id"%TYPE,
2732 "issue"."id"%TYPE,
2733 "member"."id"%TYPE,
2734 BOOLEAN )
2735 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2739 ---------------------------------------------------------
2740 -- Single row returning function for delegation chains --
2741 ---------------------------------------------------------
2744 CREATE TYPE "delegation_info_loop_type" AS ENUM
2745 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2747 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''';
2750 CREATE TYPE "delegation_info_type" AS (
2751 "own_participation" BOOLEAN,
2752 "own_delegation_scope" "delegation_scope",
2753 "first_trustee_id" INT4,
2754 "first_trustee_participation" BOOLEAN,
2755 "first_trustee_ellipsis" BOOLEAN,
2756 "other_trustee_id" INT4,
2757 "other_trustee_participation" BOOLEAN,
2758 "other_trustee_ellipsis" BOOLEAN,
2759 "delegation_loop" "delegation_info_loop_type",
2760 "participating_member_id" INT4 );
2762 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';
2764 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2765 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2766 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2767 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2768 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2769 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2770 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)';
2771 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2772 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';
2773 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2776 CREATE FUNCTION "delegation_info"
2777 ( "member_id_p" "member"."id"%TYPE,
2778 "unit_id_p" "unit"."id"%TYPE,
2779 "area_id_p" "area"."id"%TYPE,
2780 "issue_id_p" "issue"."id"%TYPE,
2781 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2782 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2783 RETURNS "delegation_info_type"
2784 LANGUAGE 'plpgsql' STABLE AS $$
2785 DECLARE
2786 "current_row" "delegation_chain_row";
2787 "result" "delegation_info_type";
2788 BEGIN
2789 "result"."own_participation" := FALSE;
2790 FOR "current_row" IN
2791 SELECT * FROM "delegation_chain"(
2792 "member_id_p",
2793 "unit_id_p", "area_id_p", "issue_id_p",
2794 "simulate_trustee_id_p", "simulate_default_p")
2795 LOOP
2796 IF
2797 "result"."participating_member_id" ISNULL AND
2798 "current_row"."participation"
2799 THEN
2800 "result"."participating_member_id" := "current_row"."member_id";
2801 END IF;
2802 IF "current_row"."member_id" = "member_id_p" THEN
2803 "result"."own_participation" := "current_row"."participation";
2804 "result"."own_delegation_scope" := "current_row"."scope_out";
2805 IF "current_row"."loop" = 'first' THEN
2806 "result"."delegation_loop" := 'own';
2807 END IF;
2808 ELSIF
2809 "current_row"."member_valid" AND
2810 ( "current_row"."loop" ISNULL OR
2811 "current_row"."loop" != 'repetition' )
2812 THEN
2813 IF "result"."first_trustee_id" ISNULL THEN
2814 "result"."first_trustee_id" := "current_row"."member_id";
2815 "result"."first_trustee_participation" := "current_row"."participation";
2816 "result"."first_trustee_ellipsis" := FALSE;
2817 IF "current_row"."loop" = 'first' THEN
2818 "result"."delegation_loop" := 'first';
2819 END IF;
2820 ELSIF "result"."other_trustee_id" ISNULL THEN
2821 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2822 "result"."other_trustee_id" := "current_row"."member_id";
2823 "result"."other_trustee_participation" := TRUE;
2824 "result"."other_trustee_ellipsis" := FALSE;
2825 IF "current_row"."loop" = 'first' THEN
2826 "result"."delegation_loop" := 'other';
2827 END IF;
2828 ELSE
2829 "result"."first_trustee_ellipsis" := TRUE;
2830 IF "current_row"."loop" = 'first' THEN
2831 "result"."delegation_loop" := 'first_ellipsis';
2832 END IF;
2833 END IF;
2834 ELSE
2835 "result"."other_trustee_ellipsis" := TRUE;
2836 IF "current_row"."loop" = 'first' THEN
2837 "result"."delegation_loop" := 'other_ellipsis';
2838 END IF;
2839 END IF;
2840 END IF;
2841 END LOOP;
2842 RETURN "result";
2843 END;
2844 $$;
2846 COMMENT ON FUNCTION "delegation_info"
2847 ( "member"."id"%TYPE,
2848 "unit"."id"%TYPE,
2849 "area"."id"%TYPE,
2850 "issue"."id"%TYPE,
2851 "member"."id"%TYPE,
2852 BOOLEAN )
2853 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2857 ---------------------------
2858 -- Transaction isolation --
2859 ---------------------------
2862 CREATE FUNCTION "require_transaction_isolation"()
2863 RETURNS VOID
2864 LANGUAGE 'plpgsql' VOLATILE AS $$
2865 BEGIN
2866 IF
2867 current_setting('transaction_isolation') NOT IN
2868 ('repeatable read', 'serializable')
2869 THEN
2870 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
2871 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
2872 END IF;
2873 RETURN;
2874 END;
2875 $$;
2877 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
2880 CREATE FUNCTION "dont_require_transaction_isolation"()
2881 RETURNS VOID
2882 LANGUAGE 'plpgsql' VOLATILE AS $$
2883 BEGIN
2884 IF
2885 current_setting('transaction_isolation') IN
2886 ('repeatable read', 'serializable')
2887 THEN
2888 RAISE WARNING 'Unneccessary transaction isolation level: %',
2889 current_setting('transaction_isolation');
2890 END IF;
2891 RETURN;
2892 END;
2893 $$;
2895 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
2899 ------------------------------------------------------------------------
2900 -- Regular tasks, except calculcation of snapshots and voting results --
2901 ------------------------------------------------------------------------
2904 CREATE FUNCTION "check_activity"()
2905 RETURNS VOID
2906 LANGUAGE 'plpgsql' VOLATILE AS $$
2907 DECLARE
2908 "system_setting_row" "system_setting"%ROWTYPE;
2909 BEGIN
2910 PERFORM "dont_require_transaction_isolation"();
2911 SELECT * INTO "system_setting_row" FROM "system_setting";
2912 IF "system_setting_row"."member_ttl" NOTNULL THEN
2913 UPDATE "member" SET "active" = FALSE
2914 WHERE "active" = TRUE
2915 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2916 END IF;
2917 RETURN;
2918 END;
2919 $$;
2921 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2924 CREATE FUNCTION "calculate_member_counts"()
2925 RETURNS VOID
2926 LANGUAGE 'plpgsql' VOLATILE AS $$
2927 BEGIN
2928 PERFORM "require_transaction_isolation"();
2929 DELETE FROM "member_count";
2930 INSERT INTO "member_count" ("total_count")
2931 SELECT "total_count" FROM "member_count_view";
2932 UPDATE "unit" SET "member_count" = "view"."member_count"
2933 FROM "unit_member_count" AS "view"
2934 WHERE "view"."unit_id" = "unit"."id";
2935 UPDATE "area" SET
2936 "direct_member_count" = "view"."direct_member_count",
2937 "member_weight" = "view"."member_weight"
2938 FROM "area_member_count" AS "view"
2939 WHERE "view"."area_id" = "area"."id";
2940 RETURN;
2941 END;
2942 $$;
2944 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"';
2948 ------------------------------------
2949 -- Calculation of harmonic weight --
2950 ------------------------------------
2953 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2954 SELECT
2955 "direct_interest_snapshot"."issue_id",
2956 "direct_interest_snapshot"."event",
2957 "direct_interest_snapshot"."member_id",
2958 "direct_interest_snapshot"."weight" AS "weight_num",
2959 count("initiative"."id") AS "weight_den"
2960 FROM "issue"
2961 JOIN "direct_interest_snapshot"
2962 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
2963 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
2964 JOIN "initiative"
2965 ON "issue"."id" = "initiative"."issue_id"
2966 AND "initiative"."harmonic_weight" ISNULL
2967 JOIN "direct_supporter_snapshot"
2968 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2969 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
2970 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
2971 AND (
2972 "direct_supporter_snapshot"."satisfied" = TRUE OR
2973 coalesce("initiative"."admitted", FALSE) = FALSE
2975 GROUP BY
2976 "direct_interest_snapshot"."issue_id",
2977 "direct_interest_snapshot"."event",
2978 "direct_interest_snapshot"."member_id",
2979 "direct_interest_snapshot"."weight";
2981 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
2984 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
2985 SELECT
2986 "initiative"."issue_id",
2987 "initiative"."id" AS "initiative_id",
2988 "initiative"."admitted",
2989 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
2990 "remaining_harmonic_supporter_weight"."weight_den"
2991 FROM "remaining_harmonic_supporter_weight"
2992 JOIN "initiative"
2993 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
2994 AND "initiative"."harmonic_weight" ISNULL
2995 JOIN "direct_supporter_snapshot"
2996 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2997 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
2998 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
2999 AND (
3000 "direct_supporter_snapshot"."satisfied" = TRUE OR
3001 coalesce("initiative"."admitted", FALSE) = FALSE
3003 GROUP BY
3004 "initiative"."issue_id",
3005 "initiative"."id",
3006 "initiative"."admitted",
3007 "remaining_harmonic_supporter_weight"."weight_den";
3009 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
3012 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
3013 SELECT
3014 "issue_id",
3015 "id" AS "initiative_id",
3016 "admitted",
3017 0 AS "weight_num",
3018 1 AS "weight_den"
3019 FROM "initiative"
3020 WHERE "harmonic_weight" ISNULL;
3022 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';
3025 CREATE FUNCTION "set_harmonic_initiative_weights"
3026 ( "issue_id_p" "issue"."id"%TYPE )
3027 RETURNS VOID
3028 LANGUAGE 'plpgsql' VOLATILE AS $$
3029 DECLARE
3030 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
3031 "i" INT4;
3032 "count_v" INT4;
3033 "summand_v" FLOAT;
3034 "id_ary" INT4[];
3035 "weight_ary" FLOAT[];
3036 "min_weight_v" FLOAT;
3037 BEGIN
3038 PERFORM "require_transaction_isolation"();
3039 UPDATE "initiative" SET "harmonic_weight" = NULL
3040 WHERE "issue_id" = "issue_id_p";
3041 LOOP
3042 "min_weight_v" := NULL;
3043 "i" := 0;
3044 "count_v" := 0;
3045 FOR "weight_row" IN
3046 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
3047 WHERE "issue_id" = "issue_id_p"
3048 AND (
3049 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3050 SELECT NULL FROM "initiative"
3051 WHERE "issue_id" = "issue_id_p"
3052 AND "harmonic_weight" ISNULL
3053 AND coalesce("admitted", FALSE) = FALSE
3056 UNION ALL -- needed for corner cases
3057 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
3058 WHERE "issue_id" = "issue_id_p"
3059 AND (
3060 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3061 SELECT NULL FROM "initiative"
3062 WHERE "issue_id" = "issue_id_p"
3063 AND "harmonic_weight" ISNULL
3064 AND coalesce("admitted", FALSE) = FALSE
3067 ORDER BY "initiative_id" DESC, "weight_den" DESC
3068 -- NOTE: non-admitted initiatives placed first (at last positions),
3069 -- latest initiatives treated worse in case of tie
3070 LOOP
3071 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
3072 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
3073 "i" := "i" + 1;
3074 "count_v" := "i";
3075 "id_ary"["i"] := "weight_row"."initiative_id";
3076 "weight_ary"["i"] := "summand_v";
3077 ELSE
3078 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
3079 END IF;
3080 END LOOP;
3081 EXIT WHEN "count_v" = 0;
3082 "i" := 1;
3083 LOOP
3084 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
3085 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
3086 "min_weight_v" := "weight_ary"["i"];
3087 END IF;
3088 "i" := "i" + 1;
3089 EXIT WHEN "i" > "count_v";
3090 END LOOP;
3091 "i" := 1;
3092 LOOP
3093 IF "weight_ary"["i"] = "min_weight_v" THEN
3094 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
3095 WHERE "id" = "id_ary"["i"];
3096 EXIT;
3097 END IF;
3098 "i" := "i" + 1;
3099 END LOOP;
3100 END LOOP;
3101 UPDATE "initiative" SET "harmonic_weight" = 0
3102 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
3103 END;
3104 $$;
3106 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
3107 ( "issue"."id"%TYPE )
3108 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
3112 ------------------------------
3113 -- Calculation of snapshots --
3114 ------------------------------
3117 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3118 ( "issue_id_p" "issue"."id"%TYPE,
3119 "member_id_p" "member"."id"%TYPE,
3120 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3121 RETURNS "direct_population_snapshot"."weight"%TYPE
3122 LANGUAGE 'plpgsql' VOLATILE AS $$
3123 DECLARE
3124 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3125 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3126 "weight_v" INT4;
3127 "sub_weight_v" INT4;
3128 BEGIN
3129 PERFORM "require_transaction_isolation"();
3130 "weight_v" := 0;
3131 FOR "issue_delegation_row" IN
3132 SELECT * FROM "issue_delegation"
3133 WHERE "trustee_id" = "member_id_p"
3134 AND "issue_id" = "issue_id_p"
3135 LOOP
3136 IF NOT EXISTS (
3137 SELECT NULL FROM "direct_population_snapshot"
3138 WHERE "issue_id" = "issue_id_p"
3139 AND "event" = 'periodic'
3140 AND "member_id" = "issue_delegation_row"."truster_id"
3141 ) AND NOT EXISTS (
3142 SELECT NULL FROM "delegating_population_snapshot"
3143 WHERE "issue_id" = "issue_id_p"
3144 AND "event" = 'periodic'
3145 AND "member_id" = "issue_delegation_row"."truster_id"
3146 ) THEN
3147 "delegate_member_ids_v" :=
3148 "member_id_p" || "delegate_member_ids_p";
3149 INSERT INTO "delegating_population_snapshot" (
3150 "issue_id",
3151 "event",
3152 "member_id",
3153 "scope",
3154 "delegate_member_ids"
3155 ) VALUES (
3156 "issue_id_p",
3157 'periodic',
3158 "issue_delegation_row"."truster_id",
3159 "issue_delegation_row"."scope",
3160 "delegate_member_ids_v"
3161 );
3162 "sub_weight_v" := 1 +
3163 "weight_of_added_delegations_for_population_snapshot"(
3164 "issue_id_p",
3165 "issue_delegation_row"."truster_id",
3166 "delegate_member_ids_v"
3167 );
3168 UPDATE "delegating_population_snapshot"
3169 SET "weight" = "sub_weight_v"
3170 WHERE "issue_id" = "issue_id_p"
3171 AND "event" = 'periodic'
3172 AND "member_id" = "issue_delegation_row"."truster_id";
3173 "weight_v" := "weight_v" + "sub_weight_v";
3174 END IF;
3175 END LOOP;
3176 RETURN "weight_v";
3177 END;
3178 $$;
3180 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3181 ( "issue"."id"%TYPE,
3182 "member"."id"%TYPE,
3183 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3184 IS 'Helper function for "create_population_snapshot" function';
3187 CREATE FUNCTION "create_population_snapshot"
3188 ( "issue_id_p" "issue"."id"%TYPE )
3189 RETURNS VOID
3190 LANGUAGE 'plpgsql' VOLATILE AS $$
3191 DECLARE
3192 "member_id_v" "member"."id"%TYPE;
3193 BEGIN
3194 PERFORM "require_transaction_isolation"();
3195 DELETE FROM "direct_population_snapshot"
3196 WHERE "issue_id" = "issue_id_p"
3197 AND "event" = 'periodic';
3198 DELETE FROM "delegating_population_snapshot"
3199 WHERE "issue_id" = "issue_id_p"
3200 AND "event" = 'periodic';
3201 INSERT INTO "direct_population_snapshot"
3202 ("issue_id", "event", "member_id")
3203 SELECT
3204 "issue_id_p" AS "issue_id",
3205 'periodic'::"snapshot_event" AS "event",
3206 "member"."id" AS "member_id"
3207 FROM "issue"
3208 JOIN "area" ON "issue"."area_id" = "area"."id"
3209 JOIN "membership" ON "area"."id" = "membership"."area_id"
3210 JOIN "member" ON "membership"."member_id" = "member"."id"
3211 JOIN "privilege"
3212 ON "privilege"."unit_id" = "area"."unit_id"
3213 AND "privilege"."member_id" = "member"."id"
3214 WHERE "issue"."id" = "issue_id_p"
3215 AND "member"."active" AND "privilege"."voting_right"
3216 UNION
3217 SELECT
3218 "issue_id_p" AS "issue_id",
3219 'periodic'::"snapshot_event" AS "event",
3220 "member"."id" AS "member_id"
3221 FROM "issue"
3222 JOIN "area" ON "issue"."area_id" = "area"."id"
3223 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3224 JOIN "member" ON "interest"."member_id" = "member"."id"
3225 JOIN "privilege"
3226 ON "privilege"."unit_id" = "area"."unit_id"
3227 AND "privilege"."member_id" = "member"."id"
3228 WHERE "issue"."id" = "issue_id_p"
3229 AND "member"."active" AND "privilege"."voting_right";
3230 FOR "member_id_v" IN
3231 SELECT "member_id" FROM "direct_population_snapshot"
3232 WHERE "issue_id" = "issue_id_p"
3233 AND "event" = 'periodic'
3234 LOOP
3235 UPDATE "direct_population_snapshot" SET
3236 "weight" = 1 +
3237 "weight_of_added_delegations_for_population_snapshot"(
3238 "issue_id_p",
3239 "member_id_v",
3240 '{}'
3242 WHERE "issue_id" = "issue_id_p"
3243 AND "event" = 'periodic'
3244 AND "member_id" = "member_id_v";
3245 END LOOP;
3246 RETURN;
3247 END;
3248 $$;
3250 COMMENT ON FUNCTION "create_population_snapshot"
3251 ( "issue"."id"%TYPE )
3252 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.';
3255 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3256 ( "issue_id_p" "issue"."id"%TYPE,
3257 "member_id_p" "member"."id"%TYPE,
3258 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3259 RETURNS "direct_interest_snapshot"."weight"%TYPE
3260 LANGUAGE 'plpgsql' VOLATILE AS $$
3261 DECLARE
3262 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3263 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3264 "weight_v" INT4;
3265 "sub_weight_v" INT4;
3266 BEGIN
3267 PERFORM "require_transaction_isolation"();
3268 "weight_v" := 0;
3269 FOR "issue_delegation_row" IN
3270 SELECT * FROM "issue_delegation"
3271 WHERE "trustee_id" = "member_id_p"
3272 AND "issue_id" = "issue_id_p"
3273 LOOP
3274 IF NOT EXISTS (
3275 SELECT NULL FROM "direct_interest_snapshot"
3276 WHERE "issue_id" = "issue_id_p"
3277 AND "event" = 'periodic'
3278 AND "member_id" = "issue_delegation_row"."truster_id"
3279 ) AND NOT EXISTS (
3280 SELECT NULL FROM "delegating_interest_snapshot"
3281 WHERE "issue_id" = "issue_id_p"
3282 AND "event" = 'periodic'
3283 AND "member_id" = "issue_delegation_row"."truster_id"
3284 ) THEN
3285 "delegate_member_ids_v" :=
3286 "member_id_p" || "delegate_member_ids_p";
3287 INSERT INTO "delegating_interest_snapshot" (
3288 "issue_id",
3289 "event",
3290 "member_id",
3291 "scope",
3292 "delegate_member_ids"
3293 ) VALUES (
3294 "issue_id_p",
3295 'periodic',
3296 "issue_delegation_row"."truster_id",
3297 "issue_delegation_row"."scope",
3298 "delegate_member_ids_v"
3299 );
3300 "sub_weight_v" := 1 +
3301 "weight_of_added_delegations_for_interest_snapshot"(
3302 "issue_id_p",
3303 "issue_delegation_row"."truster_id",
3304 "delegate_member_ids_v"
3305 );
3306 UPDATE "delegating_interest_snapshot"
3307 SET "weight" = "sub_weight_v"
3308 WHERE "issue_id" = "issue_id_p"
3309 AND "event" = 'periodic'
3310 AND "member_id" = "issue_delegation_row"."truster_id";
3311 "weight_v" := "weight_v" + "sub_weight_v";
3312 END IF;
3313 END LOOP;
3314 RETURN "weight_v";
3315 END;
3316 $$;
3318 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3319 ( "issue"."id"%TYPE,
3320 "member"."id"%TYPE,
3321 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3322 IS 'Helper function for "create_interest_snapshot" function';
3325 CREATE FUNCTION "create_interest_snapshot"
3326 ( "issue_id_p" "issue"."id"%TYPE )
3327 RETURNS VOID
3328 LANGUAGE 'plpgsql' VOLATILE AS $$
3329 DECLARE
3330 "member_id_v" "member"."id"%TYPE;
3331 BEGIN
3332 PERFORM "require_transaction_isolation"();
3333 DELETE FROM "direct_interest_snapshot"
3334 WHERE "issue_id" = "issue_id_p"
3335 AND "event" = 'periodic';
3336 DELETE FROM "delegating_interest_snapshot"
3337 WHERE "issue_id" = "issue_id_p"
3338 AND "event" = 'periodic';
3339 DELETE FROM "direct_supporter_snapshot"
3340 USING "initiative" -- NOTE: due to missing index on issue_id
3341 WHERE "initiative"."issue_id" = "issue_id_p"
3342 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3343 AND "direct_supporter_snapshot"."event" = 'periodic';
3344 INSERT INTO "direct_interest_snapshot"
3345 ("issue_id", "event", "member_id")
3346 SELECT
3347 "issue_id_p" AS "issue_id",
3348 'periodic' AS "event",
3349 "member"."id" AS "member_id"
3350 FROM "issue"
3351 JOIN "area" ON "issue"."area_id" = "area"."id"
3352 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3353 JOIN "member" ON "interest"."member_id" = "member"."id"
3354 JOIN "privilege"
3355 ON "privilege"."unit_id" = "area"."unit_id"
3356 AND "privilege"."member_id" = "member"."id"
3357 WHERE "issue"."id" = "issue_id_p"
3358 AND "member"."active" AND "privilege"."voting_right";
3359 FOR "member_id_v" IN
3360 SELECT "member_id" FROM "direct_interest_snapshot"
3361 WHERE "issue_id" = "issue_id_p"
3362 AND "event" = 'periodic'
3363 LOOP
3364 UPDATE "direct_interest_snapshot" SET
3365 "weight" = 1 +
3366 "weight_of_added_delegations_for_interest_snapshot"(
3367 "issue_id_p",
3368 "member_id_v",
3369 '{}'
3371 WHERE "issue_id" = "issue_id_p"
3372 AND "event" = 'periodic'
3373 AND "member_id" = "member_id_v";
3374 END LOOP;
3375 INSERT INTO "direct_supporter_snapshot"
3376 ( "issue_id", "initiative_id", "event", "member_id",
3377 "draft_id", "informed", "satisfied" )
3378 SELECT
3379 "issue_id_p" AS "issue_id",
3380 "initiative"."id" AS "initiative_id",
3381 'periodic' AS "event",
3382 "supporter"."member_id" AS "member_id",
3383 "supporter"."draft_id" AS "draft_id",
3384 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3385 NOT EXISTS (
3386 SELECT NULL FROM "critical_opinion"
3387 WHERE "initiative_id" = "initiative"."id"
3388 AND "member_id" = "supporter"."member_id"
3389 ) AS "satisfied"
3390 FROM "initiative"
3391 JOIN "supporter"
3392 ON "supporter"."initiative_id" = "initiative"."id"
3393 JOIN "current_draft"
3394 ON "initiative"."id" = "current_draft"."initiative_id"
3395 JOIN "direct_interest_snapshot"
3396 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3397 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3398 AND "event" = 'periodic'
3399 WHERE "initiative"."issue_id" = "issue_id_p";
3400 RETURN;
3401 END;
3402 $$;
3404 COMMENT ON FUNCTION "create_interest_snapshot"
3405 ( "issue"."id"%TYPE )
3406 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.';
3409 CREATE FUNCTION "create_snapshot"
3410 ( "issue_id_p" "issue"."id"%TYPE )
3411 RETURNS VOID
3412 LANGUAGE 'plpgsql' VOLATILE AS $$
3413 DECLARE
3414 "initiative_id_v" "initiative"."id"%TYPE;
3415 "suggestion_id_v" "suggestion"."id"%TYPE;
3416 BEGIN
3417 PERFORM "require_transaction_isolation"();
3418 PERFORM "create_population_snapshot"("issue_id_p");
3419 PERFORM "create_interest_snapshot"("issue_id_p");
3420 UPDATE "issue" SET
3421 "snapshot" = coalesce("phase_finished", now()),
3422 "latest_snapshot_event" = 'periodic',
3423 "population" = (
3424 SELECT coalesce(sum("weight"), 0)
3425 FROM "direct_population_snapshot"
3426 WHERE "issue_id" = "issue_id_p"
3427 AND "event" = 'periodic'
3429 WHERE "id" = "issue_id_p";
3430 FOR "initiative_id_v" IN
3431 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3432 LOOP
3433 UPDATE "initiative" SET
3434 "supporter_count" = (
3435 SELECT coalesce(sum("di"."weight"), 0)
3436 FROM "direct_interest_snapshot" AS "di"
3437 JOIN "direct_supporter_snapshot" AS "ds"
3438 ON "di"."member_id" = "ds"."member_id"
3439 WHERE "di"."issue_id" = "issue_id_p"
3440 AND "di"."event" = 'periodic'
3441 AND "ds"."initiative_id" = "initiative_id_v"
3442 AND "ds"."event" = 'periodic'
3443 ),
3444 "informed_supporter_count" = (
3445 SELECT coalesce(sum("di"."weight"), 0)
3446 FROM "direct_interest_snapshot" AS "di"
3447 JOIN "direct_supporter_snapshot" AS "ds"
3448 ON "di"."member_id" = "ds"."member_id"
3449 WHERE "di"."issue_id" = "issue_id_p"
3450 AND "di"."event" = 'periodic'
3451 AND "ds"."initiative_id" = "initiative_id_v"
3452 AND "ds"."event" = 'periodic'
3453 AND "ds"."informed"
3454 ),
3455 "satisfied_supporter_count" = (
3456 SELECT coalesce(sum("di"."weight"), 0)
3457 FROM "direct_interest_snapshot" AS "di"
3458 JOIN "direct_supporter_snapshot" AS "ds"
3459 ON "di"."member_id" = "ds"."member_id"
3460 WHERE "di"."issue_id" = "issue_id_p"
3461 AND "di"."event" = 'periodic'
3462 AND "ds"."initiative_id" = "initiative_id_v"
3463 AND "ds"."event" = 'periodic'
3464 AND "ds"."satisfied"
3465 ),
3466 "satisfied_informed_supporter_count" = (
3467 SELECT coalesce(sum("di"."weight"), 0)
3468 FROM "direct_interest_snapshot" AS "di"
3469 JOIN "direct_supporter_snapshot" AS "ds"
3470 ON "di"."member_id" = "ds"."member_id"
3471 WHERE "di"."issue_id" = "issue_id_p"
3472 AND "di"."event" = 'periodic'
3473 AND "ds"."initiative_id" = "initiative_id_v"
3474 AND "ds"."event" = 'periodic'
3475 AND "ds"."informed"
3476 AND "ds"."satisfied"
3478 WHERE "id" = "initiative_id_v";
3479 FOR "suggestion_id_v" IN
3480 SELECT "id" FROM "suggestion"
3481 WHERE "initiative_id" = "initiative_id_v"
3482 LOOP
3483 UPDATE "suggestion" SET
3484 "minus2_unfulfilled_count" = (
3485 SELECT coalesce(sum("snapshot"."weight"), 0)
3486 FROM "issue" CROSS JOIN "opinion"
3487 JOIN "direct_interest_snapshot" AS "snapshot"
3488 ON "snapshot"."issue_id" = "issue"."id"
3489 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3490 AND "snapshot"."member_id" = "opinion"."member_id"
3491 WHERE "issue"."id" = "issue_id_p"
3492 AND "opinion"."suggestion_id" = "suggestion_id_v"
3493 AND "opinion"."degree" = -2
3494 AND "opinion"."fulfilled" = FALSE
3495 ),
3496 "minus2_fulfilled_count" = (
3497 SELECT coalesce(sum("snapshot"."weight"), 0)
3498 FROM "issue" CROSS JOIN "opinion"
3499 JOIN "direct_interest_snapshot" AS "snapshot"
3500 ON "snapshot"."issue_id" = "issue"."id"
3501 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3502 AND "snapshot"."member_id" = "opinion"."member_id"
3503 WHERE "issue"."id" = "issue_id_p"
3504 AND "opinion"."suggestion_id" = "suggestion_id_v"
3505 AND "opinion"."degree" = -2
3506 AND "opinion"."fulfilled" = TRUE
3507 ),
3508 "minus1_unfulfilled_count" = (
3509 SELECT coalesce(sum("snapshot"."weight"), 0)
3510 FROM "issue" CROSS JOIN "opinion"
3511 JOIN "direct_interest_snapshot" AS "snapshot"
3512 ON "snapshot"."issue_id" = "issue"."id"
3513 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3514 AND "snapshot"."member_id" = "opinion"."member_id"
3515 WHERE "issue"."id" = "issue_id_p"
3516 AND "opinion"."suggestion_id" = "suggestion_id_v"
3517 AND "opinion"."degree" = -1
3518 AND "opinion"."fulfilled" = FALSE
3519 ),
3520 "minus1_fulfilled_count" = (
3521 SELECT coalesce(sum("snapshot"."weight"), 0)
3522 FROM "issue" CROSS JOIN "opinion"
3523 JOIN "direct_interest_snapshot" AS "snapshot"
3524 ON "snapshot"."issue_id" = "issue"."id"
3525 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3526 AND "snapshot"."member_id" = "opinion"."member_id"
3527 WHERE "issue"."id" = "issue_id_p"
3528 AND "opinion"."suggestion_id" = "suggestion_id_v"
3529 AND "opinion"."degree" = -1
3530 AND "opinion"."fulfilled" = TRUE
3531 ),
3532 "plus1_unfulfilled_count" = (
3533 SELECT coalesce(sum("snapshot"."weight"), 0)
3534 FROM "issue" CROSS JOIN "opinion"
3535 JOIN "direct_interest_snapshot" AS "snapshot"
3536 ON "snapshot"."issue_id" = "issue"."id"
3537 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3538 AND "snapshot"."member_id" = "opinion"."member_id"
3539 WHERE "issue"."id" = "issue_id_p"
3540 AND "opinion"."suggestion_id" = "suggestion_id_v"
3541 AND "opinion"."degree" = 1
3542 AND "opinion"."fulfilled" = FALSE
3543 ),
3544 "plus1_fulfilled_count" = (
3545 SELECT coalesce(sum("snapshot"."weight"), 0)
3546 FROM "issue" CROSS JOIN "opinion"
3547 JOIN "direct_interest_snapshot" AS "snapshot"
3548 ON "snapshot"."issue_id" = "issue"."id"
3549 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3550 AND "snapshot"."member_id" = "opinion"."member_id"
3551 WHERE "issue"."id" = "issue_id_p"
3552 AND "opinion"."suggestion_id" = "suggestion_id_v"
3553 AND "opinion"."degree" = 1
3554 AND "opinion"."fulfilled" = TRUE
3555 ),
3556 "plus2_unfulfilled_count" = (
3557 SELECT coalesce(sum("snapshot"."weight"), 0)
3558 FROM "issue" CROSS JOIN "opinion"
3559 JOIN "direct_interest_snapshot" AS "snapshot"
3560 ON "snapshot"."issue_id" = "issue"."id"
3561 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3562 AND "snapshot"."member_id" = "opinion"."member_id"
3563 WHERE "issue"."id" = "issue_id_p"
3564 AND "opinion"."suggestion_id" = "suggestion_id_v"
3565 AND "opinion"."degree" = 2
3566 AND "opinion"."fulfilled" = FALSE
3567 ),
3568 "plus2_fulfilled_count" = (
3569 SELECT coalesce(sum("snapshot"."weight"), 0)
3570 FROM "issue" CROSS JOIN "opinion"
3571 JOIN "direct_interest_snapshot" AS "snapshot"
3572 ON "snapshot"."issue_id" = "issue"."id"
3573 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3574 AND "snapshot"."member_id" = "opinion"."member_id"
3575 WHERE "issue"."id" = "issue_id_p"
3576 AND "opinion"."suggestion_id" = "suggestion_id_v"
3577 AND "opinion"."degree" = 2
3578 AND "opinion"."fulfilled" = TRUE
3580 WHERE "suggestion"."id" = "suggestion_id_v";
3581 END LOOP;
3582 END LOOP;
3583 RETURN;
3584 END;
3585 $$;
3587 COMMENT ON FUNCTION "create_snapshot"
3588 ( "issue"."id"%TYPE )
3589 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.';
3592 CREATE FUNCTION "set_snapshot_event"
3593 ( "issue_id_p" "issue"."id"%TYPE,
3594 "event_p" "snapshot_event" )
3595 RETURNS VOID
3596 LANGUAGE 'plpgsql' VOLATILE AS $$
3597 DECLARE
3598 "event_v" "issue"."latest_snapshot_event"%TYPE;
3599 BEGIN
3600 PERFORM "require_transaction_isolation"();
3601 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3602 WHERE "id" = "issue_id_p" FOR UPDATE;
3603 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3604 WHERE "id" = "issue_id_p";
3605 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3606 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3607 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3608 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3609 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3610 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3611 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3612 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3613 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3614 FROM "initiative" -- NOTE: due to missing index on issue_id
3615 WHERE "initiative"."issue_id" = "issue_id_p"
3616 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3617 AND "direct_supporter_snapshot"."event" = "event_v";
3618 RETURN;
3619 END;
3620 $$;
3622 COMMENT ON FUNCTION "set_snapshot_event"
3623 ( "issue"."id"%TYPE,
3624 "snapshot_event" )
3625 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3629 -----------------------
3630 -- Counting of votes --
3631 -----------------------
3634 CREATE FUNCTION "weight_of_added_vote_delegations"
3635 ( "issue_id_p" "issue"."id"%TYPE,
3636 "member_id_p" "member"."id"%TYPE,
3637 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3638 RETURNS "direct_voter"."weight"%TYPE
3639 LANGUAGE 'plpgsql' VOLATILE AS $$
3640 DECLARE
3641 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3642 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3643 "weight_v" INT4;
3644 "sub_weight_v" INT4;
3645 BEGIN
3646 PERFORM "require_transaction_isolation"();
3647 "weight_v" := 0;
3648 FOR "issue_delegation_row" IN
3649 SELECT * FROM "issue_delegation"
3650 WHERE "trustee_id" = "member_id_p"
3651 AND "issue_id" = "issue_id_p"
3652 LOOP
3653 IF NOT EXISTS (
3654 SELECT NULL FROM "direct_voter"
3655 WHERE "member_id" = "issue_delegation_row"."truster_id"
3656 AND "issue_id" = "issue_id_p"
3657 ) AND NOT EXISTS (
3658 SELECT NULL FROM "delegating_voter"
3659 WHERE "member_id" = "issue_delegation_row"."truster_id"
3660 AND "issue_id" = "issue_id_p"
3661 ) THEN
3662 "delegate_member_ids_v" :=
3663 "member_id_p" || "delegate_member_ids_p";
3664 INSERT INTO "delegating_voter" (
3665 "issue_id",
3666 "member_id",
3667 "scope",
3668 "delegate_member_ids"
3669 ) VALUES (
3670 "issue_id_p",
3671 "issue_delegation_row"."truster_id",
3672 "issue_delegation_row"."scope",
3673 "delegate_member_ids_v"
3674 );
3675 "sub_weight_v" := 1 +
3676 "weight_of_added_vote_delegations"(
3677 "issue_id_p",
3678 "issue_delegation_row"."truster_id",
3679 "delegate_member_ids_v"
3680 );
3681 UPDATE "delegating_voter"
3682 SET "weight" = "sub_weight_v"
3683 WHERE "issue_id" = "issue_id_p"
3684 AND "member_id" = "issue_delegation_row"."truster_id";
3685 "weight_v" := "weight_v" + "sub_weight_v";
3686 END IF;
3687 END LOOP;
3688 RETURN "weight_v";
3689 END;
3690 $$;
3692 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3693 ( "issue"."id"%TYPE,
3694 "member"."id"%TYPE,
3695 "delegating_voter"."delegate_member_ids"%TYPE )
3696 IS 'Helper function for "add_vote_delegations" function';
3699 CREATE FUNCTION "add_vote_delegations"
3700 ( "issue_id_p" "issue"."id"%TYPE )
3701 RETURNS VOID
3702 LANGUAGE 'plpgsql' VOLATILE AS $$
3703 DECLARE
3704 "member_id_v" "member"."id"%TYPE;
3705 BEGIN
3706 PERFORM "require_transaction_isolation"();
3707 FOR "member_id_v" IN
3708 SELECT "member_id" FROM "direct_voter"
3709 WHERE "issue_id" = "issue_id_p"
3710 LOOP
3711 UPDATE "direct_voter" SET
3712 "weight" = "weight" + "weight_of_added_vote_delegations"(
3713 "issue_id_p",
3714 "member_id_v",
3715 '{}'
3717 WHERE "member_id" = "member_id_v"
3718 AND "issue_id" = "issue_id_p";
3719 END LOOP;
3720 RETURN;
3721 END;
3722 $$;
3724 COMMENT ON FUNCTION "add_vote_delegations"
3725 ( "issue_id_p" "issue"."id"%TYPE )
3726 IS 'Helper function for "close_voting" function';
3729 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3730 RETURNS VOID
3731 LANGUAGE 'plpgsql' VOLATILE AS $$
3732 DECLARE
3733 "area_id_v" "area"."id"%TYPE;
3734 "unit_id_v" "unit"."id"%TYPE;
3735 "member_id_v" "member"."id"%TYPE;
3736 BEGIN
3737 PERFORM "require_transaction_isolation"();
3738 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3739 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3740 -- override protection triggers:
3741 INSERT INTO "temporary_transaction_data" ("key", "value")
3742 VALUES ('override_protection_triggers', TRUE::TEXT);
3743 -- delete timestamp of voting comment:
3744 UPDATE "direct_voter" SET "comment_changed" = NULL
3745 WHERE "issue_id" = "issue_id_p";
3746 -- delete delegating votes (in cases of manual reset of issue state):
3747 DELETE FROM "delegating_voter"
3748 WHERE "issue_id" = "issue_id_p";
3749 -- delete votes from non-privileged voters:
3750 DELETE FROM "direct_voter"
3751 USING (
3752 SELECT
3753 "direct_voter"."member_id"
3754 FROM "direct_voter"
3755 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3756 LEFT JOIN "privilege"
3757 ON "privilege"."unit_id" = "unit_id_v"
3758 AND "privilege"."member_id" = "direct_voter"."member_id"
3759 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3760 "member"."active" = FALSE OR
3761 "privilege"."voting_right" ISNULL OR
3762 "privilege"."voting_right" = FALSE
3764 ) AS "subquery"
3765 WHERE "direct_voter"."issue_id" = "issue_id_p"
3766 AND "direct_voter"."member_id" = "subquery"."member_id";
3767 -- consider delegations:
3768 UPDATE "direct_voter" SET "weight" = 1
3769 WHERE "issue_id" = "issue_id_p";
3770 PERFORM "add_vote_delegations"("issue_id_p");
3771 -- mark first preferences:
3772 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
3773 FROM (
3774 SELECT
3775 "vote"."initiative_id",
3776 "vote"."member_id",
3777 CASE WHEN "vote"."grade" > 0 THEN
3778 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
3779 ELSE NULL
3780 END AS "first_preference"
3781 FROM "vote"
3782 JOIN "initiative" -- NOTE: due to missing index on issue_id
3783 ON "vote"."issue_id" = "initiative"."issue_id"
3784 JOIN "vote" AS "agg"
3785 ON "initiative"."id" = "agg"."initiative_id"
3786 AND "vote"."member_id" = "agg"."member_id"
3787 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
3788 ) AS "subquery"
3789 WHERE "vote"."issue_id" = "issue_id_p"
3790 AND "vote"."initiative_id" = "subquery"."initiative_id"
3791 AND "vote"."member_id" = "subquery"."member_id";
3792 -- finish overriding protection triggers (avoids garbage):
3793 DELETE FROM "temporary_transaction_data"
3794 WHERE "key" = 'override_protection_triggers';
3795 -- materialize battle_view:
3796 -- NOTE: "closed" column of issue must be set at this point
3797 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3798 INSERT INTO "battle" (
3799 "issue_id",
3800 "winning_initiative_id", "losing_initiative_id",
3801 "count"
3802 ) SELECT
3803 "issue_id",
3804 "winning_initiative_id", "losing_initiative_id",
3805 "count"
3806 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3807 -- set voter count:
3808 UPDATE "issue" SET
3809 "voter_count" = (
3810 SELECT coalesce(sum("weight"), 0)
3811 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3813 WHERE "id" = "issue_id_p";
3814 -- copy "positive_votes" and "negative_votes" from "battle" table:
3815 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
3816 UPDATE "initiative" SET
3817 "first_preference_votes" = 0,
3818 "positive_votes" = "battle_win"."count",
3819 "negative_votes" = "battle_lose"."count"
3820 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3821 WHERE
3822 "battle_win"."issue_id" = "issue_id_p" AND
3823 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3824 "battle_win"."losing_initiative_id" ISNULL AND
3825 "battle_lose"."issue_id" = "issue_id_p" AND
3826 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3827 "battle_lose"."winning_initiative_id" ISNULL;
3828 -- calculate "first_preference_votes":
3829 -- NOTE: will only set values not equal to zero
3830 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
3831 FROM (
3832 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
3833 FROM "vote" JOIN "direct_voter"
3834 ON "vote"."issue_id" = "direct_voter"."issue_id"
3835 AND "vote"."member_id" = "direct_voter"."member_id"
3836 WHERE "vote"."first_preference"
3837 GROUP BY "vote"."initiative_id"
3838 ) AS "subquery"
3839 WHERE "initiative"."issue_id" = "issue_id_p"
3840 AND "initiative"."admitted"
3841 AND "initiative"."id" = "subquery"."initiative_id";
3842 END;
3843 $$;
3845 COMMENT ON FUNCTION "close_voting"
3846 ( "issue"."id"%TYPE )
3847 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.';
3850 CREATE FUNCTION "defeat_strength"
3851 ( "positive_votes_p" INT4,
3852 "negative_votes_p" INT4,
3853 "defeat_strength_p" "defeat_strength" )
3854 RETURNS INT8
3855 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3856 BEGIN
3857 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
3858 IF "positive_votes_p" > "negative_votes_p" THEN
3859 RETURN "positive_votes_p";
3860 ELSE
3861 RETURN 0;
3862 END IF;
3863 ELSE
3864 IF "positive_votes_p" > "negative_votes_p" THEN
3865 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3866 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3867 RETURN 0;
3868 ELSE
3869 RETURN -1;
3870 END IF;
3871 END IF;
3872 END;
3873 $$;
3875 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")';
3878 CREATE FUNCTION "secondary_link_strength"
3879 ( "initiative1_ord_p" INT4,
3880 "initiative2_ord_p" INT4,
3881 "tie_breaking_p" "tie_breaking" )
3882 RETURNS INT8
3883 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3884 BEGIN
3885 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
3886 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
3887 END IF;
3888 RETURN (
3889 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
3891 ELSE
3892 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
3893 1::INT8 << 62
3894 ELSE 0 END
3896 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
3897 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
3898 ELSE
3899 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
3900 END
3901 END
3902 );
3903 END;
3904 $$;
3906 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
3909 CREATE TYPE "link_strength" AS (
3910 "primary" INT8,
3911 "secondary" INT8 );
3913 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'')';
3916 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
3917 RETURNS "link_strength"[][]
3918 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3919 DECLARE
3920 "dimension_v" INT4;
3921 "matrix_p" "link_strength"[][];
3922 "i" INT4;
3923 "j" INT4;
3924 "k" INT4;
3925 BEGIN
3926 "dimension_v" := array_upper("matrix_d", 1);
3927 "matrix_p" := "matrix_d";
3928 "i" := 1;
3929 LOOP
3930 "j" := 1;
3931 LOOP
3932 IF "i" != "j" THEN
3933 "k" := 1;
3934 LOOP
3935 IF "i" != "k" AND "j" != "k" THEN
3936 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
3937 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
3938 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
3939 END IF;
3940 ELSE
3941 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
3942 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
3943 END IF;
3944 END IF;
3945 END IF;
3946 EXIT WHEN "k" = "dimension_v";
3947 "k" := "k" + 1;
3948 END LOOP;
3949 END IF;
3950 EXIT WHEN "j" = "dimension_v";
3951 "j" := "j" + 1;
3952 END LOOP;
3953 EXIT WHEN "i" = "dimension_v";
3954 "i" := "i" + 1;
3955 END LOOP;
3956 RETURN "matrix_p";
3957 END;
3958 $$;
3960 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
3963 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3964 RETURNS VOID
3965 LANGUAGE 'plpgsql' VOLATILE AS $$
3966 DECLARE
3967 "issue_row" "issue"%ROWTYPE;
3968 "policy_row" "policy"%ROWTYPE;
3969 "dimension_v" INT4;
3970 "matrix_a" INT4[][]; -- absolute votes
3971 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
3972 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
3973 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
3974 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
3975 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
3976 "i" INT4;
3977 "j" INT4;
3978 "m" INT4;
3979 "n" INT4;
3980 "battle_row" "battle"%ROWTYPE;
3981 "rank_ary" INT4[];
3982 "rank_v" INT4;
3983 "initiative_id_v" "initiative"."id"%TYPE;
3984 BEGIN
3985 PERFORM "require_transaction_isolation"();
3986 SELECT * INTO "issue_row"
3987 FROM "issue" WHERE "id" = "issue_id_p";
3988 SELECT * INTO "policy_row"
3989 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3990 SELECT count(1) INTO "dimension_v"
3991 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3992 -- create "matrix_a" with absolute number of votes in pairwise
3993 -- comparison:
3994 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3995 "i" := 1;
3996 "j" := 2;
3997 FOR "battle_row" IN
3998 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3999 ORDER BY
4000 "winning_initiative_id" NULLS FIRST,
4001 "losing_initiative_id" NULLS FIRST
4002 LOOP
4003 "matrix_a"["i"]["j"] := "battle_row"."count";
4004 IF "j" = "dimension_v" THEN
4005 "i" := "i" + 1;
4006 "j" := 1;
4007 ELSE
4008 "j" := "j" + 1;
4009 IF "j" = "i" THEN
4010 "j" := "j" + 1;
4011 END IF;
4012 END IF;
4013 END LOOP;
4014 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
4015 RAISE EXCEPTION 'Wrong battle count (should not happen)';
4016 END IF;
4017 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
4018 -- and "secondary_link_strength" functions:
4019 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
4020 "i" := 1;
4021 LOOP
4022 "j" := 1;
4023 LOOP
4024 IF "i" != "j" THEN
4025 "matrix_d"["i"]["j"] := (
4026 "defeat_strength"(
4027 "matrix_a"["i"]["j"],
4028 "matrix_a"["j"]["i"],
4029 "policy_row"."defeat_strength"
4030 ),
4031 "secondary_link_strength"(
4032 "i",
4033 "j",
4034 "policy_row"."tie_breaking"
4036 )::"link_strength";
4037 END IF;
4038 EXIT WHEN "j" = "dimension_v";
4039 "j" := "j" + 1;
4040 END LOOP;
4041 EXIT WHEN "i" = "dimension_v";
4042 "i" := "i" + 1;
4043 END LOOP;
4044 -- find best paths:
4045 "matrix_p" := "find_best_paths"("matrix_d");
4046 -- create partial order:
4047 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
4048 "i" := 1;
4049 LOOP
4050 "j" := "i" + 1;
4051 LOOP
4052 IF "i" != "j" THEN
4053 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
4054 "matrix_b"["i"]["j"] := TRUE;
4055 "matrix_b"["j"]["i"] := FALSE;
4056 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
4057 "matrix_b"["i"]["j"] := FALSE;
4058 "matrix_b"["j"]["i"] := TRUE;
4059 END IF;
4060 END IF;
4061 EXIT WHEN "j" = "dimension_v";
4062 "j" := "j" + 1;
4063 END LOOP;
4064 EXIT WHEN "i" = "dimension_v" - 1;
4065 "i" := "i" + 1;
4066 END LOOP;
4067 -- tie-breaking by forbidding shared weakest links in beat-paths
4068 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
4069 -- is performed later by initiative id):
4070 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
4071 "m" := 1;
4072 LOOP
4073 "n" := "m" + 1;
4074 LOOP
4075 -- only process those candidates m and n, which are tied:
4076 IF "matrix_b"["m"]["n"] ISNULL THEN
4077 -- start with beat-paths prior tie-breaking:
4078 "matrix_t" := "matrix_p";
4079 -- start with all links allowed:
4080 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
4081 LOOP
4082 -- determine (and forbid) that link that is the weakest link
4083 -- in both the best path from candidate m to candidate n and
4084 -- from candidate n to candidate m:
4085 "i" := 1;
4086 <<forbid_one_link>>
4087 LOOP
4088 "j" := 1;
4089 LOOP
4090 IF "i" != "j" THEN
4091 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
4092 "matrix_f"["i"]["j"] := TRUE;
4093 -- exit for performance reasons,
4094 -- as exactly one link will be found:
4095 EXIT forbid_one_link;
4096 END IF;
4097 END IF;
4098 EXIT WHEN "j" = "dimension_v";
4099 "j" := "j" + 1;
4100 END LOOP;
4101 IF "i" = "dimension_v" THEN
4102 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
4103 END IF;
4104 "i" := "i" + 1;
4105 END LOOP;
4106 -- calculate best beat-paths while ignoring forbidden links:
4107 "i" := 1;
4108 LOOP
4109 "j" := 1;
4110 LOOP
4111 IF "i" != "j" THEN
4112 "matrix_t"["i"]["j"] := CASE
4113 WHEN "matrix_f"["i"]["j"]
4114 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
4115 ELSE "matrix_d"["i"]["j"] END;
4116 END IF;
4117 EXIT WHEN "j" = "dimension_v";
4118 "j" := "j" + 1;
4119 END LOOP;
4120 EXIT WHEN "i" = "dimension_v";
4121 "i" := "i" + 1;
4122 END LOOP;
4123 "matrix_t" := "find_best_paths"("matrix_t");
4124 -- extend partial order, if tie-breaking was successful:
4125 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
4126 "matrix_b"["m"]["n"] := TRUE;
4127 "matrix_b"["n"]["m"] := FALSE;
4128 EXIT;
4129 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
4130 "matrix_b"["m"]["n"] := FALSE;
4131 "matrix_b"["n"]["m"] := TRUE;
4132 EXIT;
4133 END IF;
4134 END LOOP;
4135 END IF;
4136 EXIT WHEN "n" = "dimension_v";
4137 "n" := "n" + 1;
4138 END LOOP;
4139 EXIT WHEN "m" = "dimension_v" - 1;
4140 "m" := "m" + 1;
4141 END LOOP;
4142 END IF;
4143 -- store a unique ranking in "rank_ary":
4144 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
4145 "rank_v" := 1;
4146 LOOP
4147 "i" := 1;
4148 <<assign_next_rank>>
4149 LOOP
4150 IF "rank_ary"["i"] ISNULL THEN
4151 "j" := 1;
4152 LOOP
4153 IF
4154 "i" != "j" AND
4155 "rank_ary"["j"] ISNULL AND
4156 ( "matrix_b"["j"]["i"] OR
4157 -- tie-breaking by "id"
4158 ( "matrix_b"["j"]["i"] ISNULL AND
4159 "j" < "i" ) )
4160 THEN
4161 -- someone else is better
4162 EXIT;
4163 END IF;
4164 IF "j" = "dimension_v" THEN
4165 -- noone is better
4166 "rank_ary"["i"] := "rank_v";
4167 EXIT assign_next_rank;
4168 END IF;
4169 "j" := "j" + 1;
4170 END LOOP;
4171 END IF;
4172 "i" := "i" + 1;
4173 IF "i" > "dimension_v" THEN
4174 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
4175 END IF;
4176 END LOOP;
4177 EXIT WHEN "rank_v" = "dimension_v";
4178 "rank_v" := "rank_v" + 1;
4179 END LOOP;
4180 -- write preliminary results:
4181 "i" := 2; -- omit status quo with "i" = 1
4182 FOR "initiative_id_v" IN
4183 SELECT "id" FROM "initiative"
4184 WHERE "issue_id" = "issue_id_p" AND "admitted"
4185 ORDER BY "id"
4186 LOOP
4187 UPDATE "initiative" SET
4188 "direct_majority" =
4189 CASE WHEN "policy_row"."direct_majority_strict" THEN
4190 "positive_votes" * "policy_row"."direct_majority_den" >
4191 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4192 ELSE
4193 "positive_votes" * "policy_row"."direct_majority_den" >=
4194 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4195 END
4196 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4197 AND "issue_row"."voter_count"-"negative_votes" >=
4198 "policy_row"."direct_majority_non_negative",
4199 "indirect_majority" =
4200 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4201 "positive_votes" * "policy_row"."indirect_majority_den" >
4202 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4203 ELSE
4204 "positive_votes" * "policy_row"."indirect_majority_den" >=
4205 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4206 END
4207 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4208 AND "issue_row"."voter_count"-"negative_votes" >=
4209 "policy_row"."indirect_majority_non_negative",
4210 "schulze_rank" = "rank_ary"["i"],
4211 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
4212 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
4213 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
4214 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
4215 THEN NULL
4216 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
4217 "eligible" = FALSE,
4218 "winner" = FALSE,
4219 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4220 WHERE "id" = "initiative_id_v";
4221 "i" := "i" + 1;
4222 END LOOP;
4223 IF "i" != "dimension_v" + 1 THEN
4224 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4225 END IF;
4226 -- take indirect majorities into account:
4227 LOOP
4228 UPDATE "initiative" SET "indirect_majority" = TRUE
4229 FROM (
4230 SELECT "new_initiative"."id" AS "initiative_id"
4231 FROM "initiative" "old_initiative"
4232 JOIN "initiative" "new_initiative"
4233 ON "new_initiative"."issue_id" = "issue_id_p"
4234 AND "new_initiative"."indirect_majority" = FALSE
4235 JOIN "battle" "battle_win"
4236 ON "battle_win"."issue_id" = "issue_id_p"
4237 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4238 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4239 JOIN "battle" "battle_lose"
4240 ON "battle_lose"."issue_id" = "issue_id_p"
4241 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4242 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4243 WHERE "old_initiative"."issue_id" = "issue_id_p"
4244 AND "old_initiative"."indirect_majority" = TRUE
4245 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4246 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4247 "policy_row"."indirect_majority_num" *
4248 ("battle_win"."count"+"battle_lose"."count")
4249 ELSE
4250 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4251 "policy_row"."indirect_majority_num" *
4252 ("battle_win"."count"+"battle_lose"."count")
4253 END
4254 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4255 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4256 "policy_row"."indirect_majority_non_negative"
4257 ) AS "subquery"
4258 WHERE "id" = "subquery"."initiative_id";
4259 EXIT WHEN NOT FOUND;
4260 END LOOP;
4261 -- set "multistage_majority" for remaining matching initiatives:
4262 UPDATE "initiative" SET "multistage_majority" = TRUE
4263 FROM (
4264 SELECT "losing_initiative"."id" AS "initiative_id"
4265 FROM "initiative" "losing_initiative"
4266 JOIN "initiative" "winning_initiative"
4267 ON "winning_initiative"."issue_id" = "issue_id_p"
4268 AND "winning_initiative"."admitted"
4269 JOIN "battle" "battle_win"
4270 ON "battle_win"."issue_id" = "issue_id_p"
4271 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4272 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4273 JOIN "battle" "battle_lose"
4274 ON "battle_lose"."issue_id" = "issue_id_p"
4275 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4276 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4277 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4278 AND "losing_initiative"."admitted"
4279 AND "winning_initiative"."schulze_rank" <
4280 "losing_initiative"."schulze_rank"
4281 AND "battle_win"."count" > "battle_lose"."count"
4282 AND (
4283 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4284 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4285 ) AS "subquery"
4286 WHERE "id" = "subquery"."initiative_id";
4287 -- mark eligible initiatives:
4288 UPDATE "initiative" SET "eligible" = TRUE
4289 WHERE "issue_id" = "issue_id_p"
4290 AND "initiative"."direct_majority"
4291 AND "initiative"."indirect_majority"
4292 AND "initiative"."better_than_status_quo"
4293 AND (
4294 "policy_row"."no_multistage_majority" = FALSE OR
4295 "initiative"."multistage_majority" = FALSE )
4296 AND (
4297 "policy_row"."no_reverse_beat_path" = FALSE OR
4298 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
4299 -- mark final winner:
4300 UPDATE "initiative" SET "winner" = TRUE
4301 FROM (
4302 SELECT "id" AS "initiative_id"
4303 FROM "initiative"
4304 WHERE "issue_id" = "issue_id_p" AND "eligible"
4305 ORDER BY
4306 "schulze_rank",
4307 "id"
4308 LIMIT 1
4309 ) AS "subquery"
4310 WHERE "id" = "subquery"."initiative_id";
4311 -- write (final) ranks:
4312 "rank_v" := 1;
4313 FOR "initiative_id_v" IN
4314 SELECT "id"
4315 FROM "initiative"
4316 WHERE "issue_id" = "issue_id_p" AND "admitted"
4317 ORDER BY
4318 "winner" DESC,
4319 "eligible" DESC,
4320 "schulze_rank",
4321 "id"
4322 LOOP
4323 UPDATE "initiative" SET "rank" = "rank_v"
4324 WHERE "id" = "initiative_id_v";
4325 "rank_v" := "rank_v" + 1;
4326 END LOOP;
4327 -- set schulze rank of status quo and mark issue as finished:
4328 UPDATE "issue" SET
4329 "status_quo_schulze_rank" = "rank_ary"[1],
4330 "state" =
4331 CASE WHEN EXISTS (
4332 SELECT NULL FROM "initiative"
4333 WHERE "issue_id" = "issue_id_p" AND "winner"
4334 ) THEN
4335 'finished_with_winner'::"issue_state"
4336 ELSE
4337 'finished_without_winner'::"issue_state"
4338 END,
4339 "closed" = "phase_finished",
4340 "phase_finished" = NULL
4341 WHERE "id" = "issue_id_p";
4342 RETURN;
4343 END;
4344 $$;
4346 COMMENT ON FUNCTION "calculate_ranks"
4347 ( "issue"."id"%TYPE )
4348 IS 'Determine ranking (Votes have to be counted first)';
4352 -----------------------------
4353 -- Automatic state changes --
4354 -----------------------------
4357 CREATE TYPE "check_issue_persistence" AS (
4358 "state" "issue_state",
4359 "phase_finished" BOOLEAN,
4360 "issue_revoked" BOOLEAN,
4361 "snapshot_created" BOOLEAN,
4362 "harmonic_weights_set" BOOLEAN,
4363 "closed_voting" BOOLEAN );
4365 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';
4368 CREATE FUNCTION "check_issue"
4369 ( "issue_id_p" "issue"."id"%TYPE,
4370 "persist" "check_issue_persistence" )
4371 RETURNS "check_issue_persistence"
4372 LANGUAGE 'plpgsql' VOLATILE AS $$
4373 DECLARE
4374 "issue_row" "issue"%ROWTYPE;
4375 "policy_row" "policy"%ROWTYPE;
4376 "initiative_row" "initiative"%ROWTYPE;
4377 "state_v" "issue_state";
4378 BEGIN
4379 PERFORM "require_transaction_isolation"();
4380 IF "persist" ISNULL THEN
4381 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4382 FOR UPDATE;
4383 IF "issue_row"."closed" NOTNULL THEN
4384 RETURN NULL;
4385 END IF;
4386 "persist"."state" := "issue_row"."state";
4387 IF
4388 ( "issue_row"."state" = 'admission' AND now() >=
4389 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
4390 ( "issue_row"."state" = 'discussion' AND now() >=
4391 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4392 ( "issue_row"."state" = 'verification' AND now() >=
4393 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4394 ( "issue_row"."state" = 'voting' AND now() >=
4395 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4396 THEN
4397 "persist"."phase_finished" := TRUE;
4398 ELSE
4399 "persist"."phase_finished" := FALSE;
4400 END IF;
4401 IF
4402 NOT EXISTS (
4403 -- all initiatives are revoked
4404 SELECT NULL FROM "initiative"
4405 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4406 ) AND (
4407 -- and issue has not been accepted yet
4408 "persist"."state" = 'admission' OR
4409 -- or verification time has elapsed
4410 ( "persist"."state" = 'verification' AND
4411 "persist"."phase_finished" ) OR
4412 -- or no initiatives have been revoked lately
4413 NOT EXISTS (
4414 SELECT NULL FROM "initiative"
4415 WHERE "issue_id" = "issue_id_p"
4416 AND now() < "revoked" + "issue_row"."verification_time"
4419 THEN
4420 "persist"."issue_revoked" := TRUE;
4421 ELSE
4422 "persist"."issue_revoked" := FALSE;
4423 END IF;
4424 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4425 UPDATE "issue" SET "phase_finished" = now()
4426 WHERE "id" = "issue_row"."id";
4427 RETURN "persist";
4428 ELSIF
4429 "persist"."state" IN ('admission', 'discussion', 'verification')
4430 THEN
4431 RETURN "persist";
4432 ELSE
4433 RETURN NULL;
4434 END IF;
4435 END IF;
4436 IF
4437 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4438 coalesce("persist"."snapshot_created", FALSE) = FALSE
4439 THEN
4440 PERFORM "create_snapshot"("issue_id_p");
4441 "persist"."snapshot_created" = TRUE;
4442 IF "persist"."phase_finished" THEN
4443 IF "persist"."state" = 'admission' THEN
4444 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4445 ELSIF "persist"."state" = 'discussion' THEN
4446 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4447 ELSIF "persist"."state" = 'verification' THEN
4448 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4449 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4450 SELECT * INTO "policy_row" FROM "policy"
4451 WHERE "id" = "issue_row"."policy_id";
4452 FOR "initiative_row" IN
4453 SELECT * FROM "initiative"
4454 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4455 FOR UPDATE
4456 LOOP
4457 IF
4458 "initiative_row"."polling" OR (
4459 "initiative_row"."satisfied_supporter_count" > 0 AND
4460 "initiative_row"."satisfied_supporter_count" *
4461 "policy_row"."initiative_quorum_den" >=
4462 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4464 THEN
4465 UPDATE "initiative" SET "admitted" = TRUE
4466 WHERE "id" = "initiative_row"."id";
4467 ELSE
4468 UPDATE "initiative" SET "admitted" = FALSE
4469 WHERE "id" = "initiative_row"."id";
4470 END IF;
4471 END LOOP;
4472 END IF;
4473 END IF;
4474 RETURN "persist";
4475 END IF;
4476 IF
4477 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4478 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4479 THEN
4480 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4481 "persist"."harmonic_weights_set" = TRUE;
4482 IF
4483 "persist"."phase_finished" OR
4484 "persist"."issue_revoked" OR
4485 "persist"."state" = 'admission'
4486 THEN
4487 RETURN "persist";
4488 ELSE
4489 RETURN NULL;
4490 END IF;
4491 END IF;
4492 IF "persist"."issue_revoked" THEN
4493 IF "persist"."state" = 'admission' THEN
4494 "state_v" := 'canceled_revoked_before_accepted';
4495 ELSIF "persist"."state" = 'discussion' THEN
4496 "state_v" := 'canceled_after_revocation_during_discussion';
4497 ELSIF "persist"."state" = 'verification' THEN
4498 "state_v" := 'canceled_after_revocation_during_verification';
4499 END IF;
4500 UPDATE "issue" SET
4501 "state" = "state_v",
4502 "closed" = "phase_finished",
4503 "phase_finished" = NULL
4504 WHERE "id" = "issue_id_p";
4505 RETURN NULL;
4506 END IF;
4507 IF "persist"."state" = 'admission' THEN
4508 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4509 FOR UPDATE;
4510 SELECT * INTO "policy_row"
4511 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4512 IF
4513 ( now() >=
4514 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
4515 EXISTS (
4516 SELECT NULL FROM "initiative"
4517 WHERE "issue_id" = "issue_id_p"
4518 AND "supporter_count" > 0
4519 AND "supporter_count" * "policy_row"."issue_quorum_den"
4520 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4522 THEN
4523 UPDATE "issue" SET
4524 "state" = 'discussion',
4525 "accepted" = coalesce("phase_finished", now()),
4526 "phase_finished" = NULL
4527 WHERE "id" = "issue_id_p";
4528 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4529 UPDATE "issue" SET
4530 "state" = 'canceled_issue_not_accepted',
4531 "closed" = "phase_finished",
4532 "phase_finished" = NULL
4533 WHERE "id" = "issue_id_p";
4534 END IF;
4535 RETURN NULL;
4536 END IF;
4537 IF "persist"."phase_finished" THEN
4538 IF "persist"."state" = 'discussion' THEN
4539 UPDATE "issue" SET
4540 "state" = 'verification',
4541 "half_frozen" = "phase_finished",
4542 "phase_finished" = NULL
4543 WHERE "id" = "issue_id_p";
4544 RETURN NULL;
4545 END IF;
4546 IF "persist"."state" = 'verification' THEN
4547 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4548 FOR UPDATE;
4549 SELECT * INTO "policy_row" FROM "policy"
4550 WHERE "id" = "issue_row"."policy_id";
4551 IF EXISTS (
4552 SELECT NULL FROM "initiative"
4553 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4554 ) THEN
4555 UPDATE "issue" SET
4556 "state" = 'voting',
4557 "fully_frozen" = "phase_finished",
4558 "phase_finished" = NULL
4559 WHERE "id" = "issue_id_p";
4560 ELSE
4561 UPDATE "issue" SET
4562 "state" = 'canceled_no_initiative_admitted',
4563 "fully_frozen" = "phase_finished",
4564 "closed" = "phase_finished",
4565 "phase_finished" = NULL
4566 WHERE "id" = "issue_id_p";
4567 -- NOTE: The following DELETE statements have effect only when
4568 -- issue state has been manipulated
4569 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4570 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4571 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4572 END IF;
4573 RETURN NULL;
4574 END IF;
4575 IF "persist"."state" = 'voting' THEN
4576 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4577 PERFORM "close_voting"("issue_id_p");
4578 "persist"."closed_voting" = TRUE;
4579 RETURN "persist";
4580 END IF;
4581 PERFORM "calculate_ranks"("issue_id_p");
4582 RETURN NULL;
4583 END IF;
4584 END IF;
4585 RAISE WARNING 'should not happen';
4586 RETURN NULL;
4587 END;
4588 $$;
4590 COMMENT ON FUNCTION "check_issue"
4591 ( "issue"."id"%TYPE,
4592 "check_issue_persistence" )
4593 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")';
4596 CREATE FUNCTION "check_everything"()
4597 RETURNS VOID
4598 LANGUAGE 'plpgsql' VOLATILE AS $$
4599 DECLARE
4600 "issue_id_v" "issue"."id"%TYPE;
4601 "persist_v" "check_issue_persistence";
4602 BEGIN
4603 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4604 DELETE FROM "expired_session";
4605 PERFORM "check_activity"();
4606 PERFORM "calculate_member_counts"();
4607 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4608 "persist_v" := NULL;
4609 LOOP
4610 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4611 EXIT WHEN "persist_v" ISNULL;
4612 END LOOP;
4613 END LOOP;
4614 RETURN;
4615 END;
4616 $$;
4618 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.';
4622 ----------------------
4623 -- Deletion of data --
4624 ----------------------
4627 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4628 RETURNS VOID
4629 LANGUAGE 'plpgsql' VOLATILE AS $$
4630 BEGIN
4631 IF EXISTS (
4632 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
4633 ) THEN
4634 -- override protection triggers:
4635 INSERT INTO "temporary_transaction_data" ("key", "value")
4636 VALUES ('override_protection_triggers', TRUE::TEXT);
4637 -- clean data:
4638 DELETE FROM "delegating_voter"
4639 WHERE "issue_id" = "issue_id_p";
4640 DELETE FROM "direct_voter"
4641 WHERE "issue_id" = "issue_id_p";
4642 DELETE FROM "delegating_interest_snapshot"
4643 WHERE "issue_id" = "issue_id_p";
4644 DELETE FROM "direct_interest_snapshot"
4645 WHERE "issue_id" = "issue_id_p";
4646 DELETE FROM "delegating_population_snapshot"
4647 WHERE "issue_id" = "issue_id_p";
4648 DELETE FROM "direct_population_snapshot"
4649 WHERE "issue_id" = "issue_id_p";
4650 DELETE FROM "non_voter"
4651 WHERE "issue_id" = "issue_id_p";
4652 DELETE FROM "delegation"
4653 WHERE "issue_id" = "issue_id_p";
4654 DELETE FROM "supporter"
4655 USING "initiative" -- NOTE: due to missing index on issue_id
4656 WHERE "initiative"."issue_id" = "issue_id_p"
4657 AND "supporter"."initiative_id" = "initiative_id";
4658 -- mark issue as cleaned:
4659 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
4660 -- finish overriding protection triggers (avoids garbage):
4661 DELETE FROM "temporary_transaction_data"
4662 WHERE "key" = 'override_protection_triggers';
4663 END IF;
4664 RETURN;
4665 END;
4666 $$;
4668 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4671 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4672 RETURNS VOID
4673 LANGUAGE 'plpgsql' VOLATILE AS $$
4674 BEGIN
4675 UPDATE "member" SET
4676 "last_login" = NULL,
4677 "last_delegation_check" = NULL,
4678 "login" = NULL,
4679 "password" = NULL,
4680 "authority" = NULL,
4681 "authority_uid" = NULL,
4682 "authority_login" = NULL,
4683 "locked" = TRUE,
4684 "active" = FALSE,
4685 "notify_email" = NULL,
4686 "notify_email_unconfirmed" = NULL,
4687 "notify_email_secret" = NULL,
4688 "notify_email_secret_expiry" = NULL,
4689 "notify_email_lock_expiry" = NULL,
4690 "login_recovery_expiry" = NULL,
4691 "password_reset_secret" = NULL,
4692 "password_reset_secret_expiry" = NULL,
4693 "organizational_unit" = NULL,
4694 "internal_posts" = NULL,
4695 "realname" = NULL,
4696 "birthday" = NULL,
4697 "address" = NULL,
4698 "email" = NULL,
4699 "xmpp_address" = NULL,
4700 "website" = NULL,
4701 "phone" = NULL,
4702 "mobile_phone" = NULL,
4703 "profession" = NULL,
4704 "external_memberships" = NULL,
4705 "external_posts" = NULL,
4706 "statement" = NULL
4707 WHERE "id" = "member_id_p";
4708 -- "text_search_data" is updated by triggers
4709 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4710 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4711 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4712 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4713 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4714 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4715 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4716 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4717 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4718 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4719 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4720 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4721 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4722 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4723 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4724 DELETE FROM "direct_voter" USING "issue"
4725 WHERE "direct_voter"."issue_id" = "issue"."id"
4726 AND "issue"."closed" ISNULL
4727 AND "member_id" = "member_id_p";
4728 RETURN;
4729 END;
4730 $$;
4732 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)';
4735 CREATE FUNCTION "delete_private_data"()
4736 RETURNS VOID
4737 LANGUAGE 'plpgsql' VOLATILE AS $$
4738 BEGIN
4739 DELETE FROM "temporary_transaction_data";
4740 DELETE FROM "member" WHERE "activated" ISNULL;
4741 UPDATE "member" SET
4742 "invite_code" = NULL,
4743 "invite_code_expiry" = NULL,
4744 "admin_comment" = NULL,
4745 "last_login" = NULL,
4746 "last_delegation_check" = NULL,
4747 "login" = NULL,
4748 "password" = NULL,
4749 "authority" = NULL,
4750 "authority_uid" = NULL,
4751 "authority_login" = NULL,
4752 "lang" = NULL,
4753 "notify_email" = NULL,
4754 "notify_email_unconfirmed" = NULL,
4755 "notify_email_secret" = NULL,
4756 "notify_email_secret_expiry" = NULL,
4757 "notify_email_lock_expiry" = NULL,
4758 "notify_level" = NULL,
4759 "login_recovery_expiry" = NULL,
4760 "password_reset_secret" = NULL,
4761 "password_reset_secret_expiry" = NULL,
4762 "organizational_unit" = NULL,
4763 "internal_posts" = NULL,
4764 "realname" = NULL,
4765 "birthday" = NULL,
4766 "address" = NULL,
4767 "email" = NULL,
4768 "xmpp_address" = NULL,
4769 "website" = NULL,
4770 "phone" = NULL,
4771 "mobile_phone" = NULL,
4772 "profession" = NULL,
4773 "external_memberships" = NULL,
4774 "external_posts" = NULL,
4775 "formatting_engine" = NULL,
4776 "statement" = NULL;
4777 -- "text_search_data" is updated by triggers
4778 DELETE FROM "setting";
4779 DELETE FROM "setting_map";
4780 DELETE FROM "member_relation_setting";
4781 DELETE FROM "member_image";
4782 DELETE FROM "contact";
4783 DELETE FROM "ignored_member";
4784 DELETE FROM "session";
4785 DELETE FROM "area_setting";
4786 DELETE FROM "issue_setting";
4787 DELETE FROM "ignored_initiative";
4788 DELETE FROM "initiative_setting";
4789 DELETE FROM "suggestion_setting";
4790 DELETE FROM "non_voter";
4791 DELETE FROM "direct_voter" USING "issue"
4792 WHERE "direct_voter"."issue_id" = "issue"."id"
4793 AND "issue"."closed" ISNULL;
4794 RETURN;
4795 END;
4796 $$;
4798 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.';
4802 COMMIT;

Impressum / About Us