liquid_feedback_core

view core.sql @ 461:4c3522ba2552

Changed reference to "member_id" in two tables to INT4 (was INT8)
author jbe
date Thu Mar 17 03:12:19 2016 +0100 (2016-03-17)
parents 6d4e51332251
children e9525f069607
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 "setting" (
230 PRIMARY KEY ("member_id", "key"),
231 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
232 "key" TEXT NOT NULL,
233 "value" TEXT NOT NULL );
234 CREATE INDEX "setting_key_idx" ON "setting" ("key");
236 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
238 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
241 CREATE TABLE "setting_map" (
242 PRIMARY KEY ("member_id", "key", "subkey"),
243 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
244 "key" TEXT NOT NULL,
245 "subkey" TEXT NOT NULL,
246 "value" TEXT NOT NULL );
247 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
249 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
251 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
252 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
253 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
256 CREATE TABLE "member_relation_setting" (
257 PRIMARY KEY ("member_id", "key", "other_member_id"),
258 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
259 "key" TEXT NOT NULL,
260 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
261 "value" TEXT NOT NULL );
263 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
266 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
268 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
271 CREATE TABLE "member_image" (
272 PRIMARY KEY ("member_id", "image_type", "scaled"),
273 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
274 "image_type" "member_image_type",
275 "scaled" BOOLEAN,
276 "content_type" TEXT,
277 "data" BYTEA NOT NULL );
279 COMMENT ON TABLE "member_image" IS 'Images of members';
281 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
284 CREATE TABLE "member_count" (
285 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
286 "total_count" INT4 NOT NULL );
288 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';
290 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
291 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
294 CREATE TABLE "contact" (
295 PRIMARY KEY ("member_id", "other_member_id"),
296 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
297 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
298 "public" BOOLEAN NOT NULL DEFAULT FALSE,
299 CONSTRAINT "cant_save_yourself_as_contact"
300 CHECK ("member_id" != "other_member_id") );
301 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
303 COMMENT ON TABLE "contact" IS 'Contact lists';
305 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
306 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
307 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
310 CREATE TABLE "ignored_member" (
311 PRIMARY KEY ("member_id", "other_member_id"),
312 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
313 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
314 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
316 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
318 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
319 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
322 CREATE TABLE "session" (
323 "ident" TEXT PRIMARY KEY,
324 "additional_secret" TEXT,
325 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
326 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
327 "authority" TEXT,
328 "authority_uid" TEXT,
329 "authority_login" TEXT,
330 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
331 "lang" TEXT );
332 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
334 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
336 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
337 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
338 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
339 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
340 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
341 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
342 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';
343 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
346 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
348 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';
351 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
353 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';
357 CREATE TABLE "policy" (
358 "id" SERIAL4 PRIMARY KEY,
359 "index" INT4 NOT NULL,
360 "active" BOOLEAN NOT NULL DEFAULT TRUE,
361 "name" TEXT NOT NULL UNIQUE,
362 "description" TEXT NOT NULL DEFAULT '',
363 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
364 "min_admission_time" INTERVAL,
365 "max_admission_time" INTERVAL,
366 "discussion_time" INTERVAL,
367 "verification_time" INTERVAL,
368 "voting_time" INTERVAL,
369 "issue_quorum_num" INT4,
370 "issue_quorum_den" INT4,
371 "initiative_quorum_num" INT4 NOT NULL,
372 "initiative_quorum_den" INT4 NOT NULL,
373 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
374 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
375 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
376 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
377 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
378 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
379 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
380 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
381 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
382 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
383 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
384 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
385 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
386 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
387 CONSTRAINT "timing" CHECK (
388 ( "polling" = FALSE AND
389 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
390 "min_admission_time" <= "max_admission_time" AND
391 "discussion_time" NOTNULL AND
392 "verification_time" NOTNULL AND
393 "voting_time" NOTNULL ) OR
394 ( "polling" = TRUE AND
395 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
396 "discussion_time" NOTNULL AND
397 "verification_time" NOTNULL AND
398 "voting_time" NOTNULL ) OR
399 ( "polling" = TRUE AND
400 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
401 "discussion_time" ISNULL AND
402 "verification_time" ISNULL AND
403 "voting_time" ISNULL ) ),
404 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
405 "polling" = ("issue_quorum_num" ISNULL) AND
406 "polling" = ("issue_quorum_den" ISNULL) ),
407 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
408 "defeat_strength" = 'tuple'::"defeat_strength" OR
409 "no_reverse_beat_path" = FALSE ) );
410 CREATE INDEX "policy_active_idx" ON "policy" ("active");
412 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
414 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
415 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
416 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';
417 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open';
418 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
419 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
420 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"';
421 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'')';
422 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''';
423 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''';
424 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
425 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
426 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';
427 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
428 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
429 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
430 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.';
431 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
432 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';
433 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';
434 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';
435 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.';
436 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';
437 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';
438 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.';
439 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").';
442 CREATE TABLE "unit" (
443 "id" SERIAL4 PRIMARY KEY,
444 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
445 "active" BOOLEAN NOT NULL DEFAULT TRUE,
446 "name" TEXT NOT NULL,
447 "description" TEXT NOT NULL DEFAULT '',
448 "external_reference" TEXT,
449 "member_count" INT4,
450 "text_search_data" TSVECTOR );
451 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
452 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
453 CREATE INDEX "unit_active_idx" ON "unit" ("active");
454 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
455 CREATE TRIGGER "update_text_search_data"
456 BEFORE INSERT OR UPDATE ON "unit"
457 FOR EACH ROW EXECUTE PROCEDURE
458 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
459 "name", "description" );
461 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
463 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
464 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
465 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
466 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
469 CREATE TABLE "unit_setting" (
470 PRIMARY KEY ("member_id", "key", "unit_id"),
471 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
472 "key" TEXT NOT NULL,
473 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
474 "value" TEXT NOT NULL );
476 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
479 CREATE TABLE "area" (
480 "id" SERIAL4 PRIMARY KEY,
481 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
482 "active" BOOLEAN NOT NULL DEFAULT TRUE,
483 "name" TEXT NOT NULL,
484 "description" TEXT NOT NULL DEFAULT '',
485 "external_reference" TEXT,
486 "direct_member_count" INT4,
487 "member_weight" INT4,
488 "text_search_data" TSVECTOR );
489 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
490 CREATE INDEX "area_active_idx" ON "area" ("active");
491 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
492 CREATE TRIGGER "update_text_search_data"
493 BEFORE INSERT OR UPDATE ON "area"
494 FOR EACH ROW EXECUTE PROCEDURE
495 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
496 "name", "description" );
498 COMMENT ON TABLE "area" IS 'Subject areas';
500 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
501 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
502 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"';
503 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
506 CREATE TABLE "area_setting" (
507 PRIMARY KEY ("member_id", "key", "area_id"),
508 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
509 "key" TEXT NOT NULL,
510 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
511 "value" TEXT NOT NULL );
513 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
516 CREATE TABLE "allowed_policy" (
517 PRIMARY KEY ("area_id", "policy_id"),
518 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
519 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
520 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
521 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
523 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
525 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
528 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
530 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';
533 CREATE TYPE "issue_state" AS ENUM (
534 'admission', 'discussion', 'verification', 'voting',
535 'canceled_by_admin',
536 'canceled_revoked_before_accepted',
537 'canceled_issue_not_accepted',
538 'canceled_after_revocation_during_discussion',
539 'canceled_after_revocation_during_verification',
540 'canceled_no_initiative_admitted',
541 'finished_without_winner', 'finished_with_winner');
543 COMMENT ON TYPE "issue_state" IS 'State of issues';
546 CREATE TABLE "issue" (
547 "id" SERIAL4 PRIMARY KEY,
548 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
549 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
550 "admin_notice" TEXT,
551 "external_reference" TEXT,
552 "state" "issue_state" NOT NULL DEFAULT 'admission',
553 "phase_finished" TIMESTAMPTZ,
554 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
555 "accepted" TIMESTAMPTZ,
556 "half_frozen" TIMESTAMPTZ,
557 "fully_frozen" TIMESTAMPTZ,
558 "closed" TIMESTAMPTZ,
559 "cleaned" TIMESTAMPTZ,
560 "min_admission_time" INTERVAL,
561 "max_admission_time" INTERVAL,
562 "discussion_time" INTERVAL NOT NULL,
563 "verification_time" INTERVAL NOT NULL,
564 "voting_time" INTERVAL NOT NULL,
565 "snapshot" TIMESTAMPTZ,
566 "latest_snapshot_event" "snapshot_event",
567 "population" INT4,
568 "voter_count" INT4,
569 "status_quo_schulze_rank" INT4,
570 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
571 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
572 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
573 CONSTRAINT "valid_state" CHECK (
574 (
575 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
576 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
577 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
578 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
579 ) AND (
580 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
581 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
582 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
583 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
584 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
585 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
586 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
587 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
588 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
589 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
590 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
591 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
592 )),
593 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
594 "phase_finished" ISNULL OR "closed" ISNULL ),
595 CONSTRAINT "state_change_order" CHECK (
596 "created" <= "accepted" AND
597 "accepted" <= "half_frozen" AND
598 "half_frozen" <= "fully_frozen" AND
599 "fully_frozen" <= "closed" ),
600 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
601 "cleaned" ISNULL OR "closed" NOTNULL ),
602 CONSTRAINT "last_snapshot_on_full_freeze"
603 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
604 CONSTRAINT "freeze_requires_snapshot"
605 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
606 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
607 CHECK (("snapshot" NOTNULL) = ("latest_snapshot_event" NOTNULL)) );
608 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
609 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
610 CREATE INDEX "issue_created_idx" ON "issue" ("created");
611 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
612 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
613 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
614 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
615 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
616 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
618 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
620 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
621 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
622 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';
623 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
624 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.';
625 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.';
626 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.';
627 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
628 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
629 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
630 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
631 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
632 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
633 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
634 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';
635 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
636 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';
637 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
640 CREATE TABLE "issue_order_in_admission_state" (
641 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
642 "order_in_area" INT4,
643 "order_in_unit" INT4 );
645 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"';
647 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';
648 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';
649 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';
652 CREATE TABLE "issue_setting" (
653 PRIMARY KEY ("member_id", "key", "issue_id"),
654 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
655 "key" TEXT NOT NULL,
656 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
657 "value" TEXT NOT NULL );
659 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
662 CREATE TABLE "initiative" (
663 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
664 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
665 "id" SERIAL4 PRIMARY KEY,
666 "name" TEXT NOT NULL,
667 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
668 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
669 "revoked" TIMESTAMPTZ,
670 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
671 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
672 "external_reference" TEXT,
673 "admitted" BOOLEAN,
674 "supporter_count" INT4,
675 "informed_supporter_count" INT4,
676 "satisfied_supporter_count" INT4,
677 "satisfied_informed_supporter_count" INT4,
678 "harmonic_weight" NUMERIC(12, 3),
679 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
680 "first_preference_votes" INT4,
681 "positive_votes" INT4,
682 "negative_votes" INT4,
683 "direct_majority" BOOLEAN,
684 "indirect_majority" BOOLEAN,
685 "schulze_rank" INT4,
686 "better_than_status_quo" BOOLEAN,
687 "worse_than_status_quo" BOOLEAN,
688 "reverse_beat_path" BOOLEAN,
689 "multistage_majority" BOOLEAN,
690 "eligible" BOOLEAN,
691 "winner" BOOLEAN,
692 "rank" INT4,
693 "text_search_data" TSVECTOR,
694 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
695 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
696 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
697 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
698 CONSTRAINT "revoked_initiatives_cant_be_admitted"
699 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
700 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
701 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
702 ( "first_preference_votes" ISNULL AND
703 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
704 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
705 "schulze_rank" ISNULL AND
706 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
707 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
708 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
709 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
710 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
711 "eligible" = FALSE OR
712 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
713 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
714 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
715 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
716 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
717 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
718 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
719 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
720 CREATE TRIGGER "update_text_search_data"
721 BEFORE INSERT OR UPDATE ON "initiative"
722 FOR EACH ROW EXECUTE PROCEDURE
723 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
725 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.';
727 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
728 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
729 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
730 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
731 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
732 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
733 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
734 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
735 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
736 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';
737 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
738 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
739 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
740 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
741 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"';
742 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
743 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
744 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
745 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)';
746 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''';
747 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';
748 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"';
749 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
750 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';
753 CREATE TABLE "battle" (
754 "issue_id" INT4 NOT NULL,
755 "winning_initiative_id" INT4,
756 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
757 "losing_initiative_id" INT4,
758 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
759 "count" INT4 NOT NULL,
760 CONSTRAINT "initiative_ids_not_equal" CHECK (
761 "winning_initiative_id" != "losing_initiative_id" OR
762 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
763 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
764 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
765 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
766 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
768 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';
771 CREATE TABLE "ignored_initiative" (
772 PRIMARY KEY ("initiative_id", "member_id"),
773 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
774 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
775 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
777 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
780 CREATE TABLE "initiative_setting" (
781 PRIMARY KEY ("member_id", "key", "initiative_id"),
782 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
783 "key" TEXT NOT NULL,
784 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
785 "value" TEXT NOT NULL );
787 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
790 CREATE TABLE "draft" (
791 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
792 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
793 "id" SERIAL8 PRIMARY KEY,
794 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
795 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
796 "formatting_engine" TEXT,
797 "content" TEXT NOT NULL,
798 "external_reference" TEXT,
799 "text_search_data" TSVECTOR );
800 CREATE INDEX "draft_created_idx" ON "draft" ("created");
801 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
802 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
803 CREATE TRIGGER "update_text_search_data"
804 BEFORE INSERT OR UPDATE ON "draft"
805 FOR EACH ROW EXECUTE PROCEDURE
806 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
808 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.';
810 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
811 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
812 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
815 CREATE TABLE "rendered_draft" (
816 PRIMARY KEY ("draft_id", "format"),
817 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
818 "format" TEXT,
819 "content" TEXT NOT NULL );
821 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)';
824 CREATE TABLE "suggestion" (
825 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
826 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
827 "id" SERIAL8 PRIMARY KEY,
828 "draft_id" INT8 NOT NULL,
829 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
830 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
831 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
832 "name" TEXT NOT NULL,
833 "formatting_engine" TEXT,
834 "content" TEXT NOT NULL DEFAULT '',
835 "external_reference" TEXT,
836 "text_search_data" TSVECTOR,
837 "minus2_unfulfilled_count" INT4,
838 "minus2_fulfilled_count" INT4,
839 "minus1_unfulfilled_count" INT4,
840 "minus1_fulfilled_count" INT4,
841 "plus1_unfulfilled_count" INT4,
842 "plus1_fulfilled_count" INT4,
843 "plus2_unfulfilled_count" INT4,
844 "plus2_fulfilled_count" INT4,
845 "proportional_order" INT4 );
846 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
847 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
848 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
849 CREATE TRIGGER "update_text_search_data"
850 BEFORE INSERT OR UPDATE ON "suggestion"
851 FOR EACH ROW EXECUTE PROCEDURE
852 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
853 "name", "content");
855 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';
857 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")';
858 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
859 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
860 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
861 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
862 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
863 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
864 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
865 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
866 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
867 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"';
870 CREATE TABLE "rendered_suggestion" (
871 PRIMARY KEY ("suggestion_id", "format"),
872 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
873 "format" TEXT,
874 "content" TEXT NOT NULL );
876 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)';
879 CREATE TABLE "suggestion_setting" (
880 PRIMARY KEY ("member_id", "key", "suggestion_id"),
881 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
882 "key" TEXT NOT NULL,
883 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
884 "value" TEXT NOT NULL );
886 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
889 CREATE TABLE "privilege" (
890 PRIMARY KEY ("unit_id", "member_id"),
891 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
892 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
893 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
894 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
895 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
896 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
897 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
898 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
899 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
901 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
903 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
904 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
905 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
906 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
907 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
908 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
909 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';
912 CREATE TABLE "subscription" (
913 PRIMARY KEY ("unit_id", "member_id"),
914 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
915 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
916 CREATE INDEX "subscription_member_id_idx" ON "subscription" ("member_id");
918 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';
921 CREATE TABLE "ignored_area" (
922 PRIMARY KEY ("area_id", "member_id"),
923 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
924 "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
925 CREATE INDEX "ignored_area_member_id_idx" ON "ignored_area" ("member_id");
927 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';
930 CREATE TABLE "membership" (
931 PRIMARY KEY ("area_id", "member_id"),
932 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
933 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
934 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
936 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
939 CREATE TABLE "interest" (
940 PRIMARY KEY ("issue_id", "member_id"),
941 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
942 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
943 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
945 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.';
948 CREATE TABLE "initiator" (
949 PRIMARY KEY ("initiative_id", "member_id"),
950 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
951 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
952 "accepted" BOOLEAN );
953 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
955 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.';
957 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.';
960 CREATE TABLE "supporter" (
961 "issue_id" INT4 NOT NULL,
962 PRIMARY KEY ("initiative_id", "member_id"),
963 "initiative_id" INT4,
964 "member_id" INT4,
965 "draft_id" INT8 NOT NULL,
966 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
967 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
968 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
970 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.';
972 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
973 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")';
976 CREATE TABLE "opinion" (
977 "initiative_id" INT4 NOT NULL,
978 PRIMARY KEY ("suggestion_id", "member_id"),
979 "suggestion_id" INT8,
980 "member_id" INT4,
981 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
982 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
983 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
984 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
985 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
987 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.';
989 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
992 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
994 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
997 CREATE TABLE "delegation" (
998 "id" SERIAL8 PRIMARY KEY,
999 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1000 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1001 "scope" "delegation_scope" NOT NULL,
1002 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1003 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1004 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1005 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1006 CONSTRAINT "no_unit_delegation_to_null"
1007 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1008 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1009 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1010 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1011 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1012 UNIQUE ("unit_id", "truster_id"),
1013 UNIQUE ("area_id", "truster_id"),
1014 UNIQUE ("issue_id", "truster_id") );
1015 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1016 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1018 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1020 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1021 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1022 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1025 CREATE TABLE "direct_population_snapshot" (
1026 PRIMARY KEY ("issue_id", "event", "member_id"),
1027 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1028 "event" "snapshot_event",
1029 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1030 "weight" INT4 );
1031 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
1033 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';
1035 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1036 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
1039 CREATE TABLE "delegating_population_snapshot" (
1040 PRIMARY KEY ("issue_id", "event", "member_id"),
1041 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1042 "event" "snapshot_event",
1043 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1044 "weight" INT4,
1045 "scope" "delegation_scope" NOT NULL,
1046 "delegate_member_ids" INT4[] NOT NULL );
1047 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
1049 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';
1051 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1052 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
1053 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
1054 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"';
1057 CREATE TABLE "direct_interest_snapshot" (
1058 PRIMARY KEY ("issue_id", "event", "member_id"),
1059 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1060 "event" "snapshot_event",
1061 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1062 "weight" INT4 );
1063 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1065 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';
1067 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1068 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1071 CREATE TABLE "delegating_interest_snapshot" (
1072 PRIMARY KEY ("issue_id", "event", "member_id"),
1073 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1074 "event" "snapshot_event",
1075 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1076 "weight" INT4,
1077 "scope" "delegation_scope" NOT NULL,
1078 "delegate_member_ids" INT4[] NOT NULL );
1079 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1081 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';
1083 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1084 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1085 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1086 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"';
1089 CREATE TABLE "direct_supporter_snapshot" (
1090 "issue_id" INT4 NOT NULL,
1091 PRIMARY KEY ("initiative_id", "event", "member_id"),
1092 "initiative_id" INT4,
1093 "event" "snapshot_event",
1094 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1095 "draft_id" INT8 NOT NULL,
1096 "informed" BOOLEAN NOT NULL,
1097 "satisfied" BOOLEAN NOT NULL,
1098 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1099 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1100 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1101 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1103 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';
1105 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';
1106 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1107 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1108 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1111 CREATE TABLE "non_voter" (
1112 PRIMARY KEY ("issue_id", "member_id"),
1113 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1114 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1115 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1117 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1120 CREATE TABLE "direct_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 RESTRICT ON UPDATE RESTRICT,
1124 "weight" INT4,
1125 "comment_changed" TIMESTAMPTZ,
1126 "formatting_engine" TEXT,
1127 "comment" TEXT,
1128 "text_search_data" TSVECTOR );
1129 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1130 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1131 CREATE TRIGGER "update_text_search_data"
1132 BEFORE INSERT OR UPDATE ON "direct_voter"
1133 FOR EACH ROW EXECUTE PROCEDURE
1134 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1136 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';
1138 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1139 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';
1140 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';
1141 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.';
1144 CREATE TABLE "rendered_voter_comment" (
1145 PRIMARY KEY ("issue_id", "member_id", "format"),
1146 FOREIGN KEY ("issue_id", "member_id")
1147 REFERENCES "direct_voter" ("issue_id", "member_id")
1148 ON DELETE CASCADE ON UPDATE CASCADE,
1149 "issue_id" INT4,
1150 "member_id" INT4,
1151 "format" TEXT,
1152 "content" TEXT NOT NULL );
1154 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)';
1157 CREATE TABLE "delegating_voter" (
1158 PRIMARY KEY ("issue_id", "member_id"),
1159 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1160 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1161 "weight" INT4,
1162 "scope" "delegation_scope" NOT NULL,
1163 "delegate_member_ids" INT4[] NOT NULL );
1164 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1166 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';
1168 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1169 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1170 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"';
1173 CREATE TABLE "vote" (
1174 "issue_id" INT4 NOT NULL,
1175 PRIMARY KEY ("initiative_id", "member_id"),
1176 "initiative_id" INT4,
1177 "member_id" INT4,
1178 "grade" INT4 NOT NULL,
1179 "first_preference" BOOLEAN,
1180 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1181 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1182 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1183 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1184 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1186 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';
1188 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1189 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.';
1190 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.';
1193 CREATE TYPE "event_type" AS ENUM (
1194 'issue_state_changed',
1195 'initiative_created_in_new_issue',
1196 'initiative_created_in_existing_issue',
1197 'initiative_revoked',
1198 'new_draft_created',
1199 'suggestion_created');
1201 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1204 CREATE TABLE "event" (
1205 "id" SERIAL8 PRIMARY KEY,
1206 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1207 "event" "event_type" NOT NULL,
1208 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1209 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1210 "state" "issue_state",
1211 "initiative_id" INT4,
1212 "draft_id" INT8,
1213 "suggestion_id" INT8,
1214 FOREIGN KEY ("issue_id", "initiative_id")
1215 REFERENCES "initiative" ("issue_id", "id")
1216 ON DELETE CASCADE ON UPDATE CASCADE,
1217 FOREIGN KEY ("initiative_id", "draft_id")
1218 REFERENCES "draft" ("initiative_id", "id")
1219 ON DELETE CASCADE ON UPDATE CASCADE,
1220 FOREIGN KEY ("initiative_id", "suggestion_id")
1221 REFERENCES "suggestion" ("initiative_id", "id")
1222 ON DELETE CASCADE ON UPDATE CASCADE,
1223 CONSTRAINT "null_constr_for_issue_state_changed" CHECK (
1224 "event" != 'issue_state_changed' OR (
1225 "member_id" ISNULL AND
1226 "issue_id" NOTNULL AND
1227 "state" NOTNULL AND
1228 "initiative_id" ISNULL AND
1229 "draft_id" ISNULL AND
1230 "suggestion_id" ISNULL )),
1231 CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1232 "event" NOT IN (
1233 'initiative_created_in_new_issue',
1234 'initiative_created_in_existing_issue',
1235 'initiative_revoked',
1236 'new_draft_created'
1237 ) OR (
1238 "member_id" NOTNULL AND
1239 "issue_id" NOTNULL AND
1240 "state" NOTNULL AND
1241 "initiative_id" NOTNULL AND
1242 "draft_id" NOTNULL AND
1243 "suggestion_id" ISNULL )),
1244 CONSTRAINT "null_constr_for_suggestion_creation" CHECK (
1245 "event" != 'suggestion_created' OR (
1246 "member_id" NOTNULL AND
1247 "issue_id" NOTNULL AND
1248 "state" NOTNULL AND
1249 "initiative_id" NOTNULL AND
1250 "draft_id" ISNULL AND
1251 "suggestion_id" NOTNULL )) );
1252 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1254 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1256 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1257 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1258 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1259 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1262 CREATE TABLE "notification_sent" (
1263 "event_id" INT8 NOT NULL );
1264 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1266 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1267 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1271 ----------------------------------------------
1272 -- Writing of history entries and event log --
1273 ----------------------------------------------
1276 CREATE FUNCTION "write_member_history_trigger"()
1277 RETURNS TRIGGER
1278 LANGUAGE 'plpgsql' VOLATILE AS $$
1279 BEGIN
1280 IF
1281 ( NEW."active" != OLD."active" OR
1282 NEW."name" != OLD."name" ) AND
1283 OLD."activated" NOTNULL
1284 THEN
1285 INSERT INTO "member_history"
1286 ("member_id", "active", "name")
1287 VALUES (NEW."id", OLD."active", OLD."name");
1288 END IF;
1289 RETURN NULL;
1290 END;
1291 $$;
1293 CREATE TRIGGER "write_member_history"
1294 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1295 "write_member_history_trigger"();
1297 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1298 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1301 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1302 RETURNS TRIGGER
1303 LANGUAGE 'plpgsql' VOLATILE AS $$
1304 BEGIN
1305 IF NEW."state" != OLD."state" THEN
1306 INSERT INTO "event" ("event", "issue_id", "state")
1307 VALUES ('issue_state_changed', NEW."id", NEW."state");
1308 END IF;
1309 RETURN NULL;
1310 END;
1311 $$;
1313 CREATE TRIGGER "write_event_issue_state_changed"
1314 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1315 "write_event_issue_state_changed_trigger"();
1317 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1318 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1321 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1322 RETURNS TRIGGER
1323 LANGUAGE 'plpgsql' VOLATILE AS $$
1324 DECLARE
1325 "initiative_row" "initiative"%ROWTYPE;
1326 "issue_row" "issue"%ROWTYPE;
1327 "event_v" "event_type";
1328 BEGIN
1329 SELECT * INTO "initiative_row" FROM "initiative"
1330 WHERE "id" = NEW."initiative_id";
1331 SELECT * INTO "issue_row" FROM "issue"
1332 WHERE "id" = "initiative_row"."issue_id";
1333 IF EXISTS (
1334 SELECT NULL FROM "draft"
1335 WHERE "initiative_id" = NEW."initiative_id"
1336 AND "id" != NEW."id"
1337 ) THEN
1338 "event_v" := 'new_draft_created';
1339 ELSE
1340 IF EXISTS (
1341 SELECT NULL FROM "initiative"
1342 WHERE "issue_id" = "initiative_row"."issue_id"
1343 AND "id" != "initiative_row"."id"
1344 ) THEN
1345 "event_v" := 'initiative_created_in_existing_issue';
1346 ELSE
1347 "event_v" := 'initiative_created_in_new_issue';
1348 END IF;
1349 END IF;
1350 INSERT INTO "event" (
1351 "event", "member_id",
1352 "issue_id", "state", "initiative_id", "draft_id"
1353 ) VALUES (
1354 "event_v",
1355 NEW."author_id",
1356 "initiative_row"."issue_id",
1357 "issue_row"."state",
1358 "initiative_row"."id",
1359 NEW."id" );
1360 RETURN NULL;
1361 END;
1362 $$;
1364 CREATE TRIGGER "write_event_initiative_or_draft_created"
1365 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1366 "write_event_initiative_or_draft_created_trigger"();
1368 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1369 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1372 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1373 RETURNS TRIGGER
1374 LANGUAGE 'plpgsql' VOLATILE AS $$
1375 DECLARE
1376 "issue_row" "issue"%ROWTYPE;
1377 "draft_id_v" "draft"."id"%TYPE;
1378 BEGIN
1379 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1380 SELECT * INTO "issue_row" FROM "issue"
1381 WHERE "id" = NEW."issue_id";
1382 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1383 WHERE "initiative_id" = NEW."id";
1384 INSERT INTO "event" (
1385 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1386 ) VALUES (
1387 'initiative_revoked',
1388 NEW."revoked_by_member_id",
1389 NEW."issue_id",
1390 "issue_row"."state",
1391 NEW."id",
1392 "draft_id_v");
1393 END IF;
1394 RETURN NULL;
1395 END;
1396 $$;
1398 CREATE TRIGGER "write_event_initiative_revoked"
1399 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1400 "write_event_initiative_revoked_trigger"();
1402 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1403 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1406 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1407 RETURNS TRIGGER
1408 LANGUAGE 'plpgsql' VOLATILE AS $$
1409 DECLARE
1410 "initiative_row" "initiative"%ROWTYPE;
1411 "issue_row" "issue"%ROWTYPE;
1412 BEGIN
1413 SELECT * INTO "initiative_row" FROM "initiative"
1414 WHERE "id" = NEW."initiative_id";
1415 SELECT * INTO "issue_row" FROM "issue"
1416 WHERE "id" = "initiative_row"."issue_id";
1417 INSERT INTO "event" (
1418 "event", "member_id",
1419 "issue_id", "state", "initiative_id", "suggestion_id"
1420 ) VALUES (
1421 'suggestion_created',
1422 NEW."author_id",
1423 "initiative_row"."issue_id",
1424 "issue_row"."state",
1425 "initiative_row"."id",
1426 NEW."id" );
1427 RETURN NULL;
1428 END;
1429 $$;
1431 CREATE TRIGGER "write_event_suggestion_created"
1432 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1433 "write_event_suggestion_created_trigger"();
1435 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1436 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1440 ----------------------------
1441 -- Additional constraints --
1442 ----------------------------
1445 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1446 RETURNS TRIGGER
1447 LANGUAGE 'plpgsql' VOLATILE AS $$
1448 BEGIN
1449 IF NOT EXISTS (
1450 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1451 ) THEN
1452 --RAISE 'Cannot create issue without an initial initiative.' USING
1453 -- ERRCODE = 'integrity_constraint_violation',
1454 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1455 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1456 END IF;
1457 RETURN NULL;
1458 END;
1459 $$;
1461 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1462 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1463 FOR EACH ROW EXECUTE PROCEDURE
1464 "issue_requires_first_initiative_trigger"();
1466 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1467 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1470 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1471 RETURNS TRIGGER
1472 LANGUAGE 'plpgsql' VOLATILE AS $$
1473 DECLARE
1474 "reference_lost" BOOLEAN;
1475 BEGIN
1476 IF TG_OP = 'DELETE' THEN
1477 "reference_lost" := TRUE;
1478 ELSE
1479 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1480 END IF;
1481 IF
1482 "reference_lost" AND NOT EXISTS (
1483 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1485 THEN
1486 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1487 END IF;
1488 RETURN NULL;
1489 END;
1490 $$;
1492 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1493 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1494 FOR EACH ROW EXECUTE PROCEDURE
1495 "last_initiative_deletes_issue_trigger"();
1497 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1498 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1501 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1502 RETURNS TRIGGER
1503 LANGUAGE 'plpgsql' VOLATILE AS $$
1504 BEGIN
1505 IF NOT EXISTS (
1506 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1507 ) THEN
1508 --RAISE 'Cannot create initiative without an initial draft.' USING
1509 -- ERRCODE = 'integrity_constraint_violation',
1510 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1511 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1512 END IF;
1513 RETURN NULL;
1514 END;
1515 $$;
1517 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1518 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1519 FOR EACH ROW EXECUTE PROCEDURE
1520 "initiative_requires_first_draft_trigger"();
1522 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1523 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1526 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1527 RETURNS TRIGGER
1528 LANGUAGE 'plpgsql' VOLATILE AS $$
1529 DECLARE
1530 "reference_lost" BOOLEAN;
1531 BEGIN
1532 IF TG_OP = 'DELETE' THEN
1533 "reference_lost" := TRUE;
1534 ELSE
1535 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1536 END IF;
1537 IF
1538 "reference_lost" AND NOT EXISTS (
1539 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1541 THEN
1542 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1543 END IF;
1544 RETURN NULL;
1545 END;
1546 $$;
1548 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1549 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1550 FOR EACH ROW EXECUTE PROCEDURE
1551 "last_draft_deletes_initiative_trigger"();
1553 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1554 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1557 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1558 RETURNS TRIGGER
1559 LANGUAGE 'plpgsql' VOLATILE AS $$
1560 BEGIN
1561 IF NOT EXISTS (
1562 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1563 ) THEN
1564 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1565 END IF;
1566 RETURN NULL;
1567 END;
1568 $$;
1570 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1571 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1572 FOR EACH ROW EXECUTE PROCEDURE
1573 "suggestion_requires_first_opinion_trigger"();
1575 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1576 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1579 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1580 RETURNS TRIGGER
1581 LANGUAGE 'plpgsql' VOLATILE AS $$
1582 DECLARE
1583 "reference_lost" BOOLEAN;
1584 BEGIN
1585 IF TG_OP = 'DELETE' THEN
1586 "reference_lost" := TRUE;
1587 ELSE
1588 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1589 END IF;
1590 IF
1591 "reference_lost" AND NOT EXISTS (
1592 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1594 THEN
1595 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1596 END IF;
1597 RETURN NULL;
1598 END;
1599 $$;
1601 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1602 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1603 FOR EACH ROW EXECUTE PROCEDURE
1604 "last_opinion_deletes_suggestion_trigger"();
1606 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1607 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1610 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1611 RETURNS TRIGGER
1612 LANGUAGE 'plpgsql' VOLATILE AS $$
1613 BEGIN
1614 DELETE FROM "direct_voter"
1615 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1616 RETURN NULL;
1617 END;
1618 $$;
1620 CREATE TRIGGER "non_voter_deletes_direct_voter"
1621 AFTER INSERT OR UPDATE ON "non_voter"
1622 FOR EACH ROW EXECUTE PROCEDURE
1623 "non_voter_deletes_direct_voter_trigger"();
1625 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1626 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")';
1629 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1630 RETURNS TRIGGER
1631 LANGUAGE 'plpgsql' VOLATILE AS $$
1632 BEGIN
1633 DELETE FROM "non_voter"
1634 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1635 RETURN NULL;
1636 END;
1637 $$;
1639 CREATE TRIGGER "direct_voter_deletes_non_voter"
1640 AFTER INSERT OR UPDATE ON "direct_voter"
1641 FOR EACH ROW EXECUTE PROCEDURE
1642 "direct_voter_deletes_non_voter_trigger"();
1644 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1645 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")';
1648 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1649 RETURNS TRIGGER
1650 LANGUAGE 'plpgsql' VOLATILE AS $$
1651 BEGIN
1652 IF NEW."comment" ISNULL THEN
1653 NEW."comment_changed" := NULL;
1654 NEW."formatting_engine" := NULL;
1655 END IF;
1656 RETURN NEW;
1657 END;
1658 $$;
1660 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1661 BEFORE INSERT OR UPDATE ON "direct_voter"
1662 FOR EACH ROW EXECUTE PROCEDURE
1663 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1665 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"';
1666 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.';
1669 ---------------------------------------------------------------
1670 -- Ensure that votes are not modified when issues are closed --
1671 ---------------------------------------------------------------
1673 -- NOTE: Frontends should ensure this anyway, but in case of programming
1674 -- errors the following triggers ensure data integrity.
1677 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1678 RETURNS TRIGGER
1679 LANGUAGE 'plpgsql' VOLATILE AS $$
1680 DECLARE
1681 "issue_id_v" "issue"."id"%TYPE;
1682 "issue_row" "issue"%ROWTYPE;
1683 BEGIN
1684 IF EXISTS (
1685 SELECT NULL FROM "temporary_transaction_data"
1686 WHERE "txid" = txid_current()
1687 AND "key" = 'override_protection_triggers'
1688 AND "value" = TRUE::TEXT
1689 ) THEN
1690 RETURN NULL;
1691 END IF;
1692 IF TG_OP = 'DELETE' THEN
1693 "issue_id_v" := OLD."issue_id";
1694 ELSE
1695 "issue_id_v" := NEW."issue_id";
1696 END IF;
1697 SELECT INTO "issue_row" * FROM "issue"
1698 WHERE "id" = "issue_id_v" FOR SHARE;
1699 IF (
1700 "issue_row"."closed" NOTNULL OR (
1701 "issue_row"."state" = 'voting' AND
1702 "issue_row"."phase_finished" NOTNULL
1704 ) THEN
1705 IF
1706 TG_RELID = 'direct_voter'::regclass AND
1707 TG_OP = 'UPDATE'
1708 THEN
1709 IF
1710 OLD."issue_id" = NEW."issue_id" AND
1711 OLD."member_id" = NEW."member_id" AND
1712 OLD."weight" = NEW."weight"
1713 THEN
1714 RETURN NULL; -- allows changing of voter comment
1715 END IF;
1716 END IF;
1717 RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
1718 END IF;
1719 RETURN NULL;
1720 END;
1721 $$;
1723 CREATE TRIGGER "forbid_changes_on_closed_issue"
1724 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1725 FOR EACH ROW EXECUTE PROCEDURE
1726 "forbid_changes_on_closed_issue_trigger"();
1728 CREATE TRIGGER "forbid_changes_on_closed_issue"
1729 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1730 FOR EACH ROW EXECUTE PROCEDURE
1731 "forbid_changes_on_closed_issue_trigger"();
1733 CREATE TRIGGER "forbid_changes_on_closed_issue"
1734 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1735 FOR EACH ROW EXECUTE PROCEDURE
1736 "forbid_changes_on_closed_issue_trigger"();
1738 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"';
1739 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';
1740 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';
1741 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';
1745 --------------------------------------------------------------------
1746 -- Auto-retrieval of fields only needed for referential integrity --
1747 --------------------------------------------------------------------
1750 CREATE FUNCTION "autofill_issue_id_trigger"()
1751 RETURNS TRIGGER
1752 LANGUAGE 'plpgsql' VOLATILE AS $$
1753 BEGIN
1754 IF NEW."issue_id" ISNULL THEN
1755 SELECT "issue_id" INTO NEW."issue_id"
1756 FROM "initiative" WHERE "id" = NEW."initiative_id";
1757 END IF;
1758 RETURN NEW;
1759 END;
1760 $$;
1762 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1763 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1765 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1766 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1768 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1769 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1770 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1773 CREATE FUNCTION "autofill_initiative_id_trigger"()
1774 RETURNS TRIGGER
1775 LANGUAGE 'plpgsql' VOLATILE AS $$
1776 BEGIN
1777 IF NEW."initiative_id" ISNULL THEN
1778 SELECT "initiative_id" INTO NEW."initiative_id"
1779 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1780 END IF;
1781 RETURN NEW;
1782 END;
1783 $$;
1785 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1786 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1788 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1789 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1793 -----------------------------------------------------
1794 -- Automatic calculation of certain default values --
1795 -----------------------------------------------------
1798 CREATE FUNCTION "copy_timings_trigger"()
1799 RETURNS TRIGGER
1800 LANGUAGE 'plpgsql' VOLATILE AS $$
1801 DECLARE
1802 "policy_row" "policy"%ROWTYPE;
1803 BEGIN
1804 SELECT * INTO "policy_row" FROM "policy"
1805 WHERE "id" = NEW."policy_id";
1806 IF NEW."min_admission_time" ISNULL THEN
1807 NEW."min_admission_time" := "policy_row"."min_admission_time";
1808 END IF;
1809 IF NEW."max_admission_time" ISNULL THEN
1810 NEW."max_admission_time" := "policy_row"."max_admission_time";
1811 END IF;
1812 IF NEW."discussion_time" ISNULL THEN
1813 NEW."discussion_time" := "policy_row"."discussion_time";
1814 END IF;
1815 IF NEW."verification_time" ISNULL THEN
1816 NEW."verification_time" := "policy_row"."verification_time";
1817 END IF;
1818 IF NEW."voting_time" ISNULL THEN
1819 NEW."voting_time" := "policy_row"."voting_time";
1820 END IF;
1821 RETURN NEW;
1822 END;
1823 $$;
1825 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1826 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1828 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1829 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1832 CREATE FUNCTION "default_for_draft_id_trigger"()
1833 RETURNS TRIGGER
1834 LANGUAGE 'plpgsql' VOLATILE AS $$
1835 BEGIN
1836 IF NEW."draft_id" ISNULL THEN
1837 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1838 WHERE "initiative_id" = NEW."initiative_id";
1839 END IF;
1840 RETURN NEW;
1841 END;
1842 $$;
1844 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1845 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1846 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1847 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1849 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1850 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';
1851 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';
1855 ----------------------------------------
1856 -- Automatic creation of dependencies --
1857 ----------------------------------------
1860 CREATE FUNCTION "autocreate_interest_trigger"()
1861 RETURNS TRIGGER
1862 LANGUAGE 'plpgsql' VOLATILE AS $$
1863 BEGIN
1864 IF NOT EXISTS (
1865 SELECT NULL FROM "initiative" JOIN "interest"
1866 ON "initiative"."issue_id" = "interest"."issue_id"
1867 WHERE "initiative"."id" = NEW."initiative_id"
1868 AND "interest"."member_id" = NEW."member_id"
1869 ) THEN
1870 BEGIN
1871 INSERT INTO "interest" ("issue_id", "member_id")
1872 SELECT "issue_id", NEW."member_id"
1873 FROM "initiative" WHERE "id" = NEW."initiative_id";
1874 EXCEPTION WHEN unique_violation THEN END;
1875 END IF;
1876 RETURN NEW;
1877 END;
1878 $$;
1880 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1881 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1883 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1884 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';
1887 CREATE FUNCTION "autocreate_supporter_trigger"()
1888 RETURNS TRIGGER
1889 LANGUAGE 'plpgsql' VOLATILE AS $$
1890 BEGIN
1891 IF NOT EXISTS (
1892 SELECT NULL FROM "suggestion" JOIN "supporter"
1893 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1894 WHERE "suggestion"."id" = NEW."suggestion_id"
1895 AND "supporter"."member_id" = NEW."member_id"
1896 ) THEN
1897 BEGIN
1898 INSERT INTO "supporter" ("initiative_id", "member_id")
1899 SELECT "initiative_id", NEW."member_id"
1900 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1901 EXCEPTION WHEN unique_violation THEN END;
1902 END IF;
1903 RETURN NEW;
1904 END;
1905 $$;
1907 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1908 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1910 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1911 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.';
1915 ------------------------------------------
1916 -- Views and helper functions for views --
1917 ------------------------------------------
1920 CREATE VIEW "unit_delegation" AS
1921 SELECT
1922 "unit"."id" AS "unit_id",
1923 "delegation"."id",
1924 "delegation"."truster_id",
1925 "delegation"."trustee_id",
1926 "delegation"."scope"
1927 FROM "unit"
1928 JOIN "delegation"
1929 ON "delegation"."unit_id" = "unit"."id"
1930 JOIN "member"
1931 ON "delegation"."truster_id" = "member"."id"
1932 JOIN "privilege"
1933 ON "delegation"."unit_id" = "privilege"."unit_id"
1934 AND "delegation"."truster_id" = "privilege"."member_id"
1935 WHERE "member"."active" AND "privilege"."voting_right";
1937 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1940 CREATE VIEW "area_delegation" AS
1941 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1942 "area"."id" AS "area_id",
1943 "delegation"."id",
1944 "delegation"."truster_id",
1945 "delegation"."trustee_id",
1946 "delegation"."scope"
1947 FROM "area"
1948 JOIN "delegation"
1949 ON "delegation"."unit_id" = "area"."unit_id"
1950 OR "delegation"."area_id" = "area"."id"
1951 JOIN "member"
1952 ON "delegation"."truster_id" = "member"."id"
1953 JOIN "privilege"
1954 ON "area"."unit_id" = "privilege"."unit_id"
1955 AND "delegation"."truster_id" = "privilege"."member_id"
1956 WHERE "member"."active" AND "privilege"."voting_right"
1957 ORDER BY
1958 "area"."id",
1959 "delegation"."truster_id",
1960 "delegation"."scope" DESC;
1962 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1965 CREATE VIEW "issue_delegation" AS
1966 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1967 "issue"."id" AS "issue_id",
1968 "delegation"."id",
1969 "delegation"."truster_id",
1970 "delegation"."trustee_id",
1971 "delegation"."scope"
1972 FROM "issue"
1973 JOIN "area"
1974 ON "area"."id" = "issue"."area_id"
1975 JOIN "delegation"
1976 ON "delegation"."unit_id" = "area"."unit_id"
1977 OR "delegation"."area_id" = "area"."id"
1978 OR "delegation"."issue_id" = "issue"."id"
1979 JOIN "member"
1980 ON "delegation"."truster_id" = "member"."id"
1981 JOIN "privilege"
1982 ON "area"."unit_id" = "privilege"."unit_id"
1983 AND "delegation"."truster_id" = "privilege"."member_id"
1984 WHERE "member"."active" AND "privilege"."voting_right"
1985 ORDER BY
1986 "issue"."id",
1987 "delegation"."truster_id",
1988 "delegation"."scope" DESC;
1990 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1993 CREATE FUNCTION "membership_weight_with_skipping"
1994 ( "area_id_p" "area"."id"%TYPE,
1995 "member_id_p" "member"."id"%TYPE,
1996 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1997 RETURNS INT4
1998 LANGUAGE 'plpgsql' STABLE AS $$
1999 DECLARE
2000 "sum_v" INT4;
2001 "delegation_row" "area_delegation"%ROWTYPE;
2002 BEGIN
2003 "sum_v" := 1;
2004 FOR "delegation_row" IN
2005 SELECT "area_delegation".*
2006 FROM "area_delegation" LEFT JOIN "membership"
2007 ON "membership"."area_id" = "area_id_p"
2008 AND "membership"."member_id" = "area_delegation"."truster_id"
2009 WHERE "area_delegation"."area_id" = "area_id_p"
2010 AND "area_delegation"."trustee_id" = "member_id_p"
2011 AND "membership"."member_id" ISNULL
2012 LOOP
2013 IF NOT
2014 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
2015 THEN
2016 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
2017 "area_id_p",
2018 "delegation_row"."truster_id",
2019 "skip_member_ids_p" || "delegation_row"."truster_id"
2020 );
2021 END IF;
2022 END LOOP;
2023 RETURN "sum_v";
2024 END;
2025 $$;
2027 COMMENT ON FUNCTION "membership_weight_with_skipping"
2028 ( "area"."id"%TYPE,
2029 "member"."id"%TYPE,
2030 INT4[] )
2031 IS 'Helper function for "membership_weight" function';
2034 CREATE FUNCTION "membership_weight"
2035 ( "area_id_p" "area"."id"%TYPE,
2036 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
2037 RETURNS INT4
2038 LANGUAGE 'plpgsql' STABLE AS $$
2039 BEGIN
2040 RETURN "membership_weight_with_skipping"(
2041 "area_id_p",
2042 "member_id_p",
2043 ARRAY["member_id_p"]
2044 );
2045 END;
2046 $$;
2048 COMMENT ON FUNCTION "membership_weight"
2049 ( "area"."id"%TYPE,
2050 "member"."id"%TYPE )
2051 IS 'Calculates the potential voting weight of a member in a given area';
2054 CREATE VIEW "member_count_view" AS
2055 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
2057 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
2060 CREATE VIEW "unit_member_count" AS
2061 SELECT
2062 "unit"."id" AS "unit_id",
2063 count("member"."id") AS "member_count"
2064 FROM "unit"
2065 LEFT JOIN "privilege"
2066 ON "privilege"."unit_id" = "unit"."id"
2067 AND "privilege"."voting_right"
2068 LEFT JOIN "member"
2069 ON "member"."id" = "privilege"."member_id"
2070 AND "member"."active"
2071 GROUP BY "unit"."id";
2073 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
2076 CREATE VIEW "area_member_count" AS
2077 SELECT
2078 "area"."id" AS "area_id",
2079 count("member"."id") AS "direct_member_count",
2080 coalesce(
2081 sum(
2082 CASE WHEN "member"."id" NOTNULL THEN
2083 "membership_weight"("area"."id", "member"."id")
2084 ELSE 0 END
2086 ) AS "member_weight"
2087 FROM "area"
2088 LEFT JOIN "membership"
2089 ON "area"."id" = "membership"."area_id"
2090 LEFT JOIN "privilege"
2091 ON "privilege"."unit_id" = "area"."unit_id"
2092 AND "privilege"."member_id" = "membership"."member_id"
2093 AND "privilege"."voting_right"
2094 LEFT JOIN "member"
2095 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2096 AND "member"."active"
2097 GROUP BY "area"."id";
2099 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2102 CREATE VIEW "opening_draft" AS
2103 SELECT "draft".* FROM (
2104 SELECT
2105 "initiative"."id" AS "initiative_id",
2106 min("draft"."id") AS "draft_id"
2107 FROM "initiative" JOIN "draft"
2108 ON "initiative"."id" = "draft"."initiative_id"
2109 GROUP BY "initiative"."id"
2110 ) AS "subquery"
2111 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2113 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2116 CREATE VIEW "current_draft" AS
2117 SELECT "draft".* FROM (
2118 SELECT
2119 "initiative"."id" AS "initiative_id",
2120 max("draft"."id") AS "draft_id"
2121 FROM "initiative" JOIN "draft"
2122 ON "initiative"."id" = "draft"."initiative_id"
2123 GROUP BY "initiative"."id"
2124 ) AS "subquery"
2125 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2127 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2130 CREATE VIEW "critical_opinion" AS
2131 SELECT * FROM "opinion"
2132 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2133 OR ("degree" = -2 AND "fulfilled" = TRUE);
2135 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2138 CREATE VIEW "issue_supporter_in_admission_state" AS
2139 SELECT DISTINCT
2140 "area"."unit_id",
2141 "issue"."area_id",
2142 "issue"."id" AS "issue_id",
2143 "supporter"."member_id",
2144 "direct_interest_snapshot"."weight"
2145 FROM "issue"
2146 JOIN "area" ON "area"."id" = "issue"."area_id"
2147 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
2148 JOIN "direct_interest_snapshot"
2149 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2150 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2151 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
2152 WHERE "issue"."state" = 'admission'::"issue_state";
2154 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';
2157 CREATE VIEW "initiative_suggestion_order_calculation" AS
2158 SELECT
2159 "initiative"."id" AS "initiative_id",
2160 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
2161 FROM "initiative" JOIN "issue"
2162 ON "initiative"."issue_id" = "issue"."id"
2163 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
2164 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
2166 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
2168 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';
2171 CREATE VIEW "individual_suggestion_ranking" AS
2172 SELECT
2173 "opinion"."initiative_id",
2174 "opinion"."member_id",
2175 "direct_interest_snapshot"."weight",
2176 CASE WHEN
2177 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
2178 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
2179 THEN 1 ELSE
2180 CASE WHEN
2181 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
2182 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
2183 THEN 2 ELSE
2184 CASE WHEN
2185 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
2186 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
2187 THEN 3 ELSE 4 END
2188 END
2189 END AS "preference",
2190 "opinion"."suggestion_id"
2191 FROM "opinion"
2192 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
2193 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2194 JOIN "direct_interest_snapshot"
2195 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2196 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2197 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
2199 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
2202 CREATE VIEW "battle_participant" AS
2203 SELECT "initiative"."id", "initiative"."issue_id"
2204 FROM "issue" JOIN "initiative"
2205 ON "issue"."id" = "initiative"."issue_id"
2206 WHERE "initiative"."admitted"
2207 UNION ALL
2208 SELECT NULL, "id" AS "issue_id"
2209 FROM "issue";
2211 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2214 CREATE VIEW "battle_view" AS
2215 SELECT
2216 "issue"."id" AS "issue_id",
2217 "winning_initiative"."id" AS "winning_initiative_id",
2218 "losing_initiative"."id" AS "losing_initiative_id",
2219 sum(
2220 CASE WHEN
2221 coalesce("better_vote"."grade", 0) >
2222 coalesce("worse_vote"."grade", 0)
2223 THEN "direct_voter"."weight" ELSE 0 END
2224 ) AS "count"
2225 FROM "issue"
2226 LEFT JOIN "direct_voter"
2227 ON "issue"."id" = "direct_voter"."issue_id"
2228 JOIN "battle_participant" AS "winning_initiative"
2229 ON "issue"."id" = "winning_initiative"."issue_id"
2230 JOIN "battle_participant" AS "losing_initiative"
2231 ON "issue"."id" = "losing_initiative"."issue_id"
2232 LEFT JOIN "vote" AS "better_vote"
2233 ON "direct_voter"."member_id" = "better_vote"."member_id"
2234 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2235 LEFT JOIN "vote" AS "worse_vote"
2236 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2237 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2238 WHERE "issue"."state" = 'voting'
2239 AND "issue"."phase_finished" NOTNULL
2240 AND (
2241 "winning_initiative"."id" != "losing_initiative"."id" OR
2242 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2243 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2244 GROUP BY
2245 "issue"."id",
2246 "winning_initiative"."id",
2247 "losing_initiative"."id";
2249 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';
2252 CREATE VIEW "expired_session" AS
2253 SELECT * FROM "session" WHERE now() > "expiry";
2255 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2256 DELETE FROM "session" WHERE "ident" = OLD."ident";
2258 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2259 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2262 CREATE VIEW "open_issue" AS
2263 SELECT * FROM "issue" WHERE "closed" ISNULL;
2265 COMMENT ON VIEW "open_issue" IS 'All open issues';
2268 CREATE VIEW "member_contingent" AS
2269 SELECT
2270 "member"."id" AS "member_id",
2271 "contingent"."polling",
2272 "contingent"."time_frame",
2273 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2275 SELECT count(1) FROM "draft"
2276 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2277 WHERE "draft"."author_id" = "member"."id"
2278 AND "initiative"."polling" = "contingent"."polling"
2279 AND "draft"."created" > now() - "contingent"."time_frame"
2280 ) + (
2281 SELECT count(1) FROM "suggestion"
2282 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2283 WHERE "suggestion"."author_id" = "member"."id"
2284 AND "contingent"."polling" = FALSE
2285 AND "suggestion"."created" > now() - "contingent"."time_frame"
2287 ELSE NULL END AS "text_entry_count",
2288 "contingent"."text_entry_limit",
2289 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2290 SELECT count(1) FROM "opening_draft" AS "draft"
2291 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2292 WHERE "draft"."author_id" = "member"."id"
2293 AND "initiative"."polling" = "contingent"."polling"
2294 AND "draft"."created" > now() - "contingent"."time_frame"
2295 ) ELSE NULL END AS "initiative_count",
2296 "contingent"."initiative_limit"
2297 FROM "member" CROSS JOIN "contingent";
2299 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2301 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2302 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2305 CREATE VIEW "member_contingent_left" AS
2306 SELECT
2307 "member_id",
2308 "polling",
2309 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2310 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2311 FROM "member_contingent" GROUP BY "member_id", "polling";
2313 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.';
2316 CREATE VIEW "event_seen_by_member" AS
2317 SELECT
2318 "member"."id" AS "seen_by_member_id",
2319 CASE WHEN "event"."state" IN (
2320 'voting',
2321 'finished_without_winner',
2322 'finished_with_winner'
2323 ) THEN
2324 'voting'::"notify_level"
2325 ELSE
2326 CASE WHEN "event"."state" IN (
2327 'verification',
2328 'canceled_after_revocation_during_verification',
2329 'canceled_no_initiative_admitted'
2330 ) THEN
2331 'verification'::"notify_level"
2332 ELSE
2333 CASE WHEN "event"."state" IN (
2334 'discussion',
2335 'canceled_after_revocation_during_discussion'
2336 ) THEN
2337 'discussion'::"notify_level"
2338 ELSE
2339 'all'::"notify_level"
2340 END
2341 END
2342 END AS "notify_level",
2343 "event".*
2344 FROM "member" CROSS JOIN "event"
2345 LEFT JOIN "issue"
2346 ON "event"."issue_id" = "issue"."id"
2347 LEFT JOIN "membership"
2348 ON "member"."id" = "membership"."member_id"
2349 AND "issue"."area_id" = "membership"."area_id"
2350 LEFT JOIN "interest"
2351 ON "member"."id" = "interest"."member_id"
2352 AND "event"."issue_id" = "interest"."issue_id"
2353 LEFT JOIN "ignored_member"
2354 ON "member"."id" = "ignored_member"."member_id"
2355 AND "event"."member_id" = "ignored_member"."other_member_id"
2356 LEFT JOIN "ignored_initiative"
2357 ON "member"."id" = "ignored_initiative"."member_id"
2358 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2359 WHERE (
2360 "interest"."member_id" NOTNULL OR
2361 ( "membership"."member_id" NOTNULL AND
2362 "event"."event" IN (
2363 'issue_state_changed',
2364 'initiative_created_in_new_issue',
2365 'initiative_created_in_existing_issue',
2366 'initiative_revoked' ) ) )
2367 AND "ignored_member"."member_id" ISNULL
2368 AND "ignored_initiative"."member_id" ISNULL;
2370 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"';
2374 ------------------------------------------------------
2375 -- Row set returning function for delegation chains --
2376 ------------------------------------------------------
2379 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2380 ('first', 'intermediate', 'last', 'repetition');
2382 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2385 CREATE TYPE "delegation_chain_row" AS (
2386 "index" INT4,
2387 "member_id" INT4,
2388 "member_valid" BOOLEAN,
2389 "participation" BOOLEAN,
2390 "overridden" BOOLEAN,
2391 "scope_in" "delegation_scope",
2392 "scope_out" "delegation_scope",
2393 "disabled_out" BOOLEAN,
2394 "loop" "delegation_chain_loop_tag" );
2396 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2398 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2399 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';
2400 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2401 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2402 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2403 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2404 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2407 CREATE FUNCTION "delegation_chain_for_closed_issue"
2408 ( "member_id_p" "member"."id"%TYPE,
2409 "issue_id_p" "issue"."id"%TYPE )
2410 RETURNS SETOF "delegation_chain_row"
2411 LANGUAGE 'plpgsql' STABLE AS $$
2412 DECLARE
2413 "output_row" "delegation_chain_row";
2414 "direct_voter_row" "direct_voter"%ROWTYPE;
2415 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2416 BEGIN
2417 "output_row"."index" := 0;
2418 "output_row"."member_id" := "member_id_p";
2419 "output_row"."member_valid" := TRUE;
2420 "output_row"."participation" := FALSE;
2421 "output_row"."overridden" := FALSE;
2422 "output_row"."disabled_out" := FALSE;
2423 LOOP
2424 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2425 WHERE "issue_id" = "issue_id_p"
2426 AND "member_id" = "output_row"."member_id";
2427 IF "direct_voter_row"."member_id" NOTNULL THEN
2428 "output_row"."participation" := TRUE;
2429 "output_row"."scope_out" := NULL;
2430 "output_row"."disabled_out" := NULL;
2431 RETURN NEXT "output_row";
2432 RETURN;
2433 END IF;
2434 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2435 WHERE "issue_id" = "issue_id_p"
2436 AND "member_id" = "output_row"."member_id";
2437 IF "delegating_voter_row"."member_id" ISNULL THEN
2438 RETURN;
2439 END IF;
2440 "output_row"."scope_out" := "delegating_voter_row"."scope";
2441 RETURN NEXT "output_row";
2442 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2443 "output_row"."scope_in" := "output_row"."scope_out";
2444 END LOOP;
2445 END;
2446 $$;
2448 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2449 ( "member"."id"%TYPE,
2450 "member"."id"%TYPE )
2451 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2454 CREATE FUNCTION "delegation_chain"
2455 ( "member_id_p" "member"."id"%TYPE,
2456 "unit_id_p" "unit"."id"%TYPE,
2457 "area_id_p" "area"."id"%TYPE,
2458 "issue_id_p" "issue"."id"%TYPE,
2459 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2460 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2461 RETURNS SETOF "delegation_chain_row"
2462 LANGUAGE 'plpgsql' STABLE AS $$
2463 DECLARE
2464 "scope_v" "delegation_scope";
2465 "unit_id_v" "unit"."id"%TYPE;
2466 "area_id_v" "area"."id"%TYPE;
2467 "issue_row" "issue"%ROWTYPE;
2468 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2469 "loop_member_id_v" "member"."id"%TYPE;
2470 "output_row" "delegation_chain_row";
2471 "output_rows" "delegation_chain_row"[];
2472 "simulate_v" BOOLEAN;
2473 "simulate_here_v" BOOLEAN;
2474 "delegation_row" "delegation"%ROWTYPE;
2475 "row_count" INT4;
2476 "i" INT4;
2477 "loop_v" BOOLEAN;
2478 BEGIN
2479 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2480 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2481 END IF;
2482 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2483 "simulate_v" := TRUE;
2484 ELSE
2485 "simulate_v" := FALSE;
2486 END IF;
2487 IF
2488 "unit_id_p" NOTNULL AND
2489 "area_id_p" ISNULL AND
2490 "issue_id_p" ISNULL
2491 THEN
2492 "scope_v" := 'unit';
2493 "unit_id_v" := "unit_id_p";
2494 ELSIF
2495 "unit_id_p" ISNULL AND
2496 "area_id_p" NOTNULL AND
2497 "issue_id_p" ISNULL
2498 THEN
2499 "scope_v" := 'area';
2500 "area_id_v" := "area_id_p";
2501 SELECT "unit_id" INTO "unit_id_v"
2502 FROM "area" WHERE "id" = "area_id_v";
2503 ELSIF
2504 "unit_id_p" ISNULL AND
2505 "area_id_p" ISNULL AND
2506 "issue_id_p" NOTNULL
2507 THEN
2508 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2509 IF "issue_row"."id" ISNULL THEN
2510 RETURN;
2511 END IF;
2512 IF "issue_row"."closed" NOTNULL THEN
2513 IF "simulate_v" THEN
2514 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2515 END IF;
2516 FOR "output_row" IN
2517 SELECT * FROM
2518 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2519 LOOP
2520 RETURN NEXT "output_row";
2521 END LOOP;
2522 RETURN;
2523 END IF;
2524 "scope_v" := 'issue';
2525 SELECT "area_id" INTO "area_id_v"
2526 FROM "issue" WHERE "id" = "issue_id_p";
2527 SELECT "unit_id" INTO "unit_id_v"
2528 FROM "area" WHERE "id" = "area_id_v";
2529 ELSE
2530 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2531 END IF;
2532 "visited_member_ids" := '{}';
2533 "loop_member_id_v" := NULL;
2534 "output_rows" := '{}';
2535 "output_row"."index" := 0;
2536 "output_row"."member_id" := "member_id_p";
2537 "output_row"."member_valid" := TRUE;
2538 "output_row"."participation" := FALSE;
2539 "output_row"."overridden" := FALSE;
2540 "output_row"."disabled_out" := FALSE;
2541 "output_row"."scope_out" := NULL;
2542 LOOP
2543 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2544 "loop_member_id_v" := "output_row"."member_id";
2545 ELSE
2546 "visited_member_ids" :=
2547 "visited_member_ids" || "output_row"."member_id";
2548 END IF;
2549 IF "output_row"."participation" ISNULL THEN
2550 "output_row"."overridden" := NULL;
2551 ELSIF "output_row"."participation" THEN
2552 "output_row"."overridden" := TRUE;
2553 END IF;
2554 "output_row"."scope_in" := "output_row"."scope_out";
2555 "output_row"."member_valid" := EXISTS (
2556 SELECT NULL FROM "member" JOIN "privilege"
2557 ON "privilege"."member_id" = "member"."id"
2558 AND "privilege"."unit_id" = "unit_id_v"
2559 WHERE "id" = "output_row"."member_id"
2560 AND "member"."active" AND "privilege"."voting_right"
2561 );
2562 "simulate_here_v" := (
2563 "simulate_v" AND
2564 "output_row"."member_id" = "member_id_p"
2565 );
2566 "delegation_row" := ROW(NULL);
2567 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2568 IF "scope_v" = 'unit' THEN
2569 IF NOT "simulate_here_v" THEN
2570 SELECT * INTO "delegation_row" FROM "delegation"
2571 WHERE "truster_id" = "output_row"."member_id"
2572 AND "unit_id" = "unit_id_v";
2573 END IF;
2574 ELSIF "scope_v" = 'area' THEN
2575 "output_row"."participation" := EXISTS (
2576 SELECT NULL FROM "membership"
2577 WHERE "area_id" = "area_id_p"
2578 AND "member_id" = "output_row"."member_id"
2579 );
2580 IF "simulate_here_v" THEN
2581 IF "simulate_trustee_id_p" ISNULL THEN
2582 SELECT * INTO "delegation_row" FROM "delegation"
2583 WHERE "truster_id" = "output_row"."member_id"
2584 AND "unit_id" = "unit_id_v";
2585 END IF;
2586 ELSE
2587 SELECT * INTO "delegation_row" FROM "delegation"
2588 WHERE "truster_id" = "output_row"."member_id"
2589 AND (
2590 "unit_id" = "unit_id_v" OR
2591 "area_id" = "area_id_v"
2593 ORDER BY "scope" DESC;
2594 END IF;
2595 ELSIF "scope_v" = 'issue' THEN
2596 IF "issue_row"."fully_frozen" ISNULL THEN
2597 "output_row"."participation" := EXISTS (
2598 SELECT NULL FROM "interest"
2599 WHERE "issue_id" = "issue_id_p"
2600 AND "member_id" = "output_row"."member_id"
2601 );
2602 ELSE
2603 IF "output_row"."member_id" = "member_id_p" THEN
2604 "output_row"."participation" := EXISTS (
2605 SELECT NULL FROM "direct_voter"
2606 WHERE "issue_id" = "issue_id_p"
2607 AND "member_id" = "output_row"."member_id"
2608 );
2609 ELSE
2610 "output_row"."participation" := NULL;
2611 END IF;
2612 END IF;
2613 IF "simulate_here_v" THEN
2614 IF "simulate_trustee_id_p" ISNULL THEN
2615 SELECT * INTO "delegation_row" FROM "delegation"
2616 WHERE "truster_id" = "output_row"."member_id"
2617 AND (
2618 "unit_id" = "unit_id_v" OR
2619 "area_id" = "area_id_v"
2621 ORDER BY "scope" DESC;
2622 END IF;
2623 ELSE
2624 SELECT * INTO "delegation_row" FROM "delegation"
2625 WHERE "truster_id" = "output_row"."member_id"
2626 AND (
2627 "unit_id" = "unit_id_v" OR
2628 "area_id" = "area_id_v" OR
2629 "issue_id" = "issue_id_p"
2631 ORDER BY "scope" DESC;
2632 END IF;
2633 END IF;
2634 ELSE
2635 "output_row"."participation" := FALSE;
2636 END IF;
2637 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2638 "output_row"."scope_out" := "scope_v";
2639 "output_rows" := "output_rows" || "output_row";
2640 "output_row"."member_id" := "simulate_trustee_id_p";
2641 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2642 "output_row"."scope_out" := "delegation_row"."scope";
2643 "output_rows" := "output_rows" || "output_row";
2644 "output_row"."member_id" := "delegation_row"."trustee_id";
2645 ELSIF "delegation_row"."scope" NOTNULL THEN
2646 "output_row"."scope_out" := "delegation_row"."scope";
2647 "output_row"."disabled_out" := TRUE;
2648 "output_rows" := "output_rows" || "output_row";
2649 EXIT;
2650 ELSE
2651 "output_row"."scope_out" := NULL;
2652 "output_rows" := "output_rows" || "output_row";
2653 EXIT;
2654 END IF;
2655 EXIT WHEN "loop_member_id_v" NOTNULL;
2656 "output_row"."index" := "output_row"."index" + 1;
2657 END LOOP;
2658 "row_count" := array_upper("output_rows", 1);
2659 "i" := 1;
2660 "loop_v" := FALSE;
2661 LOOP
2662 "output_row" := "output_rows"["i"];
2663 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2664 IF "loop_v" THEN
2665 IF "i" + 1 = "row_count" THEN
2666 "output_row"."loop" := 'last';
2667 ELSIF "i" = "row_count" THEN
2668 "output_row"."loop" := 'repetition';
2669 ELSE
2670 "output_row"."loop" := 'intermediate';
2671 END IF;
2672 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2673 "output_row"."loop" := 'first';
2674 "loop_v" := TRUE;
2675 END IF;
2676 IF "scope_v" = 'unit' THEN
2677 "output_row"."participation" := NULL;
2678 END IF;
2679 RETURN NEXT "output_row";
2680 "i" := "i" + 1;
2681 END LOOP;
2682 RETURN;
2683 END;
2684 $$;
2686 COMMENT ON FUNCTION "delegation_chain"
2687 ( "member"."id"%TYPE,
2688 "unit"."id"%TYPE,
2689 "area"."id"%TYPE,
2690 "issue"."id"%TYPE,
2691 "member"."id"%TYPE,
2692 BOOLEAN )
2693 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2697 ---------------------------------------------------------
2698 -- Single row returning function for delegation chains --
2699 ---------------------------------------------------------
2702 CREATE TYPE "delegation_info_loop_type" AS ENUM
2703 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2705 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''';
2708 CREATE TYPE "delegation_info_type" AS (
2709 "own_participation" BOOLEAN,
2710 "own_delegation_scope" "delegation_scope",
2711 "first_trustee_id" INT4,
2712 "first_trustee_participation" BOOLEAN,
2713 "first_trustee_ellipsis" BOOLEAN,
2714 "other_trustee_id" INT4,
2715 "other_trustee_participation" BOOLEAN,
2716 "other_trustee_ellipsis" BOOLEAN,
2717 "delegation_loop" "delegation_info_loop_type",
2718 "participating_member_id" INT4 );
2720 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';
2722 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2723 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2724 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2725 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2726 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2727 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2728 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)';
2729 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2730 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';
2731 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2734 CREATE FUNCTION "delegation_info"
2735 ( "member_id_p" "member"."id"%TYPE,
2736 "unit_id_p" "unit"."id"%TYPE,
2737 "area_id_p" "area"."id"%TYPE,
2738 "issue_id_p" "issue"."id"%TYPE,
2739 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2740 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2741 RETURNS "delegation_info_type"
2742 LANGUAGE 'plpgsql' STABLE AS $$
2743 DECLARE
2744 "current_row" "delegation_chain_row";
2745 "result" "delegation_info_type";
2746 BEGIN
2747 "result"."own_participation" := FALSE;
2748 FOR "current_row" IN
2749 SELECT * FROM "delegation_chain"(
2750 "member_id_p",
2751 "unit_id_p", "area_id_p", "issue_id_p",
2752 "simulate_trustee_id_p", "simulate_default_p")
2753 LOOP
2754 IF
2755 "result"."participating_member_id" ISNULL AND
2756 "current_row"."participation"
2757 THEN
2758 "result"."participating_member_id" := "current_row"."member_id";
2759 END IF;
2760 IF "current_row"."member_id" = "member_id_p" THEN
2761 "result"."own_participation" := "current_row"."participation";
2762 "result"."own_delegation_scope" := "current_row"."scope_out";
2763 IF "current_row"."loop" = 'first' THEN
2764 "result"."delegation_loop" := 'own';
2765 END IF;
2766 ELSIF
2767 "current_row"."member_valid" AND
2768 ( "current_row"."loop" ISNULL OR
2769 "current_row"."loop" != 'repetition' )
2770 THEN
2771 IF "result"."first_trustee_id" ISNULL THEN
2772 "result"."first_trustee_id" := "current_row"."member_id";
2773 "result"."first_trustee_participation" := "current_row"."participation";
2774 "result"."first_trustee_ellipsis" := FALSE;
2775 IF "current_row"."loop" = 'first' THEN
2776 "result"."delegation_loop" := 'first';
2777 END IF;
2778 ELSIF "result"."other_trustee_id" ISNULL THEN
2779 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2780 "result"."other_trustee_id" := "current_row"."member_id";
2781 "result"."other_trustee_participation" := TRUE;
2782 "result"."other_trustee_ellipsis" := FALSE;
2783 IF "current_row"."loop" = 'first' THEN
2784 "result"."delegation_loop" := 'other';
2785 END IF;
2786 ELSE
2787 "result"."first_trustee_ellipsis" := TRUE;
2788 IF "current_row"."loop" = 'first' THEN
2789 "result"."delegation_loop" := 'first_ellipsis';
2790 END IF;
2791 END IF;
2792 ELSE
2793 "result"."other_trustee_ellipsis" := TRUE;
2794 IF "current_row"."loop" = 'first' THEN
2795 "result"."delegation_loop" := 'other_ellipsis';
2796 END IF;
2797 END IF;
2798 END IF;
2799 END LOOP;
2800 RETURN "result";
2801 END;
2802 $$;
2804 COMMENT ON FUNCTION "delegation_info"
2805 ( "member"."id"%TYPE,
2806 "unit"."id"%TYPE,
2807 "area"."id"%TYPE,
2808 "issue"."id"%TYPE,
2809 "member"."id"%TYPE,
2810 BOOLEAN )
2811 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2815 ---------------------------
2816 -- Transaction isolation --
2817 ---------------------------
2820 CREATE FUNCTION "require_transaction_isolation"()
2821 RETURNS VOID
2822 LANGUAGE 'plpgsql' VOLATILE AS $$
2823 BEGIN
2824 IF
2825 current_setting('transaction_isolation') NOT IN
2826 ('repeatable read', 'serializable')
2827 THEN
2828 RAISE EXCEPTION 'Insufficient transaction isolation level';
2829 END IF;
2830 RETURN;
2831 END;
2832 $$;
2834 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
2837 CREATE FUNCTION "dont_require_transaction_isolation"()
2838 RETURNS VOID
2839 LANGUAGE 'plpgsql' VOLATILE AS $$
2840 BEGIN
2841 IF
2842 current_setting('transaction_isolation') IN
2843 ('repeatable read', 'serializable')
2844 THEN
2845 RAISE WARNING 'Unneccessary transaction isolation level: %',
2846 current_setting('transaction_isolation');
2847 END IF;
2848 RETURN;
2849 END;
2850 $$;
2852 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
2856 ------------------------------------------------------------------------
2857 -- Regular tasks, except calculcation of snapshots and voting results --
2858 ------------------------------------------------------------------------
2861 CREATE FUNCTION "check_activity"()
2862 RETURNS VOID
2863 LANGUAGE 'plpgsql' VOLATILE AS $$
2864 DECLARE
2865 "system_setting_row" "system_setting"%ROWTYPE;
2866 BEGIN
2867 PERFORM "dont_require_transaction_isolation"();
2868 SELECT * INTO "system_setting_row" FROM "system_setting";
2869 IF "system_setting_row"."member_ttl" NOTNULL THEN
2870 UPDATE "member" SET "active" = FALSE
2871 WHERE "active" = TRUE
2872 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2873 END IF;
2874 RETURN;
2875 END;
2876 $$;
2878 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2881 CREATE FUNCTION "calculate_member_counts"()
2882 RETURNS VOID
2883 LANGUAGE 'plpgsql' VOLATILE AS $$
2884 BEGIN
2885 PERFORM "require_transaction_isolation"();
2886 DELETE FROM "member_count";
2887 INSERT INTO "member_count" ("total_count")
2888 SELECT "total_count" FROM "member_count_view";
2889 UPDATE "unit" SET "member_count" = "view"."member_count"
2890 FROM "unit_member_count" AS "view"
2891 WHERE "view"."unit_id" = "unit"."id";
2892 UPDATE "area" SET
2893 "direct_member_count" = "view"."direct_member_count",
2894 "member_weight" = "view"."member_weight"
2895 FROM "area_member_count" AS "view"
2896 WHERE "view"."area_id" = "area"."id";
2897 RETURN;
2898 END;
2899 $$;
2901 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"';
2905 ------------------------------------
2906 -- Calculation of harmonic weight --
2907 ------------------------------------
2910 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2911 SELECT
2912 "direct_interest_snapshot"."issue_id",
2913 "direct_interest_snapshot"."event",
2914 "direct_interest_snapshot"."member_id",
2915 "direct_interest_snapshot"."weight" AS "weight_num",
2916 count("initiative"."id") AS "weight_den"
2917 FROM "issue"
2918 JOIN "direct_interest_snapshot"
2919 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
2920 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
2921 JOIN "initiative"
2922 ON "issue"."id" = "initiative"."issue_id"
2923 AND "initiative"."harmonic_weight" ISNULL
2924 JOIN "direct_supporter_snapshot"
2925 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2926 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
2927 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
2928 AND (
2929 "direct_supporter_snapshot"."satisfied" = TRUE OR
2930 coalesce("initiative"."admitted", FALSE) = FALSE
2932 GROUP BY
2933 "direct_interest_snapshot"."issue_id",
2934 "direct_interest_snapshot"."event",
2935 "direct_interest_snapshot"."member_id",
2936 "direct_interest_snapshot"."weight";
2938 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
2941 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
2942 SELECT
2943 "initiative"."issue_id",
2944 "initiative"."id" AS "initiative_id",
2945 "initiative"."admitted",
2946 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
2947 "remaining_harmonic_supporter_weight"."weight_den"
2948 FROM "remaining_harmonic_supporter_weight"
2949 JOIN "initiative"
2950 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
2951 AND "initiative"."harmonic_weight" ISNULL
2952 JOIN "direct_supporter_snapshot"
2953 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2954 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
2955 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
2956 AND (
2957 "direct_supporter_snapshot"."satisfied" = TRUE OR
2958 coalesce("initiative"."admitted", FALSE) = FALSE
2960 GROUP BY
2961 "initiative"."issue_id",
2962 "initiative"."id",
2963 "initiative"."admitted",
2964 "remaining_harmonic_supporter_weight"."weight_den";
2966 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
2969 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
2970 SELECT
2971 "issue_id",
2972 "id" AS "initiative_id",
2973 "admitted",
2974 0 AS "weight_num",
2975 1 AS "weight_den"
2976 FROM "initiative"
2977 WHERE "harmonic_weight" ISNULL;
2979 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';
2982 CREATE FUNCTION "set_harmonic_initiative_weights"
2983 ( "issue_id_p" "issue"."id"%TYPE )
2984 RETURNS VOID
2985 LANGUAGE 'plpgsql' VOLATILE AS $$
2986 DECLARE
2987 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
2988 "i" INT4;
2989 "count_v" INT4;
2990 "summand_v" FLOAT;
2991 "id_ary" INT4[];
2992 "weight_ary" FLOAT[];
2993 "min_weight_v" FLOAT;
2994 BEGIN
2995 PERFORM "require_transaction_isolation"();
2996 UPDATE "initiative" SET "harmonic_weight" = NULL
2997 WHERE "issue_id" = "issue_id_p";
2998 LOOP
2999 "min_weight_v" := NULL;
3000 "i" := 0;
3001 "count_v" := 0;
3002 FOR "weight_row" IN
3003 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
3004 WHERE "issue_id" = "issue_id_p"
3005 AND (
3006 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3007 SELECT NULL FROM "initiative"
3008 WHERE "issue_id" = "issue_id_p"
3009 AND "harmonic_weight" ISNULL
3010 AND coalesce("admitted", FALSE) = FALSE
3013 UNION ALL -- needed for corner cases
3014 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
3015 WHERE "issue_id" = "issue_id_p"
3016 AND (
3017 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3018 SELECT NULL FROM "initiative"
3019 WHERE "issue_id" = "issue_id_p"
3020 AND "harmonic_weight" ISNULL
3021 AND coalesce("admitted", FALSE) = FALSE
3024 ORDER BY "initiative_id" DESC, "weight_den" DESC
3025 -- NOTE: non-admitted initiatives placed first (at last positions),
3026 -- latest initiatives treated worse in case of tie
3027 LOOP
3028 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
3029 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
3030 "i" := "i" + 1;
3031 "count_v" := "i";
3032 "id_ary"["i"] := "weight_row"."initiative_id";
3033 "weight_ary"["i"] := "summand_v";
3034 ELSE
3035 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
3036 END IF;
3037 END LOOP;
3038 EXIT WHEN "count_v" = 0;
3039 "i" := 1;
3040 LOOP
3041 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
3042 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
3043 "min_weight_v" := "weight_ary"["i"];
3044 END IF;
3045 "i" := "i" + 1;
3046 EXIT WHEN "i" > "count_v";
3047 END LOOP;
3048 "i" := 1;
3049 LOOP
3050 IF "weight_ary"["i"] = "min_weight_v" THEN
3051 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
3052 WHERE "id" = "id_ary"["i"];
3053 EXIT;
3054 END IF;
3055 "i" := "i" + 1;
3056 END LOOP;
3057 END LOOP;
3058 UPDATE "initiative" SET "harmonic_weight" = 0
3059 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
3060 END;
3061 $$;
3063 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
3064 ( "issue"."id"%TYPE )
3065 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
3069 ------------------------------
3070 -- Calculation of snapshots --
3071 ------------------------------
3074 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3075 ( "issue_id_p" "issue"."id"%TYPE,
3076 "member_id_p" "member"."id"%TYPE,
3077 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3078 RETURNS "direct_population_snapshot"."weight"%TYPE
3079 LANGUAGE 'plpgsql' VOLATILE AS $$
3080 DECLARE
3081 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3082 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3083 "weight_v" INT4;
3084 "sub_weight_v" INT4;
3085 BEGIN
3086 PERFORM "require_transaction_isolation"();
3087 "weight_v" := 0;
3088 FOR "issue_delegation_row" IN
3089 SELECT * FROM "issue_delegation"
3090 WHERE "trustee_id" = "member_id_p"
3091 AND "issue_id" = "issue_id_p"
3092 LOOP
3093 IF NOT EXISTS (
3094 SELECT NULL FROM "direct_population_snapshot"
3095 WHERE "issue_id" = "issue_id_p"
3096 AND "event" = 'periodic'
3097 AND "member_id" = "issue_delegation_row"."truster_id"
3098 ) AND NOT EXISTS (
3099 SELECT NULL FROM "delegating_population_snapshot"
3100 WHERE "issue_id" = "issue_id_p"
3101 AND "event" = 'periodic'
3102 AND "member_id" = "issue_delegation_row"."truster_id"
3103 ) THEN
3104 "delegate_member_ids_v" :=
3105 "member_id_p" || "delegate_member_ids_p";
3106 INSERT INTO "delegating_population_snapshot" (
3107 "issue_id",
3108 "event",
3109 "member_id",
3110 "scope",
3111 "delegate_member_ids"
3112 ) VALUES (
3113 "issue_id_p",
3114 'periodic',
3115 "issue_delegation_row"."truster_id",
3116 "issue_delegation_row"."scope",
3117 "delegate_member_ids_v"
3118 );
3119 "sub_weight_v" := 1 +
3120 "weight_of_added_delegations_for_population_snapshot"(
3121 "issue_id_p",
3122 "issue_delegation_row"."truster_id",
3123 "delegate_member_ids_v"
3124 );
3125 UPDATE "delegating_population_snapshot"
3126 SET "weight" = "sub_weight_v"
3127 WHERE "issue_id" = "issue_id_p"
3128 AND "event" = 'periodic'
3129 AND "member_id" = "issue_delegation_row"."truster_id";
3130 "weight_v" := "weight_v" + "sub_weight_v";
3131 END IF;
3132 END LOOP;
3133 RETURN "weight_v";
3134 END;
3135 $$;
3137 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3138 ( "issue"."id"%TYPE,
3139 "member"."id"%TYPE,
3140 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3141 IS 'Helper function for "create_population_snapshot" function';
3144 CREATE FUNCTION "create_population_snapshot"
3145 ( "issue_id_p" "issue"."id"%TYPE )
3146 RETURNS VOID
3147 LANGUAGE 'plpgsql' VOLATILE AS $$
3148 DECLARE
3149 "member_id_v" "member"."id"%TYPE;
3150 BEGIN
3151 PERFORM "require_transaction_isolation"();
3152 DELETE FROM "direct_population_snapshot"
3153 WHERE "issue_id" = "issue_id_p"
3154 AND "event" = 'periodic';
3155 DELETE FROM "delegating_population_snapshot"
3156 WHERE "issue_id" = "issue_id_p"
3157 AND "event" = 'periodic';
3158 INSERT INTO "direct_population_snapshot"
3159 ("issue_id", "event", "member_id")
3160 SELECT
3161 "issue_id_p" AS "issue_id",
3162 'periodic'::"snapshot_event" AS "event",
3163 "member"."id" AS "member_id"
3164 FROM "issue"
3165 JOIN "area" ON "issue"."area_id" = "area"."id"
3166 JOIN "membership" ON "area"."id" = "membership"."area_id"
3167 JOIN "member" ON "membership"."member_id" = "member"."id"
3168 JOIN "privilege"
3169 ON "privilege"."unit_id" = "area"."unit_id"
3170 AND "privilege"."member_id" = "member"."id"
3171 WHERE "issue"."id" = "issue_id_p"
3172 AND "member"."active" AND "privilege"."voting_right"
3173 UNION
3174 SELECT
3175 "issue_id_p" AS "issue_id",
3176 'periodic'::"snapshot_event" AS "event",
3177 "member"."id" AS "member_id"
3178 FROM "issue"
3179 JOIN "area" ON "issue"."area_id" = "area"."id"
3180 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3181 JOIN "member" ON "interest"."member_id" = "member"."id"
3182 JOIN "privilege"
3183 ON "privilege"."unit_id" = "area"."unit_id"
3184 AND "privilege"."member_id" = "member"."id"
3185 WHERE "issue"."id" = "issue_id_p"
3186 AND "member"."active" AND "privilege"."voting_right";
3187 FOR "member_id_v" IN
3188 SELECT "member_id" FROM "direct_population_snapshot"
3189 WHERE "issue_id" = "issue_id_p"
3190 AND "event" = 'periodic'
3191 LOOP
3192 UPDATE "direct_population_snapshot" SET
3193 "weight" = 1 +
3194 "weight_of_added_delegations_for_population_snapshot"(
3195 "issue_id_p",
3196 "member_id_v",
3197 '{}'
3199 WHERE "issue_id" = "issue_id_p"
3200 AND "event" = 'periodic'
3201 AND "member_id" = "member_id_v";
3202 END LOOP;
3203 RETURN;
3204 END;
3205 $$;
3207 COMMENT ON FUNCTION "create_population_snapshot"
3208 ( "issue"."id"%TYPE )
3209 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.';
3212 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3213 ( "issue_id_p" "issue"."id"%TYPE,
3214 "member_id_p" "member"."id"%TYPE,
3215 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3216 RETURNS "direct_interest_snapshot"."weight"%TYPE
3217 LANGUAGE 'plpgsql' VOLATILE AS $$
3218 DECLARE
3219 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3220 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3221 "weight_v" INT4;
3222 "sub_weight_v" INT4;
3223 BEGIN
3224 PERFORM "require_transaction_isolation"();
3225 "weight_v" := 0;
3226 FOR "issue_delegation_row" IN
3227 SELECT * FROM "issue_delegation"
3228 WHERE "trustee_id" = "member_id_p"
3229 AND "issue_id" = "issue_id_p"
3230 LOOP
3231 IF NOT EXISTS (
3232 SELECT NULL FROM "direct_interest_snapshot"
3233 WHERE "issue_id" = "issue_id_p"
3234 AND "event" = 'periodic'
3235 AND "member_id" = "issue_delegation_row"."truster_id"
3236 ) AND NOT EXISTS (
3237 SELECT NULL FROM "delegating_interest_snapshot"
3238 WHERE "issue_id" = "issue_id_p"
3239 AND "event" = 'periodic'
3240 AND "member_id" = "issue_delegation_row"."truster_id"
3241 ) THEN
3242 "delegate_member_ids_v" :=
3243 "member_id_p" || "delegate_member_ids_p";
3244 INSERT INTO "delegating_interest_snapshot" (
3245 "issue_id",
3246 "event",
3247 "member_id",
3248 "scope",
3249 "delegate_member_ids"
3250 ) VALUES (
3251 "issue_id_p",
3252 'periodic',
3253 "issue_delegation_row"."truster_id",
3254 "issue_delegation_row"."scope",
3255 "delegate_member_ids_v"
3256 );
3257 "sub_weight_v" := 1 +
3258 "weight_of_added_delegations_for_interest_snapshot"(
3259 "issue_id_p",
3260 "issue_delegation_row"."truster_id",
3261 "delegate_member_ids_v"
3262 );
3263 UPDATE "delegating_interest_snapshot"
3264 SET "weight" = "sub_weight_v"
3265 WHERE "issue_id" = "issue_id_p"
3266 AND "event" = 'periodic'
3267 AND "member_id" = "issue_delegation_row"."truster_id";
3268 "weight_v" := "weight_v" + "sub_weight_v";
3269 END IF;
3270 END LOOP;
3271 RETURN "weight_v";
3272 END;
3273 $$;
3275 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3276 ( "issue"."id"%TYPE,
3277 "member"."id"%TYPE,
3278 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3279 IS 'Helper function for "create_interest_snapshot" function';
3282 CREATE FUNCTION "create_interest_snapshot"
3283 ( "issue_id_p" "issue"."id"%TYPE )
3284 RETURNS VOID
3285 LANGUAGE 'plpgsql' VOLATILE AS $$
3286 DECLARE
3287 "member_id_v" "member"."id"%TYPE;
3288 BEGIN
3289 PERFORM "require_transaction_isolation"();
3290 DELETE FROM "direct_interest_snapshot"
3291 WHERE "issue_id" = "issue_id_p"
3292 AND "event" = 'periodic';
3293 DELETE FROM "delegating_interest_snapshot"
3294 WHERE "issue_id" = "issue_id_p"
3295 AND "event" = 'periodic';
3296 DELETE FROM "direct_supporter_snapshot"
3297 USING "initiative" -- NOTE: due to missing index on issue_id
3298 WHERE "initiative"."issue_id" = "issue_id_p"
3299 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3300 AND "direct_supporter_snapshot"."event" = 'periodic';
3301 INSERT INTO "direct_interest_snapshot"
3302 ("issue_id", "event", "member_id")
3303 SELECT
3304 "issue_id_p" AS "issue_id",
3305 'periodic' AS "event",
3306 "member"."id" AS "member_id"
3307 FROM "issue"
3308 JOIN "area" ON "issue"."area_id" = "area"."id"
3309 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3310 JOIN "member" ON "interest"."member_id" = "member"."id"
3311 JOIN "privilege"
3312 ON "privilege"."unit_id" = "area"."unit_id"
3313 AND "privilege"."member_id" = "member"."id"
3314 WHERE "issue"."id" = "issue_id_p"
3315 AND "member"."active" AND "privilege"."voting_right";
3316 FOR "member_id_v" IN
3317 SELECT "member_id" FROM "direct_interest_snapshot"
3318 WHERE "issue_id" = "issue_id_p"
3319 AND "event" = 'periodic'
3320 LOOP
3321 UPDATE "direct_interest_snapshot" SET
3322 "weight" = 1 +
3323 "weight_of_added_delegations_for_interest_snapshot"(
3324 "issue_id_p",
3325 "member_id_v",
3326 '{}'
3328 WHERE "issue_id" = "issue_id_p"
3329 AND "event" = 'periodic'
3330 AND "member_id" = "member_id_v";
3331 END LOOP;
3332 INSERT INTO "direct_supporter_snapshot"
3333 ( "issue_id", "initiative_id", "event", "member_id",
3334 "draft_id", "informed", "satisfied" )
3335 SELECT
3336 "issue_id_p" AS "issue_id",
3337 "initiative"."id" AS "initiative_id",
3338 'periodic' AS "event",
3339 "supporter"."member_id" AS "member_id",
3340 "supporter"."draft_id" AS "draft_id",
3341 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3342 NOT EXISTS (
3343 SELECT NULL FROM "critical_opinion"
3344 WHERE "initiative_id" = "initiative"."id"
3345 AND "member_id" = "supporter"."member_id"
3346 ) AS "satisfied"
3347 FROM "initiative"
3348 JOIN "supporter"
3349 ON "supporter"."initiative_id" = "initiative"."id"
3350 JOIN "current_draft"
3351 ON "initiative"."id" = "current_draft"."initiative_id"
3352 JOIN "direct_interest_snapshot"
3353 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3354 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3355 AND "event" = 'periodic'
3356 WHERE "initiative"."issue_id" = "issue_id_p";
3357 RETURN;
3358 END;
3359 $$;
3361 COMMENT ON FUNCTION "create_interest_snapshot"
3362 ( "issue"."id"%TYPE )
3363 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.';
3366 CREATE FUNCTION "create_snapshot"
3367 ( "issue_id_p" "issue"."id"%TYPE )
3368 RETURNS VOID
3369 LANGUAGE 'plpgsql' VOLATILE AS $$
3370 DECLARE
3371 "initiative_id_v" "initiative"."id"%TYPE;
3372 "suggestion_id_v" "suggestion"."id"%TYPE;
3373 BEGIN
3374 PERFORM "require_transaction_isolation"();
3375 PERFORM "create_population_snapshot"("issue_id_p");
3376 PERFORM "create_interest_snapshot"("issue_id_p");
3377 UPDATE "issue" SET
3378 "snapshot" = coalesce("phase_finished", now()),
3379 "latest_snapshot_event" = 'periodic',
3380 "population" = (
3381 SELECT coalesce(sum("weight"), 0)
3382 FROM "direct_population_snapshot"
3383 WHERE "issue_id" = "issue_id_p"
3384 AND "event" = 'periodic'
3386 WHERE "id" = "issue_id_p";
3387 FOR "initiative_id_v" IN
3388 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3389 LOOP
3390 UPDATE "initiative" SET
3391 "supporter_count" = (
3392 SELECT coalesce(sum("di"."weight"), 0)
3393 FROM "direct_interest_snapshot" AS "di"
3394 JOIN "direct_supporter_snapshot" AS "ds"
3395 ON "di"."member_id" = "ds"."member_id"
3396 WHERE "di"."issue_id" = "issue_id_p"
3397 AND "di"."event" = 'periodic'
3398 AND "ds"."initiative_id" = "initiative_id_v"
3399 AND "ds"."event" = 'periodic'
3400 ),
3401 "informed_supporter_count" = (
3402 SELECT coalesce(sum("di"."weight"), 0)
3403 FROM "direct_interest_snapshot" AS "di"
3404 JOIN "direct_supporter_snapshot" AS "ds"
3405 ON "di"."member_id" = "ds"."member_id"
3406 WHERE "di"."issue_id" = "issue_id_p"
3407 AND "di"."event" = 'periodic'
3408 AND "ds"."initiative_id" = "initiative_id_v"
3409 AND "ds"."event" = 'periodic'
3410 AND "ds"."informed"
3411 ),
3412 "satisfied_supporter_count" = (
3413 SELECT coalesce(sum("di"."weight"), 0)
3414 FROM "direct_interest_snapshot" AS "di"
3415 JOIN "direct_supporter_snapshot" AS "ds"
3416 ON "di"."member_id" = "ds"."member_id"
3417 WHERE "di"."issue_id" = "issue_id_p"
3418 AND "di"."event" = 'periodic'
3419 AND "ds"."initiative_id" = "initiative_id_v"
3420 AND "ds"."event" = 'periodic'
3421 AND "ds"."satisfied"
3422 ),
3423 "satisfied_informed_supporter_count" = (
3424 SELECT coalesce(sum("di"."weight"), 0)
3425 FROM "direct_interest_snapshot" AS "di"
3426 JOIN "direct_supporter_snapshot" AS "ds"
3427 ON "di"."member_id" = "ds"."member_id"
3428 WHERE "di"."issue_id" = "issue_id_p"
3429 AND "di"."event" = 'periodic'
3430 AND "ds"."initiative_id" = "initiative_id_v"
3431 AND "ds"."event" = 'periodic'
3432 AND "ds"."informed"
3433 AND "ds"."satisfied"
3435 WHERE "id" = "initiative_id_v";
3436 FOR "suggestion_id_v" IN
3437 SELECT "id" FROM "suggestion"
3438 WHERE "initiative_id" = "initiative_id_v"
3439 LOOP
3440 UPDATE "suggestion" SET
3441 "minus2_unfulfilled_count" = (
3442 SELECT coalesce(sum("snapshot"."weight"), 0)
3443 FROM "issue" CROSS JOIN "opinion"
3444 JOIN "direct_interest_snapshot" AS "snapshot"
3445 ON "snapshot"."issue_id" = "issue"."id"
3446 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3447 AND "snapshot"."member_id" = "opinion"."member_id"
3448 WHERE "issue"."id" = "issue_id_p"
3449 AND "opinion"."suggestion_id" = "suggestion_id_v"
3450 AND "opinion"."degree" = -2
3451 AND "opinion"."fulfilled" = FALSE
3452 ),
3453 "minus2_fulfilled_count" = (
3454 SELECT coalesce(sum("snapshot"."weight"), 0)
3455 FROM "issue" CROSS JOIN "opinion"
3456 JOIN "direct_interest_snapshot" AS "snapshot"
3457 ON "snapshot"."issue_id" = "issue"."id"
3458 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3459 AND "snapshot"."member_id" = "opinion"."member_id"
3460 WHERE "issue"."id" = "issue_id_p"
3461 AND "opinion"."suggestion_id" = "suggestion_id_v"
3462 AND "opinion"."degree" = -2
3463 AND "opinion"."fulfilled" = TRUE
3464 ),
3465 "minus1_unfulfilled_count" = (
3466 SELECT coalesce(sum("snapshot"."weight"), 0)
3467 FROM "issue" CROSS JOIN "opinion"
3468 JOIN "direct_interest_snapshot" AS "snapshot"
3469 ON "snapshot"."issue_id" = "issue"."id"
3470 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3471 AND "snapshot"."member_id" = "opinion"."member_id"
3472 WHERE "issue"."id" = "issue_id_p"
3473 AND "opinion"."suggestion_id" = "suggestion_id_v"
3474 AND "opinion"."degree" = -1
3475 AND "opinion"."fulfilled" = FALSE
3476 ),
3477 "minus1_fulfilled_count" = (
3478 SELECT coalesce(sum("snapshot"."weight"), 0)
3479 FROM "issue" CROSS JOIN "opinion"
3480 JOIN "direct_interest_snapshot" AS "snapshot"
3481 ON "snapshot"."issue_id" = "issue"."id"
3482 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3483 AND "snapshot"."member_id" = "opinion"."member_id"
3484 WHERE "issue"."id" = "issue_id_p"
3485 AND "opinion"."suggestion_id" = "suggestion_id_v"
3486 AND "opinion"."degree" = -1
3487 AND "opinion"."fulfilled" = TRUE
3488 ),
3489 "plus1_unfulfilled_count" = (
3490 SELECT coalesce(sum("snapshot"."weight"), 0)
3491 FROM "issue" CROSS JOIN "opinion"
3492 JOIN "direct_interest_snapshot" AS "snapshot"
3493 ON "snapshot"."issue_id" = "issue"."id"
3494 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3495 AND "snapshot"."member_id" = "opinion"."member_id"
3496 WHERE "issue"."id" = "issue_id_p"
3497 AND "opinion"."suggestion_id" = "suggestion_id_v"
3498 AND "opinion"."degree" = 1
3499 AND "opinion"."fulfilled" = FALSE
3500 ),
3501 "plus1_fulfilled_count" = (
3502 SELECT coalesce(sum("snapshot"."weight"), 0)
3503 FROM "issue" CROSS JOIN "opinion"
3504 JOIN "direct_interest_snapshot" AS "snapshot"
3505 ON "snapshot"."issue_id" = "issue"."id"
3506 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3507 AND "snapshot"."member_id" = "opinion"."member_id"
3508 WHERE "issue"."id" = "issue_id_p"
3509 AND "opinion"."suggestion_id" = "suggestion_id_v"
3510 AND "opinion"."degree" = 1
3511 AND "opinion"."fulfilled" = TRUE
3512 ),
3513 "plus2_unfulfilled_count" = (
3514 SELECT coalesce(sum("snapshot"."weight"), 0)
3515 FROM "issue" CROSS JOIN "opinion"
3516 JOIN "direct_interest_snapshot" AS "snapshot"
3517 ON "snapshot"."issue_id" = "issue"."id"
3518 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3519 AND "snapshot"."member_id" = "opinion"."member_id"
3520 WHERE "issue"."id" = "issue_id_p"
3521 AND "opinion"."suggestion_id" = "suggestion_id_v"
3522 AND "opinion"."degree" = 2
3523 AND "opinion"."fulfilled" = FALSE
3524 ),
3525 "plus2_fulfilled_count" = (
3526 SELECT coalesce(sum("snapshot"."weight"), 0)
3527 FROM "issue" CROSS JOIN "opinion"
3528 JOIN "direct_interest_snapshot" AS "snapshot"
3529 ON "snapshot"."issue_id" = "issue"."id"
3530 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3531 AND "snapshot"."member_id" = "opinion"."member_id"
3532 WHERE "issue"."id" = "issue_id_p"
3533 AND "opinion"."suggestion_id" = "suggestion_id_v"
3534 AND "opinion"."degree" = 2
3535 AND "opinion"."fulfilled" = TRUE
3537 WHERE "suggestion"."id" = "suggestion_id_v";
3538 END LOOP;
3539 END LOOP;
3540 RETURN;
3541 END;
3542 $$;
3544 COMMENT ON FUNCTION "create_snapshot"
3545 ( "issue"."id"%TYPE )
3546 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.';
3549 CREATE FUNCTION "set_snapshot_event"
3550 ( "issue_id_p" "issue"."id"%TYPE,
3551 "event_p" "snapshot_event" )
3552 RETURNS VOID
3553 LANGUAGE 'plpgsql' VOLATILE AS $$
3554 DECLARE
3555 "event_v" "issue"."latest_snapshot_event"%TYPE;
3556 BEGIN
3557 PERFORM "require_transaction_isolation"();
3558 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3559 WHERE "id" = "issue_id_p" FOR UPDATE;
3560 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3561 WHERE "id" = "issue_id_p";
3562 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3563 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3564 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3565 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3566 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3567 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3568 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3569 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3570 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3571 FROM "initiative" -- NOTE: due to missing index on issue_id
3572 WHERE "initiative"."issue_id" = "issue_id_p"
3573 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3574 AND "direct_supporter_snapshot"."event" = "event_v";
3575 RETURN;
3576 END;
3577 $$;
3579 COMMENT ON FUNCTION "set_snapshot_event"
3580 ( "issue"."id"%TYPE,
3581 "snapshot_event" )
3582 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3586 -----------------------
3587 -- Counting of votes --
3588 -----------------------
3591 CREATE FUNCTION "weight_of_added_vote_delegations"
3592 ( "issue_id_p" "issue"."id"%TYPE,
3593 "member_id_p" "member"."id"%TYPE,
3594 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3595 RETURNS "direct_voter"."weight"%TYPE
3596 LANGUAGE 'plpgsql' VOLATILE AS $$
3597 DECLARE
3598 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3599 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3600 "weight_v" INT4;
3601 "sub_weight_v" INT4;
3602 BEGIN
3603 PERFORM "require_transaction_isolation"();
3604 "weight_v" := 0;
3605 FOR "issue_delegation_row" IN
3606 SELECT * FROM "issue_delegation"
3607 WHERE "trustee_id" = "member_id_p"
3608 AND "issue_id" = "issue_id_p"
3609 LOOP
3610 IF NOT EXISTS (
3611 SELECT NULL FROM "direct_voter"
3612 WHERE "member_id" = "issue_delegation_row"."truster_id"
3613 AND "issue_id" = "issue_id_p"
3614 ) AND NOT EXISTS (
3615 SELECT NULL FROM "delegating_voter"
3616 WHERE "member_id" = "issue_delegation_row"."truster_id"
3617 AND "issue_id" = "issue_id_p"
3618 ) THEN
3619 "delegate_member_ids_v" :=
3620 "member_id_p" || "delegate_member_ids_p";
3621 INSERT INTO "delegating_voter" (
3622 "issue_id",
3623 "member_id",
3624 "scope",
3625 "delegate_member_ids"
3626 ) VALUES (
3627 "issue_id_p",
3628 "issue_delegation_row"."truster_id",
3629 "issue_delegation_row"."scope",
3630 "delegate_member_ids_v"
3631 );
3632 "sub_weight_v" := 1 +
3633 "weight_of_added_vote_delegations"(
3634 "issue_id_p",
3635 "issue_delegation_row"."truster_id",
3636 "delegate_member_ids_v"
3637 );
3638 UPDATE "delegating_voter"
3639 SET "weight" = "sub_weight_v"
3640 WHERE "issue_id" = "issue_id_p"
3641 AND "member_id" = "issue_delegation_row"."truster_id";
3642 "weight_v" := "weight_v" + "sub_weight_v";
3643 END IF;
3644 END LOOP;
3645 RETURN "weight_v";
3646 END;
3647 $$;
3649 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3650 ( "issue"."id"%TYPE,
3651 "member"."id"%TYPE,
3652 "delegating_voter"."delegate_member_ids"%TYPE )
3653 IS 'Helper function for "add_vote_delegations" function';
3656 CREATE FUNCTION "add_vote_delegations"
3657 ( "issue_id_p" "issue"."id"%TYPE )
3658 RETURNS VOID
3659 LANGUAGE 'plpgsql' VOLATILE AS $$
3660 DECLARE
3661 "member_id_v" "member"."id"%TYPE;
3662 BEGIN
3663 PERFORM "require_transaction_isolation"();
3664 FOR "member_id_v" IN
3665 SELECT "member_id" FROM "direct_voter"
3666 WHERE "issue_id" = "issue_id_p"
3667 LOOP
3668 UPDATE "direct_voter" SET
3669 "weight" = "weight" + "weight_of_added_vote_delegations"(
3670 "issue_id_p",
3671 "member_id_v",
3672 '{}'
3674 WHERE "member_id" = "member_id_v"
3675 AND "issue_id" = "issue_id_p";
3676 END LOOP;
3677 RETURN;
3678 END;
3679 $$;
3681 COMMENT ON FUNCTION "add_vote_delegations"
3682 ( "issue_id_p" "issue"."id"%TYPE )
3683 IS 'Helper function for "close_voting" function';
3686 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3687 RETURNS VOID
3688 LANGUAGE 'plpgsql' VOLATILE AS $$
3689 DECLARE
3690 "area_id_v" "area"."id"%TYPE;
3691 "unit_id_v" "unit"."id"%TYPE;
3692 "member_id_v" "member"."id"%TYPE;
3693 BEGIN
3694 PERFORM "require_transaction_isolation"();
3695 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3696 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3697 -- override protection triggers:
3698 INSERT INTO "temporary_transaction_data" ("key", "value")
3699 VALUES ('override_protection_triggers', TRUE::TEXT);
3700 -- delete timestamp of voting comment:
3701 UPDATE "direct_voter" SET "comment_changed" = NULL
3702 WHERE "issue_id" = "issue_id_p";
3703 -- delete delegating votes (in cases of manual reset of issue state):
3704 DELETE FROM "delegating_voter"
3705 WHERE "issue_id" = "issue_id_p";
3706 -- delete votes from non-privileged voters:
3707 DELETE FROM "direct_voter"
3708 USING (
3709 SELECT
3710 "direct_voter"."member_id"
3711 FROM "direct_voter"
3712 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3713 LEFT JOIN "privilege"
3714 ON "privilege"."unit_id" = "unit_id_v"
3715 AND "privilege"."member_id" = "direct_voter"."member_id"
3716 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3717 "member"."active" = FALSE OR
3718 "privilege"."voting_right" ISNULL OR
3719 "privilege"."voting_right" = FALSE
3721 ) AS "subquery"
3722 WHERE "direct_voter"."issue_id" = "issue_id_p"
3723 AND "direct_voter"."member_id" = "subquery"."member_id";
3724 -- consider delegations:
3725 UPDATE "direct_voter" SET "weight" = 1
3726 WHERE "issue_id" = "issue_id_p";
3727 PERFORM "add_vote_delegations"("issue_id_p");
3728 -- mark first preferences:
3729 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
3730 FROM (
3731 SELECT
3732 "vote"."initiative_id",
3733 "vote"."member_id",
3734 CASE WHEN "vote"."grade" > 0 THEN
3735 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
3736 ELSE NULL
3737 END AS "first_preference"
3738 FROM "vote"
3739 JOIN "initiative" -- NOTE: due to missing index on issue_id
3740 ON "vote"."issue_id" = "initiative"."issue_id"
3741 JOIN "vote" AS "agg"
3742 ON "initiative"."id" = "agg"."initiative_id"
3743 AND "vote"."member_id" = "agg"."member_id"
3744 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
3745 ) AS "subquery"
3746 WHERE "vote"."issue_id" = "issue_id_p"
3747 AND "vote"."initiative_id" = "subquery"."initiative_id"
3748 AND "vote"."member_id" = "subquery"."member_id";
3749 -- finish overriding protection triggers (avoids garbage):
3750 DELETE FROM "temporary_transaction_data"
3751 WHERE "key" = 'override_protection_triggers';
3752 -- materialize battle_view:
3753 -- NOTE: "closed" column of issue must be set at this point
3754 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3755 INSERT INTO "battle" (
3756 "issue_id",
3757 "winning_initiative_id", "losing_initiative_id",
3758 "count"
3759 ) SELECT
3760 "issue_id",
3761 "winning_initiative_id", "losing_initiative_id",
3762 "count"
3763 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3764 -- set voter count:
3765 UPDATE "issue" SET
3766 "voter_count" = (
3767 SELECT coalesce(sum("weight"), 0)
3768 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3770 WHERE "id" = "issue_id_p";
3771 -- copy "positive_votes" and "negative_votes" from "battle" table:
3772 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
3773 UPDATE "initiative" SET
3774 "first_preference_votes" = 0,
3775 "positive_votes" = "battle_win"."count",
3776 "negative_votes" = "battle_lose"."count"
3777 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3778 WHERE
3779 "battle_win"."issue_id" = "issue_id_p" AND
3780 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3781 "battle_win"."losing_initiative_id" ISNULL AND
3782 "battle_lose"."issue_id" = "issue_id_p" AND
3783 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3784 "battle_lose"."winning_initiative_id" ISNULL;
3785 -- calculate "first_preference_votes":
3786 -- NOTE: will only set values not equal to zero
3787 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
3788 FROM (
3789 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
3790 FROM "vote" JOIN "direct_voter"
3791 ON "vote"."issue_id" = "direct_voter"."issue_id"
3792 AND "vote"."member_id" = "direct_voter"."member_id"
3793 WHERE "vote"."first_preference"
3794 GROUP BY "vote"."initiative_id"
3795 ) AS "subquery"
3796 WHERE "initiative"."issue_id" = "issue_id_p"
3797 AND "initiative"."admitted"
3798 AND "initiative"."id" = "subquery"."initiative_id";
3799 END;
3800 $$;
3802 COMMENT ON FUNCTION "close_voting"
3803 ( "issue"."id"%TYPE )
3804 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.';
3807 CREATE FUNCTION "defeat_strength"
3808 ( "positive_votes_p" INT4,
3809 "negative_votes_p" INT4,
3810 "defeat_strength_p" "defeat_strength" )
3811 RETURNS INT8
3812 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3813 BEGIN
3814 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
3815 IF "positive_votes_p" > "negative_votes_p" THEN
3816 RETURN "positive_votes_p";
3817 ELSE
3818 RETURN 0;
3819 END IF;
3820 ELSE
3821 IF "positive_votes_p" > "negative_votes_p" THEN
3822 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3823 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3824 RETURN 0;
3825 ELSE
3826 RETURN -1;
3827 END IF;
3828 END IF;
3829 END;
3830 $$;
3832 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")';
3835 CREATE FUNCTION "secondary_link_strength"
3836 ( "initiative1_ord_p" INT4,
3837 "initiative2_ord_p" INT4,
3838 "tie_breaking_p" "tie_breaking" )
3839 RETURNS INT8
3840 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3841 BEGIN
3842 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
3843 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
3844 END IF;
3845 RETURN (
3846 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
3848 ELSE
3849 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
3850 1::INT8 << 62
3851 ELSE 0 END
3853 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
3854 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
3855 ELSE
3856 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
3857 END
3858 END
3859 );
3860 END;
3861 $$;
3863 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
3866 CREATE TYPE "link_strength" AS (
3867 "primary" INT8,
3868 "secondary" INT8 );
3870 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'')';
3873 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
3874 RETURNS "link_strength"[][]
3875 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3876 DECLARE
3877 "dimension_v" INT4;
3878 "matrix_p" "link_strength"[][];
3879 "i" INT4;
3880 "j" INT4;
3881 "k" INT4;
3882 BEGIN
3883 "dimension_v" := array_upper("matrix_d", 1);
3884 "matrix_p" := "matrix_d";
3885 "i" := 1;
3886 LOOP
3887 "j" := 1;
3888 LOOP
3889 IF "i" != "j" THEN
3890 "k" := 1;
3891 LOOP
3892 IF "i" != "k" AND "j" != "k" THEN
3893 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
3894 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
3895 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
3896 END IF;
3897 ELSE
3898 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
3899 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
3900 END IF;
3901 END IF;
3902 END IF;
3903 EXIT WHEN "k" = "dimension_v";
3904 "k" := "k" + 1;
3905 END LOOP;
3906 END IF;
3907 EXIT WHEN "j" = "dimension_v";
3908 "j" := "j" + 1;
3909 END LOOP;
3910 EXIT WHEN "i" = "dimension_v";
3911 "i" := "i" + 1;
3912 END LOOP;
3913 RETURN "matrix_p";
3914 END;
3915 $$;
3917 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
3920 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3921 RETURNS VOID
3922 LANGUAGE 'plpgsql' VOLATILE AS $$
3923 DECLARE
3924 "issue_row" "issue"%ROWTYPE;
3925 "policy_row" "policy"%ROWTYPE;
3926 "dimension_v" INT4;
3927 "matrix_a" INT4[][]; -- absolute votes
3928 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
3929 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
3930 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
3931 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
3932 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
3933 "i" INT4;
3934 "j" INT4;
3935 "m" INT4;
3936 "n" INT4;
3937 "battle_row" "battle"%ROWTYPE;
3938 "rank_ary" INT4[];
3939 "rank_v" INT4;
3940 "initiative_id_v" "initiative"."id"%TYPE;
3941 BEGIN
3942 PERFORM "require_transaction_isolation"();
3943 SELECT * INTO "issue_row"
3944 FROM "issue" WHERE "id" = "issue_id_p";
3945 SELECT * INTO "policy_row"
3946 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3947 SELECT count(1) INTO "dimension_v"
3948 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3949 -- create "matrix_a" with absolute number of votes in pairwise
3950 -- comparison:
3951 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3952 "i" := 1;
3953 "j" := 2;
3954 FOR "battle_row" IN
3955 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3956 ORDER BY
3957 "winning_initiative_id" NULLS FIRST,
3958 "losing_initiative_id" NULLS FIRST
3959 LOOP
3960 "matrix_a"["i"]["j"] := "battle_row"."count";
3961 IF "j" = "dimension_v" THEN
3962 "i" := "i" + 1;
3963 "j" := 1;
3964 ELSE
3965 "j" := "j" + 1;
3966 IF "j" = "i" THEN
3967 "j" := "j" + 1;
3968 END IF;
3969 END IF;
3970 END LOOP;
3971 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3972 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3973 END IF;
3974 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
3975 -- and "secondary_link_strength" functions:
3976 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3977 "i" := 1;
3978 LOOP
3979 "j" := 1;
3980 LOOP
3981 IF "i" != "j" THEN
3982 "matrix_d"["i"]["j"] := (
3983 "defeat_strength"(
3984 "matrix_a"["i"]["j"],
3985 "matrix_a"["j"]["i"],
3986 "policy_row"."defeat_strength"
3987 ),
3988 "secondary_link_strength"(
3989 "i",
3990 "j",
3991 "policy_row"."tie_breaking"
3993 )::"link_strength";
3994 END IF;
3995 EXIT WHEN "j" = "dimension_v";
3996 "j" := "j" + 1;
3997 END LOOP;
3998 EXIT WHEN "i" = "dimension_v";
3999 "i" := "i" + 1;
4000 END LOOP;
4001 -- find best paths:
4002 "matrix_p" := "find_best_paths"("matrix_d");
4003 -- create partial order:
4004 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
4005 "i" := 1;
4006 LOOP
4007 "j" := "i" + 1;
4008 LOOP
4009 IF "i" != "j" THEN
4010 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
4011 "matrix_b"["i"]["j"] := TRUE;
4012 "matrix_b"["j"]["i"] := FALSE;
4013 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
4014 "matrix_b"["i"]["j"] := FALSE;
4015 "matrix_b"["j"]["i"] := TRUE;
4016 END IF;
4017 END IF;
4018 EXIT WHEN "j" = "dimension_v";
4019 "j" := "j" + 1;
4020 END LOOP;
4021 EXIT WHEN "i" = "dimension_v" - 1;
4022 "i" := "i" + 1;
4023 END LOOP;
4024 -- tie-breaking by forbidding shared weakest links in beat-paths
4025 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
4026 -- is performed later by initiative id):
4027 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
4028 "m" := 1;
4029 LOOP
4030 "n" := "m" + 1;
4031 LOOP
4032 -- only process those candidates m and n, which are tied:
4033 IF "matrix_b"["m"]["n"] ISNULL THEN
4034 -- start with beat-paths prior tie-breaking:
4035 "matrix_t" := "matrix_p";
4036 -- start with all links allowed:
4037 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
4038 LOOP
4039 -- determine (and forbid) that link that is the weakest link
4040 -- in both the best path from candidate m to candidate n and
4041 -- from candidate n to candidate m:
4042 "i" := 1;
4043 <<forbid_one_link>>
4044 LOOP
4045 "j" := 1;
4046 LOOP
4047 IF "i" != "j" THEN
4048 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
4049 "matrix_f"["i"]["j"] := TRUE;
4050 -- exit for performance reasons,
4051 -- as exactly one link will be found:
4052 EXIT forbid_one_link;
4053 END IF;
4054 END IF;
4055 EXIT WHEN "j" = "dimension_v";
4056 "j" := "j" + 1;
4057 END LOOP;
4058 IF "i" = "dimension_v" THEN
4059 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
4060 END IF;
4061 "i" := "i" + 1;
4062 END LOOP;
4063 -- calculate best beat-paths while ignoring forbidden links:
4064 "i" := 1;
4065 LOOP
4066 "j" := 1;
4067 LOOP
4068 IF "i" != "j" THEN
4069 "matrix_t"["i"]["j"] := CASE
4070 WHEN "matrix_f"["i"]["j"]
4071 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
4072 ELSE "matrix_d"["i"]["j"] END;
4073 END IF;
4074 EXIT WHEN "j" = "dimension_v";
4075 "j" := "j" + 1;
4076 END LOOP;
4077 EXIT WHEN "i" = "dimension_v";
4078 "i" := "i" + 1;
4079 END LOOP;
4080 "matrix_t" := "find_best_paths"("matrix_t");
4081 -- extend partial order, if tie-breaking was successful:
4082 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
4083 "matrix_b"["m"]["n"] := TRUE;
4084 "matrix_b"["n"]["m"] := FALSE;
4085 EXIT;
4086 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
4087 "matrix_b"["m"]["n"] := FALSE;
4088 "matrix_b"["n"]["m"] := TRUE;
4089 EXIT;
4090 END IF;
4091 END LOOP;
4092 END IF;
4093 EXIT WHEN "n" = "dimension_v";
4094 "n" := "n" + 1;
4095 END LOOP;
4096 EXIT WHEN "m" = "dimension_v" - 1;
4097 "m" := "m" + 1;
4098 END LOOP;
4099 END IF;
4100 -- store a unique ranking in "rank_ary":
4101 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
4102 "rank_v" := 1;
4103 LOOP
4104 "i" := 1;
4105 <<assign_next_rank>>
4106 LOOP
4107 IF "rank_ary"["i"] ISNULL THEN
4108 "j" := 1;
4109 LOOP
4110 IF
4111 "i" != "j" AND
4112 "rank_ary"["j"] ISNULL AND
4113 ( "matrix_b"["j"]["i"] OR
4114 -- tie-breaking by "id"
4115 ( "matrix_b"["j"]["i"] ISNULL AND
4116 "j" < "i" ) )
4117 THEN
4118 -- someone else is better
4119 EXIT;
4120 END IF;
4121 IF "j" = "dimension_v" THEN
4122 -- noone is better
4123 "rank_ary"["i"] := "rank_v";
4124 EXIT assign_next_rank;
4125 END IF;
4126 "j" := "j" + 1;
4127 END LOOP;
4128 END IF;
4129 "i" := "i" + 1;
4130 IF "i" > "dimension_v" THEN
4131 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
4132 END IF;
4133 END LOOP;
4134 EXIT WHEN "rank_v" = "dimension_v";
4135 "rank_v" := "rank_v" + 1;
4136 END LOOP;
4137 -- write preliminary results:
4138 "i" := 2; -- omit status quo with "i" = 1
4139 FOR "initiative_id_v" IN
4140 SELECT "id" FROM "initiative"
4141 WHERE "issue_id" = "issue_id_p" AND "admitted"
4142 ORDER BY "id"
4143 LOOP
4144 UPDATE "initiative" SET
4145 "direct_majority" =
4146 CASE WHEN "policy_row"."direct_majority_strict" THEN
4147 "positive_votes" * "policy_row"."direct_majority_den" >
4148 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4149 ELSE
4150 "positive_votes" * "policy_row"."direct_majority_den" >=
4151 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4152 END
4153 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4154 AND "issue_row"."voter_count"-"negative_votes" >=
4155 "policy_row"."direct_majority_non_negative",
4156 "indirect_majority" =
4157 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4158 "positive_votes" * "policy_row"."indirect_majority_den" >
4159 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4160 ELSE
4161 "positive_votes" * "policy_row"."indirect_majority_den" >=
4162 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4163 END
4164 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4165 AND "issue_row"."voter_count"-"negative_votes" >=
4166 "policy_row"."indirect_majority_non_negative",
4167 "schulze_rank" = "rank_ary"["i"],
4168 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
4169 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
4170 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
4171 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
4172 THEN NULL
4173 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
4174 "eligible" = FALSE,
4175 "winner" = FALSE,
4176 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4177 WHERE "id" = "initiative_id_v";
4178 "i" := "i" + 1;
4179 END LOOP;
4180 IF "i" != "dimension_v" + 1 THEN
4181 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4182 END IF;
4183 -- take indirect majorities into account:
4184 LOOP
4185 UPDATE "initiative" SET "indirect_majority" = TRUE
4186 FROM (
4187 SELECT "new_initiative"."id" AS "initiative_id"
4188 FROM "initiative" "old_initiative"
4189 JOIN "initiative" "new_initiative"
4190 ON "new_initiative"."issue_id" = "issue_id_p"
4191 AND "new_initiative"."indirect_majority" = FALSE
4192 JOIN "battle" "battle_win"
4193 ON "battle_win"."issue_id" = "issue_id_p"
4194 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4195 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4196 JOIN "battle" "battle_lose"
4197 ON "battle_lose"."issue_id" = "issue_id_p"
4198 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4199 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4200 WHERE "old_initiative"."issue_id" = "issue_id_p"
4201 AND "old_initiative"."indirect_majority" = TRUE
4202 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4203 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4204 "policy_row"."indirect_majority_num" *
4205 ("battle_win"."count"+"battle_lose"."count")
4206 ELSE
4207 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4208 "policy_row"."indirect_majority_num" *
4209 ("battle_win"."count"+"battle_lose"."count")
4210 END
4211 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4212 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4213 "policy_row"."indirect_majority_non_negative"
4214 ) AS "subquery"
4215 WHERE "id" = "subquery"."initiative_id";
4216 EXIT WHEN NOT FOUND;
4217 END LOOP;
4218 -- set "multistage_majority" for remaining matching initiatives:
4219 UPDATE "initiative" SET "multistage_majority" = TRUE
4220 FROM (
4221 SELECT "losing_initiative"."id" AS "initiative_id"
4222 FROM "initiative" "losing_initiative"
4223 JOIN "initiative" "winning_initiative"
4224 ON "winning_initiative"."issue_id" = "issue_id_p"
4225 AND "winning_initiative"."admitted"
4226 JOIN "battle" "battle_win"
4227 ON "battle_win"."issue_id" = "issue_id_p"
4228 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4229 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4230 JOIN "battle" "battle_lose"
4231 ON "battle_lose"."issue_id" = "issue_id_p"
4232 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4233 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4234 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4235 AND "losing_initiative"."admitted"
4236 AND "winning_initiative"."schulze_rank" <
4237 "losing_initiative"."schulze_rank"
4238 AND "battle_win"."count" > "battle_lose"."count"
4239 AND (
4240 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4241 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4242 ) AS "subquery"
4243 WHERE "id" = "subquery"."initiative_id";
4244 -- mark eligible initiatives:
4245 UPDATE "initiative" SET "eligible" = TRUE
4246 WHERE "issue_id" = "issue_id_p"
4247 AND "initiative"."direct_majority"
4248 AND "initiative"."indirect_majority"
4249 AND "initiative"."better_than_status_quo"
4250 AND (
4251 "policy_row"."no_multistage_majority" = FALSE OR
4252 "initiative"."multistage_majority" = FALSE )
4253 AND (
4254 "policy_row"."no_reverse_beat_path" = FALSE OR
4255 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
4256 -- mark final winner:
4257 UPDATE "initiative" SET "winner" = TRUE
4258 FROM (
4259 SELECT "id" AS "initiative_id"
4260 FROM "initiative"
4261 WHERE "issue_id" = "issue_id_p" AND "eligible"
4262 ORDER BY
4263 "schulze_rank",
4264 "id"
4265 LIMIT 1
4266 ) AS "subquery"
4267 WHERE "id" = "subquery"."initiative_id";
4268 -- write (final) ranks:
4269 "rank_v" := 1;
4270 FOR "initiative_id_v" IN
4271 SELECT "id"
4272 FROM "initiative"
4273 WHERE "issue_id" = "issue_id_p" AND "admitted"
4274 ORDER BY
4275 "winner" DESC,
4276 "eligible" DESC,
4277 "schulze_rank",
4278 "id"
4279 LOOP
4280 UPDATE "initiative" SET "rank" = "rank_v"
4281 WHERE "id" = "initiative_id_v";
4282 "rank_v" := "rank_v" + 1;
4283 END LOOP;
4284 -- set schulze rank of status quo and mark issue as finished:
4285 UPDATE "issue" SET
4286 "status_quo_schulze_rank" = "rank_ary"[1],
4287 "state" =
4288 CASE WHEN EXISTS (
4289 SELECT NULL FROM "initiative"
4290 WHERE "issue_id" = "issue_id_p" AND "winner"
4291 ) THEN
4292 'finished_with_winner'::"issue_state"
4293 ELSE
4294 'finished_without_winner'::"issue_state"
4295 END,
4296 "closed" = "phase_finished",
4297 "phase_finished" = NULL
4298 WHERE "id" = "issue_id_p";
4299 RETURN;
4300 END;
4301 $$;
4303 COMMENT ON FUNCTION "calculate_ranks"
4304 ( "issue"."id"%TYPE )
4305 IS 'Determine ranking (Votes have to be counted first)';
4309 -----------------------------
4310 -- Automatic state changes --
4311 -----------------------------
4314 CREATE TYPE "check_issue_persistence" AS (
4315 "state" "issue_state",
4316 "phase_finished" BOOLEAN,
4317 "issue_revoked" BOOLEAN,
4318 "snapshot_created" BOOLEAN,
4319 "harmonic_weights_set" BOOLEAN,
4320 "closed_voting" BOOLEAN );
4322 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';
4325 CREATE FUNCTION "check_issue"
4326 ( "issue_id_p" "issue"."id"%TYPE,
4327 "persist" "check_issue_persistence" )
4328 RETURNS "check_issue_persistence"
4329 LANGUAGE 'plpgsql' VOLATILE AS $$
4330 DECLARE
4331 "issue_row" "issue"%ROWTYPE;
4332 "policy_row" "policy"%ROWTYPE;
4333 "initiative_row" "initiative"%ROWTYPE;
4334 "state_v" "issue_state";
4335 BEGIN
4336 PERFORM "require_transaction_isolation"();
4337 IF "persist" ISNULL THEN
4338 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4339 FOR UPDATE;
4340 IF "issue_row"."closed" NOTNULL THEN
4341 RETURN NULL;
4342 END IF;
4343 "persist"."state" := "issue_row"."state";
4344 IF
4345 ( "issue_row"."state" = 'admission' AND now() >=
4346 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
4347 ( "issue_row"."state" = 'discussion' AND now() >=
4348 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4349 ( "issue_row"."state" = 'verification' AND now() >=
4350 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4351 ( "issue_row"."state" = 'voting' AND now() >=
4352 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4353 THEN
4354 "persist"."phase_finished" := TRUE;
4355 ELSE
4356 "persist"."phase_finished" := FALSE;
4357 END IF;
4358 IF
4359 NOT EXISTS (
4360 -- all initiatives are revoked
4361 SELECT NULL FROM "initiative"
4362 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4363 ) AND (
4364 -- and issue has not been accepted yet
4365 "persist"."state" = 'admission' OR
4366 -- or verification time has elapsed
4367 ( "persist"."state" = 'verification' AND
4368 "persist"."phase_finished" ) OR
4369 -- or no initiatives have been revoked lately
4370 NOT EXISTS (
4371 SELECT NULL FROM "initiative"
4372 WHERE "issue_id" = "issue_id_p"
4373 AND now() < "revoked" + "issue_row"."verification_time"
4376 THEN
4377 "persist"."issue_revoked" := TRUE;
4378 ELSE
4379 "persist"."issue_revoked" := FALSE;
4380 END IF;
4381 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4382 UPDATE "issue" SET "phase_finished" = now()
4383 WHERE "id" = "issue_row"."id";
4384 RETURN "persist";
4385 ELSIF
4386 "persist"."state" IN ('admission', 'discussion', 'verification')
4387 THEN
4388 RETURN "persist";
4389 ELSE
4390 RETURN NULL;
4391 END IF;
4392 END IF;
4393 IF
4394 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4395 coalesce("persist"."snapshot_created", FALSE) = FALSE
4396 THEN
4397 PERFORM "create_snapshot"("issue_id_p");
4398 "persist"."snapshot_created" = TRUE;
4399 IF "persist"."phase_finished" THEN
4400 IF "persist"."state" = 'admission' THEN
4401 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4402 ELSIF "persist"."state" = 'discussion' THEN
4403 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4404 ELSIF "persist"."state" = 'verification' THEN
4405 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4406 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4407 SELECT * INTO "policy_row" FROM "policy"
4408 WHERE "id" = "issue_row"."policy_id";
4409 FOR "initiative_row" IN
4410 SELECT * FROM "initiative"
4411 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4412 FOR UPDATE
4413 LOOP
4414 IF
4415 "initiative_row"."polling" OR (
4416 "initiative_row"."satisfied_supporter_count" > 0 AND
4417 "initiative_row"."satisfied_supporter_count" *
4418 "policy_row"."initiative_quorum_den" >=
4419 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4421 THEN
4422 UPDATE "initiative" SET "admitted" = TRUE
4423 WHERE "id" = "initiative_row"."id";
4424 ELSE
4425 UPDATE "initiative" SET "admitted" = FALSE
4426 WHERE "id" = "initiative_row"."id";
4427 END IF;
4428 END LOOP;
4429 END IF;
4430 END IF;
4431 RETURN "persist";
4432 END IF;
4433 IF
4434 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4435 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4436 THEN
4437 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4438 "persist"."harmonic_weights_set" = TRUE;
4439 IF
4440 "persist"."phase_finished" OR
4441 "persist"."issue_revoked" OR
4442 "persist"."state" = 'admission'
4443 THEN
4444 RETURN "persist";
4445 ELSE
4446 RETURN NULL;
4447 END IF;
4448 END IF;
4449 IF "persist"."issue_revoked" THEN
4450 IF "persist"."state" = 'admission' THEN
4451 "state_v" := 'canceled_revoked_before_accepted';
4452 ELSIF "persist"."state" = 'discussion' THEN
4453 "state_v" := 'canceled_after_revocation_during_discussion';
4454 ELSIF "persist"."state" = 'verification' THEN
4455 "state_v" := 'canceled_after_revocation_during_verification';
4456 END IF;
4457 UPDATE "issue" SET
4458 "state" = "state_v",
4459 "closed" = "phase_finished",
4460 "phase_finished" = NULL
4461 WHERE "id" = "issue_id_p";
4462 RETURN NULL;
4463 END IF;
4464 IF "persist"."state" = 'admission' THEN
4465 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4466 FOR UPDATE;
4467 SELECT * INTO "policy_row"
4468 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4469 IF
4470 ( now() >=
4471 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
4472 EXISTS (
4473 SELECT NULL FROM "initiative"
4474 WHERE "issue_id" = "issue_id_p"
4475 AND "supporter_count" > 0
4476 AND "supporter_count" * "policy_row"."issue_quorum_den"
4477 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4479 THEN
4480 UPDATE "issue" SET
4481 "state" = 'discussion',
4482 "accepted" = coalesce("phase_finished", now()),
4483 "phase_finished" = NULL
4484 WHERE "id" = "issue_id_p";
4485 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4486 UPDATE "issue" SET
4487 "state" = 'canceled_issue_not_accepted',
4488 "closed" = "phase_finished",
4489 "phase_finished" = NULL
4490 WHERE "id" = "issue_id_p";
4491 END IF;
4492 RETURN NULL;
4493 END IF;
4494 IF "persist"."phase_finished" THEN
4495 IF "persist"."state" = 'discussion' THEN
4496 UPDATE "issue" SET
4497 "state" = 'verification',
4498 "half_frozen" = "phase_finished",
4499 "phase_finished" = NULL
4500 WHERE "id" = "issue_id_p";
4501 RETURN NULL;
4502 END IF;
4503 IF "persist"."state" = 'verification' THEN
4504 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4505 FOR UPDATE;
4506 SELECT * INTO "policy_row" FROM "policy"
4507 WHERE "id" = "issue_row"."policy_id";
4508 IF EXISTS (
4509 SELECT NULL FROM "initiative"
4510 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4511 ) THEN
4512 UPDATE "issue" SET
4513 "state" = 'voting',
4514 "fully_frozen" = "phase_finished",
4515 "phase_finished" = NULL
4516 WHERE "id" = "issue_id_p";
4517 ELSE
4518 UPDATE "issue" SET
4519 "state" = 'canceled_no_initiative_admitted',
4520 "fully_frozen" = "phase_finished",
4521 "closed" = "phase_finished",
4522 "phase_finished" = NULL
4523 WHERE "id" = "issue_id_p";
4524 -- NOTE: The following DELETE statements have effect only when
4525 -- issue state has been manipulated
4526 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4527 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4528 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4529 END IF;
4530 RETURN NULL;
4531 END IF;
4532 IF "persist"."state" = 'voting' THEN
4533 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4534 PERFORM "close_voting"("issue_id_p");
4535 "persist"."closed_voting" = TRUE;
4536 RETURN "persist";
4537 END IF;
4538 PERFORM "calculate_ranks"("issue_id_p");
4539 RETURN NULL;
4540 END IF;
4541 END IF;
4542 RAISE WARNING 'should not happen';
4543 RETURN NULL;
4544 END;
4545 $$;
4547 COMMENT ON FUNCTION "check_issue"
4548 ( "issue"."id"%TYPE,
4549 "check_issue_persistence" )
4550 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")';
4553 CREATE FUNCTION "check_everything"()
4554 RETURNS VOID
4555 LANGUAGE 'plpgsql' VOLATILE AS $$
4556 DECLARE
4557 "issue_id_v" "issue"."id"%TYPE;
4558 "persist_v" "check_issue_persistence";
4559 BEGIN
4560 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4561 DELETE FROM "expired_session";
4562 PERFORM "check_activity"();
4563 PERFORM "calculate_member_counts"();
4564 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4565 "persist_v" := NULL;
4566 LOOP
4567 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4568 EXIT WHEN "persist_v" ISNULL;
4569 END LOOP;
4570 END LOOP;
4571 RETURN;
4572 END;
4573 $$;
4575 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.';
4579 ----------------------
4580 -- Deletion of data --
4581 ----------------------
4584 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4585 RETURNS VOID
4586 LANGUAGE 'plpgsql' VOLATILE AS $$
4587 BEGIN
4588 IF EXISTS (
4589 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
4590 ) THEN
4591 -- override protection triggers:
4592 INSERT INTO "temporary_transaction_data" ("key", "value")
4593 VALUES ('override_protection_triggers', TRUE::TEXT);
4594 -- clean data:
4595 DELETE FROM "delegating_voter"
4596 WHERE "issue_id" = "issue_id_p";
4597 DELETE FROM "direct_voter"
4598 WHERE "issue_id" = "issue_id_p";
4599 DELETE FROM "delegating_interest_snapshot"
4600 WHERE "issue_id" = "issue_id_p";
4601 DELETE FROM "direct_interest_snapshot"
4602 WHERE "issue_id" = "issue_id_p";
4603 DELETE FROM "delegating_population_snapshot"
4604 WHERE "issue_id" = "issue_id_p";
4605 DELETE FROM "direct_population_snapshot"
4606 WHERE "issue_id" = "issue_id_p";
4607 DELETE FROM "non_voter"
4608 WHERE "issue_id" = "issue_id_p";
4609 DELETE FROM "delegation"
4610 WHERE "issue_id" = "issue_id_p";
4611 DELETE FROM "supporter"
4612 USING "initiative" -- NOTE: due to missing index on issue_id
4613 WHERE "initiative"."issue_id" = "issue_id_p"
4614 AND "supporter"."initiative_id" = "initiative_id";
4615 -- mark issue as cleaned:
4616 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
4617 -- finish overriding protection triggers (avoids garbage):
4618 DELETE FROM "temporary_transaction_data"
4619 WHERE "key" = 'override_protection_triggers';
4620 END IF;
4621 RETURN;
4622 END;
4623 $$;
4625 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4628 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4629 RETURNS VOID
4630 LANGUAGE 'plpgsql' VOLATILE AS $$
4631 BEGIN
4632 UPDATE "member" SET
4633 "last_login" = NULL,
4634 "last_delegation_check" = NULL,
4635 "login" = NULL,
4636 "password" = NULL,
4637 "authority" = NULL,
4638 "authority_uid" = NULL,
4639 "authority_login" = NULL,
4640 "locked" = TRUE,
4641 "active" = FALSE,
4642 "notify_email" = NULL,
4643 "notify_email_unconfirmed" = NULL,
4644 "notify_email_secret" = NULL,
4645 "notify_email_secret_expiry" = NULL,
4646 "notify_email_lock_expiry" = NULL,
4647 "login_recovery_expiry" = NULL,
4648 "password_reset_secret" = NULL,
4649 "password_reset_secret_expiry" = NULL,
4650 "organizational_unit" = NULL,
4651 "internal_posts" = NULL,
4652 "realname" = NULL,
4653 "birthday" = NULL,
4654 "address" = NULL,
4655 "email" = NULL,
4656 "xmpp_address" = NULL,
4657 "website" = NULL,
4658 "phone" = NULL,
4659 "mobile_phone" = NULL,
4660 "profession" = NULL,
4661 "external_memberships" = NULL,
4662 "external_posts" = NULL,
4663 "statement" = NULL
4664 WHERE "id" = "member_id_p";
4665 -- "text_search_data" is updated by triggers
4666 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4667 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4668 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4669 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4670 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4671 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4672 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4673 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4674 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4675 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4676 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4677 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4678 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4679 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4680 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4681 DELETE FROM "direct_voter" USING "issue"
4682 WHERE "direct_voter"."issue_id" = "issue"."id"
4683 AND "issue"."closed" ISNULL
4684 AND "member_id" = "member_id_p";
4685 RETURN;
4686 END;
4687 $$;
4689 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)';
4692 CREATE FUNCTION "delete_private_data"()
4693 RETURNS VOID
4694 LANGUAGE 'plpgsql' VOLATILE AS $$
4695 BEGIN
4696 DELETE FROM "temporary_transaction_data";
4697 DELETE FROM "member" WHERE "activated" ISNULL;
4698 UPDATE "member" SET
4699 "invite_code" = NULL,
4700 "invite_code_expiry" = NULL,
4701 "admin_comment" = NULL,
4702 "last_login" = NULL,
4703 "last_delegation_check" = NULL,
4704 "login" = NULL,
4705 "password" = NULL,
4706 "authority" = NULL,
4707 "authority_uid" = NULL,
4708 "authority_login" = NULL,
4709 "lang" = NULL,
4710 "notify_email" = NULL,
4711 "notify_email_unconfirmed" = NULL,
4712 "notify_email_secret" = NULL,
4713 "notify_email_secret_expiry" = NULL,
4714 "notify_email_lock_expiry" = NULL,
4715 "notify_level" = NULL,
4716 "login_recovery_expiry" = NULL,
4717 "password_reset_secret" = NULL,
4718 "password_reset_secret_expiry" = NULL,
4719 "organizational_unit" = NULL,
4720 "internal_posts" = NULL,
4721 "realname" = NULL,
4722 "birthday" = NULL,
4723 "address" = NULL,
4724 "email" = NULL,
4725 "xmpp_address" = NULL,
4726 "website" = NULL,
4727 "phone" = NULL,
4728 "mobile_phone" = NULL,
4729 "profession" = NULL,
4730 "external_memberships" = NULL,
4731 "external_posts" = NULL,
4732 "formatting_engine" = NULL,
4733 "statement" = NULL;
4734 -- "text_search_data" is updated by triggers
4735 DELETE FROM "setting";
4736 DELETE FROM "setting_map";
4737 DELETE FROM "member_relation_setting";
4738 DELETE FROM "member_image";
4739 DELETE FROM "contact";
4740 DELETE FROM "ignored_member";
4741 DELETE FROM "session";
4742 DELETE FROM "area_setting";
4743 DELETE FROM "issue_setting";
4744 DELETE FROM "ignored_initiative";
4745 DELETE FROM "initiative_setting";
4746 DELETE FROM "suggestion_setting";
4747 DELETE FROM "non_voter";
4748 DELETE FROM "direct_voter" USING "issue"
4749 WHERE "direct_voter"."issue_id" = "issue"."id"
4750 AND "issue"."closed" ISNULL;
4751 RETURN;
4752 END;
4753 $$;
4755 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.';
4759 COMMIT;

Impressum / About Us