liquid_feedback_core

view core.sql @ 486:9aa403a05261

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

Impressum / About Us