liquid_feedback_core

view core.sql @ 489:5abcd0043fff

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

Impressum / About Us