liquid_feedback_core

view core.sql @ 445:fbb49f35b4e1

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

Impressum / About Us