liquid_feedback_core

view core.sql @ 415:ffc4c08cd835

When marking first preferences, use JOIN via "initiative" table due to missing index on "vote"."issue_id"
author jbe
date Wed Mar 26 14:26:46 2014 +0100 (2014-03-26)
parents 719ad5c5c940
children db9ccf3c05f4
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.0', 3, 0, 0))
11 AS "subquery"("string", "major", "minor", "revision");
15 ----------------------
16 -- Full text search --
17 ----------------------
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
21 RETURNS TSQUERY
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
23 BEGIN
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
25 END;
26 $$;
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
31 CREATE FUNCTION "highlight"
32 ( "body_p" TEXT,
33 "query_text_p" TEXT )
34 RETURNS TEXT
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
36 BEGIN
37 RETURN ts_headline(
38 'pg_catalog.simple',
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
40 "text_search_query"("query_text_p"),
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
42 END;
43 $$;
45 COMMENT ON FUNCTION "highlight"
46 ( "body_p" TEXT,
47 "query_text_p" TEXT )
48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
52 -------------------------
53 -- Tables and indicies --
54 -------------------------
57 CREATE TABLE "temporary_transaction_data" (
58 PRIMARY KEY ("txid", "key"),
59 "txid" INT8 DEFAULT txid_current(),
60 "key" TEXT,
61 "value" TEXT NOT NULL );
63 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
65 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
68 CREATE TABLE "system_setting" (
69 "member_ttl" INTERVAL );
70 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
72 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
73 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
75 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
78 CREATE TABLE "contingent" (
79 PRIMARY KEY ("polling", "time_frame"),
80 "polling" BOOLEAN,
81 "time_frame" INTERVAL,
82 "text_entry_limit" INT4,
83 "initiative_limit" INT4 );
85 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
87 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
88 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
89 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
92 CREATE TYPE "notify_level" AS ENUM
93 ('none', 'voting', 'verification', 'discussion', 'all');
95 COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything';
98 CREATE TABLE "member" (
99 "id" SERIAL4 PRIMARY KEY,
100 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
101 "invite_code" TEXT UNIQUE,
102 "invite_code_expiry" TIMESTAMPTZ,
103 "admin_comment" TEXT,
104 "activated" TIMESTAMPTZ,
105 "last_activity" DATE,
106 "last_login" TIMESTAMPTZ,
107 "last_delegation_check" TIMESTAMPTZ,
108 "login" TEXT UNIQUE,
109 "password" TEXT,
110 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
111 "active" BOOLEAN NOT NULL DEFAULT FALSE,
112 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
113 "lang" TEXT,
114 "notify_email" TEXT,
115 "notify_email_unconfirmed" TEXT,
116 "notify_email_secret" TEXT UNIQUE,
117 "notify_email_secret_expiry" TIMESTAMPTZ,
118 "notify_email_lock_expiry" TIMESTAMPTZ,
119 "notify_level" "notify_level",
120 "login_recovery_expiry" TIMESTAMPTZ,
121 "password_reset_secret" TEXT UNIQUE,
122 "password_reset_secret_expiry" TIMESTAMPTZ,
123 "name" TEXT UNIQUE,
124 "identification" TEXT UNIQUE,
125 "authentication" TEXT,
126 "organizational_unit" TEXT,
127 "internal_posts" TEXT,
128 "realname" TEXT,
129 "birthday" DATE,
130 "address" TEXT,
131 "email" TEXT,
132 "xmpp_address" TEXT,
133 "website" TEXT,
134 "phone" TEXT,
135 "mobile_phone" TEXT,
136 "profession" TEXT,
137 "external_memberships" TEXT,
138 "external_posts" TEXT,
139 "formatting_engine" TEXT,
140 "statement" TEXT,
141 "text_search_data" TSVECTOR,
142 CONSTRAINT "active_requires_activated_and_last_activity"
143 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
144 CONSTRAINT "name_not_null_if_activated"
145 CHECK ("activated" ISNULL OR "name" NOTNULL) );
146 CREATE INDEX "member_active_idx" ON "member" ("active");
147 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
148 CREATE TRIGGER "update_text_search_data"
149 BEFORE INSERT OR UPDATE ON "member"
150 FOR EACH ROW EXECUTE PROCEDURE
151 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
152 "name", "identification", "organizational_unit", "internal_posts",
153 "realname", "external_memberships", "external_posts", "statement" );
155 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
157 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
158 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
159 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
160 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
161 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';
162 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
163 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
164 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
165 COMMENT ON COLUMN "member"."login" IS 'Login name';
166 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
167 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
168 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".';
169 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
170 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
171 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
172 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
173 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
174 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
175 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
176 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';
177 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
178 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
179 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';
180 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
181 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
182 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
183 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
184 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
185 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
186 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
187 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
188 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
189 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
190 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
193 -- DEPRECATED API TABLES --
195 CREATE TYPE "application_access_level" AS ENUM
196 ('member', 'full', 'pseudonymous', 'anonymous');
198 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
201 CREATE TABLE "member_application" (
202 "id" SERIAL8 PRIMARY KEY,
203 UNIQUE ("member_id", "name"),
204 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
205 ON DELETE CASCADE ON UPDATE CASCADE,
206 "name" TEXT NOT NULL,
207 "comment" TEXT,
208 "access_level" "application_access_level" NOT NULL,
209 "key" TEXT NOT NULL UNIQUE,
210 "last_usage" TIMESTAMPTZ );
212 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
214 -- END OF DEPRECARED API TABLES --
217 CREATE TABLE "member_history" (
218 "id" SERIAL8 PRIMARY KEY,
219 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
220 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
221 "active" BOOLEAN NOT NULL,
222 "name" TEXT NOT NULL );
223 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
225 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
227 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
228 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
231 CREATE TABLE "rendered_member_statement" (
232 PRIMARY KEY ("member_id", "format"),
233 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
234 "format" TEXT,
235 "content" TEXT NOT NULL );
237 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)';
240 CREATE TABLE "setting" (
241 PRIMARY KEY ("member_id", "key"),
242 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
243 "key" TEXT NOT NULL,
244 "value" TEXT NOT NULL );
245 CREATE INDEX "setting_key_idx" ON "setting" ("key");
247 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
249 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
252 CREATE TABLE "setting_map" (
253 PRIMARY KEY ("member_id", "key", "subkey"),
254 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
255 "key" TEXT NOT NULL,
256 "subkey" TEXT NOT NULL,
257 "value" TEXT NOT NULL );
258 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
260 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
262 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
263 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
264 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
267 CREATE TABLE "member_relation_setting" (
268 PRIMARY KEY ("member_id", "key", "other_member_id"),
269 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
270 "key" TEXT NOT NULL,
271 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
272 "value" TEXT NOT NULL );
274 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
277 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
279 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
282 CREATE TABLE "member_image" (
283 PRIMARY KEY ("member_id", "image_type", "scaled"),
284 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
285 "image_type" "member_image_type",
286 "scaled" BOOLEAN,
287 "content_type" TEXT,
288 "data" BYTEA NOT NULL );
290 COMMENT ON TABLE "member_image" IS 'Images of members';
292 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
295 CREATE TABLE "member_count" (
296 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
297 "total_count" INT4 NOT NULL );
299 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';
301 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
302 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
305 CREATE TABLE "contact" (
306 PRIMARY KEY ("member_id", "other_member_id"),
307 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
308 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
309 "public" BOOLEAN NOT NULL DEFAULT FALSE,
310 CONSTRAINT "cant_save_yourself_as_contact"
311 CHECK ("member_id" != "other_member_id") );
312 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
314 COMMENT ON TABLE "contact" IS 'Contact lists';
316 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
317 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
318 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
321 CREATE TABLE "ignored_member" (
322 PRIMARY KEY ("member_id", "other_member_id"),
323 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
324 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
325 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
327 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
329 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
330 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
333 CREATE TABLE "session" (
334 "ident" TEXT PRIMARY KEY,
335 "additional_secret" TEXT,
336 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
337 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
338 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
339 "lang" TEXT );
340 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
342 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
344 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
345 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
346 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
347 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';
348 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
351 CREATE TABLE "policy" (
352 "id" SERIAL4 PRIMARY KEY,
353 "index" INT4 NOT NULL,
354 "active" BOOLEAN NOT NULL DEFAULT TRUE,
355 "name" TEXT NOT NULL UNIQUE,
356 "description" TEXT NOT NULL DEFAULT '',
357 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
358 "admission_time" INTERVAL,
359 "discussion_time" INTERVAL,
360 "verification_time" INTERVAL,
361 "voting_time" INTERVAL,
362 "issue_quorum_num" INT4,
363 "issue_quorum_den" INT4,
364 "initiative_quorum_num" INT4 NOT NULL,
365 "initiative_quorum_den" INT4 NOT NULL,
366 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
367 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
368 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
369 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
370 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
371 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
372 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
373 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
374 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
375 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
376 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
377 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
378 CONSTRAINT "timing" CHECK (
379 ( "polling" = FALSE AND
380 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
381 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
382 ( "polling" = TRUE AND
383 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
384 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
385 ( "polling" = TRUE AND
386 "admission_time" ISNULL AND "discussion_time" ISNULL AND
387 "verification_time" ISNULL AND "voting_time" ISNULL ) ),
388 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
389 "polling" = "issue_quorum_num" ISNULL AND
390 "polling" = "issue_quorum_den" ISNULL ) );
391 CREATE INDEX "policy_active_idx" ON "policy" ("active");
393 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
395 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
396 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
397 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';
398 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
399 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
400 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"';
401 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'')';
402 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''';
403 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''';
404 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
405 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
406 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
407 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
408 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.';
409 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
410 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';
411 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';
412 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';
413 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.';
414 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';
415 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';
416 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS '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.';
417 COMMENT ON COLUMN "policy"."no_multistage_majority" IS '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").';
420 CREATE TABLE "unit" (
421 "id" SERIAL4 PRIMARY KEY,
422 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
423 "active" BOOLEAN NOT NULL DEFAULT TRUE,
424 "name" TEXT NOT NULL,
425 "description" TEXT NOT NULL DEFAULT '',
426 "member_count" INT4,
427 "text_search_data" TSVECTOR );
428 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
429 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
430 CREATE INDEX "unit_active_idx" ON "unit" ("active");
431 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
432 CREATE TRIGGER "update_text_search_data"
433 BEFORE INSERT OR UPDATE ON "unit"
434 FOR EACH ROW EXECUTE PROCEDURE
435 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
436 "name", "description" );
438 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
440 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
441 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
442 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
445 CREATE TABLE "unit_setting" (
446 PRIMARY KEY ("member_id", "key", "unit_id"),
447 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
448 "key" TEXT NOT NULL,
449 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
450 "value" TEXT NOT NULL );
452 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
455 CREATE TABLE "area" (
456 "id" SERIAL4 PRIMARY KEY,
457 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
458 "active" BOOLEAN NOT NULL DEFAULT TRUE,
459 "name" TEXT NOT NULL,
460 "description" TEXT NOT NULL DEFAULT '',
461 "direct_member_count" INT4,
462 "member_weight" INT4,
463 "text_search_data" TSVECTOR );
464 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
465 CREATE INDEX "area_active_idx" ON "area" ("active");
466 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
467 CREATE TRIGGER "update_text_search_data"
468 BEFORE INSERT OR UPDATE ON "area"
469 FOR EACH ROW EXECUTE PROCEDURE
470 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
471 "name", "description" );
473 COMMENT ON TABLE "area" IS 'Subject areas';
475 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
476 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"';
477 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
480 CREATE TABLE "area_setting" (
481 PRIMARY KEY ("member_id", "key", "area_id"),
482 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
483 "key" TEXT NOT NULL,
484 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
485 "value" TEXT NOT NULL );
487 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
490 CREATE TABLE "allowed_policy" (
491 PRIMARY KEY ("area_id", "policy_id"),
492 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
493 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
494 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
495 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
497 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
499 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
502 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
504 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';
507 CREATE TYPE "issue_state" AS ENUM (
508 'admission', 'discussion', 'verification', 'voting',
509 'canceled_by_admin',
510 'canceled_revoked_before_accepted',
511 'canceled_issue_not_accepted',
512 'canceled_after_revocation_during_discussion',
513 'canceled_after_revocation_during_verification',
514 'canceled_no_initiative_admitted',
515 'finished_without_winner', 'finished_with_winner');
517 COMMENT ON TYPE "issue_state" IS 'State of issues';
520 CREATE TABLE "issue" (
521 "id" SERIAL4 PRIMARY KEY,
522 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
523 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
524 "admin_notice" TEXT,
525 "state" "issue_state" NOT NULL DEFAULT 'admission',
526 "phase_finished" TIMESTAMPTZ,
527 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
528 "accepted" TIMESTAMPTZ,
529 "half_frozen" TIMESTAMPTZ,
530 "fully_frozen" TIMESTAMPTZ,
531 "closed" TIMESTAMPTZ,
532 "cleaned" TIMESTAMPTZ,
533 "admission_time" INTERVAL,
534 "discussion_time" INTERVAL NOT NULL,
535 "verification_time" INTERVAL NOT NULL,
536 "voting_time" INTERVAL NOT NULL,
537 "snapshot" TIMESTAMPTZ,
538 "latest_snapshot_event" "snapshot_event",
539 "population" INT4,
540 "voter_count" INT4,
541 "status_quo_schulze_rank" INT4,
542 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
543 "admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created") ),
544 CONSTRAINT "valid_state" CHECK (
545 (
546 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
547 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
548 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
549 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
550 ) AND (
551 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
552 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
553 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
554 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
555 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
556 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
557 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
558 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
559 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
560 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
561 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
562 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
563 )),
564 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
565 "phase_finished" ISNULL OR "closed" ISNULL ),
566 CONSTRAINT "state_change_order" CHECK (
567 "created" <= "accepted" AND
568 "accepted" <= "half_frozen" AND
569 "half_frozen" <= "fully_frozen" AND
570 "fully_frozen" <= "closed" ),
571 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
572 "cleaned" ISNULL OR "closed" NOTNULL ),
573 CONSTRAINT "last_snapshot_on_full_freeze"
574 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
575 CONSTRAINT "freeze_requires_snapshot"
576 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
577 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
578 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
579 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
580 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
581 CREATE INDEX "issue_created_idx" ON "issue" ("created");
582 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
583 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
584 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
585 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
586 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
587 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
589 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
591 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
592 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';
593 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
594 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.';
595 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.';
596 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.';
597 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
598 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
599 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
600 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
601 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
602 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
603 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';
604 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
605 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';
606 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
609 CREATE TABLE "issue_order_in_admission_state" (
610 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
611 "order_in_area" INT4,
612 "order_in_unit" INT4 );
614 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"';
616 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';
617 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';
618 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';
621 CREATE TABLE "issue_setting" (
622 PRIMARY KEY ("member_id", "key", "issue_id"),
623 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
624 "key" TEXT NOT NULL,
625 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
626 "value" TEXT NOT NULL );
628 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
631 CREATE TABLE "initiative" (
632 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
633 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
634 "id" SERIAL4 PRIMARY KEY,
635 "name" TEXT NOT NULL,
636 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
637 "discussion_url" TEXT,
638 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
639 "revoked" TIMESTAMPTZ,
640 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
641 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
642 "admitted" BOOLEAN,
643 "supporter_count" INT4,
644 "informed_supporter_count" INT4,
645 "satisfied_supporter_count" INT4,
646 "satisfied_informed_supporter_count" INT4,
647 "harmonic_weight" NUMERIC(12, 3),
648 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
649 "first_preference_votes" INT4,
650 "positive_votes" INT4,
651 "negative_votes" INT4,
652 "direct_majority" BOOLEAN,
653 "indirect_majority" BOOLEAN,
654 "schulze_rank" INT4,
655 "better_than_status_quo" BOOLEAN,
656 "worse_than_status_quo" BOOLEAN,
657 "reverse_beat_path" BOOLEAN,
658 "multistage_majority" BOOLEAN,
659 "eligible" BOOLEAN,
660 "winner" BOOLEAN,
661 "rank" INT4,
662 "text_search_data" TSVECTOR,
663 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
664 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
665 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
666 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
667 CONSTRAINT "revoked_initiatives_cant_be_admitted"
668 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
669 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
670 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
671 ( "first_preference_votes" ISNULL AND
672 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
673 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
674 "schulze_rank" ISNULL AND
675 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
676 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
677 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
678 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
679 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
680 "eligible" = FALSE OR
681 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
682 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
683 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
684 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
685 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
686 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
687 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
688 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
689 CREATE TRIGGER "update_text_search_data"
690 BEFORE INSERT OR UPDATE ON "initiative"
691 FOR EACH ROW EXECUTE PROCEDURE
692 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
693 "name", "discussion_url");
695 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.';
697 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
698 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
699 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
700 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
701 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
702 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
703 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
704 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
705 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
706 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';
707 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
708 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
709 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
710 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
711 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"';
712 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
713 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
714 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
715 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)';
716 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';
717 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';
718 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"';
719 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
720 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';
723 CREATE TABLE "battle" (
724 "issue_id" INT4 NOT NULL,
725 "winning_initiative_id" INT4,
726 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
727 "losing_initiative_id" INT4,
728 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
729 "count" INT4 NOT NULL,
730 CONSTRAINT "initiative_ids_not_equal" CHECK (
731 "winning_initiative_id" != "losing_initiative_id" OR
732 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
733 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
734 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
735 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
736 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
738 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';
741 CREATE TABLE "ignored_initiative" (
742 PRIMARY KEY ("initiative_id", "member_id"),
743 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
744 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
745 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
747 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
750 CREATE TABLE "initiative_setting" (
751 PRIMARY KEY ("member_id", "key", "initiative_id"),
752 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
753 "key" TEXT NOT NULL,
754 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
755 "value" TEXT NOT NULL );
757 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
760 CREATE TABLE "draft" (
761 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
762 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
763 "id" SERIAL8 PRIMARY KEY,
764 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
765 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
766 "formatting_engine" TEXT,
767 "content" TEXT NOT NULL,
768 "text_search_data" TSVECTOR );
769 CREATE INDEX "draft_created_idx" ON "draft" ("created");
770 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
771 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
772 CREATE TRIGGER "update_text_search_data"
773 BEFORE INSERT OR UPDATE ON "draft"
774 FOR EACH ROW EXECUTE PROCEDURE
775 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
777 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.';
779 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
780 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
783 CREATE TABLE "rendered_draft" (
784 PRIMARY KEY ("draft_id", "format"),
785 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
786 "format" TEXT,
787 "content" TEXT NOT NULL );
789 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)';
792 CREATE TABLE "suggestion" (
793 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
794 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
795 "id" SERIAL8 PRIMARY KEY,
796 "draft_id" INT8 NOT NULL,
797 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
798 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
799 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
800 "name" TEXT NOT NULL,
801 "formatting_engine" TEXT,
802 "content" TEXT NOT NULL DEFAULT '',
803 "text_search_data" TSVECTOR,
804 "minus2_unfulfilled_count" INT4,
805 "minus2_fulfilled_count" INT4,
806 "minus1_unfulfilled_count" INT4,
807 "minus1_fulfilled_count" INT4,
808 "plus1_unfulfilled_count" INT4,
809 "plus1_fulfilled_count" INT4,
810 "plus2_unfulfilled_count" INT4,
811 "plus2_fulfilled_count" INT4,
812 "proportional_order" INT4 );
813 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
814 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
815 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
816 CREATE TRIGGER "update_text_search_data"
817 BEFORE INSERT OR UPDATE ON "suggestion"
818 FOR EACH ROW EXECUTE PROCEDURE
819 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
820 "name", "content");
822 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';
824 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")';
825 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
826 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
827 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
828 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
829 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
830 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
831 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
832 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
833 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"';
836 CREATE TABLE "rendered_suggestion" (
837 PRIMARY KEY ("suggestion_id", "format"),
838 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
839 "format" TEXT,
840 "content" TEXT NOT NULL );
842 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)';
845 CREATE TABLE "suggestion_setting" (
846 PRIMARY KEY ("member_id", "key", "suggestion_id"),
847 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
848 "key" TEXT NOT NULL,
849 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
850 "value" TEXT NOT NULL );
852 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
855 CREATE TABLE "privilege" (
856 PRIMARY KEY ("unit_id", "member_id"),
857 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
858 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
859 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
860 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
861 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
862 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
863 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
864 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
865 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
867 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
869 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
870 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
871 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
872 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
873 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
874 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
875 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';
878 CREATE TABLE "membership" (
879 PRIMARY KEY ("area_id", "member_id"),
880 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
881 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
882 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
884 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
887 CREATE TABLE "interest" (
888 PRIMARY KEY ("issue_id", "member_id"),
889 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
890 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
891 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
893 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.';
896 CREATE TABLE "initiator" (
897 PRIMARY KEY ("initiative_id", "member_id"),
898 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
899 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
900 "accepted" BOOLEAN );
901 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
903 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.';
905 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.';
908 CREATE TABLE "supporter" (
909 "issue_id" INT4 NOT NULL,
910 PRIMARY KEY ("initiative_id", "member_id"),
911 "initiative_id" INT4,
912 "member_id" INT4,
913 "draft_id" INT8 NOT NULL,
914 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
915 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
916 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
918 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.';
920 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
921 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")';
924 CREATE TABLE "opinion" (
925 "initiative_id" INT4 NOT NULL,
926 PRIMARY KEY ("suggestion_id", "member_id"),
927 "suggestion_id" INT8,
928 "member_id" INT4,
929 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
930 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
931 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
932 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
933 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
935 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.';
937 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
940 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
942 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
945 CREATE TABLE "delegation" (
946 "id" SERIAL8 PRIMARY KEY,
947 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
948 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
949 "scope" "delegation_scope" NOT NULL,
950 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
951 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
952 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
953 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
954 CONSTRAINT "no_unit_delegation_to_null"
955 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
956 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
957 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
958 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
959 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
960 UNIQUE ("unit_id", "truster_id"),
961 UNIQUE ("area_id", "truster_id"),
962 UNIQUE ("issue_id", "truster_id") );
963 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
964 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
966 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
968 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
969 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
970 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
973 CREATE TABLE "direct_population_snapshot" (
974 PRIMARY KEY ("issue_id", "event", "member_id"),
975 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
976 "event" "snapshot_event",
977 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
978 "weight" INT4 );
979 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
981 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';
983 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
984 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
987 CREATE TABLE "delegating_population_snapshot" (
988 PRIMARY KEY ("issue_id", "event", "member_id"),
989 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
990 "event" "snapshot_event",
991 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
992 "weight" INT4,
993 "scope" "delegation_scope" NOT NULL,
994 "delegate_member_ids" INT4[] NOT NULL );
995 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
997 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';
999 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1000 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
1001 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
1002 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"';
1005 CREATE TABLE "direct_interest_snapshot" (
1006 PRIMARY KEY ("issue_id", "event", "member_id"),
1007 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1008 "event" "snapshot_event",
1009 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1010 "weight" INT4 );
1011 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1013 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';
1015 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1016 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1019 CREATE TABLE "delegating_interest_snapshot" (
1020 PRIMARY KEY ("issue_id", "event", "member_id"),
1021 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1022 "event" "snapshot_event",
1023 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1024 "weight" INT4,
1025 "scope" "delegation_scope" NOT NULL,
1026 "delegate_member_ids" INT4[] NOT NULL );
1027 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1029 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';
1031 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1032 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1033 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1034 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"';
1037 CREATE TABLE "direct_supporter_snapshot" (
1038 "issue_id" INT4 NOT NULL,
1039 PRIMARY KEY ("initiative_id", "event", "member_id"),
1040 "initiative_id" INT4,
1041 "event" "snapshot_event",
1042 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1043 "draft_id" INT8 NOT NULL,
1044 "informed" BOOLEAN NOT NULL,
1045 "satisfied" BOOLEAN NOT NULL,
1046 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1047 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1048 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1049 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1051 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';
1053 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';
1054 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1055 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1056 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1059 CREATE TABLE "non_voter" (
1060 PRIMARY KEY ("issue_id", "member_id"),
1061 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1062 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1063 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1065 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1068 CREATE TABLE "direct_voter" (
1069 PRIMARY KEY ("issue_id", "member_id"),
1070 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1071 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1072 "weight" INT4,
1073 "comment_changed" TIMESTAMPTZ,
1074 "formatting_engine" TEXT,
1075 "comment" TEXT,
1076 "text_search_data" TSVECTOR );
1077 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1078 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1079 CREATE TRIGGER "update_text_search_data"
1080 BEFORE INSERT OR UPDATE ON "direct_voter"
1081 FOR EACH ROW EXECUTE PROCEDURE
1082 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1084 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';
1086 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1087 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';
1088 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';
1089 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.';
1092 CREATE TABLE "rendered_voter_comment" (
1093 PRIMARY KEY ("issue_id", "member_id", "format"),
1094 FOREIGN KEY ("issue_id", "member_id")
1095 REFERENCES "direct_voter" ("issue_id", "member_id")
1096 ON DELETE CASCADE ON UPDATE CASCADE,
1097 "issue_id" INT4,
1098 "member_id" INT4,
1099 "format" TEXT,
1100 "content" TEXT NOT NULL );
1102 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)';
1105 CREATE TABLE "delegating_voter" (
1106 PRIMARY KEY ("issue_id", "member_id"),
1107 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1108 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1109 "weight" INT4,
1110 "scope" "delegation_scope" NOT NULL,
1111 "delegate_member_ids" INT4[] NOT NULL );
1112 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1114 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';
1116 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1117 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1118 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"';
1121 CREATE TABLE "vote" (
1122 "issue_id" INT4 NOT NULL,
1123 PRIMARY KEY ("initiative_id", "member_id"),
1124 "initiative_id" INT4,
1125 "member_id" INT4,
1126 "grade" INT4 NOT NULL,
1127 "first_preference" BOOLEAN,
1128 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1129 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1130 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1131 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1132 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1134 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';
1136 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1137 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.';
1138 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.';
1141 CREATE TYPE "event_type" AS ENUM (
1142 'issue_state_changed',
1143 'initiative_created_in_new_issue',
1144 'initiative_created_in_existing_issue',
1145 'initiative_revoked',
1146 'new_draft_created',
1147 'suggestion_created');
1149 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1152 CREATE TABLE "event" (
1153 "id" SERIAL8 PRIMARY KEY,
1154 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1155 "event" "event_type" NOT NULL,
1156 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1157 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1158 "state" "issue_state",
1159 "initiative_id" INT4,
1160 "draft_id" INT8,
1161 "suggestion_id" INT8,
1162 FOREIGN KEY ("issue_id", "initiative_id")
1163 REFERENCES "initiative" ("issue_id", "id")
1164 ON DELETE CASCADE ON UPDATE CASCADE,
1165 FOREIGN KEY ("initiative_id", "draft_id")
1166 REFERENCES "draft" ("initiative_id", "id")
1167 ON DELETE CASCADE ON UPDATE CASCADE,
1168 FOREIGN KEY ("initiative_id", "suggestion_id")
1169 REFERENCES "suggestion" ("initiative_id", "id")
1170 ON DELETE CASCADE ON UPDATE CASCADE,
1171 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1172 "event" != 'issue_state_changed' OR (
1173 "member_id" ISNULL AND
1174 "issue_id" NOTNULL AND
1175 "state" NOTNULL AND
1176 "initiative_id" ISNULL AND
1177 "draft_id" ISNULL AND
1178 "suggestion_id" ISNULL )),
1179 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1180 "event" NOT IN (
1181 'initiative_created_in_new_issue',
1182 'initiative_created_in_existing_issue',
1183 'initiative_revoked',
1184 'new_draft_created'
1185 ) OR (
1186 "member_id" NOTNULL AND
1187 "issue_id" NOTNULL AND
1188 "state" NOTNULL AND
1189 "initiative_id" NOTNULL AND
1190 "draft_id" NOTNULL AND
1191 "suggestion_id" ISNULL )),
1192 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1193 "event" != 'suggestion_created' OR (
1194 "member_id" NOTNULL AND
1195 "issue_id" NOTNULL AND
1196 "state" NOTNULL AND
1197 "initiative_id" NOTNULL AND
1198 "draft_id" ISNULL AND
1199 "suggestion_id" NOTNULL )) );
1200 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1202 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1204 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1205 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1206 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1207 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1210 CREATE TABLE "notification_sent" (
1211 "event_id" INT8 NOT NULL );
1212 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1214 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1215 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1219 ----------------------------------------------
1220 -- Writing of history entries and event log --
1221 ----------------------------------------------
1224 CREATE FUNCTION "write_member_history_trigger"()
1225 RETURNS TRIGGER
1226 LANGUAGE 'plpgsql' VOLATILE AS $$
1227 BEGIN
1228 IF
1229 ( NEW."active" != OLD."active" OR
1230 NEW."name" != OLD."name" ) AND
1231 OLD."activated" NOTNULL
1232 THEN
1233 INSERT INTO "member_history"
1234 ("member_id", "active", "name")
1235 VALUES (NEW."id", OLD."active", OLD."name");
1236 END IF;
1237 RETURN NULL;
1238 END;
1239 $$;
1241 CREATE TRIGGER "write_member_history"
1242 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1243 "write_member_history_trigger"();
1245 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1246 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1249 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1250 RETURNS TRIGGER
1251 LANGUAGE 'plpgsql' VOLATILE AS $$
1252 BEGIN
1253 IF NEW."state" != OLD."state" THEN
1254 INSERT INTO "event" ("event", "issue_id", "state")
1255 VALUES ('issue_state_changed', NEW."id", NEW."state");
1256 END IF;
1257 RETURN NULL;
1258 END;
1259 $$;
1261 CREATE TRIGGER "write_event_issue_state_changed"
1262 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1263 "write_event_issue_state_changed_trigger"();
1265 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1266 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1269 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1270 RETURNS TRIGGER
1271 LANGUAGE 'plpgsql' VOLATILE AS $$
1272 DECLARE
1273 "initiative_row" "initiative"%ROWTYPE;
1274 "issue_row" "issue"%ROWTYPE;
1275 "event_v" "event_type";
1276 BEGIN
1277 SELECT * INTO "initiative_row" FROM "initiative"
1278 WHERE "id" = NEW."initiative_id";
1279 SELECT * INTO "issue_row" FROM "issue"
1280 WHERE "id" = "initiative_row"."issue_id";
1281 IF EXISTS (
1282 SELECT NULL FROM "draft"
1283 WHERE "initiative_id" = NEW."initiative_id"
1284 AND "id" != NEW."id"
1285 ) THEN
1286 "event_v" := 'new_draft_created';
1287 ELSE
1288 IF EXISTS (
1289 SELECT NULL FROM "initiative"
1290 WHERE "issue_id" = "initiative_row"."issue_id"
1291 AND "id" != "initiative_row"."id"
1292 ) THEN
1293 "event_v" := 'initiative_created_in_existing_issue';
1294 ELSE
1295 "event_v" := 'initiative_created_in_new_issue';
1296 END IF;
1297 END IF;
1298 INSERT INTO "event" (
1299 "event", "member_id",
1300 "issue_id", "state", "initiative_id", "draft_id"
1301 ) VALUES (
1302 "event_v",
1303 NEW."author_id",
1304 "initiative_row"."issue_id",
1305 "issue_row"."state",
1306 "initiative_row"."id",
1307 NEW."id" );
1308 RETURN NULL;
1309 END;
1310 $$;
1312 CREATE TRIGGER "write_event_initiative_or_draft_created"
1313 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1314 "write_event_initiative_or_draft_created_trigger"();
1316 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1317 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1320 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1321 RETURNS TRIGGER
1322 LANGUAGE 'plpgsql' VOLATILE AS $$
1323 DECLARE
1324 "issue_row" "issue"%ROWTYPE;
1325 "draft_id_v" "draft"."id"%TYPE;
1326 BEGIN
1327 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1328 SELECT * INTO "issue_row" FROM "issue"
1329 WHERE "id" = NEW."issue_id";
1330 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1331 WHERE "initiative_id" = NEW."id";
1332 INSERT INTO "event" (
1333 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1334 ) VALUES (
1335 'initiative_revoked',
1336 NEW."revoked_by_member_id",
1337 NEW."issue_id",
1338 "issue_row"."state",
1339 NEW."id",
1340 "draft_id_v");
1341 END IF;
1342 RETURN NULL;
1343 END;
1344 $$;
1346 CREATE TRIGGER "write_event_initiative_revoked"
1347 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1348 "write_event_initiative_revoked_trigger"();
1350 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1351 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1354 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1355 RETURNS TRIGGER
1356 LANGUAGE 'plpgsql' VOLATILE AS $$
1357 DECLARE
1358 "initiative_row" "initiative"%ROWTYPE;
1359 "issue_row" "issue"%ROWTYPE;
1360 BEGIN
1361 SELECT * INTO "initiative_row" FROM "initiative"
1362 WHERE "id" = NEW."initiative_id";
1363 SELECT * INTO "issue_row" FROM "issue"
1364 WHERE "id" = "initiative_row"."issue_id";
1365 INSERT INTO "event" (
1366 "event", "member_id",
1367 "issue_id", "state", "initiative_id", "suggestion_id"
1368 ) VALUES (
1369 'suggestion_created',
1370 NEW."author_id",
1371 "initiative_row"."issue_id",
1372 "issue_row"."state",
1373 "initiative_row"."id",
1374 NEW."id" );
1375 RETURN NULL;
1376 END;
1377 $$;
1379 CREATE TRIGGER "write_event_suggestion_created"
1380 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1381 "write_event_suggestion_created_trigger"();
1383 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1384 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1388 ----------------------------
1389 -- Additional constraints --
1390 ----------------------------
1393 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1394 RETURNS TRIGGER
1395 LANGUAGE 'plpgsql' VOLATILE AS $$
1396 BEGIN
1397 IF NOT EXISTS (
1398 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1399 ) THEN
1400 --RAISE 'Cannot create issue without an initial initiative.' USING
1401 -- ERRCODE = 'integrity_constraint_violation',
1402 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1403 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1404 END IF;
1405 RETURN NULL;
1406 END;
1407 $$;
1409 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1410 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1411 FOR EACH ROW EXECUTE PROCEDURE
1412 "issue_requires_first_initiative_trigger"();
1414 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1415 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1418 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1419 RETURNS TRIGGER
1420 LANGUAGE 'plpgsql' VOLATILE AS $$
1421 DECLARE
1422 "reference_lost" BOOLEAN;
1423 BEGIN
1424 IF TG_OP = 'DELETE' THEN
1425 "reference_lost" := TRUE;
1426 ELSE
1427 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1428 END IF;
1429 IF
1430 "reference_lost" AND NOT EXISTS (
1431 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1433 THEN
1434 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1435 END IF;
1436 RETURN NULL;
1437 END;
1438 $$;
1440 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1441 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1442 FOR EACH ROW EXECUTE PROCEDURE
1443 "last_initiative_deletes_issue_trigger"();
1445 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1446 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1449 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1450 RETURNS TRIGGER
1451 LANGUAGE 'plpgsql' VOLATILE AS $$
1452 BEGIN
1453 IF NOT EXISTS (
1454 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1455 ) THEN
1456 --RAISE 'Cannot create initiative without an initial draft.' USING
1457 -- ERRCODE = 'integrity_constraint_violation',
1458 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1459 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1460 END IF;
1461 RETURN NULL;
1462 END;
1463 $$;
1465 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1466 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1467 FOR EACH ROW EXECUTE PROCEDURE
1468 "initiative_requires_first_draft_trigger"();
1470 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1471 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1474 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1475 RETURNS TRIGGER
1476 LANGUAGE 'plpgsql' VOLATILE AS $$
1477 DECLARE
1478 "reference_lost" BOOLEAN;
1479 BEGIN
1480 IF TG_OP = 'DELETE' THEN
1481 "reference_lost" := TRUE;
1482 ELSE
1483 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1484 END IF;
1485 IF
1486 "reference_lost" AND NOT EXISTS (
1487 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1489 THEN
1490 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1491 END IF;
1492 RETURN NULL;
1493 END;
1494 $$;
1496 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1497 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1498 FOR EACH ROW EXECUTE PROCEDURE
1499 "last_draft_deletes_initiative_trigger"();
1501 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1502 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1505 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1506 RETURNS TRIGGER
1507 LANGUAGE 'plpgsql' VOLATILE AS $$
1508 BEGIN
1509 IF NOT EXISTS (
1510 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1511 ) THEN
1512 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1513 END IF;
1514 RETURN NULL;
1515 END;
1516 $$;
1518 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1519 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1520 FOR EACH ROW EXECUTE PROCEDURE
1521 "suggestion_requires_first_opinion_trigger"();
1523 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1524 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1527 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1528 RETURNS TRIGGER
1529 LANGUAGE 'plpgsql' VOLATILE AS $$
1530 DECLARE
1531 "reference_lost" BOOLEAN;
1532 BEGIN
1533 IF TG_OP = 'DELETE' THEN
1534 "reference_lost" := TRUE;
1535 ELSE
1536 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1537 END IF;
1538 IF
1539 "reference_lost" AND NOT EXISTS (
1540 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1542 THEN
1543 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1544 END IF;
1545 RETURN NULL;
1546 END;
1547 $$;
1549 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1550 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1551 FOR EACH ROW EXECUTE PROCEDURE
1552 "last_opinion_deletes_suggestion_trigger"();
1554 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1555 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1558 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1559 RETURNS TRIGGER
1560 LANGUAGE 'plpgsql' VOLATILE AS $$
1561 BEGIN
1562 DELETE FROM "direct_voter"
1563 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1564 RETURN NULL;
1565 END;
1566 $$;
1568 CREATE TRIGGER "non_voter_deletes_direct_voter"
1569 AFTER INSERT OR UPDATE ON "non_voter"
1570 FOR EACH ROW EXECUTE PROCEDURE
1571 "non_voter_deletes_direct_voter_trigger"();
1573 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1574 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")';
1577 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1578 RETURNS TRIGGER
1579 LANGUAGE 'plpgsql' VOLATILE AS $$
1580 BEGIN
1581 DELETE FROM "non_voter"
1582 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1583 RETURN NULL;
1584 END;
1585 $$;
1587 CREATE TRIGGER "direct_voter_deletes_non_voter"
1588 AFTER INSERT OR UPDATE ON "direct_voter"
1589 FOR EACH ROW EXECUTE PROCEDURE
1590 "direct_voter_deletes_non_voter_trigger"();
1592 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1593 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")';
1596 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1597 RETURNS TRIGGER
1598 LANGUAGE 'plpgsql' VOLATILE AS $$
1599 BEGIN
1600 IF NEW."comment" ISNULL THEN
1601 NEW."comment_changed" := NULL;
1602 NEW."formatting_engine" := NULL;
1603 END IF;
1604 RETURN NEW;
1605 END;
1606 $$;
1608 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1609 BEFORE INSERT OR UPDATE ON "direct_voter"
1610 FOR EACH ROW EXECUTE PROCEDURE
1611 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1613 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"';
1614 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.';
1617 ---------------------------------------------------------------
1618 -- Ensure that votes are not modified when issues are closed --
1619 ---------------------------------------------------------------
1621 -- NOTE: Frontends should ensure this anyway, but in case of programming
1622 -- errors the following triggers ensure data integrity.
1625 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1626 RETURNS TRIGGER
1627 LANGUAGE 'plpgsql' VOLATILE AS $$
1628 DECLARE
1629 "issue_id_v" "issue"."id"%TYPE;
1630 "issue_row" "issue"%ROWTYPE;
1631 BEGIN
1632 IF EXISTS (
1633 SELECT NULL FROM "temporary_transaction_data"
1634 WHERE "txid" = txid_current()
1635 AND "key" = 'override_protection_triggers'
1636 AND "value" = TRUE::TEXT
1637 ) THEN
1638 RETURN NULL;
1639 END IF;
1640 IF TG_OP = 'DELETE' THEN
1641 "issue_id_v" := OLD."issue_id";
1642 ELSE
1643 "issue_id_v" := NEW."issue_id";
1644 END IF;
1645 SELECT INTO "issue_row" * FROM "issue"
1646 WHERE "id" = "issue_id_v" FOR SHARE;
1647 IF (
1648 "issue_row"."closed" NOTNULL OR (
1649 "issue_row"."state" = 'voting' AND
1650 "issue_row"."phase_finished" NOTNULL
1652 ) THEN
1653 IF
1654 TG_RELID = 'direct_voter'::regclass AND
1655 TG_OP = 'UPDATE'
1656 THEN
1657 IF
1658 OLD."issue_id" = NEW."issue_id" AND
1659 OLD."member_id" = NEW."member_id" AND
1660 OLD."weight" = NEW."weight"
1661 THEN
1662 RETURN NULL; -- allows changing of voter comment
1663 END IF;
1664 END IF;
1665 RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
1666 END IF;
1667 RETURN NULL;
1668 END;
1669 $$;
1671 CREATE TRIGGER "forbid_changes_on_closed_issue"
1672 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1673 FOR EACH ROW EXECUTE PROCEDURE
1674 "forbid_changes_on_closed_issue_trigger"();
1676 CREATE TRIGGER "forbid_changes_on_closed_issue"
1677 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1678 FOR EACH ROW EXECUTE PROCEDURE
1679 "forbid_changes_on_closed_issue_trigger"();
1681 CREATE TRIGGER "forbid_changes_on_closed_issue"
1682 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1683 FOR EACH ROW EXECUTE PROCEDURE
1684 "forbid_changes_on_closed_issue_trigger"();
1686 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"';
1687 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';
1688 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';
1689 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';
1693 --------------------------------------------------------------------
1694 -- Auto-retrieval of fields only needed for referential integrity --
1695 --------------------------------------------------------------------
1698 CREATE FUNCTION "autofill_issue_id_trigger"()
1699 RETURNS TRIGGER
1700 LANGUAGE 'plpgsql' VOLATILE AS $$
1701 BEGIN
1702 IF NEW."issue_id" ISNULL THEN
1703 SELECT "issue_id" INTO NEW."issue_id"
1704 FROM "initiative" WHERE "id" = NEW."initiative_id";
1705 END IF;
1706 RETURN NEW;
1707 END;
1708 $$;
1710 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1711 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1713 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1714 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1716 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1717 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1718 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1721 CREATE FUNCTION "autofill_initiative_id_trigger"()
1722 RETURNS TRIGGER
1723 LANGUAGE 'plpgsql' VOLATILE AS $$
1724 BEGIN
1725 IF NEW."initiative_id" ISNULL THEN
1726 SELECT "initiative_id" INTO NEW."initiative_id"
1727 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1728 END IF;
1729 RETURN NEW;
1730 END;
1731 $$;
1733 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1734 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1736 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1737 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1741 -----------------------------------------------------
1742 -- Automatic calculation of certain default values --
1743 -----------------------------------------------------
1746 CREATE FUNCTION "copy_timings_trigger"()
1747 RETURNS TRIGGER
1748 LANGUAGE 'plpgsql' VOLATILE AS $$
1749 DECLARE
1750 "policy_row" "policy"%ROWTYPE;
1751 BEGIN
1752 SELECT * INTO "policy_row" FROM "policy"
1753 WHERE "id" = NEW."policy_id";
1754 IF NEW."admission_time" ISNULL THEN
1755 NEW."admission_time" := "policy_row"."admission_time";
1756 END IF;
1757 IF NEW."discussion_time" ISNULL THEN
1758 NEW."discussion_time" := "policy_row"."discussion_time";
1759 END IF;
1760 IF NEW."verification_time" ISNULL THEN
1761 NEW."verification_time" := "policy_row"."verification_time";
1762 END IF;
1763 IF NEW."voting_time" ISNULL THEN
1764 NEW."voting_time" := "policy_row"."voting_time";
1765 END IF;
1766 RETURN NEW;
1767 END;
1768 $$;
1770 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1771 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1773 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1774 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1777 CREATE FUNCTION "default_for_draft_id_trigger"()
1778 RETURNS TRIGGER
1779 LANGUAGE 'plpgsql' VOLATILE AS $$
1780 BEGIN
1781 IF NEW."draft_id" ISNULL THEN
1782 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1783 WHERE "initiative_id" = NEW."initiative_id";
1784 END IF;
1785 RETURN NEW;
1786 END;
1787 $$;
1789 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1790 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1791 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1792 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1794 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1795 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';
1796 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';
1800 ----------------------------------------
1801 -- Automatic creation of dependencies --
1802 ----------------------------------------
1805 CREATE FUNCTION "autocreate_interest_trigger"()
1806 RETURNS TRIGGER
1807 LANGUAGE 'plpgsql' VOLATILE AS $$
1808 BEGIN
1809 IF NOT EXISTS (
1810 SELECT NULL FROM "initiative" JOIN "interest"
1811 ON "initiative"."issue_id" = "interest"."issue_id"
1812 WHERE "initiative"."id" = NEW."initiative_id"
1813 AND "interest"."member_id" = NEW."member_id"
1814 ) THEN
1815 BEGIN
1816 INSERT INTO "interest" ("issue_id", "member_id")
1817 SELECT "issue_id", NEW."member_id"
1818 FROM "initiative" WHERE "id" = NEW."initiative_id";
1819 EXCEPTION WHEN unique_violation THEN END;
1820 END IF;
1821 RETURN NEW;
1822 END;
1823 $$;
1825 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1826 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1828 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1829 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';
1832 CREATE FUNCTION "autocreate_supporter_trigger"()
1833 RETURNS TRIGGER
1834 LANGUAGE 'plpgsql' VOLATILE AS $$
1835 BEGIN
1836 IF NOT EXISTS (
1837 SELECT NULL FROM "suggestion" JOIN "supporter"
1838 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1839 WHERE "suggestion"."id" = NEW."suggestion_id"
1840 AND "supporter"."member_id" = NEW."member_id"
1841 ) THEN
1842 BEGIN
1843 INSERT INTO "supporter" ("initiative_id", "member_id")
1844 SELECT "initiative_id", NEW."member_id"
1845 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1846 EXCEPTION WHEN unique_violation THEN END;
1847 END IF;
1848 RETURN NEW;
1849 END;
1850 $$;
1852 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1853 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1855 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1856 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.';
1860 ------------------------------------------
1861 -- Views and helper functions for views --
1862 ------------------------------------------
1865 CREATE VIEW "unit_delegation" AS
1866 SELECT
1867 "unit"."id" AS "unit_id",
1868 "delegation"."id",
1869 "delegation"."truster_id",
1870 "delegation"."trustee_id",
1871 "delegation"."scope"
1872 FROM "unit"
1873 JOIN "delegation"
1874 ON "delegation"."unit_id" = "unit"."id"
1875 JOIN "member"
1876 ON "delegation"."truster_id" = "member"."id"
1877 JOIN "privilege"
1878 ON "delegation"."unit_id" = "privilege"."unit_id"
1879 AND "delegation"."truster_id" = "privilege"."member_id"
1880 WHERE "member"."active" AND "privilege"."voting_right";
1882 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1885 CREATE VIEW "area_delegation" AS
1886 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1887 "area"."id" AS "area_id",
1888 "delegation"."id",
1889 "delegation"."truster_id",
1890 "delegation"."trustee_id",
1891 "delegation"."scope"
1892 FROM "area"
1893 JOIN "delegation"
1894 ON "delegation"."unit_id" = "area"."unit_id"
1895 OR "delegation"."area_id" = "area"."id"
1896 JOIN "member"
1897 ON "delegation"."truster_id" = "member"."id"
1898 JOIN "privilege"
1899 ON "area"."unit_id" = "privilege"."unit_id"
1900 AND "delegation"."truster_id" = "privilege"."member_id"
1901 WHERE "member"."active" AND "privilege"."voting_right"
1902 ORDER BY
1903 "area"."id",
1904 "delegation"."truster_id",
1905 "delegation"."scope" DESC;
1907 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1910 CREATE VIEW "issue_delegation" AS
1911 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1912 "issue"."id" AS "issue_id",
1913 "delegation"."id",
1914 "delegation"."truster_id",
1915 "delegation"."trustee_id",
1916 "delegation"."scope"
1917 FROM "issue"
1918 JOIN "area"
1919 ON "area"."id" = "issue"."area_id"
1920 JOIN "delegation"
1921 ON "delegation"."unit_id" = "area"."unit_id"
1922 OR "delegation"."area_id" = "area"."id"
1923 OR "delegation"."issue_id" = "issue"."id"
1924 JOIN "member"
1925 ON "delegation"."truster_id" = "member"."id"
1926 JOIN "privilege"
1927 ON "area"."unit_id" = "privilege"."unit_id"
1928 AND "delegation"."truster_id" = "privilege"."member_id"
1929 WHERE "member"."active" AND "privilege"."voting_right"
1930 ORDER BY
1931 "issue"."id",
1932 "delegation"."truster_id",
1933 "delegation"."scope" DESC;
1935 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1938 CREATE FUNCTION "membership_weight_with_skipping"
1939 ( "area_id_p" "area"."id"%TYPE,
1940 "member_id_p" "member"."id"%TYPE,
1941 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1942 RETURNS INT4
1943 LANGUAGE 'plpgsql' STABLE AS $$
1944 DECLARE
1945 "sum_v" INT4;
1946 "delegation_row" "area_delegation"%ROWTYPE;
1947 BEGIN
1948 "sum_v" := 1;
1949 FOR "delegation_row" IN
1950 SELECT "area_delegation".*
1951 FROM "area_delegation" LEFT JOIN "membership"
1952 ON "membership"."area_id" = "area_id_p"
1953 AND "membership"."member_id" = "area_delegation"."truster_id"
1954 WHERE "area_delegation"."area_id" = "area_id_p"
1955 AND "area_delegation"."trustee_id" = "member_id_p"
1956 AND "membership"."member_id" ISNULL
1957 LOOP
1958 IF NOT
1959 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1960 THEN
1961 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1962 "area_id_p",
1963 "delegation_row"."truster_id",
1964 "skip_member_ids_p" || "delegation_row"."truster_id"
1965 );
1966 END IF;
1967 END LOOP;
1968 RETURN "sum_v";
1969 END;
1970 $$;
1972 COMMENT ON FUNCTION "membership_weight_with_skipping"
1973 ( "area"."id"%TYPE,
1974 "member"."id"%TYPE,
1975 INT4[] )
1976 IS 'Helper function for "membership_weight" function';
1979 CREATE FUNCTION "membership_weight"
1980 ( "area_id_p" "area"."id"%TYPE,
1981 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1982 RETURNS INT4
1983 LANGUAGE 'plpgsql' STABLE AS $$
1984 BEGIN
1985 RETURN "membership_weight_with_skipping"(
1986 "area_id_p",
1987 "member_id_p",
1988 ARRAY["member_id_p"]
1989 );
1990 END;
1991 $$;
1993 COMMENT ON FUNCTION "membership_weight"
1994 ( "area"."id"%TYPE,
1995 "member"."id"%TYPE )
1996 IS 'Calculates the potential voting weight of a member in a given area';
1999 CREATE VIEW "member_count_view" AS
2000 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
2002 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
2005 CREATE VIEW "unit_member_count" AS
2006 SELECT
2007 "unit"."id" AS "unit_id",
2008 count("member"."id") AS "member_count"
2009 FROM "unit"
2010 LEFT JOIN "privilege"
2011 ON "privilege"."unit_id" = "unit"."id"
2012 AND "privilege"."voting_right"
2013 LEFT JOIN "member"
2014 ON "member"."id" = "privilege"."member_id"
2015 AND "member"."active"
2016 GROUP BY "unit"."id";
2018 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
2021 CREATE VIEW "area_member_count" AS
2022 SELECT
2023 "area"."id" AS "area_id",
2024 count("member"."id") AS "direct_member_count",
2025 coalesce(
2026 sum(
2027 CASE WHEN "member"."id" NOTNULL THEN
2028 "membership_weight"("area"."id", "member"."id")
2029 ELSE 0 END
2031 ) AS "member_weight"
2032 FROM "area"
2033 LEFT JOIN "membership"
2034 ON "area"."id" = "membership"."area_id"
2035 LEFT JOIN "privilege"
2036 ON "privilege"."unit_id" = "area"."unit_id"
2037 AND "privilege"."member_id" = "membership"."member_id"
2038 AND "privilege"."voting_right"
2039 LEFT JOIN "member"
2040 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2041 AND "member"."active"
2042 GROUP BY "area"."id";
2044 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2047 CREATE VIEW "opening_draft" AS
2048 SELECT "draft".* FROM (
2049 SELECT
2050 "initiative"."id" AS "initiative_id",
2051 min("draft"."id") AS "draft_id"
2052 FROM "initiative" JOIN "draft"
2053 ON "initiative"."id" = "draft"."initiative_id"
2054 GROUP BY "initiative"."id"
2055 ) AS "subquery"
2056 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2058 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2061 CREATE VIEW "current_draft" AS
2062 SELECT "draft".* FROM (
2063 SELECT
2064 "initiative"."id" AS "initiative_id",
2065 max("draft"."id") AS "draft_id"
2066 FROM "initiative" JOIN "draft"
2067 ON "initiative"."id" = "draft"."initiative_id"
2068 GROUP BY "initiative"."id"
2069 ) AS "subquery"
2070 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2072 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2075 CREATE VIEW "critical_opinion" AS
2076 SELECT * FROM "opinion"
2077 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2078 OR ("degree" = -2 AND "fulfilled" = TRUE);
2080 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2083 CREATE VIEW "issue_supporter_in_admission_state" AS
2084 SELECT DISTINCT
2085 "area"."unit_id",
2086 "issue"."area_id",
2087 "issue"."id" AS "issue_id",
2088 "supporter"."member_id",
2089 "direct_interest_snapshot"."weight"
2090 FROM "issue"
2091 JOIN "area" ON "area"."id" = "issue"."area_id"
2092 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
2093 JOIN "direct_interest_snapshot"
2094 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2095 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2096 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
2097 WHERE "issue"."state" = 'admission'::"issue_state";
2099 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';
2102 CREATE VIEW "initiative_suggestion_order_calculation" AS
2103 SELECT
2104 "initiative"."id" AS "initiative_id",
2105 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
2106 FROM "initiative" JOIN "issue"
2107 ON "initiative"."issue_id" = "issue"."id"
2108 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
2109 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
2111 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
2113 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';
2116 CREATE VIEW "individual_suggestion_ranking" AS
2117 SELECT
2118 "opinion"."initiative_id",
2119 "opinion"."member_id",
2120 "direct_interest_snapshot"."weight",
2121 CASE WHEN
2122 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
2123 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
2124 THEN 1 ELSE
2125 CASE WHEN
2126 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
2127 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
2128 THEN 2 ELSE
2129 CASE WHEN
2130 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
2131 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
2132 THEN 3 ELSE 4 END
2133 END
2134 END AS "preference",
2135 "opinion"."suggestion_id"
2136 FROM "opinion"
2137 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
2138 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2139 JOIN "direct_interest_snapshot"
2140 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2141 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2142 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
2144 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
2147 CREATE VIEW "battle_participant" AS
2148 SELECT "initiative"."id", "initiative"."issue_id"
2149 FROM "issue" JOIN "initiative"
2150 ON "issue"."id" = "initiative"."issue_id"
2151 WHERE "initiative"."admitted"
2152 UNION ALL
2153 SELECT NULL, "id" AS "issue_id"
2154 FROM "issue";
2156 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2159 CREATE VIEW "battle_view" AS
2160 SELECT
2161 "issue"."id" AS "issue_id",
2162 "winning_initiative"."id" AS "winning_initiative_id",
2163 "losing_initiative"."id" AS "losing_initiative_id",
2164 sum(
2165 CASE WHEN
2166 coalesce("better_vote"."grade", 0) >
2167 coalesce("worse_vote"."grade", 0)
2168 THEN "direct_voter"."weight" ELSE 0 END
2169 ) AS "count"
2170 FROM "issue"
2171 LEFT JOIN "direct_voter"
2172 ON "issue"."id" = "direct_voter"."issue_id"
2173 JOIN "battle_participant" AS "winning_initiative"
2174 ON "issue"."id" = "winning_initiative"."issue_id"
2175 JOIN "battle_participant" AS "losing_initiative"
2176 ON "issue"."id" = "losing_initiative"."issue_id"
2177 LEFT JOIN "vote" AS "better_vote"
2178 ON "direct_voter"."member_id" = "better_vote"."member_id"
2179 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2180 LEFT JOIN "vote" AS "worse_vote"
2181 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2182 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2183 WHERE "issue"."state" = 'voting'
2184 AND "issue"."phase_finished" NOTNULL
2185 AND (
2186 "winning_initiative"."id" != "losing_initiative"."id" OR
2187 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2188 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2189 GROUP BY
2190 "issue"."id",
2191 "winning_initiative"."id",
2192 "losing_initiative"."id";
2194 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';
2197 CREATE VIEW "expired_session" AS
2198 SELECT * FROM "session" WHERE now() > "expiry";
2200 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2201 DELETE FROM "session" WHERE "ident" = OLD."ident";
2203 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2204 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2207 CREATE VIEW "open_issue" AS
2208 SELECT * FROM "issue" WHERE "closed" ISNULL;
2210 COMMENT ON VIEW "open_issue" IS 'All open issues';
2213 CREATE VIEW "member_contingent" AS
2214 SELECT
2215 "member"."id" AS "member_id",
2216 "contingent"."polling",
2217 "contingent"."time_frame",
2218 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2220 SELECT count(1) FROM "draft"
2221 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2222 WHERE "draft"."author_id" = "member"."id"
2223 AND "initiative"."polling" = "contingent"."polling"
2224 AND "draft"."created" > now() - "contingent"."time_frame"
2225 ) + (
2226 SELECT count(1) FROM "suggestion"
2227 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2228 WHERE "suggestion"."author_id" = "member"."id"
2229 AND "contingent"."polling" = FALSE
2230 AND "suggestion"."created" > now() - "contingent"."time_frame"
2232 ELSE NULL END AS "text_entry_count",
2233 "contingent"."text_entry_limit",
2234 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2235 SELECT count(1) FROM "opening_draft" AS "draft"
2236 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2237 WHERE "draft"."author_id" = "member"."id"
2238 AND "initiative"."polling" = "contingent"."polling"
2239 AND "draft"."created" > now() - "contingent"."time_frame"
2240 ) ELSE NULL END AS "initiative_count",
2241 "contingent"."initiative_limit"
2242 FROM "member" CROSS JOIN "contingent";
2244 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2246 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2247 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2250 CREATE VIEW "member_contingent_left" AS
2251 SELECT
2252 "member_id",
2253 "polling",
2254 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2255 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2256 FROM "member_contingent" GROUP BY "member_id", "polling";
2258 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.';
2261 CREATE VIEW "event_seen_by_member" AS
2262 SELECT
2263 "member"."id" AS "seen_by_member_id",
2264 CASE WHEN "event"."state" IN (
2265 'voting',
2266 'finished_without_winner',
2267 'finished_with_winner'
2268 ) THEN
2269 'voting'::"notify_level"
2270 ELSE
2271 CASE WHEN "event"."state" IN (
2272 'verification',
2273 'canceled_after_revocation_during_verification',
2274 'canceled_no_initiative_admitted'
2275 ) THEN
2276 'verification'::"notify_level"
2277 ELSE
2278 CASE WHEN "event"."state" IN (
2279 'discussion',
2280 'canceled_after_revocation_during_discussion'
2281 ) THEN
2282 'discussion'::"notify_level"
2283 ELSE
2284 'all'::"notify_level"
2285 END
2286 END
2287 END AS "notify_level",
2288 "event".*
2289 FROM "member" CROSS JOIN "event"
2290 LEFT JOIN "issue"
2291 ON "event"."issue_id" = "issue"."id"
2292 LEFT JOIN "membership"
2293 ON "member"."id" = "membership"."member_id"
2294 AND "issue"."area_id" = "membership"."area_id"
2295 LEFT JOIN "interest"
2296 ON "member"."id" = "interest"."member_id"
2297 AND "event"."issue_id" = "interest"."issue_id"
2298 LEFT JOIN "ignored_member"
2299 ON "member"."id" = "ignored_member"."member_id"
2300 AND "event"."member_id" = "ignored_member"."other_member_id"
2301 LEFT JOIN "ignored_initiative"
2302 ON "member"."id" = "ignored_initiative"."member_id"
2303 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2304 WHERE (
2305 "interest"."member_id" NOTNULL OR
2306 ( "membership"."member_id" NOTNULL AND
2307 "event"."event" IN (
2308 'issue_state_changed',
2309 'initiative_created_in_new_issue',
2310 'initiative_created_in_existing_issue',
2311 'initiative_revoked' ) ) )
2312 AND "ignored_member"."member_id" ISNULL
2313 AND "ignored_initiative"."member_id" ISNULL;
2315 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"';
2318 CREATE VIEW "selected_event_seen_by_member" AS
2319 SELECT
2320 "member"."id" AS "seen_by_member_id",
2321 CASE WHEN "event"."state" IN (
2322 'voting',
2323 'finished_without_winner',
2324 'finished_with_winner'
2325 ) THEN
2326 'voting'::"notify_level"
2327 ELSE
2328 CASE WHEN "event"."state" IN (
2329 'verification',
2330 'canceled_after_revocation_during_verification',
2331 'canceled_no_initiative_admitted'
2332 ) THEN
2333 'verification'::"notify_level"
2334 ELSE
2335 CASE WHEN "event"."state" IN (
2336 'discussion',
2337 'canceled_after_revocation_during_discussion'
2338 ) THEN
2339 'discussion'::"notify_level"
2340 ELSE
2341 'all'::"notify_level"
2342 END
2343 END
2344 END AS "notify_level",
2345 "event".*
2346 FROM "member" CROSS JOIN "event"
2347 LEFT JOIN "issue"
2348 ON "event"."issue_id" = "issue"."id"
2349 LEFT JOIN "membership"
2350 ON "member"."id" = "membership"."member_id"
2351 AND "issue"."area_id" = "membership"."area_id"
2352 LEFT JOIN "interest"
2353 ON "member"."id" = "interest"."member_id"
2354 AND "event"."issue_id" = "interest"."issue_id"
2355 LEFT JOIN "ignored_member"
2356 ON "member"."id" = "ignored_member"."member_id"
2357 AND "event"."member_id" = "ignored_member"."other_member_id"
2358 LEFT JOIN "ignored_initiative"
2359 ON "member"."id" = "ignored_initiative"."member_id"
2360 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2361 WHERE (
2362 ( "member"."notify_level" >= 'all' ) OR
2363 ( "member"."notify_level" >= 'voting' AND
2364 "event"."state" IN (
2365 'voting',
2366 'finished_without_winner',
2367 'finished_with_winner' ) ) OR
2368 ( "member"."notify_level" >= 'verification' AND
2369 "event"."state" IN (
2370 'verification',
2371 'canceled_after_revocation_during_verification',
2372 'canceled_no_initiative_admitted' ) ) OR
2373 ( "member"."notify_level" >= 'discussion' AND
2374 "event"."state" IN (
2375 'discussion',
2376 'canceled_after_revocation_during_discussion' ) ) )
2377 AND (
2378 "interest"."member_id" NOTNULL OR
2379 ( "membership"."member_id" NOTNULL AND
2380 "event"."event" IN (
2381 'issue_state_changed',
2382 'initiative_created_in_new_issue',
2383 'initiative_created_in_existing_issue',
2384 'initiative_revoked' ) ) )
2385 AND "ignored_member"."member_id" ISNULL
2386 AND "ignored_initiative"."member_id" ISNULL;
2388 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"';
2392 ------------------------------------------------------
2393 -- Row set returning function for delegation chains --
2394 ------------------------------------------------------
2397 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2398 ('first', 'intermediate', 'last', 'repetition');
2400 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2403 CREATE TYPE "delegation_chain_row" AS (
2404 "index" INT4,
2405 "member_id" INT4,
2406 "member_valid" BOOLEAN,
2407 "participation" BOOLEAN,
2408 "overridden" BOOLEAN,
2409 "scope_in" "delegation_scope",
2410 "scope_out" "delegation_scope",
2411 "disabled_out" BOOLEAN,
2412 "loop" "delegation_chain_loop_tag" );
2414 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2416 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2417 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';
2418 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2419 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2420 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2421 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2422 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2425 CREATE FUNCTION "delegation_chain_for_closed_issue"
2426 ( "member_id_p" "member"."id"%TYPE,
2427 "issue_id_p" "issue"."id"%TYPE )
2428 RETURNS SETOF "delegation_chain_row"
2429 LANGUAGE 'plpgsql' STABLE AS $$
2430 DECLARE
2431 "output_row" "delegation_chain_row";
2432 "direct_voter_row" "direct_voter"%ROWTYPE;
2433 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2434 BEGIN
2435 "output_row"."index" := 0;
2436 "output_row"."member_id" := "member_id_p";
2437 "output_row"."member_valid" := TRUE;
2438 "output_row"."participation" := FALSE;
2439 "output_row"."overridden" := FALSE;
2440 "output_row"."disabled_out" := FALSE;
2441 LOOP
2442 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2443 WHERE "issue_id" = "issue_id_p"
2444 AND "member_id" = "output_row"."member_id";
2445 IF "direct_voter_row"."member_id" NOTNULL THEN
2446 "output_row"."participation" := TRUE;
2447 "output_row"."scope_out" := NULL;
2448 "output_row"."disabled_out" := NULL;
2449 RETURN NEXT "output_row";
2450 RETURN;
2451 END IF;
2452 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2453 WHERE "issue_id" = "issue_id_p"
2454 AND "member_id" = "output_row"."member_id";
2455 IF "delegating_voter_row"."member_id" ISNULL THEN
2456 RETURN;
2457 END IF;
2458 "output_row"."scope_out" := "delegating_voter_row"."scope";
2459 RETURN NEXT "output_row";
2460 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2461 "output_row"."scope_in" := "output_row"."scope_out";
2462 END LOOP;
2463 END;
2464 $$;
2466 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2467 ( "member"."id"%TYPE,
2468 "member"."id"%TYPE )
2469 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2472 CREATE FUNCTION "delegation_chain"
2473 ( "member_id_p" "member"."id"%TYPE,
2474 "unit_id_p" "unit"."id"%TYPE,
2475 "area_id_p" "area"."id"%TYPE,
2476 "issue_id_p" "issue"."id"%TYPE,
2477 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2478 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2479 RETURNS SETOF "delegation_chain_row"
2480 LANGUAGE 'plpgsql' STABLE AS $$
2481 DECLARE
2482 "scope_v" "delegation_scope";
2483 "unit_id_v" "unit"."id"%TYPE;
2484 "area_id_v" "area"."id"%TYPE;
2485 "issue_row" "issue"%ROWTYPE;
2486 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2487 "loop_member_id_v" "member"."id"%TYPE;
2488 "output_row" "delegation_chain_row";
2489 "output_rows" "delegation_chain_row"[];
2490 "simulate_v" BOOLEAN;
2491 "simulate_here_v" BOOLEAN;
2492 "delegation_row" "delegation"%ROWTYPE;
2493 "row_count" INT4;
2494 "i" INT4;
2495 "loop_v" BOOLEAN;
2496 BEGIN
2497 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2498 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2499 END IF;
2500 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2501 "simulate_v" := TRUE;
2502 ELSE
2503 "simulate_v" := FALSE;
2504 END IF;
2505 IF
2506 "unit_id_p" NOTNULL AND
2507 "area_id_p" ISNULL AND
2508 "issue_id_p" ISNULL
2509 THEN
2510 "scope_v" := 'unit';
2511 "unit_id_v" := "unit_id_p";
2512 ELSIF
2513 "unit_id_p" ISNULL AND
2514 "area_id_p" NOTNULL AND
2515 "issue_id_p" ISNULL
2516 THEN
2517 "scope_v" := 'area';
2518 "area_id_v" := "area_id_p";
2519 SELECT "unit_id" INTO "unit_id_v"
2520 FROM "area" WHERE "id" = "area_id_v";
2521 ELSIF
2522 "unit_id_p" ISNULL AND
2523 "area_id_p" ISNULL AND
2524 "issue_id_p" NOTNULL
2525 THEN
2526 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2527 IF "issue_row"."id" ISNULL THEN
2528 RETURN;
2529 END IF;
2530 IF "issue_row"."closed" NOTNULL THEN
2531 IF "simulate_v" THEN
2532 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2533 END IF;
2534 FOR "output_row" IN
2535 SELECT * FROM
2536 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2537 LOOP
2538 RETURN NEXT "output_row";
2539 END LOOP;
2540 RETURN;
2541 END IF;
2542 "scope_v" := 'issue';
2543 SELECT "area_id" INTO "area_id_v"
2544 FROM "issue" WHERE "id" = "issue_id_p";
2545 SELECT "unit_id" INTO "unit_id_v"
2546 FROM "area" WHERE "id" = "area_id_v";
2547 ELSE
2548 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2549 END IF;
2550 "visited_member_ids" := '{}';
2551 "loop_member_id_v" := NULL;
2552 "output_rows" := '{}';
2553 "output_row"."index" := 0;
2554 "output_row"."member_id" := "member_id_p";
2555 "output_row"."member_valid" := TRUE;
2556 "output_row"."participation" := FALSE;
2557 "output_row"."overridden" := FALSE;
2558 "output_row"."disabled_out" := FALSE;
2559 "output_row"."scope_out" := NULL;
2560 LOOP
2561 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2562 "loop_member_id_v" := "output_row"."member_id";
2563 ELSE
2564 "visited_member_ids" :=
2565 "visited_member_ids" || "output_row"."member_id";
2566 END IF;
2567 IF "output_row"."participation" ISNULL THEN
2568 "output_row"."overridden" := NULL;
2569 ELSIF "output_row"."participation" THEN
2570 "output_row"."overridden" := TRUE;
2571 END IF;
2572 "output_row"."scope_in" := "output_row"."scope_out";
2573 "output_row"."member_valid" := EXISTS (
2574 SELECT NULL FROM "member" JOIN "privilege"
2575 ON "privilege"."member_id" = "member"."id"
2576 AND "privilege"."unit_id" = "unit_id_v"
2577 WHERE "id" = "output_row"."member_id"
2578 AND "member"."active" AND "privilege"."voting_right"
2579 );
2580 "simulate_here_v" := (
2581 "simulate_v" AND
2582 "output_row"."member_id" = "member_id_p"
2583 );
2584 "delegation_row" := ROW(NULL);
2585 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2586 IF "scope_v" = 'unit' THEN
2587 IF NOT "simulate_here_v" THEN
2588 SELECT * INTO "delegation_row" FROM "delegation"
2589 WHERE "truster_id" = "output_row"."member_id"
2590 AND "unit_id" = "unit_id_v";
2591 END IF;
2592 ELSIF "scope_v" = 'area' THEN
2593 "output_row"."participation" := EXISTS (
2594 SELECT NULL FROM "membership"
2595 WHERE "area_id" = "area_id_p"
2596 AND "member_id" = "output_row"."member_id"
2597 );
2598 IF "simulate_here_v" THEN
2599 IF "simulate_trustee_id_p" ISNULL THEN
2600 SELECT * INTO "delegation_row" FROM "delegation"
2601 WHERE "truster_id" = "output_row"."member_id"
2602 AND "unit_id" = "unit_id_v";
2603 END IF;
2604 ELSE
2605 SELECT * INTO "delegation_row" FROM "delegation"
2606 WHERE "truster_id" = "output_row"."member_id"
2607 AND (
2608 "unit_id" = "unit_id_v" OR
2609 "area_id" = "area_id_v"
2611 ORDER BY "scope" DESC;
2612 END IF;
2613 ELSIF "scope_v" = 'issue' THEN
2614 IF "issue_row"."fully_frozen" ISNULL THEN
2615 "output_row"."participation" := EXISTS (
2616 SELECT NULL FROM "interest"
2617 WHERE "issue_id" = "issue_id_p"
2618 AND "member_id" = "output_row"."member_id"
2619 );
2620 ELSE
2621 IF "output_row"."member_id" = "member_id_p" THEN
2622 "output_row"."participation" := EXISTS (
2623 SELECT NULL FROM "direct_voter"
2624 WHERE "issue_id" = "issue_id_p"
2625 AND "member_id" = "output_row"."member_id"
2626 );
2627 ELSE
2628 "output_row"."participation" := NULL;
2629 END IF;
2630 END IF;
2631 IF "simulate_here_v" THEN
2632 IF "simulate_trustee_id_p" ISNULL THEN
2633 SELECT * INTO "delegation_row" FROM "delegation"
2634 WHERE "truster_id" = "output_row"."member_id"
2635 AND (
2636 "unit_id" = "unit_id_v" OR
2637 "area_id" = "area_id_v"
2639 ORDER BY "scope" DESC;
2640 END IF;
2641 ELSE
2642 SELECT * INTO "delegation_row" FROM "delegation"
2643 WHERE "truster_id" = "output_row"."member_id"
2644 AND (
2645 "unit_id" = "unit_id_v" OR
2646 "area_id" = "area_id_v" OR
2647 "issue_id" = "issue_id_p"
2649 ORDER BY "scope" DESC;
2650 END IF;
2651 END IF;
2652 ELSE
2653 "output_row"."participation" := FALSE;
2654 END IF;
2655 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2656 "output_row"."scope_out" := "scope_v";
2657 "output_rows" := "output_rows" || "output_row";
2658 "output_row"."member_id" := "simulate_trustee_id_p";
2659 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2660 "output_row"."scope_out" := "delegation_row"."scope";
2661 "output_rows" := "output_rows" || "output_row";
2662 "output_row"."member_id" := "delegation_row"."trustee_id";
2663 ELSIF "delegation_row"."scope" NOTNULL THEN
2664 "output_row"."scope_out" := "delegation_row"."scope";
2665 "output_row"."disabled_out" := TRUE;
2666 "output_rows" := "output_rows" || "output_row";
2667 EXIT;
2668 ELSE
2669 "output_row"."scope_out" := NULL;
2670 "output_rows" := "output_rows" || "output_row";
2671 EXIT;
2672 END IF;
2673 EXIT WHEN "loop_member_id_v" NOTNULL;
2674 "output_row"."index" := "output_row"."index" + 1;
2675 END LOOP;
2676 "row_count" := array_upper("output_rows", 1);
2677 "i" := 1;
2678 "loop_v" := FALSE;
2679 LOOP
2680 "output_row" := "output_rows"["i"];
2681 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2682 IF "loop_v" THEN
2683 IF "i" + 1 = "row_count" THEN
2684 "output_row"."loop" := 'last';
2685 ELSIF "i" = "row_count" THEN
2686 "output_row"."loop" := 'repetition';
2687 ELSE
2688 "output_row"."loop" := 'intermediate';
2689 END IF;
2690 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2691 "output_row"."loop" := 'first';
2692 "loop_v" := TRUE;
2693 END IF;
2694 IF "scope_v" = 'unit' THEN
2695 "output_row"."participation" := NULL;
2696 END IF;
2697 RETURN NEXT "output_row";
2698 "i" := "i" + 1;
2699 END LOOP;
2700 RETURN;
2701 END;
2702 $$;
2704 COMMENT ON FUNCTION "delegation_chain"
2705 ( "member"."id"%TYPE,
2706 "unit"."id"%TYPE,
2707 "area"."id"%TYPE,
2708 "issue"."id"%TYPE,
2709 "member"."id"%TYPE,
2710 BOOLEAN )
2711 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2715 ---------------------------------------------------------
2716 -- Single row returning function for delegation chains --
2717 ---------------------------------------------------------
2720 CREATE TYPE "delegation_info_loop_type" AS ENUM
2721 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2723 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''';
2726 CREATE TYPE "delegation_info_type" AS (
2727 "own_participation" BOOLEAN,
2728 "own_delegation_scope" "delegation_scope",
2729 "first_trustee_id" INT4,
2730 "first_trustee_participation" BOOLEAN,
2731 "first_trustee_ellipsis" BOOLEAN,
2732 "other_trustee_id" INT4,
2733 "other_trustee_participation" BOOLEAN,
2734 "other_trustee_ellipsis" BOOLEAN,
2735 "delegation_loop" "delegation_info_loop_type",
2736 "participating_member_id" INT4 );
2738 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';
2740 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2741 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2742 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2743 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2744 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2745 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2746 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)';
2747 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2748 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';
2749 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2752 CREATE FUNCTION "delegation_info"
2753 ( "member_id_p" "member"."id"%TYPE,
2754 "unit_id_p" "unit"."id"%TYPE,
2755 "area_id_p" "area"."id"%TYPE,
2756 "issue_id_p" "issue"."id"%TYPE,
2757 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2758 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2759 RETURNS "delegation_info_type"
2760 LANGUAGE 'plpgsql' STABLE AS $$
2761 DECLARE
2762 "current_row" "delegation_chain_row";
2763 "result" "delegation_info_type";
2764 BEGIN
2765 "result"."own_participation" := FALSE;
2766 FOR "current_row" IN
2767 SELECT * FROM "delegation_chain"(
2768 "member_id_p",
2769 "unit_id_p", "area_id_p", "issue_id_p",
2770 "simulate_trustee_id_p", "simulate_default_p")
2771 LOOP
2772 IF
2773 "result"."participating_member_id" ISNULL AND
2774 "current_row"."participation"
2775 THEN
2776 "result"."participating_member_id" := "current_row"."member_id";
2777 END IF;
2778 IF "current_row"."member_id" = "member_id_p" THEN
2779 "result"."own_participation" := "current_row"."participation";
2780 "result"."own_delegation_scope" := "current_row"."scope_out";
2781 IF "current_row"."loop" = 'first' THEN
2782 "result"."delegation_loop" := 'own';
2783 END IF;
2784 ELSIF
2785 "current_row"."member_valid" AND
2786 ( "current_row"."loop" ISNULL OR
2787 "current_row"."loop" != 'repetition' )
2788 THEN
2789 IF "result"."first_trustee_id" ISNULL THEN
2790 "result"."first_trustee_id" := "current_row"."member_id";
2791 "result"."first_trustee_participation" := "current_row"."participation";
2792 "result"."first_trustee_ellipsis" := FALSE;
2793 IF "current_row"."loop" = 'first' THEN
2794 "result"."delegation_loop" := 'first';
2795 END IF;
2796 ELSIF "result"."other_trustee_id" ISNULL THEN
2797 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2798 "result"."other_trustee_id" := "current_row"."member_id";
2799 "result"."other_trustee_participation" := TRUE;
2800 "result"."other_trustee_ellipsis" := FALSE;
2801 IF "current_row"."loop" = 'first' THEN
2802 "result"."delegation_loop" := 'other';
2803 END IF;
2804 ELSE
2805 "result"."first_trustee_ellipsis" := TRUE;
2806 IF "current_row"."loop" = 'first' THEN
2807 "result"."delegation_loop" := 'first_ellipsis';
2808 END IF;
2809 END IF;
2810 ELSE
2811 "result"."other_trustee_ellipsis" := TRUE;
2812 IF "current_row"."loop" = 'first' THEN
2813 "result"."delegation_loop" := 'other_ellipsis';
2814 END IF;
2815 END IF;
2816 END IF;
2817 END LOOP;
2818 RETURN "result";
2819 END;
2820 $$;
2822 COMMENT ON FUNCTION "delegation_info"
2823 ( "member"."id"%TYPE,
2824 "unit"."id"%TYPE,
2825 "area"."id"%TYPE,
2826 "issue"."id"%TYPE,
2827 "member"."id"%TYPE,
2828 BOOLEAN )
2829 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2833 ---------------------------
2834 -- Transaction isolation --
2835 ---------------------------
2838 CREATE FUNCTION "require_transaction_isolation"()
2839 RETURNS VOID
2840 LANGUAGE 'plpgsql' VOLATILE AS $$
2841 BEGIN
2842 IF
2843 current_setting('transaction_isolation') NOT IN
2844 ('repeatable read', 'serializable')
2845 THEN
2846 RAISE EXCEPTION 'Insufficient transaction isolation level';
2847 END IF;
2848 RETURN;
2849 END;
2850 $$;
2852 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
2855 CREATE FUNCTION "dont_require_transaction_isolation"()
2856 RETURNS VOID
2857 LANGUAGE 'plpgsql' VOLATILE AS $$
2858 BEGIN
2859 IF
2860 current_setting('transaction_isolation') IN
2861 ('repeatable read', 'serializable')
2862 THEN
2863 RAISE WARNING 'Unneccessary transaction isolation level: %',
2864 current_setting('transaction_isolation');
2865 END IF;
2866 RETURN;
2867 END;
2868 $$;
2870 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
2874 ------------------------------------------------------------------------
2875 -- Regular tasks, except calculcation of snapshots and voting results --
2876 ------------------------------------------------------------------------
2879 CREATE FUNCTION "check_activity"()
2880 RETURNS VOID
2881 LANGUAGE 'plpgsql' VOLATILE AS $$
2882 DECLARE
2883 "system_setting_row" "system_setting"%ROWTYPE;
2884 BEGIN
2885 PERFORM "dont_require_transaction_isolation"();
2886 SELECT * INTO "system_setting_row" FROM "system_setting";
2887 IF "system_setting_row"."member_ttl" NOTNULL THEN
2888 UPDATE "member" SET "active" = FALSE
2889 WHERE "active" = TRUE
2890 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2891 END IF;
2892 RETURN;
2893 END;
2894 $$;
2896 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2899 CREATE FUNCTION "calculate_member_counts"()
2900 RETURNS VOID
2901 LANGUAGE 'plpgsql' VOLATILE AS $$
2902 BEGIN
2903 PERFORM "require_transaction_isolation"();
2904 DELETE FROM "member_count";
2905 INSERT INTO "member_count" ("total_count")
2906 SELECT "total_count" FROM "member_count_view";
2907 UPDATE "unit" SET "member_count" = "view"."member_count"
2908 FROM "unit_member_count" AS "view"
2909 WHERE "view"."unit_id" = "unit"."id";
2910 UPDATE "area" SET
2911 "direct_member_count" = "view"."direct_member_count",
2912 "member_weight" = "view"."member_weight"
2913 FROM "area_member_count" AS "view"
2914 WHERE "view"."area_id" = "area"."id";
2915 RETURN;
2916 END;
2917 $$;
2919 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"';
2923 ------------------------------------
2924 -- Calculation of harmonic weight --
2925 ------------------------------------
2928 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2929 SELECT
2930 "direct_interest_snapshot"."issue_id",
2931 "direct_interest_snapshot"."event",
2932 "direct_interest_snapshot"."member_id",
2933 "direct_interest_snapshot"."weight" AS "weight_num",
2934 count("initiative"."id") AS "weight_den"
2935 FROM "issue"
2936 JOIN "direct_interest_snapshot"
2937 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
2938 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
2939 JOIN "initiative"
2940 ON "issue"."id" = "initiative"."issue_id"
2941 AND "initiative"."harmonic_weight" ISNULL
2942 JOIN "direct_supporter_snapshot"
2943 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2944 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
2945 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
2946 AND (
2947 "direct_supporter_snapshot"."satisfied" = TRUE OR
2948 coalesce("initiative"."admitted", FALSE) = FALSE
2950 GROUP BY
2951 "direct_interest_snapshot"."issue_id",
2952 "direct_interest_snapshot"."event",
2953 "direct_interest_snapshot"."member_id",
2954 "direct_interest_snapshot"."weight";
2956 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
2959 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
2960 SELECT
2961 "initiative"."issue_id",
2962 "initiative"."id" AS "initiative_id",
2963 "initiative"."admitted",
2964 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
2965 "remaining_harmonic_supporter_weight"."weight_den"
2966 FROM "remaining_harmonic_supporter_weight"
2967 JOIN "initiative"
2968 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
2969 AND "initiative"."harmonic_weight" ISNULL
2970 JOIN "direct_supporter_snapshot"
2971 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2972 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
2973 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
2974 AND (
2975 "direct_supporter_snapshot"."satisfied" = TRUE OR
2976 coalesce("initiative"."admitted", FALSE) = FALSE
2978 GROUP BY
2979 "initiative"."issue_id",
2980 "initiative"."id",
2981 "initiative"."admitted",
2982 "remaining_harmonic_supporter_weight"."weight_den";
2984 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
2987 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
2988 SELECT
2989 "issue_id",
2990 "id" AS "initiative_id",
2991 "admitted",
2992 0 AS "weight_num",
2993 1 AS "weight_den"
2994 FROM "initiative"
2995 WHERE "harmonic_weight" ISNULL;
2997 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';
3000 CREATE FUNCTION "set_harmonic_initiative_weights"
3001 ( "issue_id_p" "issue"."id"%TYPE )
3002 RETURNS VOID
3003 LANGUAGE 'plpgsql' VOLATILE AS $$
3004 DECLARE
3005 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
3006 "i" INT4;
3007 "count_v" INT4;
3008 "summand_v" FLOAT;
3009 "id_ary" INT4[];
3010 "weight_ary" FLOAT[];
3011 "min_weight_v" FLOAT;
3012 BEGIN
3013 PERFORM "require_transaction_isolation"();
3014 UPDATE "initiative" SET "harmonic_weight" = NULL
3015 WHERE "issue_id" = "issue_id_p";
3016 LOOP
3017 "min_weight_v" := NULL;
3018 "i" := 0;
3019 "count_v" := 0;
3020 FOR "weight_row" IN
3021 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
3022 WHERE "issue_id" = "issue_id_p"
3023 AND (
3024 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3025 SELECT NULL FROM "initiative"
3026 WHERE "issue_id" = "issue_id_p"
3027 AND "harmonic_weight" ISNULL
3028 AND coalesce("admitted", FALSE) = FALSE
3031 UNION ALL -- needed for corner cases
3032 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
3033 WHERE "issue_id" = "issue_id_p"
3034 AND (
3035 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3036 SELECT NULL FROM "initiative"
3037 WHERE "issue_id" = "issue_id_p"
3038 AND "harmonic_weight" ISNULL
3039 AND coalesce("admitted", FALSE) = FALSE
3042 ORDER BY "initiative_id" DESC, "weight_den" DESC
3043 -- NOTE: non-admitted initiatives placed first (at last positions),
3044 -- latest initiatives treated worse in case of tie
3045 LOOP
3046 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
3047 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
3048 "i" := "i" + 1;
3049 "count_v" := "i";
3050 "id_ary"["i"] := "weight_row"."initiative_id";
3051 "weight_ary"["i"] := "summand_v";
3052 ELSE
3053 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
3054 END IF;
3055 END LOOP;
3056 EXIT WHEN "count_v" = 0;
3057 "i" := 1;
3058 LOOP
3059 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
3060 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
3061 "min_weight_v" := "weight_ary"["i"];
3062 END IF;
3063 "i" := "i" + 1;
3064 EXIT WHEN "i" > "count_v";
3065 END LOOP;
3066 "i" := 1;
3067 LOOP
3068 IF "weight_ary"["i"] = "min_weight_v" THEN
3069 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
3070 WHERE "id" = "id_ary"["i"];
3071 EXIT;
3072 END IF;
3073 "i" := "i" + 1;
3074 END LOOP;
3075 END LOOP;
3076 UPDATE "initiative" SET "harmonic_weight" = 0
3077 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
3078 END;
3079 $$;
3081 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
3082 ( "issue"."id"%TYPE )
3083 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
3087 ------------------------------
3088 -- Calculation of snapshots --
3089 ------------------------------
3092 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3093 ( "issue_id_p" "issue"."id"%TYPE,
3094 "member_id_p" "member"."id"%TYPE,
3095 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3096 RETURNS "direct_population_snapshot"."weight"%TYPE
3097 LANGUAGE 'plpgsql' VOLATILE AS $$
3098 DECLARE
3099 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3100 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3101 "weight_v" INT4;
3102 "sub_weight_v" INT4;
3103 BEGIN
3104 PERFORM "require_transaction_isolation"();
3105 "weight_v" := 0;
3106 FOR "issue_delegation_row" IN
3107 SELECT * FROM "issue_delegation"
3108 WHERE "trustee_id" = "member_id_p"
3109 AND "issue_id" = "issue_id_p"
3110 LOOP
3111 IF NOT EXISTS (
3112 SELECT NULL FROM "direct_population_snapshot"
3113 WHERE "issue_id" = "issue_id_p"
3114 AND "event" = 'periodic'
3115 AND "member_id" = "issue_delegation_row"."truster_id"
3116 ) AND NOT EXISTS (
3117 SELECT NULL FROM "delegating_population_snapshot"
3118 WHERE "issue_id" = "issue_id_p"
3119 AND "event" = 'periodic'
3120 AND "member_id" = "issue_delegation_row"."truster_id"
3121 ) THEN
3122 "delegate_member_ids_v" :=
3123 "member_id_p" || "delegate_member_ids_p";
3124 INSERT INTO "delegating_population_snapshot" (
3125 "issue_id",
3126 "event",
3127 "member_id",
3128 "scope",
3129 "delegate_member_ids"
3130 ) VALUES (
3131 "issue_id_p",
3132 'periodic',
3133 "issue_delegation_row"."truster_id",
3134 "issue_delegation_row"."scope",
3135 "delegate_member_ids_v"
3136 );
3137 "sub_weight_v" := 1 +
3138 "weight_of_added_delegations_for_population_snapshot"(
3139 "issue_id_p",
3140 "issue_delegation_row"."truster_id",
3141 "delegate_member_ids_v"
3142 );
3143 UPDATE "delegating_population_snapshot"
3144 SET "weight" = "sub_weight_v"
3145 WHERE "issue_id" = "issue_id_p"
3146 AND "event" = 'periodic'
3147 AND "member_id" = "issue_delegation_row"."truster_id";
3148 "weight_v" := "weight_v" + "sub_weight_v";
3149 END IF;
3150 END LOOP;
3151 RETURN "weight_v";
3152 END;
3153 $$;
3155 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3156 ( "issue"."id"%TYPE,
3157 "member"."id"%TYPE,
3158 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3159 IS 'Helper function for "create_population_snapshot" function';
3162 CREATE FUNCTION "create_population_snapshot"
3163 ( "issue_id_p" "issue"."id"%TYPE )
3164 RETURNS VOID
3165 LANGUAGE 'plpgsql' VOLATILE AS $$
3166 DECLARE
3167 "member_id_v" "member"."id"%TYPE;
3168 BEGIN
3169 PERFORM "require_transaction_isolation"();
3170 DELETE FROM "direct_population_snapshot"
3171 WHERE "issue_id" = "issue_id_p"
3172 AND "event" = 'periodic';
3173 DELETE FROM "delegating_population_snapshot"
3174 WHERE "issue_id" = "issue_id_p"
3175 AND "event" = 'periodic';
3176 INSERT INTO "direct_population_snapshot"
3177 ("issue_id", "event", "member_id")
3178 SELECT
3179 "issue_id_p" AS "issue_id",
3180 'periodic'::"snapshot_event" AS "event",
3181 "member"."id" AS "member_id"
3182 FROM "issue"
3183 JOIN "area" ON "issue"."area_id" = "area"."id"
3184 JOIN "membership" ON "area"."id" = "membership"."area_id"
3185 JOIN "member" ON "membership"."member_id" = "member"."id"
3186 JOIN "privilege"
3187 ON "privilege"."unit_id" = "area"."unit_id"
3188 AND "privilege"."member_id" = "member"."id"
3189 WHERE "issue"."id" = "issue_id_p"
3190 AND "member"."active" AND "privilege"."voting_right"
3191 UNION
3192 SELECT
3193 "issue_id_p" AS "issue_id",
3194 'periodic'::"snapshot_event" AS "event",
3195 "member"."id" AS "member_id"
3196 FROM "issue"
3197 JOIN "area" ON "issue"."area_id" = "area"."id"
3198 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3199 JOIN "member" ON "interest"."member_id" = "member"."id"
3200 JOIN "privilege"
3201 ON "privilege"."unit_id" = "area"."unit_id"
3202 AND "privilege"."member_id" = "member"."id"
3203 WHERE "issue"."id" = "issue_id_p"
3204 AND "member"."active" AND "privilege"."voting_right";
3205 FOR "member_id_v" IN
3206 SELECT "member_id" FROM "direct_population_snapshot"
3207 WHERE "issue_id" = "issue_id_p"
3208 AND "event" = 'periodic'
3209 LOOP
3210 UPDATE "direct_population_snapshot" SET
3211 "weight" = 1 +
3212 "weight_of_added_delegations_for_population_snapshot"(
3213 "issue_id_p",
3214 "member_id_v",
3215 '{}'
3217 WHERE "issue_id" = "issue_id_p"
3218 AND "event" = 'periodic'
3219 AND "member_id" = "member_id_v";
3220 END LOOP;
3221 RETURN;
3222 END;
3223 $$;
3225 COMMENT ON FUNCTION "create_population_snapshot"
3226 ( "issue"."id"%TYPE )
3227 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.';
3230 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3231 ( "issue_id_p" "issue"."id"%TYPE,
3232 "member_id_p" "member"."id"%TYPE,
3233 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3234 RETURNS "direct_interest_snapshot"."weight"%TYPE
3235 LANGUAGE 'plpgsql' VOLATILE AS $$
3236 DECLARE
3237 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3238 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3239 "weight_v" INT4;
3240 "sub_weight_v" INT4;
3241 BEGIN
3242 PERFORM "require_transaction_isolation"();
3243 "weight_v" := 0;
3244 FOR "issue_delegation_row" IN
3245 SELECT * FROM "issue_delegation"
3246 WHERE "trustee_id" = "member_id_p"
3247 AND "issue_id" = "issue_id_p"
3248 LOOP
3249 IF NOT EXISTS (
3250 SELECT NULL FROM "direct_interest_snapshot"
3251 WHERE "issue_id" = "issue_id_p"
3252 AND "event" = 'periodic'
3253 AND "member_id" = "issue_delegation_row"."truster_id"
3254 ) AND NOT EXISTS (
3255 SELECT NULL FROM "delegating_interest_snapshot"
3256 WHERE "issue_id" = "issue_id_p"
3257 AND "event" = 'periodic'
3258 AND "member_id" = "issue_delegation_row"."truster_id"
3259 ) THEN
3260 "delegate_member_ids_v" :=
3261 "member_id_p" || "delegate_member_ids_p";
3262 INSERT INTO "delegating_interest_snapshot" (
3263 "issue_id",
3264 "event",
3265 "member_id",
3266 "scope",
3267 "delegate_member_ids"
3268 ) VALUES (
3269 "issue_id_p",
3270 'periodic',
3271 "issue_delegation_row"."truster_id",
3272 "issue_delegation_row"."scope",
3273 "delegate_member_ids_v"
3274 );
3275 "sub_weight_v" := 1 +
3276 "weight_of_added_delegations_for_interest_snapshot"(
3277 "issue_id_p",
3278 "issue_delegation_row"."truster_id",
3279 "delegate_member_ids_v"
3280 );
3281 UPDATE "delegating_interest_snapshot"
3282 SET "weight" = "sub_weight_v"
3283 WHERE "issue_id" = "issue_id_p"
3284 AND "event" = 'periodic'
3285 AND "member_id" = "issue_delegation_row"."truster_id";
3286 "weight_v" := "weight_v" + "sub_weight_v";
3287 END IF;
3288 END LOOP;
3289 RETURN "weight_v";
3290 END;
3291 $$;
3293 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3294 ( "issue"."id"%TYPE,
3295 "member"."id"%TYPE,
3296 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3297 IS 'Helper function for "create_interest_snapshot" function';
3300 CREATE FUNCTION "create_interest_snapshot"
3301 ( "issue_id_p" "issue"."id"%TYPE )
3302 RETURNS VOID
3303 LANGUAGE 'plpgsql' VOLATILE AS $$
3304 DECLARE
3305 "member_id_v" "member"."id"%TYPE;
3306 BEGIN
3307 PERFORM "require_transaction_isolation"();
3308 DELETE FROM "direct_interest_snapshot"
3309 WHERE "issue_id" = "issue_id_p"
3310 AND "event" = 'periodic';
3311 DELETE FROM "delegating_interest_snapshot"
3312 WHERE "issue_id" = "issue_id_p"
3313 AND "event" = 'periodic';
3314 DELETE FROM "direct_supporter_snapshot"
3315 USING "initiative" -- NOTE: due to missing index on issue_id
3316 WHERE "initiative"."issue_id" = "issue_id_p"
3317 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3318 AND "direct_supporter_snapshot"."event" = 'periodic';
3319 INSERT INTO "direct_interest_snapshot"
3320 ("issue_id", "event", "member_id")
3321 SELECT
3322 "issue_id_p" AS "issue_id",
3323 'periodic' AS "event",
3324 "member"."id" AS "member_id"
3325 FROM "issue"
3326 JOIN "area" ON "issue"."area_id" = "area"."id"
3327 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3328 JOIN "member" ON "interest"."member_id" = "member"."id"
3329 JOIN "privilege"
3330 ON "privilege"."unit_id" = "area"."unit_id"
3331 AND "privilege"."member_id" = "member"."id"
3332 WHERE "issue"."id" = "issue_id_p"
3333 AND "member"."active" AND "privilege"."voting_right";
3334 FOR "member_id_v" IN
3335 SELECT "member_id" FROM "direct_interest_snapshot"
3336 WHERE "issue_id" = "issue_id_p"
3337 AND "event" = 'periodic'
3338 LOOP
3339 UPDATE "direct_interest_snapshot" SET
3340 "weight" = 1 +
3341 "weight_of_added_delegations_for_interest_snapshot"(
3342 "issue_id_p",
3343 "member_id_v",
3344 '{}'
3346 WHERE "issue_id" = "issue_id_p"
3347 AND "event" = 'periodic'
3348 AND "member_id" = "member_id_v";
3349 END LOOP;
3350 INSERT INTO "direct_supporter_snapshot"
3351 ( "issue_id", "initiative_id", "event", "member_id",
3352 "draft_id", "informed", "satisfied" )
3353 SELECT
3354 "issue_id_p" AS "issue_id",
3355 "initiative"."id" AS "initiative_id",
3356 'periodic' AS "event",
3357 "supporter"."member_id" AS "member_id",
3358 "supporter"."draft_id" AS "draft_id",
3359 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3360 NOT EXISTS (
3361 SELECT NULL FROM "critical_opinion"
3362 WHERE "initiative_id" = "initiative"."id"
3363 AND "member_id" = "supporter"."member_id"
3364 ) AS "satisfied"
3365 FROM "initiative"
3366 JOIN "supporter"
3367 ON "supporter"."initiative_id" = "initiative"."id"
3368 JOIN "current_draft"
3369 ON "initiative"."id" = "current_draft"."initiative_id"
3370 JOIN "direct_interest_snapshot"
3371 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3372 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3373 AND "event" = 'periodic'
3374 WHERE "initiative"."issue_id" = "issue_id_p";
3375 RETURN;
3376 END;
3377 $$;
3379 COMMENT ON FUNCTION "create_interest_snapshot"
3380 ( "issue"."id"%TYPE )
3381 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.';
3384 CREATE FUNCTION "create_snapshot"
3385 ( "issue_id_p" "issue"."id"%TYPE )
3386 RETURNS VOID
3387 LANGUAGE 'plpgsql' VOLATILE AS $$
3388 DECLARE
3389 "initiative_id_v" "initiative"."id"%TYPE;
3390 "suggestion_id_v" "suggestion"."id"%TYPE;
3391 BEGIN
3392 PERFORM "require_transaction_isolation"();
3393 PERFORM "create_population_snapshot"("issue_id_p");
3394 PERFORM "create_interest_snapshot"("issue_id_p");
3395 UPDATE "issue" SET
3396 "snapshot" = coalesce("phase_finished", now()),
3397 "latest_snapshot_event" = 'periodic',
3398 "population" = (
3399 SELECT coalesce(sum("weight"), 0)
3400 FROM "direct_population_snapshot"
3401 WHERE "issue_id" = "issue_id_p"
3402 AND "event" = 'periodic'
3404 WHERE "id" = "issue_id_p";
3405 FOR "initiative_id_v" IN
3406 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3407 LOOP
3408 UPDATE "initiative" SET
3409 "supporter_count" = (
3410 SELECT coalesce(sum("di"."weight"), 0)
3411 FROM "direct_interest_snapshot" AS "di"
3412 JOIN "direct_supporter_snapshot" AS "ds"
3413 ON "di"."member_id" = "ds"."member_id"
3414 WHERE "di"."issue_id" = "issue_id_p"
3415 AND "di"."event" = 'periodic'
3416 AND "ds"."initiative_id" = "initiative_id_v"
3417 AND "ds"."event" = 'periodic'
3418 ),
3419 "informed_supporter_count" = (
3420 SELECT coalesce(sum("di"."weight"), 0)
3421 FROM "direct_interest_snapshot" AS "di"
3422 JOIN "direct_supporter_snapshot" AS "ds"
3423 ON "di"."member_id" = "ds"."member_id"
3424 WHERE "di"."issue_id" = "issue_id_p"
3425 AND "di"."event" = 'periodic'
3426 AND "ds"."initiative_id" = "initiative_id_v"
3427 AND "ds"."event" = 'periodic'
3428 AND "ds"."informed"
3429 ),
3430 "satisfied_supporter_count" = (
3431 SELECT coalesce(sum("di"."weight"), 0)
3432 FROM "direct_interest_snapshot" AS "di"
3433 JOIN "direct_supporter_snapshot" AS "ds"
3434 ON "di"."member_id" = "ds"."member_id"
3435 WHERE "di"."issue_id" = "issue_id_p"
3436 AND "di"."event" = 'periodic'
3437 AND "ds"."initiative_id" = "initiative_id_v"
3438 AND "ds"."event" = 'periodic'
3439 AND "ds"."satisfied"
3440 ),
3441 "satisfied_informed_supporter_count" = (
3442 SELECT coalesce(sum("di"."weight"), 0)
3443 FROM "direct_interest_snapshot" AS "di"
3444 JOIN "direct_supporter_snapshot" AS "ds"
3445 ON "di"."member_id" = "ds"."member_id"
3446 WHERE "di"."issue_id" = "issue_id_p"
3447 AND "di"."event" = 'periodic'
3448 AND "ds"."initiative_id" = "initiative_id_v"
3449 AND "ds"."event" = 'periodic'
3450 AND "ds"."informed"
3451 AND "ds"."satisfied"
3453 WHERE "id" = "initiative_id_v";
3454 FOR "suggestion_id_v" IN
3455 SELECT "id" FROM "suggestion"
3456 WHERE "initiative_id" = "initiative_id_v"
3457 LOOP
3458 UPDATE "suggestion" SET
3459 "minus2_unfulfilled_count" = (
3460 SELECT coalesce(sum("snapshot"."weight"), 0)
3461 FROM "issue" CROSS JOIN "opinion"
3462 JOIN "direct_interest_snapshot" AS "snapshot"
3463 ON "snapshot"."issue_id" = "issue"."id"
3464 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3465 AND "snapshot"."member_id" = "opinion"."member_id"
3466 WHERE "issue"."id" = "issue_id_p"
3467 AND "opinion"."suggestion_id" = "suggestion_id_v"
3468 AND "opinion"."degree" = -2
3469 AND "opinion"."fulfilled" = FALSE
3470 ),
3471 "minus2_fulfilled_count" = (
3472 SELECT coalesce(sum("snapshot"."weight"), 0)
3473 FROM "issue" CROSS JOIN "opinion"
3474 JOIN "direct_interest_snapshot" AS "snapshot"
3475 ON "snapshot"."issue_id" = "issue"."id"
3476 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3477 AND "snapshot"."member_id" = "opinion"."member_id"
3478 WHERE "issue"."id" = "issue_id_p"
3479 AND "opinion"."suggestion_id" = "suggestion_id_v"
3480 AND "opinion"."degree" = -2
3481 AND "opinion"."fulfilled" = TRUE
3482 ),
3483 "minus1_unfulfilled_count" = (
3484 SELECT coalesce(sum("snapshot"."weight"), 0)
3485 FROM "issue" CROSS JOIN "opinion"
3486 JOIN "direct_interest_snapshot" AS "snapshot"
3487 ON "snapshot"."issue_id" = "issue"."id"
3488 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3489 AND "snapshot"."member_id" = "opinion"."member_id"
3490 WHERE "issue"."id" = "issue_id_p"
3491 AND "opinion"."suggestion_id" = "suggestion_id_v"
3492 AND "opinion"."degree" = -1
3493 AND "opinion"."fulfilled" = FALSE
3494 ),
3495 "minus1_fulfilled_count" = (
3496 SELECT coalesce(sum("snapshot"."weight"), 0)
3497 FROM "issue" CROSS JOIN "opinion"
3498 JOIN "direct_interest_snapshot" AS "snapshot"
3499 ON "snapshot"."issue_id" = "issue"."id"
3500 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3501 AND "snapshot"."member_id" = "opinion"."member_id"
3502 WHERE "issue"."id" = "issue_id_p"
3503 AND "opinion"."suggestion_id" = "suggestion_id_v"
3504 AND "opinion"."degree" = -1
3505 AND "opinion"."fulfilled" = TRUE
3506 ),
3507 "plus1_unfulfilled_count" = (
3508 SELECT coalesce(sum("snapshot"."weight"), 0)
3509 FROM "issue" CROSS JOIN "opinion"
3510 JOIN "direct_interest_snapshot" AS "snapshot"
3511 ON "snapshot"."issue_id" = "issue"."id"
3512 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3513 AND "snapshot"."member_id" = "opinion"."member_id"
3514 WHERE "issue"."id" = "issue_id_p"
3515 AND "opinion"."suggestion_id" = "suggestion_id_v"
3516 AND "opinion"."degree" = 1
3517 AND "opinion"."fulfilled" = FALSE
3518 ),
3519 "plus1_fulfilled_count" = (
3520 SELECT coalesce(sum("snapshot"."weight"), 0)
3521 FROM "issue" CROSS JOIN "opinion"
3522 JOIN "direct_interest_snapshot" AS "snapshot"
3523 ON "snapshot"."issue_id" = "issue"."id"
3524 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3525 AND "snapshot"."member_id" = "opinion"."member_id"
3526 WHERE "issue"."id" = "issue_id_p"
3527 AND "opinion"."suggestion_id" = "suggestion_id_v"
3528 AND "opinion"."degree" = 1
3529 AND "opinion"."fulfilled" = TRUE
3530 ),
3531 "plus2_unfulfilled_count" = (
3532 SELECT coalesce(sum("snapshot"."weight"), 0)
3533 FROM "issue" CROSS JOIN "opinion"
3534 JOIN "direct_interest_snapshot" AS "snapshot"
3535 ON "snapshot"."issue_id" = "issue"."id"
3536 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3537 AND "snapshot"."member_id" = "opinion"."member_id"
3538 WHERE "issue"."id" = "issue_id_p"
3539 AND "opinion"."suggestion_id" = "suggestion_id_v"
3540 AND "opinion"."degree" = 2
3541 AND "opinion"."fulfilled" = FALSE
3542 ),
3543 "plus2_fulfilled_count" = (
3544 SELECT coalesce(sum("snapshot"."weight"), 0)
3545 FROM "issue" CROSS JOIN "opinion"
3546 JOIN "direct_interest_snapshot" AS "snapshot"
3547 ON "snapshot"."issue_id" = "issue"."id"
3548 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3549 AND "snapshot"."member_id" = "opinion"."member_id"
3550 WHERE "issue"."id" = "issue_id_p"
3551 AND "opinion"."suggestion_id" = "suggestion_id_v"
3552 AND "opinion"."degree" = 2
3553 AND "opinion"."fulfilled" = TRUE
3555 WHERE "suggestion"."id" = "suggestion_id_v";
3556 END LOOP;
3557 END LOOP;
3558 RETURN;
3559 END;
3560 $$;
3562 COMMENT ON FUNCTION "create_snapshot"
3563 ( "issue"."id"%TYPE )
3564 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.';
3567 CREATE FUNCTION "set_snapshot_event"
3568 ( "issue_id_p" "issue"."id"%TYPE,
3569 "event_p" "snapshot_event" )
3570 RETURNS VOID
3571 LANGUAGE 'plpgsql' VOLATILE AS $$
3572 DECLARE
3573 "event_v" "issue"."latest_snapshot_event"%TYPE;
3574 BEGIN
3575 PERFORM "require_transaction_isolation"();
3576 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3577 WHERE "id" = "issue_id_p" FOR UPDATE;
3578 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3579 WHERE "id" = "issue_id_p";
3580 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3581 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3582 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3583 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3584 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3585 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3586 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3587 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3588 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3589 FROM "initiative" -- NOTE: due to missing index on issue_id
3590 WHERE "initiative"."issue_id" = "issue_id_p"
3591 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3592 AND "direct_supporter_snapshot"."event" = "event_v";
3593 RETURN;
3594 END;
3595 $$;
3597 COMMENT ON FUNCTION "set_snapshot_event"
3598 ( "issue"."id"%TYPE,
3599 "snapshot_event" )
3600 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3604 -----------------------
3605 -- Counting of votes --
3606 -----------------------
3609 CREATE FUNCTION "weight_of_added_vote_delegations"
3610 ( "issue_id_p" "issue"."id"%TYPE,
3611 "member_id_p" "member"."id"%TYPE,
3612 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3613 RETURNS "direct_voter"."weight"%TYPE
3614 LANGUAGE 'plpgsql' VOLATILE AS $$
3615 DECLARE
3616 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3617 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3618 "weight_v" INT4;
3619 "sub_weight_v" INT4;
3620 BEGIN
3621 PERFORM "require_transaction_isolation"();
3622 "weight_v" := 0;
3623 FOR "issue_delegation_row" IN
3624 SELECT * FROM "issue_delegation"
3625 WHERE "trustee_id" = "member_id_p"
3626 AND "issue_id" = "issue_id_p"
3627 LOOP
3628 IF NOT EXISTS (
3629 SELECT NULL FROM "direct_voter"
3630 WHERE "member_id" = "issue_delegation_row"."truster_id"
3631 AND "issue_id" = "issue_id_p"
3632 ) AND NOT EXISTS (
3633 SELECT NULL FROM "delegating_voter"
3634 WHERE "member_id" = "issue_delegation_row"."truster_id"
3635 AND "issue_id" = "issue_id_p"
3636 ) THEN
3637 "delegate_member_ids_v" :=
3638 "member_id_p" || "delegate_member_ids_p";
3639 INSERT INTO "delegating_voter" (
3640 "issue_id",
3641 "member_id",
3642 "scope",
3643 "delegate_member_ids"
3644 ) VALUES (
3645 "issue_id_p",
3646 "issue_delegation_row"."truster_id",
3647 "issue_delegation_row"."scope",
3648 "delegate_member_ids_v"
3649 );
3650 "sub_weight_v" := 1 +
3651 "weight_of_added_vote_delegations"(
3652 "issue_id_p",
3653 "issue_delegation_row"."truster_id",
3654 "delegate_member_ids_v"
3655 );
3656 UPDATE "delegating_voter"
3657 SET "weight" = "sub_weight_v"
3658 WHERE "issue_id" = "issue_id_p"
3659 AND "member_id" = "issue_delegation_row"."truster_id";
3660 "weight_v" := "weight_v" + "sub_weight_v";
3661 END IF;
3662 END LOOP;
3663 RETURN "weight_v";
3664 END;
3665 $$;
3667 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3668 ( "issue"."id"%TYPE,
3669 "member"."id"%TYPE,
3670 "delegating_voter"."delegate_member_ids"%TYPE )
3671 IS 'Helper function for "add_vote_delegations" function';
3674 CREATE FUNCTION "add_vote_delegations"
3675 ( "issue_id_p" "issue"."id"%TYPE )
3676 RETURNS VOID
3677 LANGUAGE 'plpgsql' VOLATILE AS $$
3678 DECLARE
3679 "member_id_v" "member"."id"%TYPE;
3680 BEGIN
3681 PERFORM "require_transaction_isolation"();
3682 FOR "member_id_v" IN
3683 SELECT "member_id" FROM "direct_voter"
3684 WHERE "issue_id" = "issue_id_p"
3685 LOOP
3686 UPDATE "direct_voter" SET
3687 "weight" = "weight" + "weight_of_added_vote_delegations"(
3688 "issue_id_p",
3689 "member_id_v",
3690 '{}'
3692 WHERE "member_id" = "member_id_v"
3693 AND "issue_id" = "issue_id_p";
3694 END LOOP;
3695 RETURN;
3696 END;
3697 $$;
3699 COMMENT ON FUNCTION "add_vote_delegations"
3700 ( "issue_id_p" "issue"."id"%TYPE )
3701 IS 'Helper function for "close_voting" function';
3704 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3705 RETURNS VOID
3706 LANGUAGE 'plpgsql' VOLATILE AS $$
3707 DECLARE
3708 "area_id_v" "area"."id"%TYPE;
3709 "unit_id_v" "unit"."id"%TYPE;
3710 "member_id_v" "member"."id"%TYPE;
3711 BEGIN
3712 PERFORM "require_transaction_isolation"();
3713 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3714 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3715 -- override protection triggers:
3716 INSERT INTO "temporary_transaction_data" ("key", "value")
3717 VALUES ('override_protection_triggers', TRUE::TEXT);
3718 -- delete timestamp of voting comment:
3719 UPDATE "direct_voter" SET "comment_changed" = NULL
3720 WHERE "issue_id" = "issue_id_p";
3721 -- delete delegating votes (in cases of manual reset of issue state):
3722 DELETE FROM "delegating_voter"
3723 WHERE "issue_id" = "issue_id_p";
3724 -- delete votes from non-privileged voters:
3725 DELETE FROM "direct_voter"
3726 USING (
3727 SELECT
3728 "direct_voter"."member_id"
3729 FROM "direct_voter"
3730 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3731 LEFT JOIN "privilege"
3732 ON "privilege"."unit_id" = "unit_id_v"
3733 AND "privilege"."member_id" = "direct_voter"."member_id"
3734 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3735 "member"."active" = FALSE OR
3736 "privilege"."voting_right" ISNULL OR
3737 "privilege"."voting_right" = FALSE
3739 ) AS "subquery"
3740 WHERE "direct_voter"."issue_id" = "issue_id_p"
3741 AND "direct_voter"."member_id" = "subquery"."member_id";
3742 -- consider delegations:
3743 UPDATE "direct_voter" SET "weight" = 1
3744 WHERE "issue_id" = "issue_id_p";
3745 PERFORM "add_vote_delegations"("issue_id_p");
3746 -- mark first preferences:
3747 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
3748 FROM (
3749 SELECT
3750 "vote"."initiative_id",
3751 "vote"."member_id",
3752 CASE WHEN "vote"."grade" > 0 THEN
3753 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
3754 ELSE NULL
3755 END AS "first_preference"
3756 FROM "vote"
3757 JOIN "initiative" -- NOTE: due to missing index on issue_id
3758 ON "vote"."issue_id" = "initiative"."issue_id"
3759 JOIN "vote" AS "agg"
3760 ON "initiative"."id" = "agg"."initiative_id"
3761 AND "vote"."member_id" = "agg"."member_id"
3762 GROUP BY "vote"."initiative_id", "vote"."member_id"
3763 ) AS "subquery"
3764 WHERE "vote"."issue_id" = "issue_id_p"
3765 AND "vote"."initiative_id" = "subquery"."initiative_id"
3766 AND "vote"."member_id" = "subquery"."member_id";
3767 -- finish overriding protection triggers (avoids garbage):
3768 DELETE FROM "temporary_transaction_data"
3769 WHERE "key" = 'override_protection_triggers';
3770 -- materialize battle_view:
3771 -- NOTE: "closed" column of issue must be set at this point
3772 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3773 INSERT INTO "battle" (
3774 "issue_id",
3775 "winning_initiative_id", "losing_initiative_id",
3776 "count"
3777 ) SELECT
3778 "issue_id",
3779 "winning_initiative_id", "losing_initiative_id",
3780 "count"
3781 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3782 -- set voter count:
3783 UPDATE "issue" SET
3784 "voter_count" = (
3785 SELECT coalesce(sum("weight"), 0)
3786 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3788 WHERE "id" = "issue_id_p";
3789 -- calculate "first_preference_votes":
3790 UPDATE "initiative"
3791 SET "first_preference_votes" = coalesce("subquery"."sum", 0)
3792 FROM (
3793 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
3794 FROM "vote" JOIN "direct_voter"
3795 ON "vote"."issue_id" = "direct_voter"."issue_id"
3796 AND "vote"."member_id" = "direct_voter"."member_id"
3797 WHERE "vote"."first_preference"
3798 GROUP BY "vote"."initiative_id"
3799 ) AS "subquery"
3800 WHERE "initiative"."issue_id" = "issue_id_p"
3801 AND "initiative"."admitted"
3802 AND "initiative"."id" = "subquery"."initiative_id";
3803 -- copy "positive_votes" and "negative_votes" from "battle" table:
3804 UPDATE "initiative" SET
3805 "positive_votes" = "battle_win"."count",
3806 "negative_votes" = "battle_lose"."count"
3807 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3808 WHERE
3809 "battle_win"."issue_id" = "issue_id_p" AND
3810 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3811 "battle_win"."losing_initiative_id" ISNULL AND
3812 "battle_lose"."issue_id" = "issue_id_p" AND
3813 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3814 "battle_lose"."winning_initiative_id" ISNULL;
3815 END;
3816 $$;
3818 COMMENT ON FUNCTION "close_voting"
3819 ( "issue"."id"%TYPE )
3820 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.';
3823 CREATE FUNCTION "defeat_strength"
3824 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3825 RETURNS INT8
3826 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3827 BEGIN
3828 IF "positive_votes_p" > "negative_votes_p" THEN
3829 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3830 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3831 RETURN 0;
3832 ELSE
3833 RETURN -1;
3834 END IF;
3835 END;
3836 $$;
3838 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4) IS 'Calculates defeat strength (INT8!) of a pairwise defeat primarily by the absolute number of votes for the winner and secondarily by the absolute number of votes for the loser';
3841 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3842 RETURNS VOID
3843 LANGUAGE 'plpgsql' VOLATILE AS $$
3844 DECLARE
3845 "issue_row" "issue"%ROWTYPE;
3846 "policy_row" "policy"%ROWTYPE;
3847 "dimension_v" INTEGER;
3848 "vote_matrix" INT4[][]; -- absolute votes
3849 "matrix" INT8[][]; -- defeat strength / best paths
3850 "i" INTEGER;
3851 "j" INTEGER;
3852 "k" INTEGER;
3853 "battle_row" "battle"%ROWTYPE;
3854 "rank_ary" INT4[];
3855 "rank_v" INT4;
3856 "initiative_id_v" "initiative"."id"%TYPE;
3857 BEGIN
3858 PERFORM "require_transaction_isolation"();
3859 SELECT * INTO "issue_row"
3860 FROM "issue" WHERE "id" = "issue_id_p";
3861 SELECT * INTO "policy_row"
3862 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3863 SELECT count(1) INTO "dimension_v"
3864 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3865 -- Create "vote_matrix" with absolute number of votes in pairwise
3866 -- comparison:
3867 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3868 "i" := 1;
3869 "j" := 2;
3870 FOR "battle_row" IN
3871 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3872 ORDER BY
3873 "winning_initiative_id" NULLS FIRST,
3874 "losing_initiative_id" NULLS FIRST
3875 LOOP
3876 "vote_matrix"["i"]["j"] := "battle_row"."count";
3877 IF "j" = "dimension_v" THEN
3878 "i" := "i" + 1;
3879 "j" := 1;
3880 ELSE
3881 "j" := "j" + 1;
3882 IF "j" = "i" THEN
3883 "j" := "j" + 1;
3884 END IF;
3885 END IF;
3886 END LOOP;
3887 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3888 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3889 END IF;
3890 -- Store defeat strengths in "matrix" using "defeat_strength"
3891 -- function:
3892 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3893 "i" := 1;
3894 LOOP
3895 "j" := 1;
3896 LOOP
3897 IF "i" != "j" THEN
3898 "matrix"["i"]["j"] := "defeat_strength"(
3899 "vote_matrix"["i"]["j"],
3900 "vote_matrix"["j"]["i"]
3901 );
3902 END IF;
3903 EXIT WHEN "j" = "dimension_v";
3904 "j" := "j" + 1;
3905 END LOOP;
3906 EXIT WHEN "i" = "dimension_v";
3907 "i" := "i" + 1;
3908 END LOOP;
3909 -- Find best paths:
3910 "i" := 1;
3911 LOOP
3912 "j" := 1;
3913 LOOP
3914 IF "i" != "j" THEN
3915 "k" := 1;
3916 LOOP
3917 IF "i" != "k" AND "j" != "k" THEN
3918 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3919 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3920 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3921 END IF;
3922 ELSE
3923 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3924 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3925 END IF;
3926 END IF;
3927 END IF;
3928 EXIT WHEN "k" = "dimension_v";
3929 "k" := "k" + 1;
3930 END LOOP;
3931 END IF;
3932 EXIT WHEN "j" = "dimension_v";
3933 "j" := "j" + 1;
3934 END LOOP;
3935 EXIT WHEN "i" = "dimension_v";
3936 "i" := "i" + 1;
3937 END LOOP;
3938 -- Determine order of winners:
3939 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3940 "rank_v" := 1;
3941 LOOP
3942 "i" := 1;
3943 LOOP
3944 IF "rank_ary"["i"] ISNULL THEN
3945 "j" := 1;
3946 LOOP
3947 IF
3948 "i" != "j" AND
3949 "rank_ary"["j"] ISNULL AND
3950 ( "matrix"["j"]["i"] > "matrix"["i"]["j"] OR
3951 -- tie-breaking by "id"
3952 ( "matrix"["j"]["i"] = "matrix"["i"]["j"] AND
3953 "j" < "i" ) )
3954 THEN
3955 -- someone else is better
3956 EXIT;
3957 END IF;
3958 "j" := "j" + 1;
3959 IF "j" = "dimension_v" + 1 THEN
3960 -- noone is better
3961 "rank_ary"["i"] := "rank_v";
3962 EXIT;
3963 END IF;
3964 END LOOP;
3965 EXIT WHEN "j" = "dimension_v" + 1;
3966 END IF;
3967 "i" := "i" + 1;
3968 IF "i" > "dimension_v" THEN
3969 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
3970 END IF;
3971 END LOOP;
3972 EXIT WHEN "rank_v" = "dimension_v";
3973 "rank_v" := "rank_v" + 1;
3974 END LOOP;
3975 -- write preliminary results:
3976 "i" := 2; -- omit status quo with "i" = 1
3977 FOR "initiative_id_v" IN
3978 SELECT "id" FROM "initiative"
3979 WHERE "issue_id" = "issue_id_p" AND "admitted"
3980 ORDER BY "id"
3981 LOOP
3982 UPDATE "initiative" SET
3983 "direct_majority" =
3984 CASE WHEN "policy_row"."direct_majority_strict" THEN
3985 "positive_votes" * "policy_row"."direct_majority_den" >
3986 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3987 ELSE
3988 "positive_votes" * "policy_row"."direct_majority_den" >=
3989 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3990 END
3991 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3992 AND "issue_row"."voter_count"-"negative_votes" >=
3993 "policy_row"."direct_majority_non_negative",
3994 "indirect_majority" =
3995 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3996 "positive_votes" * "policy_row"."indirect_majority_den" >
3997 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3998 ELSE
3999 "positive_votes" * "policy_row"."indirect_majority_den" >=
4000 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4001 END
4002 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4003 AND "issue_row"."voter_count"-"negative_votes" >=
4004 "policy_row"."indirect_majority_non_negative",
4005 "schulze_rank" = "rank_ary"["i"],
4006 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
4007 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
4008 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
4009 "reverse_beat_path" = "matrix"[1]["i"] >= 0,
4010 "eligible" = FALSE,
4011 "winner" = FALSE,
4012 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4013 WHERE "id" = "initiative_id_v";
4014 "i" := "i" + 1;
4015 END LOOP;
4016 IF "i" != "dimension_v" + 1 THEN
4017 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4018 END IF;
4019 -- take indirect majorities into account:
4020 LOOP
4021 UPDATE "initiative" SET "indirect_majority" = TRUE
4022 FROM (
4023 SELECT "new_initiative"."id" AS "initiative_id"
4024 FROM "initiative" "old_initiative"
4025 JOIN "initiative" "new_initiative"
4026 ON "new_initiative"."issue_id" = "issue_id_p"
4027 AND "new_initiative"."indirect_majority" = FALSE
4028 JOIN "battle" "battle_win"
4029 ON "battle_win"."issue_id" = "issue_id_p"
4030 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4031 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4032 JOIN "battle" "battle_lose"
4033 ON "battle_lose"."issue_id" = "issue_id_p"
4034 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4035 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4036 WHERE "old_initiative"."issue_id" = "issue_id_p"
4037 AND "old_initiative"."indirect_majority" = TRUE
4038 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4039 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4040 "policy_row"."indirect_majority_num" *
4041 ("battle_win"."count"+"battle_lose"."count")
4042 ELSE
4043 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4044 "policy_row"."indirect_majority_num" *
4045 ("battle_win"."count"+"battle_lose"."count")
4046 END
4047 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4048 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4049 "policy_row"."indirect_majority_non_negative"
4050 ) AS "subquery"
4051 WHERE "id" = "subquery"."initiative_id";
4052 EXIT WHEN NOT FOUND;
4053 END LOOP;
4054 -- set "multistage_majority" for remaining matching initiatives:
4055 UPDATE "initiative" SET "multistage_majority" = TRUE
4056 FROM (
4057 SELECT "losing_initiative"."id" AS "initiative_id"
4058 FROM "initiative" "losing_initiative"
4059 JOIN "initiative" "winning_initiative"
4060 ON "winning_initiative"."issue_id" = "issue_id_p"
4061 AND "winning_initiative"."admitted"
4062 JOIN "battle" "battle_win"
4063 ON "battle_win"."issue_id" = "issue_id_p"
4064 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4065 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4066 JOIN "battle" "battle_lose"
4067 ON "battle_lose"."issue_id" = "issue_id_p"
4068 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4069 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4070 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4071 AND "losing_initiative"."admitted"
4072 AND "winning_initiative"."schulze_rank" <
4073 "losing_initiative"."schulze_rank"
4074 AND "battle_win"."count" > "battle_lose"."count"
4075 AND (
4076 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4077 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4078 ) AS "subquery"
4079 WHERE "id" = "subquery"."initiative_id";
4080 -- mark eligible initiatives:
4081 UPDATE "initiative" SET "eligible" = TRUE
4082 WHERE "issue_id" = "issue_id_p"
4083 AND "initiative"."direct_majority"
4084 AND "initiative"."indirect_majority"
4085 AND "initiative"."better_than_status_quo"
4086 AND (
4087 "policy_row"."no_multistage_majority" = FALSE OR
4088 "initiative"."multistage_majority" = FALSE )
4089 AND (
4090 "policy_row"."no_reverse_beat_path" = FALSE OR
4091 "initiative"."reverse_beat_path" = FALSE );
4092 -- mark final winner:
4093 UPDATE "initiative" SET "winner" = TRUE
4094 FROM (
4095 SELECT "id" AS "initiative_id"
4096 FROM "initiative"
4097 WHERE "issue_id" = "issue_id_p" AND "eligible"
4098 ORDER BY
4099 "schulze_rank",
4100 "id"
4101 LIMIT 1
4102 ) AS "subquery"
4103 WHERE "id" = "subquery"."initiative_id";
4104 -- write (final) ranks:
4105 "rank_v" := 1;
4106 FOR "initiative_id_v" IN
4107 SELECT "id"
4108 FROM "initiative"
4109 WHERE "issue_id" = "issue_id_p" AND "admitted"
4110 ORDER BY
4111 "winner" DESC,
4112 "eligible" DESC,
4113 "schulze_rank",
4114 "id"
4115 LOOP
4116 UPDATE "initiative" SET "rank" = "rank_v"
4117 WHERE "id" = "initiative_id_v";
4118 "rank_v" := "rank_v" + 1;
4119 END LOOP;
4120 -- set schulze rank of status quo and mark issue as finished:
4121 UPDATE "issue" SET
4122 "status_quo_schulze_rank" = "rank_ary"[1],
4123 "state" =
4124 CASE WHEN EXISTS (
4125 SELECT NULL FROM "initiative"
4126 WHERE "issue_id" = "issue_id_p" AND "winner"
4127 ) THEN
4128 'finished_with_winner'::"issue_state"
4129 ELSE
4130 'finished_without_winner'::"issue_state"
4131 END,
4132 "closed" = "phase_finished",
4133 "phase_finished" = NULL
4134 WHERE "id" = "issue_id_p";
4135 RETURN;
4136 END;
4137 $$;
4139 COMMENT ON FUNCTION "calculate_ranks"
4140 ( "issue"."id"%TYPE )
4141 IS 'Determine ranking (Votes have to be counted first)';
4145 -----------------------------
4146 -- Automatic state changes --
4147 -----------------------------
4150 CREATE TYPE "check_issue_persistence" AS (
4151 "state" "issue_state",
4152 "phase_finished" BOOLEAN,
4153 "issue_revoked" BOOLEAN,
4154 "snapshot_created" BOOLEAN,
4155 "harmonic_weights_set" BOOLEAN,
4156 "closed_voting" BOOLEAN );
4158 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';
4161 CREATE FUNCTION "check_issue"
4162 ( "issue_id_p" "issue"."id"%TYPE,
4163 "persist" "check_issue_persistence" )
4164 RETURNS "check_issue_persistence"
4165 LANGUAGE 'plpgsql' VOLATILE AS $$
4166 DECLARE
4167 "issue_row" "issue"%ROWTYPE;
4168 "policy_row" "policy"%ROWTYPE;
4169 "initiative_row" "initiative"%ROWTYPE;
4170 "state_v" "issue_state";
4171 BEGIN
4172 PERFORM "require_transaction_isolation"();
4173 IF "persist" ISNULL THEN
4174 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4175 FOR UPDATE;
4176 IF "issue_row"."closed" NOTNULL THEN
4177 RETURN NULL;
4178 END IF;
4179 "persist"."state" := "issue_row"."state";
4180 IF
4181 ( "issue_row"."state" = 'admission' AND now() >=
4182 "issue_row"."created" + "issue_row"."admission_time" ) OR
4183 ( "issue_row"."state" = 'discussion' AND now() >=
4184 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4185 ( "issue_row"."state" = 'verification' AND now() >=
4186 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4187 ( "issue_row"."state" = 'voting' AND now() >=
4188 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4189 THEN
4190 "persist"."phase_finished" := TRUE;
4191 ELSE
4192 "persist"."phase_finished" := FALSE;
4193 END IF;
4194 IF
4195 NOT EXISTS (
4196 -- all initiatives are revoked
4197 SELECT NULL FROM "initiative"
4198 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4199 ) AND (
4200 -- and issue has not been accepted yet
4201 "persist"."state" = 'admission' OR
4202 -- or verification time has elapsed
4203 ( "persist"."state" = 'verification' AND
4204 "persist"."phase_finished" ) OR
4205 -- or no initiatives have been revoked lately
4206 NOT EXISTS (
4207 SELECT NULL FROM "initiative"
4208 WHERE "issue_id" = "issue_id_p"
4209 AND now() < "revoked" + "issue_row"."verification_time"
4212 THEN
4213 "persist"."issue_revoked" := TRUE;
4214 ELSE
4215 "persist"."issue_revoked" := FALSE;
4216 END IF;
4217 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4218 UPDATE "issue" SET "phase_finished" = now()
4219 WHERE "id" = "issue_row"."id";
4220 RETURN "persist";
4221 ELSIF
4222 "persist"."state" IN ('admission', 'discussion', 'verification')
4223 THEN
4224 RETURN "persist";
4225 ELSE
4226 RETURN NULL;
4227 END IF;
4228 END IF;
4229 IF
4230 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4231 coalesce("persist"."snapshot_created", FALSE) = FALSE
4232 THEN
4233 PERFORM "create_snapshot"("issue_id_p");
4234 "persist"."snapshot_created" = TRUE;
4235 IF "persist"."phase_finished" THEN
4236 IF "persist"."state" = 'admission' THEN
4237 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4238 ELSIF "persist"."state" = 'discussion' THEN
4239 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4240 ELSIF "persist"."state" = 'verification' THEN
4241 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4242 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4243 SELECT * INTO "policy_row" FROM "policy"
4244 WHERE "id" = "issue_row"."policy_id";
4245 FOR "initiative_row" IN
4246 SELECT * FROM "initiative"
4247 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4248 FOR UPDATE
4249 LOOP
4250 IF
4251 "initiative_row"."polling" OR (
4252 "initiative_row"."satisfied_supporter_count" > 0 AND
4253 "initiative_row"."satisfied_supporter_count" *
4254 "policy_row"."initiative_quorum_den" >=
4255 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4257 THEN
4258 UPDATE "initiative" SET "admitted" = TRUE
4259 WHERE "id" = "initiative_row"."id";
4260 ELSE
4261 UPDATE "initiative" SET "admitted" = FALSE
4262 WHERE "id" = "initiative_row"."id";
4263 END IF;
4264 END LOOP;
4265 END IF;
4266 END IF;
4267 RETURN "persist";
4268 END IF;
4269 IF
4270 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4271 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4272 THEN
4273 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4274 "persist"."harmonic_weights_set" = TRUE;
4275 IF
4276 "persist"."phase_finished" OR
4277 "persist"."issue_revoked" OR
4278 "persist"."state" = 'admission'
4279 THEN
4280 RETURN "persist";
4281 ELSE
4282 RETURN NULL;
4283 END IF;
4284 END IF;
4285 IF "persist"."issue_revoked" THEN
4286 IF "persist"."state" = 'admission' THEN
4287 "state_v" := 'canceled_revoked_before_accepted';
4288 ELSIF "persist"."state" = 'discussion' THEN
4289 "state_v" := 'canceled_after_revocation_during_discussion';
4290 ELSIF "persist"."state" = 'verification' THEN
4291 "state_v" := 'canceled_after_revocation_during_verification';
4292 END IF;
4293 UPDATE "issue" SET
4294 "state" = "state_v",
4295 "closed" = "phase_finished",
4296 "phase_finished" = NULL
4297 WHERE "id" = "issue_id_p";
4298 RETURN NULL;
4299 END IF;
4300 IF "persist"."state" = 'admission' THEN
4301 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4302 FOR UPDATE;
4303 SELECT * INTO "policy_row"
4304 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4305 IF EXISTS (
4306 SELECT NULL FROM "initiative"
4307 WHERE "issue_id" = "issue_id_p"
4308 AND "supporter_count" > 0
4309 AND "supporter_count" * "policy_row"."issue_quorum_den"
4310 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4311 ) THEN
4312 UPDATE "issue" SET
4313 "state" = 'discussion',
4314 "accepted" = coalesce("phase_finished", now()),
4315 "phase_finished" = NULL
4316 WHERE "id" = "issue_id_p";
4317 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4318 UPDATE "issue" SET
4319 "state" = 'canceled_issue_not_accepted',
4320 "closed" = "phase_finished",
4321 "phase_finished" = NULL
4322 WHERE "id" = "issue_id_p";
4323 END IF;
4324 RETURN NULL;
4325 END IF;
4326 IF "persist"."phase_finished" THEN
4327 if "persist"."state" = 'discussion' THEN
4328 UPDATE "issue" SET
4329 "state" = 'verification',
4330 "half_frozen" = "phase_finished",
4331 "phase_finished" = NULL
4332 WHERE "id" = "issue_id_p";
4333 RETURN NULL;
4334 END IF;
4335 IF "persist"."state" = 'verification' THEN
4336 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4337 FOR UPDATE;
4338 SELECT * INTO "policy_row" FROM "policy"
4339 WHERE "id" = "issue_row"."policy_id";
4340 IF EXISTS (
4341 SELECT NULL FROM "initiative"
4342 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4343 ) THEN
4344 UPDATE "issue" SET
4345 "state" = 'voting',
4346 "fully_frozen" = "phase_finished",
4347 "phase_finished" = NULL
4348 WHERE "id" = "issue_id_p";
4349 ELSE
4350 UPDATE "issue" SET
4351 "state" = 'canceled_no_initiative_admitted',
4352 "fully_frozen" = "phase_finished",
4353 "closed" = "phase_finished",
4354 "phase_finished" = NULL
4355 WHERE "id" = "issue_id_p";
4356 -- NOTE: The following DELETE statements have effect only when
4357 -- issue state has been manipulated
4358 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4359 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4360 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4361 END IF;
4362 RETURN NULL;
4363 END IF;
4364 IF "persist"."state" = 'voting' THEN
4365 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4366 PERFORM "close_voting"("issue_id_p");
4367 "persist"."closed_voting" = TRUE;
4368 RETURN "persist";
4369 END IF;
4370 PERFORM "calculate_ranks"("issue_id_p");
4371 RETURN NULL;
4372 END IF;
4373 END IF;
4374 RAISE WARNING 'should not happen';
4375 RETURN NULL;
4376 END;
4377 $$;
4379 COMMENT ON FUNCTION "check_issue"
4380 ( "issue"."id"%TYPE,
4381 "check_issue_persistence" )
4382 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")';
4385 CREATE FUNCTION "check_everything"()
4386 RETURNS VOID
4387 LANGUAGE 'plpgsql' VOLATILE AS $$
4388 DECLARE
4389 "issue_id_v" "issue"."id"%TYPE;
4390 "persist_v" "check_issue_persistence";
4391 BEGIN
4392 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4393 DELETE FROM "expired_session";
4394 PERFORM "check_activity"();
4395 PERFORM "calculate_member_counts"();
4396 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4397 "persist_v" := NULL;
4398 LOOP
4399 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4400 EXIT WHEN "persist_v" ISNULL;
4401 END LOOP;
4402 END LOOP;
4403 RETURN;
4404 END;
4405 $$;
4407 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.';
4411 ----------------------
4412 -- Deletion of data --
4413 ----------------------
4416 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4417 RETURNS VOID
4418 LANGUAGE 'plpgsql' VOLATILE AS $$
4419 BEGIN
4420 IF EXISTS (
4421 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
4422 ) THEN
4423 -- override protection triggers:
4424 INSERT INTO "temporary_transaction_data" ("key", "value")
4425 VALUES ('override_protection_triggers', TRUE::TEXT);
4426 -- clean data:
4427 DELETE FROM "delegating_voter"
4428 WHERE "issue_id" = "issue_id_p";
4429 DELETE FROM "direct_voter"
4430 WHERE "issue_id" = "issue_id_p";
4431 DELETE FROM "delegating_interest_snapshot"
4432 WHERE "issue_id" = "issue_id_p";
4433 DELETE FROM "direct_interest_snapshot"
4434 WHERE "issue_id" = "issue_id_p";
4435 DELETE FROM "delegating_population_snapshot"
4436 WHERE "issue_id" = "issue_id_p";
4437 DELETE FROM "direct_population_snapshot"
4438 WHERE "issue_id" = "issue_id_p";
4439 DELETE FROM "non_voter"
4440 WHERE "issue_id" = "issue_id_p";
4441 DELETE FROM "delegation"
4442 WHERE "issue_id" = "issue_id_p";
4443 DELETE FROM "supporter"
4444 USING "initiative" -- NOTE: due to missing index on issue_id
4445 WHERE "initiative"."issue_id" = "issue_id_p"
4446 AND "supporter"."initiative_id" = "initiative_id";
4447 -- mark issue as cleaned:
4448 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
4449 -- finish overriding protection triggers (avoids garbage):
4450 DELETE FROM "temporary_transaction_data"
4451 WHERE "key" = 'override_protection_triggers';
4452 END IF;
4453 RETURN;
4454 END;
4455 $$;
4457 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4460 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4461 RETURNS VOID
4462 LANGUAGE 'plpgsql' VOLATILE AS $$
4463 BEGIN
4464 UPDATE "member" SET
4465 "last_login" = NULL,
4466 "last_delegation_check" = NULL,
4467 "login" = NULL,
4468 "password" = NULL,
4469 "locked" = TRUE,
4470 "active" = FALSE,
4471 "notify_email" = NULL,
4472 "notify_email_unconfirmed" = NULL,
4473 "notify_email_secret" = NULL,
4474 "notify_email_secret_expiry" = NULL,
4475 "notify_email_lock_expiry" = NULL,
4476 "login_recovery_expiry" = NULL,
4477 "password_reset_secret" = NULL,
4478 "password_reset_secret_expiry" = NULL,
4479 "organizational_unit" = NULL,
4480 "internal_posts" = NULL,
4481 "realname" = NULL,
4482 "birthday" = NULL,
4483 "address" = NULL,
4484 "email" = NULL,
4485 "xmpp_address" = NULL,
4486 "website" = NULL,
4487 "phone" = NULL,
4488 "mobile_phone" = NULL,
4489 "profession" = NULL,
4490 "external_memberships" = NULL,
4491 "external_posts" = NULL,
4492 "statement" = NULL
4493 WHERE "id" = "member_id_p";
4494 -- "text_search_data" is updated by triggers
4495 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4496 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4497 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4498 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4499 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4500 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4501 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4502 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4503 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4504 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4505 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4506 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4507 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4508 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4509 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4510 DELETE FROM "direct_voter" USING "issue"
4511 WHERE "direct_voter"."issue_id" = "issue"."id"
4512 AND "issue"."closed" ISNULL
4513 AND "member_id" = "member_id_p";
4514 RETURN;
4515 END;
4516 $$;
4518 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)';
4521 CREATE FUNCTION "delete_private_data"()
4522 RETURNS VOID
4523 LANGUAGE 'plpgsql' VOLATILE AS $$
4524 BEGIN
4525 DELETE FROM "temporary_transaction_data";
4526 DELETE FROM "member" WHERE "activated" ISNULL;
4527 UPDATE "member" SET
4528 "invite_code" = NULL,
4529 "invite_code_expiry" = NULL,
4530 "admin_comment" = NULL,
4531 "last_login" = NULL,
4532 "last_delegation_check" = NULL,
4533 "login" = NULL,
4534 "password" = NULL,
4535 "lang" = NULL,
4536 "notify_email" = NULL,
4537 "notify_email_unconfirmed" = NULL,
4538 "notify_email_secret" = NULL,
4539 "notify_email_secret_expiry" = NULL,
4540 "notify_email_lock_expiry" = NULL,
4541 "notify_level" = NULL,
4542 "login_recovery_expiry" = NULL,
4543 "password_reset_secret" = NULL,
4544 "password_reset_secret_expiry" = NULL,
4545 "organizational_unit" = NULL,
4546 "internal_posts" = NULL,
4547 "realname" = NULL,
4548 "birthday" = NULL,
4549 "address" = NULL,
4550 "email" = NULL,
4551 "xmpp_address" = NULL,
4552 "website" = NULL,
4553 "phone" = NULL,
4554 "mobile_phone" = NULL,
4555 "profession" = NULL,
4556 "external_memberships" = NULL,
4557 "external_posts" = NULL,
4558 "formatting_engine" = NULL,
4559 "statement" = NULL;
4560 -- "text_search_data" is updated by triggers
4561 DELETE FROM "setting";
4562 DELETE FROM "setting_map";
4563 DELETE FROM "member_relation_setting";
4564 DELETE FROM "member_image";
4565 DELETE FROM "contact";
4566 DELETE FROM "ignored_member";
4567 DELETE FROM "session";
4568 DELETE FROM "area_setting";
4569 DELETE FROM "issue_setting";
4570 DELETE FROM "ignored_initiative";
4571 DELETE FROM "initiative_setting";
4572 DELETE FROM "suggestion_setting";
4573 DELETE FROM "non_voter";
4574 DELETE FROM "direct_voter" USING "issue"
4575 WHERE "direct_voter"."issue_id" = "issue"."id"
4576 AND "issue"."closed" ISNULL;
4577 RETURN;
4578 END;
4579 $$;
4581 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.';
4585 COMMIT;

Impressum / About Us