liquid_feedback_core

view core.sql @ 423:73c2ab2d068f

Work on configuration of complexity of counting of the votes (extent of tie-breaking):
- added configuration field in "policy" table
- calculation of secondary criterion for the defeat strength (tie-breaking of the links) based on initiative id's
author jbe
date Thu Apr 10 00:20:03 2014 +0200 (2014-04-10)
parents 044a2b65c707
children 7fbf614ca8cb
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.2', 3, 0, 2))
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 TYPE "schulze_complexity" AS ENUM ('simple', 'tuple', 'full');
353 COMMENT ON TYPE "schulze_complexity" IS 'Variant of Schulze method to use: ''simple'' = only the number of winning votes in a pairwise comparison is considered, ''tuple'' = the number of winning votes (primarily) as well as the number of losing votes (secondarily) are considered, ''full'' = same as ''tuple'' but with additional tie-breaking';
355 CREATE TABLE "policy" (
356 "id" SERIAL4 PRIMARY KEY,
357 "index" INT4 NOT NULL,
358 "active" BOOLEAN NOT NULL DEFAULT TRUE,
359 "name" TEXT NOT NULL UNIQUE,
360 "description" TEXT NOT NULL DEFAULT '',
361 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
362 "admission_time" INTERVAL,
363 "discussion_time" INTERVAL,
364 "verification_time" INTERVAL,
365 "voting_time" INTERVAL,
366 "issue_quorum_num" INT4,
367 "issue_quorum_den" INT4,
368 "initiative_quorum_num" INT4 NOT NULL,
369 "initiative_quorum_den" INT4 NOT NULL,
370 "schulze_complexity" "schulze_complexity" NOT NULL DEFAULT 'full',
371 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
372 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
373 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
374 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
375 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
376 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
377 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
378 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
379 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
380 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
381 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
382 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
383 CONSTRAINT "timing" CHECK (
384 ( "polling" = FALSE AND
385 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
386 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
387 ( "polling" = TRUE AND
388 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
389 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
390 ( "polling" = TRUE AND
391 "admission_time" ISNULL AND "discussion_time" ISNULL AND
392 "verification_time" ISNULL AND "voting_time" ISNULL ) ),
393 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
394 "polling" = "issue_quorum_num" ISNULL AND
395 "polling" = "issue_quorum_den" ISNULL ) );
396 CREATE INDEX "policy_active_idx" ON "policy" ("active");
398 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
400 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
401 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
402 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';
403 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
404 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
405 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"';
406 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'')';
407 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''';
408 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''';
409 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
410 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
411 COMMENT ON COLUMN "policy"."schulze_complexity" IS 'Variant of Schulze method to use; see type "schulze_complexity"';
412 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
413 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
414 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.';
415 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
416 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';
417 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';
418 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';
419 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.';
420 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';
421 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';
422 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
423 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
426 CREATE TABLE "unit" (
427 "id" SERIAL4 PRIMARY KEY,
428 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
429 "active" BOOLEAN NOT NULL DEFAULT TRUE,
430 "name" TEXT NOT NULL,
431 "description" TEXT NOT NULL DEFAULT '',
432 "member_count" INT4,
433 "text_search_data" TSVECTOR );
434 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
435 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
436 CREATE INDEX "unit_active_idx" ON "unit" ("active");
437 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
438 CREATE TRIGGER "update_text_search_data"
439 BEFORE INSERT OR UPDATE ON "unit"
440 FOR EACH ROW EXECUTE PROCEDURE
441 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
442 "name", "description" );
444 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
446 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
447 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
448 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
451 CREATE TABLE "unit_setting" (
452 PRIMARY KEY ("member_id", "key", "unit_id"),
453 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
454 "key" TEXT NOT NULL,
455 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
456 "value" TEXT NOT NULL );
458 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
461 CREATE TABLE "area" (
462 "id" SERIAL4 PRIMARY KEY,
463 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
464 "active" BOOLEAN NOT NULL DEFAULT TRUE,
465 "name" TEXT NOT NULL,
466 "description" TEXT NOT NULL DEFAULT '',
467 "direct_member_count" INT4,
468 "member_weight" INT4,
469 "text_search_data" TSVECTOR );
470 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
471 CREATE INDEX "area_active_idx" ON "area" ("active");
472 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
473 CREATE TRIGGER "update_text_search_data"
474 BEFORE INSERT OR UPDATE ON "area"
475 FOR EACH ROW EXECUTE PROCEDURE
476 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
477 "name", "description" );
479 COMMENT ON TABLE "area" IS 'Subject areas';
481 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
482 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"';
483 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
486 CREATE TABLE "area_setting" (
487 PRIMARY KEY ("member_id", "key", "area_id"),
488 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
489 "key" TEXT NOT NULL,
490 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
491 "value" TEXT NOT NULL );
493 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
496 CREATE TABLE "allowed_policy" (
497 PRIMARY KEY ("area_id", "policy_id"),
498 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
499 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
500 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
501 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
503 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
505 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
508 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
510 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';
513 CREATE TYPE "issue_state" AS ENUM (
514 'admission', 'discussion', 'verification', 'voting',
515 'canceled_by_admin',
516 'canceled_revoked_before_accepted',
517 'canceled_issue_not_accepted',
518 'canceled_after_revocation_during_discussion',
519 'canceled_after_revocation_during_verification',
520 'canceled_no_initiative_admitted',
521 'finished_without_winner', 'finished_with_winner');
523 COMMENT ON TYPE "issue_state" IS 'State of issues';
526 CREATE TABLE "issue" (
527 "id" SERIAL4 PRIMARY KEY,
528 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
529 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
530 "admin_notice" TEXT,
531 "state" "issue_state" NOT NULL DEFAULT 'admission',
532 "phase_finished" TIMESTAMPTZ,
533 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
534 "accepted" TIMESTAMPTZ,
535 "half_frozen" TIMESTAMPTZ,
536 "fully_frozen" TIMESTAMPTZ,
537 "closed" TIMESTAMPTZ,
538 "cleaned" TIMESTAMPTZ,
539 "admission_time" INTERVAL,
540 "discussion_time" INTERVAL NOT NULL,
541 "verification_time" INTERVAL NOT NULL,
542 "voting_time" INTERVAL NOT NULL,
543 "snapshot" TIMESTAMPTZ,
544 "latest_snapshot_event" "snapshot_event",
545 "population" INT4,
546 "voter_count" INT4,
547 "status_quo_schulze_rank" INT4,
548 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
549 "admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created") ),
550 CONSTRAINT "valid_state" CHECK (
551 (
552 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
553 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
554 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
555 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
556 ) AND (
557 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
558 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
559 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
560 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
561 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
562 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
563 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
564 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
565 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
566 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
567 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
568 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
569 )),
570 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
571 "phase_finished" ISNULL OR "closed" ISNULL ),
572 CONSTRAINT "state_change_order" CHECK (
573 "created" <= "accepted" AND
574 "accepted" <= "half_frozen" AND
575 "half_frozen" <= "fully_frozen" AND
576 "fully_frozen" <= "closed" ),
577 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
578 "cleaned" ISNULL OR "closed" NOTNULL ),
579 CONSTRAINT "last_snapshot_on_full_freeze"
580 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
581 CONSTRAINT "freeze_requires_snapshot"
582 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
583 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
584 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
585 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
586 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
587 CREATE INDEX "issue_created_idx" ON "issue" ("created");
588 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
589 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
590 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
591 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
592 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
593 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
595 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
597 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
598 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';
599 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
600 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.';
601 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.';
602 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.';
603 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
604 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
605 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
606 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
607 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
608 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
609 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';
610 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
611 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';
612 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
615 CREATE TABLE "issue_order_in_admission_state" (
616 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
617 "order_in_area" INT4,
618 "order_in_unit" INT4 );
620 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"';
622 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';
623 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';
624 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';
627 CREATE TABLE "issue_setting" (
628 PRIMARY KEY ("member_id", "key", "issue_id"),
629 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
630 "key" TEXT NOT NULL,
631 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
632 "value" TEXT NOT NULL );
634 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
637 CREATE TABLE "initiative" (
638 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
639 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
640 "id" SERIAL4 PRIMARY KEY,
641 "name" TEXT NOT NULL,
642 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
643 "discussion_url" TEXT,
644 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
645 "revoked" TIMESTAMPTZ,
646 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
647 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
648 "admitted" BOOLEAN,
649 "supporter_count" INT4,
650 "informed_supporter_count" INT4,
651 "satisfied_supporter_count" INT4,
652 "satisfied_informed_supporter_count" INT4,
653 "harmonic_weight" NUMERIC(12, 3),
654 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
655 "first_preference_votes" INT4,
656 "positive_votes" INT4,
657 "negative_votes" INT4,
658 "direct_majority" BOOLEAN,
659 "indirect_majority" BOOLEAN,
660 "schulze_rank" INT4,
661 "better_than_status_quo" BOOLEAN,
662 "worse_than_status_quo" BOOLEAN,
663 "reverse_beat_path" BOOLEAN,
664 "multistage_majority" BOOLEAN,
665 "eligible" BOOLEAN,
666 "winner" BOOLEAN,
667 "rank" INT4,
668 "text_search_data" TSVECTOR,
669 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
670 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
671 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
672 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
673 CONSTRAINT "revoked_initiatives_cant_be_admitted"
674 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
675 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
676 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
677 ( "first_preference_votes" ISNULL AND
678 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
679 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
680 "schulze_rank" ISNULL AND
681 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
682 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
683 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
684 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
685 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
686 "eligible" = FALSE OR
687 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
688 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
689 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
690 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
691 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
692 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
693 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
694 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
695 CREATE TRIGGER "update_text_search_data"
696 BEFORE INSERT OR UPDATE ON "initiative"
697 FOR EACH ROW EXECUTE PROCEDURE
698 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
699 "name", "discussion_url");
701 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.';
703 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
704 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
705 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
706 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
707 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
708 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
709 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
710 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
711 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
712 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';
713 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
714 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
715 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
716 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
717 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"';
718 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
719 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
720 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
721 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)';
722 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';
723 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';
724 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"';
725 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
726 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';
729 CREATE TABLE "battle" (
730 "issue_id" INT4 NOT NULL,
731 "winning_initiative_id" INT4,
732 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
733 "losing_initiative_id" INT4,
734 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
735 "count" INT4 NOT NULL,
736 CONSTRAINT "initiative_ids_not_equal" CHECK (
737 "winning_initiative_id" != "losing_initiative_id" OR
738 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
739 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
740 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
741 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
742 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
744 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';
747 CREATE TABLE "ignored_initiative" (
748 PRIMARY KEY ("initiative_id", "member_id"),
749 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
750 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
751 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
753 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
756 CREATE TABLE "initiative_setting" (
757 PRIMARY KEY ("member_id", "key", "initiative_id"),
758 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
759 "key" TEXT NOT NULL,
760 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
761 "value" TEXT NOT NULL );
763 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
766 CREATE TABLE "draft" (
767 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
768 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
769 "id" SERIAL8 PRIMARY KEY,
770 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
771 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
772 "formatting_engine" TEXT,
773 "content" TEXT NOT NULL,
774 "text_search_data" TSVECTOR );
775 CREATE INDEX "draft_created_idx" ON "draft" ("created");
776 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
777 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
778 CREATE TRIGGER "update_text_search_data"
779 BEFORE INSERT OR UPDATE ON "draft"
780 FOR EACH ROW EXECUTE PROCEDURE
781 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
783 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.';
785 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
786 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
789 CREATE TABLE "rendered_draft" (
790 PRIMARY KEY ("draft_id", "format"),
791 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
792 "format" TEXT,
793 "content" TEXT NOT NULL );
795 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)';
798 CREATE TABLE "suggestion" (
799 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
800 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "id" SERIAL8 PRIMARY KEY,
802 "draft_id" INT8 NOT NULL,
803 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
804 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
805 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
806 "name" TEXT NOT NULL,
807 "formatting_engine" TEXT,
808 "content" TEXT NOT NULL DEFAULT '',
809 "text_search_data" TSVECTOR,
810 "minus2_unfulfilled_count" INT4,
811 "minus2_fulfilled_count" INT4,
812 "minus1_unfulfilled_count" INT4,
813 "minus1_fulfilled_count" INT4,
814 "plus1_unfulfilled_count" INT4,
815 "plus1_fulfilled_count" INT4,
816 "plus2_unfulfilled_count" INT4,
817 "plus2_fulfilled_count" INT4,
818 "proportional_order" INT4 );
819 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
820 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
821 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
822 CREATE TRIGGER "update_text_search_data"
823 BEFORE INSERT OR UPDATE ON "suggestion"
824 FOR EACH ROW EXECUTE PROCEDURE
825 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
826 "name", "content");
828 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';
830 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")';
831 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
832 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
833 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
834 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
835 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
836 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
837 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
838 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
839 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"';
842 CREATE TABLE "rendered_suggestion" (
843 PRIMARY KEY ("suggestion_id", "format"),
844 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
845 "format" TEXT,
846 "content" TEXT NOT NULL );
848 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)';
851 CREATE TABLE "suggestion_setting" (
852 PRIMARY KEY ("member_id", "key", "suggestion_id"),
853 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
854 "key" TEXT NOT NULL,
855 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
856 "value" TEXT NOT NULL );
858 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
861 CREATE TABLE "privilege" (
862 PRIMARY KEY ("unit_id", "member_id"),
863 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
864 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
865 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
866 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
867 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
868 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
869 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
870 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
871 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
873 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
875 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
876 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
877 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
878 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
879 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
880 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
881 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';
884 CREATE TABLE "membership" (
885 PRIMARY KEY ("area_id", "member_id"),
886 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
887 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
888 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
890 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
893 CREATE TABLE "interest" (
894 PRIMARY KEY ("issue_id", "member_id"),
895 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
896 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
897 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
899 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.';
902 CREATE TABLE "initiator" (
903 PRIMARY KEY ("initiative_id", "member_id"),
904 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
905 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
906 "accepted" BOOLEAN );
907 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
909 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.';
911 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.';
914 CREATE TABLE "supporter" (
915 "issue_id" INT4 NOT NULL,
916 PRIMARY KEY ("initiative_id", "member_id"),
917 "initiative_id" INT4,
918 "member_id" INT4,
919 "draft_id" INT8 NOT NULL,
920 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
921 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
922 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
924 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.';
926 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
927 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")';
930 CREATE TABLE "opinion" (
931 "initiative_id" INT4 NOT NULL,
932 PRIMARY KEY ("suggestion_id", "member_id"),
933 "suggestion_id" INT8,
934 "member_id" INT4,
935 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
936 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
937 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
938 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
939 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
941 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.';
943 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
946 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
948 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
951 CREATE TABLE "delegation" (
952 "id" SERIAL8 PRIMARY KEY,
953 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
954 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
955 "scope" "delegation_scope" NOT NULL,
956 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
957 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
958 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
959 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
960 CONSTRAINT "no_unit_delegation_to_null"
961 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
962 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
963 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
964 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
965 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
966 UNIQUE ("unit_id", "truster_id"),
967 UNIQUE ("area_id", "truster_id"),
968 UNIQUE ("issue_id", "truster_id") );
969 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
970 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
972 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
974 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
975 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
976 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
979 CREATE TABLE "direct_population_snapshot" (
980 PRIMARY KEY ("issue_id", "event", "member_id"),
981 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
982 "event" "snapshot_event",
983 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
984 "weight" INT4 );
985 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
987 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';
989 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
990 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
993 CREATE TABLE "delegating_population_snapshot" (
994 PRIMARY KEY ("issue_id", "event", "member_id"),
995 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
996 "event" "snapshot_event",
997 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
998 "weight" INT4,
999 "scope" "delegation_scope" NOT NULL,
1000 "delegate_member_ids" INT4[] NOT NULL );
1001 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
1003 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';
1005 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1006 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
1007 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
1008 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"';
1011 CREATE TABLE "direct_interest_snapshot" (
1012 PRIMARY KEY ("issue_id", "event", "member_id"),
1013 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1014 "event" "snapshot_event",
1015 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1016 "weight" INT4 );
1017 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1019 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';
1021 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1022 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1025 CREATE TABLE "delegating_interest_snapshot" (
1026 PRIMARY KEY ("issue_id", "event", "member_id"),
1027 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1028 "event" "snapshot_event",
1029 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1030 "weight" INT4,
1031 "scope" "delegation_scope" NOT NULL,
1032 "delegate_member_ids" INT4[] NOT NULL );
1033 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1035 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';
1037 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1038 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1039 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1040 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"';
1043 CREATE TABLE "direct_supporter_snapshot" (
1044 "issue_id" INT4 NOT NULL,
1045 PRIMARY KEY ("initiative_id", "event", "member_id"),
1046 "initiative_id" INT4,
1047 "event" "snapshot_event",
1048 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1049 "draft_id" INT8 NOT NULL,
1050 "informed" BOOLEAN NOT NULL,
1051 "satisfied" BOOLEAN NOT NULL,
1052 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1053 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1054 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1055 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1057 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';
1059 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';
1060 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1061 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1062 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1065 CREATE TABLE "non_voter" (
1066 PRIMARY KEY ("issue_id", "member_id"),
1067 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1068 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1069 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1071 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1074 CREATE TABLE "direct_voter" (
1075 PRIMARY KEY ("issue_id", "member_id"),
1076 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1077 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1078 "weight" INT4,
1079 "comment_changed" TIMESTAMPTZ,
1080 "formatting_engine" TEXT,
1081 "comment" TEXT,
1082 "text_search_data" TSVECTOR );
1083 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1084 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1085 CREATE TRIGGER "update_text_search_data"
1086 BEFORE INSERT OR UPDATE ON "direct_voter"
1087 FOR EACH ROW EXECUTE PROCEDURE
1088 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1090 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';
1092 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1093 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';
1094 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';
1095 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.';
1098 CREATE TABLE "rendered_voter_comment" (
1099 PRIMARY KEY ("issue_id", "member_id", "format"),
1100 FOREIGN KEY ("issue_id", "member_id")
1101 REFERENCES "direct_voter" ("issue_id", "member_id")
1102 ON DELETE CASCADE ON UPDATE CASCADE,
1103 "issue_id" INT4,
1104 "member_id" INT4,
1105 "format" TEXT,
1106 "content" TEXT NOT NULL );
1108 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)';
1111 CREATE TABLE "delegating_voter" (
1112 PRIMARY KEY ("issue_id", "member_id"),
1113 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1114 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1115 "weight" INT4,
1116 "scope" "delegation_scope" NOT NULL,
1117 "delegate_member_ids" INT4[] NOT NULL );
1118 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1120 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';
1122 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1123 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1124 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"';
1127 CREATE TABLE "vote" (
1128 "issue_id" INT4 NOT NULL,
1129 PRIMARY KEY ("initiative_id", "member_id"),
1130 "initiative_id" INT4,
1131 "member_id" INT4,
1132 "grade" INT4 NOT NULL,
1133 "first_preference" BOOLEAN,
1134 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1135 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1136 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1137 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1138 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1140 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';
1142 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1143 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.';
1144 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.';
1147 CREATE TYPE "event_type" AS ENUM (
1148 'issue_state_changed',
1149 'initiative_created_in_new_issue',
1150 'initiative_created_in_existing_issue',
1151 'initiative_revoked',
1152 'new_draft_created',
1153 'suggestion_created');
1155 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1158 CREATE TABLE "event" (
1159 "id" SERIAL8 PRIMARY KEY,
1160 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1161 "event" "event_type" NOT NULL,
1162 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1163 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1164 "state" "issue_state",
1165 "initiative_id" INT4,
1166 "draft_id" INT8,
1167 "suggestion_id" INT8,
1168 FOREIGN KEY ("issue_id", "initiative_id")
1169 REFERENCES "initiative" ("issue_id", "id")
1170 ON DELETE CASCADE ON UPDATE CASCADE,
1171 FOREIGN KEY ("initiative_id", "draft_id")
1172 REFERENCES "draft" ("initiative_id", "id")
1173 ON DELETE CASCADE ON UPDATE CASCADE,
1174 FOREIGN KEY ("initiative_id", "suggestion_id")
1175 REFERENCES "suggestion" ("initiative_id", "id")
1176 ON DELETE CASCADE ON UPDATE CASCADE,
1177 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1178 "event" != 'issue_state_changed' OR (
1179 "member_id" ISNULL AND
1180 "issue_id" NOTNULL AND
1181 "state" NOTNULL AND
1182 "initiative_id" ISNULL AND
1183 "draft_id" ISNULL AND
1184 "suggestion_id" ISNULL )),
1185 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1186 "event" NOT IN (
1187 'initiative_created_in_new_issue',
1188 'initiative_created_in_existing_issue',
1189 'initiative_revoked',
1190 'new_draft_created'
1191 ) OR (
1192 "member_id" NOTNULL AND
1193 "issue_id" NOTNULL AND
1194 "state" NOTNULL AND
1195 "initiative_id" NOTNULL AND
1196 "draft_id" NOTNULL AND
1197 "suggestion_id" ISNULL )),
1198 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1199 "event" != 'suggestion_created' OR (
1200 "member_id" NOTNULL AND
1201 "issue_id" NOTNULL AND
1202 "state" NOTNULL AND
1203 "initiative_id" NOTNULL AND
1204 "draft_id" ISNULL AND
1205 "suggestion_id" NOTNULL )) );
1206 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1208 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1210 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1211 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1212 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1213 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1216 CREATE TABLE "notification_sent" (
1217 "event_id" INT8 NOT NULL );
1218 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1220 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1221 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1225 ----------------------------------------------
1226 -- Writing of history entries and event log --
1227 ----------------------------------------------
1230 CREATE FUNCTION "write_member_history_trigger"()
1231 RETURNS TRIGGER
1232 LANGUAGE 'plpgsql' VOLATILE AS $$
1233 BEGIN
1234 IF
1235 ( NEW."active" != OLD."active" OR
1236 NEW."name" != OLD."name" ) AND
1237 OLD."activated" NOTNULL
1238 THEN
1239 INSERT INTO "member_history"
1240 ("member_id", "active", "name")
1241 VALUES (NEW."id", OLD."active", OLD."name");
1242 END IF;
1243 RETURN NULL;
1244 END;
1245 $$;
1247 CREATE TRIGGER "write_member_history"
1248 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1249 "write_member_history_trigger"();
1251 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1252 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1255 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1256 RETURNS TRIGGER
1257 LANGUAGE 'plpgsql' VOLATILE AS $$
1258 BEGIN
1259 IF NEW."state" != OLD."state" THEN
1260 INSERT INTO "event" ("event", "issue_id", "state")
1261 VALUES ('issue_state_changed', NEW."id", NEW."state");
1262 END IF;
1263 RETURN NULL;
1264 END;
1265 $$;
1267 CREATE TRIGGER "write_event_issue_state_changed"
1268 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1269 "write_event_issue_state_changed_trigger"();
1271 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1272 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1275 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1276 RETURNS TRIGGER
1277 LANGUAGE 'plpgsql' VOLATILE AS $$
1278 DECLARE
1279 "initiative_row" "initiative"%ROWTYPE;
1280 "issue_row" "issue"%ROWTYPE;
1281 "event_v" "event_type";
1282 BEGIN
1283 SELECT * INTO "initiative_row" FROM "initiative"
1284 WHERE "id" = NEW."initiative_id";
1285 SELECT * INTO "issue_row" FROM "issue"
1286 WHERE "id" = "initiative_row"."issue_id";
1287 IF EXISTS (
1288 SELECT NULL FROM "draft"
1289 WHERE "initiative_id" = NEW."initiative_id"
1290 AND "id" != NEW."id"
1291 ) THEN
1292 "event_v" := 'new_draft_created';
1293 ELSE
1294 IF EXISTS (
1295 SELECT NULL FROM "initiative"
1296 WHERE "issue_id" = "initiative_row"."issue_id"
1297 AND "id" != "initiative_row"."id"
1298 ) THEN
1299 "event_v" := 'initiative_created_in_existing_issue';
1300 ELSE
1301 "event_v" := 'initiative_created_in_new_issue';
1302 END IF;
1303 END IF;
1304 INSERT INTO "event" (
1305 "event", "member_id",
1306 "issue_id", "state", "initiative_id", "draft_id"
1307 ) VALUES (
1308 "event_v",
1309 NEW."author_id",
1310 "initiative_row"."issue_id",
1311 "issue_row"."state",
1312 "initiative_row"."id",
1313 NEW."id" );
1314 RETURN NULL;
1315 END;
1316 $$;
1318 CREATE TRIGGER "write_event_initiative_or_draft_created"
1319 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1320 "write_event_initiative_or_draft_created_trigger"();
1322 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1323 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1326 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1327 RETURNS TRIGGER
1328 LANGUAGE 'plpgsql' VOLATILE AS $$
1329 DECLARE
1330 "issue_row" "issue"%ROWTYPE;
1331 "draft_id_v" "draft"."id"%TYPE;
1332 BEGIN
1333 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1334 SELECT * INTO "issue_row" FROM "issue"
1335 WHERE "id" = NEW."issue_id";
1336 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1337 WHERE "initiative_id" = NEW."id";
1338 INSERT INTO "event" (
1339 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1340 ) VALUES (
1341 'initiative_revoked',
1342 NEW."revoked_by_member_id",
1343 NEW."issue_id",
1344 "issue_row"."state",
1345 NEW."id",
1346 "draft_id_v");
1347 END IF;
1348 RETURN NULL;
1349 END;
1350 $$;
1352 CREATE TRIGGER "write_event_initiative_revoked"
1353 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1354 "write_event_initiative_revoked_trigger"();
1356 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1357 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1360 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1361 RETURNS TRIGGER
1362 LANGUAGE 'plpgsql' VOLATILE AS $$
1363 DECLARE
1364 "initiative_row" "initiative"%ROWTYPE;
1365 "issue_row" "issue"%ROWTYPE;
1366 BEGIN
1367 SELECT * INTO "initiative_row" FROM "initiative"
1368 WHERE "id" = NEW."initiative_id";
1369 SELECT * INTO "issue_row" FROM "issue"
1370 WHERE "id" = "initiative_row"."issue_id";
1371 INSERT INTO "event" (
1372 "event", "member_id",
1373 "issue_id", "state", "initiative_id", "suggestion_id"
1374 ) VALUES (
1375 'suggestion_created',
1376 NEW."author_id",
1377 "initiative_row"."issue_id",
1378 "issue_row"."state",
1379 "initiative_row"."id",
1380 NEW."id" );
1381 RETURN NULL;
1382 END;
1383 $$;
1385 CREATE TRIGGER "write_event_suggestion_created"
1386 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1387 "write_event_suggestion_created_trigger"();
1389 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1390 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1394 ----------------------------
1395 -- Additional constraints --
1396 ----------------------------
1399 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1400 RETURNS TRIGGER
1401 LANGUAGE 'plpgsql' VOLATILE AS $$
1402 BEGIN
1403 IF NOT EXISTS (
1404 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1405 ) THEN
1406 --RAISE 'Cannot create issue without an initial initiative.' USING
1407 -- ERRCODE = 'integrity_constraint_violation',
1408 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1409 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1410 END IF;
1411 RETURN NULL;
1412 END;
1413 $$;
1415 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1416 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1417 FOR EACH ROW EXECUTE PROCEDURE
1418 "issue_requires_first_initiative_trigger"();
1420 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1421 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1424 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1425 RETURNS TRIGGER
1426 LANGUAGE 'plpgsql' VOLATILE AS $$
1427 DECLARE
1428 "reference_lost" BOOLEAN;
1429 BEGIN
1430 IF TG_OP = 'DELETE' THEN
1431 "reference_lost" := TRUE;
1432 ELSE
1433 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1434 END IF;
1435 IF
1436 "reference_lost" AND NOT EXISTS (
1437 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1439 THEN
1440 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1441 END IF;
1442 RETURN NULL;
1443 END;
1444 $$;
1446 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1447 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1448 FOR EACH ROW EXECUTE PROCEDURE
1449 "last_initiative_deletes_issue_trigger"();
1451 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1452 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1455 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1456 RETURNS TRIGGER
1457 LANGUAGE 'plpgsql' VOLATILE AS $$
1458 BEGIN
1459 IF NOT EXISTS (
1460 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1461 ) THEN
1462 --RAISE 'Cannot create initiative without an initial draft.' USING
1463 -- ERRCODE = 'integrity_constraint_violation',
1464 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1465 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1466 END IF;
1467 RETURN NULL;
1468 END;
1469 $$;
1471 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1472 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1473 FOR EACH ROW EXECUTE PROCEDURE
1474 "initiative_requires_first_draft_trigger"();
1476 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1477 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1480 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1481 RETURNS TRIGGER
1482 LANGUAGE 'plpgsql' VOLATILE AS $$
1483 DECLARE
1484 "reference_lost" BOOLEAN;
1485 BEGIN
1486 IF TG_OP = 'DELETE' THEN
1487 "reference_lost" := TRUE;
1488 ELSE
1489 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1490 END IF;
1491 IF
1492 "reference_lost" AND NOT EXISTS (
1493 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1495 THEN
1496 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1497 END IF;
1498 RETURN NULL;
1499 END;
1500 $$;
1502 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1503 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1504 FOR EACH ROW EXECUTE PROCEDURE
1505 "last_draft_deletes_initiative_trigger"();
1507 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1508 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1511 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1512 RETURNS TRIGGER
1513 LANGUAGE 'plpgsql' VOLATILE AS $$
1514 BEGIN
1515 IF NOT EXISTS (
1516 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1517 ) THEN
1518 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1519 END IF;
1520 RETURN NULL;
1521 END;
1522 $$;
1524 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1525 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1526 FOR EACH ROW EXECUTE PROCEDURE
1527 "suggestion_requires_first_opinion_trigger"();
1529 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1530 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1533 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1534 RETURNS TRIGGER
1535 LANGUAGE 'plpgsql' VOLATILE AS $$
1536 DECLARE
1537 "reference_lost" BOOLEAN;
1538 BEGIN
1539 IF TG_OP = 'DELETE' THEN
1540 "reference_lost" := TRUE;
1541 ELSE
1542 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1543 END IF;
1544 IF
1545 "reference_lost" AND NOT EXISTS (
1546 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1548 THEN
1549 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1550 END IF;
1551 RETURN NULL;
1552 END;
1553 $$;
1555 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1556 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1557 FOR EACH ROW EXECUTE PROCEDURE
1558 "last_opinion_deletes_suggestion_trigger"();
1560 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1561 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1564 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1565 RETURNS TRIGGER
1566 LANGUAGE 'plpgsql' VOLATILE AS $$
1567 BEGIN
1568 DELETE FROM "direct_voter"
1569 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1570 RETURN NULL;
1571 END;
1572 $$;
1574 CREATE TRIGGER "non_voter_deletes_direct_voter"
1575 AFTER INSERT OR UPDATE ON "non_voter"
1576 FOR EACH ROW EXECUTE PROCEDURE
1577 "non_voter_deletes_direct_voter_trigger"();
1579 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1580 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")';
1583 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1584 RETURNS TRIGGER
1585 LANGUAGE 'plpgsql' VOLATILE AS $$
1586 BEGIN
1587 DELETE FROM "non_voter"
1588 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1589 RETURN NULL;
1590 END;
1591 $$;
1593 CREATE TRIGGER "direct_voter_deletes_non_voter"
1594 AFTER INSERT OR UPDATE ON "direct_voter"
1595 FOR EACH ROW EXECUTE PROCEDURE
1596 "direct_voter_deletes_non_voter_trigger"();
1598 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1599 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")';
1602 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1603 RETURNS TRIGGER
1604 LANGUAGE 'plpgsql' VOLATILE AS $$
1605 BEGIN
1606 IF NEW."comment" ISNULL THEN
1607 NEW."comment_changed" := NULL;
1608 NEW."formatting_engine" := NULL;
1609 END IF;
1610 RETURN NEW;
1611 END;
1612 $$;
1614 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1615 BEFORE INSERT OR UPDATE ON "direct_voter"
1616 FOR EACH ROW EXECUTE PROCEDURE
1617 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1619 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"';
1620 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.';
1623 ---------------------------------------------------------------
1624 -- Ensure that votes are not modified when issues are closed --
1625 ---------------------------------------------------------------
1627 -- NOTE: Frontends should ensure this anyway, but in case of programming
1628 -- errors the following triggers ensure data integrity.
1631 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1632 RETURNS TRIGGER
1633 LANGUAGE 'plpgsql' VOLATILE AS $$
1634 DECLARE
1635 "issue_id_v" "issue"."id"%TYPE;
1636 "issue_row" "issue"%ROWTYPE;
1637 BEGIN
1638 IF EXISTS (
1639 SELECT NULL FROM "temporary_transaction_data"
1640 WHERE "txid" = txid_current()
1641 AND "key" = 'override_protection_triggers'
1642 AND "value" = TRUE::TEXT
1643 ) THEN
1644 RETURN NULL;
1645 END IF;
1646 IF TG_OP = 'DELETE' THEN
1647 "issue_id_v" := OLD."issue_id";
1648 ELSE
1649 "issue_id_v" := NEW."issue_id";
1650 END IF;
1651 SELECT INTO "issue_row" * FROM "issue"
1652 WHERE "id" = "issue_id_v" FOR SHARE;
1653 IF (
1654 "issue_row"."closed" NOTNULL OR (
1655 "issue_row"."state" = 'voting' AND
1656 "issue_row"."phase_finished" NOTNULL
1658 ) THEN
1659 IF
1660 TG_RELID = 'direct_voter'::regclass AND
1661 TG_OP = 'UPDATE'
1662 THEN
1663 IF
1664 OLD."issue_id" = NEW."issue_id" AND
1665 OLD."member_id" = NEW."member_id" AND
1666 OLD."weight" = NEW."weight"
1667 THEN
1668 RETURN NULL; -- allows changing of voter comment
1669 END IF;
1670 END IF;
1671 RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
1672 END IF;
1673 RETURN NULL;
1674 END;
1675 $$;
1677 CREATE TRIGGER "forbid_changes_on_closed_issue"
1678 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1679 FOR EACH ROW EXECUTE PROCEDURE
1680 "forbid_changes_on_closed_issue_trigger"();
1682 CREATE TRIGGER "forbid_changes_on_closed_issue"
1683 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1684 FOR EACH ROW EXECUTE PROCEDURE
1685 "forbid_changes_on_closed_issue_trigger"();
1687 CREATE TRIGGER "forbid_changes_on_closed_issue"
1688 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1689 FOR EACH ROW EXECUTE PROCEDURE
1690 "forbid_changes_on_closed_issue_trigger"();
1692 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"';
1693 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';
1694 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';
1695 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';
1699 --------------------------------------------------------------------
1700 -- Auto-retrieval of fields only needed for referential integrity --
1701 --------------------------------------------------------------------
1704 CREATE FUNCTION "autofill_issue_id_trigger"()
1705 RETURNS TRIGGER
1706 LANGUAGE 'plpgsql' VOLATILE AS $$
1707 BEGIN
1708 IF NEW."issue_id" ISNULL THEN
1709 SELECT "issue_id" INTO NEW."issue_id"
1710 FROM "initiative" WHERE "id" = NEW."initiative_id";
1711 END IF;
1712 RETURN NEW;
1713 END;
1714 $$;
1716 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1717 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1719 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1720 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1722 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1723 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1724 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1727 CREATE FUNCTION "autofill_initiative_id_trigger"()
1728 RETURNS TRIGGER
1729 LANGUAGE 'plpgsql' VOLATILE AS $$
1730 BEGIN
1731 IF NEW."initiative_id" ISNULL THEN
1732 SELECT "initiative_id" INTO NEW."initiative_id"
1733 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1734 END IF;
1735 RETURN NEW;
1736 END;
1737 $$;
1739 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1740 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1742 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1743 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1747 -----------------------------------------------------
1748 -- Automatic calculation of certain default values --
1749 -----------------------------------------------------
1752 CREATE FUNCTION "copy_timings_trigger"()
1753 RETURNS TRIGGER
1754 LANGUAGE 'plpgsql' VOLATILE AS $$
1755 DECLARE
1756 "policy_row" "policy"%ROWTYPE;
1757 BEGIN
1758 SELECT * INTO "policy_row" FROM "policy"
1759 WHERE "id" = NEW."policy_id";
1760 IF NEW."admission_time" ISNULL THEN
1761 NEW."admission_time" := "policy_row"."admission_time";
1762 END IF;
1763 IF NEW."discussion_time" ISNULL THEN
1764 NEW."discussion_time" := "policy_row"."discussion_time";
1765 END IF;
1766 IF NEW."verification_time" ISNULL THEN
1767 NEW."verification_time" := "policy_row"."verification_time";
1768 END IF;
1769 IF NEW."voting_time" ISNULL THEN
1770 NEW."voting_time" := "policy_row"."voting_time";
1771 END IF;
1772 RETURN NEW;
1773 END;
1774 $$;
1776 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1777 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1779 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1780 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1783 CREATE FUNCTION "default_for_draft_id_trigger"()
1784 RETURNS TRIGGER
1785 LANGUAGE 'plpgsql' VOLATILE AS $$
1786 BEGIN
1787 IF NEW."draft_id" ISNULL THEN
1788 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1789 WHERE "initiative_id" = NEW."initiative_id";
1790 END IF;
1791 RETURN NEW;
1792 END;
1793 $$;
1795 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1796 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1797 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1798 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1800 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1801 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';
1802 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';
1806 ----------------------------------------
1807 -- Automatic creation of dependencies --
1808 ----------------------------------------
1811 CREATE FUNCTION "autocreate_interest_trigger"()
1812 RETURNS TRIGGER
1813 LANGUAGE 'plpgsql' VOLATILE AS $$
1814 BEGIN
1815 IF NOT EXISTS (
1816 SELECT NULL FROM "initiative" JOIN "interest"
1817 ON "initiative"."issue_id" = "interest"."issue_id"
1818 WHERE "initiative"."id" = NEW."initiative_id"
1819 AND "interest"."member_id" = NEW."member_id"
1820 ) THEN
1821 BEGIN
1822 INSERT INTO "interest" ("issue_id", "member_id")
1823 SELECT "issue_id", NEW."member_id"
1824 FROM "initiative" WHERE "id" = NEW."initiative_id";
1825 EXCEPTION WHEN unique_violation THEN END;
1826 END IF;
1827 RETURN NEW;
1828 END;
1829 $$;
1831 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1832 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1834 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1835 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';
1838 CREATE FUNCTION "autocreate_supporter_trigger"()
1839 RETURNS TRIGGER
1840 LANGUAGE 'plpgsql' VOLATILE AS $$
1841 BEGIN
1842 IF NOT EXISTS (
1843 SELECT NULL FROM "suggestion" JOIN "supporter"
1844 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1845 WHERE "suggestion"."id" = NEW."suggestion_id"
1846 AND "supporter"."member_id" = NEW."member_id"
1847 ) THEN
1848 BEGIN
1849 INSERT INTO "supporter" ("initiative_id", "member_id")
1850 SELECT "initiative_id", NEW."member_id"
1851 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1852 EXCEPTION WHEN unique_violation THEN END;
1853 END IF;
1854 RETURN NEW;
1855 END;
1856 $$;
1858 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1859 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1861 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1862 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.';
1866 ------------------------------------------
1867 -- Views and helper functions for views --
1868 ------------------------------------------
1871 CREATE VIEW "unit_delegation" AS
1872 SELECT
1873 "unit"."id" AS "unit_id",
1874 "delegation"."id",
1875 "delegation"."truster_id",
1876 "delegation"."trustee_id",
1877 "delegation"."scope"
1878 FROM "unit"
1879 JOIN "delegation"
1880 ON "delegation"."unit_id" = "unit"."id"
1881 JOIN "member"
1882 ON "delegation"."truster_id" = "member"."id"
1883 JOIN "privilege"
1884 ON "delegation"."unit_id" = "privilege"."unit_id"
1885 AND "delegation"."truster_id" = "privilege"."member_id"
1886 WHERE "member"."active" AND "privilege"."voting_right";
1888 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1891 CREATE VIEW "area_delegation" AS
1892 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1893 "area"."id" AS "area_id",
1894 "delegation"."id",
1895 "delegation"."truster_id",
1896 "delegation"."trustee_id",
1897 "delegation"."scope"
1898 FROM "area"
1899 JOIN "delegation"
1900 ON "delegation"."unit_id" = "area"."unit_id"
1901 OR "delegation"."area_id" = "area"."id"
1902 JOIN "member"
1903 ON "delegation"."truster_id" = "member"."id"
1904 JOIN "privilege"
1905 ON "area"."unit_id" = "privilege"."unit_id"
1906 AND "delegation"."truster_id" = "privilege"."member_id"
1907 WHERE "member"."active" AND "privilege"."voting_right"
1908 ORDER BY
1909 "area"."id",
1910 "delegation"."truster_id",
1911 "delegation"."scope" DESC;
1913 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1916 CREATE VIEW "issue_delegation" AS
1917 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1918 "issue"."id" AS "issue_id",
1919 "delegation"."id",
1920 "delegation"."truster_id",
1921 "delegation"."trustee_id",
1922 "delegation"."scope"
1923 FROM "issue"
1924 JOIN "area"
1925 ON "area"."id" = "issue"."area_id"
1926 JOIN "delegation"
1927 ON "delegation"."unit_id" = "area"."unit_id"
1928 OR "delegation"."area_id" = "area"."id"
1929 OR "delegation"."issue_id" = "issue"."id"
1930 JOIN "member"
1931 ON "delegation"."truster_id" = "member"."id"
1932 JOIN "privilege"
1933 ON "area"."unit_id" = "privilege"."unit_id"
1934 AND "delegation"."truster_id" = "privilege"."member_id"
1935 WHERE "member"."active" AND "privilege"."voting_right"
1936 ORDER BY
1937 "issue"."id",
1938 "delegation"."truster_id",
1939 "delegation"."scope" DESC;
1941 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1944 CREATE FUNCTION "membership_weight_with_skipping"
1945 ( "area_id_p" "area"."id"%TYPE,
1946 "member_id_p" "member"."id"%TYPE,
1947 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1948 RETURNS INT4
1949 LANGUAGE 'plpgsql' STABLE AS $$
1950 DECLARE
1951 "sum_v" INT4;
1952 "delegation_row" "area_delegation"%ROWTYPE;
1953 BEGIN
1954 "sum_v" := 1;
1955 FOR "delegation_row" IN
1956 SELECT "area_delegation".*
1957 FROM "area_delegation" LEFT JOIN "membership"
1958 ON "membership"."area_id" = "area_id_p"
1959 AND "membership"."member_id" = "area_delegation"."truster_id"
1960 WHERE "area_delegation"."area_id" = "area_id_p"
1961 AND "area_delegation"."trustee_id" = "member_id_p"
1962 AND "membership"."member_id" ISNULL
1963 LOOP
1964 IF NOT
1965 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1966 THEN
1967 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1968 "area_id_p",
1969 "delegation_row"."truster_id",
1970 "skip_member_ids_p" || "delegation_row"."truster_id"
1971 );
1972 END IF;
1973 END LOOP;
1974 RETURN "sum_v";
1975 END;
1976 $$;
1978 COMMENT ON FUNCTION "membership_weight_with_skipping"
1979 ( "area"."id"%TYPE,
1980 "member"."id"%TYPE,
1981 INT4[] )
1982 IS 'Helper function for "membership_weight" function';
1985 CREATE FUNCTION "membership_weight"
1986 ( "area_id_p" "area"."id"%TYPE,
1987 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1988 RETURNS INT4
1989 LANGUAGE 'plpgsql' STABLE AS $$
1990 BEGIN
1991 RETURN "membership_weight_with_skipping"(
1992 "area_id_p",
1993 "member_id_p",
1994 ARRAY["member_id_p"]
1995 );
1996 END;
1997 $$;
1999 COMMENT ON FUNCTION "membership_weight"
2000 ( "area"."id"%TYPE,
2001 "member"."id"%TYPE )
2002 IS 'Calculates the potential voting weight of a member in a given area';
2005 CREATE VIEW "member_count_view" AS
2006 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
2008 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
2011 CREATE VIEW "unit_member_count" AS
2012 SELECT
2013 "unit"."id" AS "unit_id",
2014 count("member"."id") AS "member_count"
2015 FROM "unit"
2016 LEFT JOIN "privilege"
2017 ON "privilege"."unit_id" = "unit"."id"
2018 AND "privilege"."voting_right"
2019 LEFT JOIN "member"
2020 ON "member"."id" = "privilege"."member_id"
2021 AND "member"."active"
2022 GROUP BY "unit"."id";
2024 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
2027 CREATE VIEW "area_member_count" AS
2028 SELECT
2029 "area"."id" AS "area_id",
2030 count("member"."id") AS "direct_member_count",
2031 coalesce(
2032 sum(
2033 CASE WHEN "member"."id" NOTNULL THEN
2034 "membership_weight"("area"."id", "member"."id")
2035 ELSE 0 END
2037 ) AS "member_weight"
2038 FROM "area"
2039 LEFT JOIN "membership"
2040 ON "area"."id" = "membership"."area_id"
2041 LEFT JOIN "privilege"
2042 ON "privilege"."unit_id" = "area"."unit_id"
2043 AND "privilege"."member_id" = "membership"."member_id"
2044 AND "privilege"."voting_right"
2045 LEFT JOIN "member"
2046 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2047 AND "member"."active"
2048 GROUP BY "area"."id";
2050 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2053 CREATE VIEW "opening_draft" AS
2054 SELECT "draft".* FROM (
2055 SELECT
2056 "initiative"."id" AS "initiative_id",
2057 min("draft"."id") AS "draft_id"
2058 FROM "initiative" JOIN "draft"
2059 ON "initiative"."id" = "draft"."initiative_id"
2060 GROUP BY "initiative"."id"
2061 ) AS "subquery"
2062 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2064 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2067 CREATE VIEW "current_draft" AS
2068 SELECT "draft".* FROM (
2069 SELECT
2070 "initiative"."id" AS "initiative_id",
2071 max("draft"."id") AS "draft_id"
2072 FROM "initiative" JOIN "draft"
2073 ON "initiative"."id" = "draft"."initiative_id"
2074 GROUP BY "initiative"."id"
2075 ) AS "subquery"
2076 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2078 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2081 CREATE VIEW "critical_opinion" AS
2082 SELECT * FROM "opinion"
2083 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2084 OR ("degree" = -2 AND "fulfilled" = TRUE);
2086 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2089 CREATE VIEW "issue_supporter_in_admission_state" AS
2090 SELECT DISTINCT
2091 "area"."unit_id",
2092 "issue"."area_id",
2093 "issue"."id" AS "issue_id",
2094 "supporter"."member_id",
2095 "direct_interest_snapshot"."weight"
2096 FROM "issue"
2097 JOIN "area" ON "area"."id" = "issue"."area_id"
2098 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
2099 JOIN "direct_interest_snapshot"
2100 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2101 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2102 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
2103 WHERE "issue"."state" = 'admission'::"issue_state";
2105 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';
2108 CREATE VIEW "initiative_suggestion_order_calculation" AS
2109 SELECT
2110 "initiative"."id" AS "initiative_id",
2111 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
2112 FROM "initiative" JOIN "issue"
2113 ON "initiative"."issue_id" = "issue"."id"
2114 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
2115 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
2117 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
2119 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';
2122 CREATE VIEW "individual_suggestion_ranking" AS
2123 SELECT
2124 "opinion"."initiative_id",
2125 "opinion"."member_id",
2126 "direct_interest_snapshot"."weight",
2127 CASE WHEN
2128 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
2129 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
2130 THEN 1 ELSE
2131 CASE WHEN
2132 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
2133 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
2134 THEN 2 ELSE
2135 CASE WHEN
2136 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
2137 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
2138 THEN 3 ELSE 4 END
2139 END
2140 END AS "preference",
2141 "opinion"."suggestion_id"
2142 FROM "opinion"
2143 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
2144 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2145 JOIN "direct_interest_snapshot"
2146 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2147 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2148 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
2150 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
2153 CREATE VIEW "battle_participant" AS
2154 SELECT "initiative"."id", "initiative"."issue_id"
2155 FROM "issue" JOIN "initiative"
2156 ON "issue"."id" = "initiative"."issue_id"
2157 WHERE "initiative"."admitted"
2158 UNION ALL
2159 SELECT NULL, "id" AS "issue_id"
2160 FROM "issue";
2162 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2165 CREATE VIEW "battle_view" AS
2166 SELECT
2167 "issue"."id" AS "issue_id",
2168 "winning_initiative"."id" AS "winning_initiative_id",
2169 "losing_initiative"."id" AS "losing_initiative_id",
2170 sum(
2171 CASE WHEN
2172 coalesce("better_vote"."grade", 0) >
2173 coalesce("worse_vote"."grade", 0)
2174 THEN "direct_voter"."weight" ELSE 0 END
2175 ) AS "count"
2176 FROM "issue"
2177 LEFT JOIN "direct_voter"
2178 ON "issue"."id" = "direct_voter"."issue_id"
2179 JOIN "battle_participant" AS "winning_initiative"
2180 ON "issue"."id" = "winning_initiative"."issue_id"
2181 JOIN "battle_participant" AS "losing_initiative"
2182 ON "issue"."id" = "losing_initiative"."issue_id"
2183 LEFT JOIN "vote" AS "better_vote"
2184 ON "direct_voter"."member_id" = "better_vote"."member_id"
2185 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2186 LEFT JOIN "vote" AS "worse_vote"
2187 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2188 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2189 WHERE "issue"."state" = 'voting'
2190 AND "issue"."phase_finished" NOTNULL
2191 AND (
2192 "winning_initiative"."id" != "losing_initiative"."id" OR
2193 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2194 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2195 GROUP BY
2196 "issue"."id",
2197 "winning_initiative"."id",
2198 "losing_initiative"."id";
2200 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';
2203 CREATE VIEW "expired_session" AS
2204 SELECT * FROM "session" WHERE now() > "expiry";
2206 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2207 DELETE FROM "session" WHERE "ident" = OLD."ident";
2209 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2210 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2213 CREATE VIEW "open_issue" AS
2214 SELECT * FROM "issue" WHERE "closed" ISNULL;
2216 COMMENT ON VIEW "open_issue" IS 'All open issues';
2219 CREATE VIEW "member_contingent" AS
2220 SELECT
2221 "member"."id" AS "member_id",
2222 "contingent"."polling",
2223 "contingent"."time_frame",
2224 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2226 SELECT count(1) FROM "draft"
2227 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2228 WHERE "draft"."author_id" = "member"."id"
2229 AND "initiative"."polling" = "contingent"."polling"
2230 AND "draft"."created" > now() - "contingent"."time_frame"
2231 ) + (
2232 SELECT count(1) FROM "suggestion"
2233 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2234 WHERE "suggestion"."author_id" = "member"."id"
2235 AND "contingent"."polling" = FALSE
2236 AND "suggestion"."created" > now() - "contingent"."time_frame"
2238 ELSE NULL END AS "text_entry_count",
2239 "contingent"."text_entry_limit",
2240 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2241 SELECT count(1) FROM "opening_draft" AS "draft"
2242 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2243 WHERE "draft"."author_id" = "member"."id"
2244 AND "initiative"."polling" = "contingent"."polling"
2245 AND "draft"."created" > now() - "contingent"."time_frame"
2246 ) ELSE NULL END AS "initiative_count",
2247 "contingent"."initiative_limit"
2248 FROM "member" CROSS JOIN "contingent";
2250 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2252 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2253 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2256 CREATE VIEW "member_contingent_left" AS
2257 SELECT
2258 "member_id",
2259 "polling",
2260 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2261 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2262 FROM "member_contingent" GROUP BY "member_id", "polling";
2264 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.';
2267 CREATE VIEW "event_seen_by_member" AS
2268 SELECT
2269 "member"."id" AS "seen_by_member_id",
2270 CASE WHEN "event"."state" IN (
2271 'voting',
2272 'finished_without_winner',
2273 'finished_with_winner'
2274 ) THEN
2275 'voting'::"notify_level"
2276 ELSE
2277 CASE WHEN "event"."state" IN (
2278 'verification',
2279 'canceled_after_revocation_during_verification',
2280 'canceled_no_initiative_admitted'
2281 ) THEN
2282 'verification'::"notify_level"
2283 ELSE
2284 CASE WHEN "event"."state" IN (
2285 'discussion',
2286 'canceled_after_revocation_during_discussion'
2287 ) THEN
2288 'discussion'::"notify_level"
2289 ELSE
2290 'all'::"notify_level"
2291 END
2292 END
2293 END AS "notify_level",
2294 "event".*
2295 FROM "member" CROSS JOIN "event"
2296 LEFT JOIN "issue"
2297 ON "event"."issue_id" = "issue"."id"
2298 LEFT JOIN "membership"
2299 ON "member"."id" = "membership"."member_id"
2300 AND "issue"."area_id" = "membership"."area_id"
2301 LEFT JOIN "interest"
2302 ON "member"."id" = "interest"."member_id"
2303 AND "event"."issue_id" = "interest"."issue_id"
2304 LEFT JOIN "ignored_member"
2305 ON "member"."id" = "ignored_member"."member_id"
2306 AND "event"."member_id" = "ignored_member"."other_member_id"
2307 LEFT JOIN "ignored_initiative"
2308 ON "member"."id" = "ignored_initiative"."member_id"
2309 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2310 WHERE (
2311 "interest"."member_id" NOTNULL OR
2312 ( "membership"."member_id" NOTNULL AND
2313 "event"."event" IN (
2314 'issue_state_changed',
2315 'initiative_created_in_new_issue',
2316 'initiative_created_in_existing_issue',
2317 'initiative_revoked' ) ) )
2318 AND "ignored_member"."member_id" ISNULL
2319 AND "ignored_initiative"."member_id" ISNULL;
2321 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"';
2324 CREATE VIEW "selected_event_seen_by_member" AS
2325 SELECT
2326 "member"."id" AS "seen_by_member_id",
2327 CASE WHEN "event"."state" IN (
2328 'voting',
2329 'finished_without_winner',
2330 'finished_with_winner'
2331 ) THEN
2332 'voting'::"notify_level"
2333 ELSE
2334 CASE WHEN "event"."state" IN (
2335 'verification',
2336 'canceled_after_revocation_during_verification',
2337 'canceled_no_initiative_admitted'
2338 ) THEN
2339 'verification'::"notify_level"
2340 ELSE
2341 CASE WHEN "event"."state" IN (
2342 'discussion',
2343 'canceled_after_revocation_during_discussion'
2344 ) THEN
2345 'discussion'::"notify_level"
2346 ELSE
2347 'all'::"notify_level"
2348 END
2349 END
2350 END AS "notify_level",
2351 "event".*
2352 FROM "member" CROSS JOIN "event"
2353 LEFT JOIN "issue"
2354 ON "event"."issue_id" = "issue"."id"
2355 LEFT JOIN "membership"
2356 ON "member"."id" = "membership"."member_id"
2357 AND "issue"."area_id" = "membership"."area_id"
2358 LEFT JOIN "interest"
2359 ON "member"."id" = "interest"."member_id"
2360 AND "event"."issue_id" = "interest"."issue_id"
2361 LEFT JOIN "ignored_member"
2362 ON "member"."id" = "ignored_member"."member_id"
2363 AND "event"."member_id" = "ignored_member"."other_member_id"
2364 LEFT JOIN "ignored_initiative"
2365 ON "member"."id" = "ignored_initiative"."member_id"
2366 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2367 WHERE (
2368 ( "member"."notify_level" >= 'all' ) OR
2369 ( "member"."notify_level" >= 'voting' AND
2370 "event"."state" IN (
2371 'voting',
2372 'finished_without_winner',
2373 'finished_with_winner' ) ) OR
2374 ( "member"."notify_level" >= 'verification' AND
2375 "event"."state" IN (
2376 'verification',
2377 'canceled_after_revocation_during_verification',
2378 'canceled_no_initiative_admitted' ) ) OR
2379 ( "member"."notify_level" >= 'discussion' AND
2380 "event"."state" IN (
2381 'discussion',
2382 'canceled_after_revocation_during_discussion' ) ) )
2383 AND (
2384 "interest"."member_id" NOTNULL OR
2385 ( "membership"."member_id" NOTNULL AND
2386 "event"."event" IN (
2387 'issue_state_changed',
2388 'initiative_created_in_new_issue',
2389 'initiative_created_in_existing_issue',
2390 'initiative_revoked' ) ) )
2391 AND "ignored_member"."member_id" ISNULL
2392 AND "ignored_initiative"."member_id" ISNULL;
2394 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"';
2398 ------------------------------------------------------
2399 -- Row set returning function for delegation chains --
2400 ------------------------------------------------------
2403 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2404 ('first', 'intermediate', 'last', 'repetition');
2406 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2409 CREATE TYPE "delegation_chain_row" AS (
2410 "index" INT4,
2411 "member_id" INT4,
2412 "member_valid" BOOLEAN,
2413 "participation" BOOLEAN,
2414 "overridden" BOOLEAN,
2415 "scope_in" "delegation_scope",
2416 "scope_out" "delegation_scope",
2417 "disabled_out" BOOLEAN,
2418 "loop" "delegation_chain_loop_tag" );
2420 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2422 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2423 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';
2424 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2425 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2426 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2427 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2428 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2431 CREATE FUNCTION "delegation_chain_for_closed_issue"
2432 ( "member_id_p" "member"."id"%TYPE,
2433 "issue_id_p" "issue"."id"%TYPE )
2434 RETURNS SETOF "delegation_chain_row"
2435 LANGUAGE 'plpgsql' STABLE AS $$
2436 DECLARE
2437 "output_row" "delegation_chain_row";
2438 "direct_voter_row" "direct_voter"%ROWTYPE;
2439 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2440 BEGIN
2441 "output_row"."index" := 0;
2442 "output_row"."member_id" := "member_id_p";
2443 "output_row"."member_valid" := TRUE;
2444 "output_row"."participation" := FALSE;
2445 "output_row"."overridden" := FALSE;
2446 "output_row"."disabled_out" := FALSE;
2447 LOOP
2448 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2449 WHERE "issue_id" = "issue_id_p"
2450 AND "member_id" = "output_row"."member_id";
2451 IF "direct_voter_row"."member_id" NOTNULL THEN
2452 "output_row"."participation" := TRUE;
2453 "output_row"."scope_out" := NULL;
2454 "output_row"."disabled_out" := NULL;
2455 RETURN NEXT "output_row";
2456 RETURN;
2457 END IF;
2458 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2459 WHERE "issue_id" = "issue_id_p"
2460 AND "member_id" = "output_row"."member_id";
2461 IF "delegating_voter_row"."member_id" ISNULL THEN
2462 RETURN;
2463 END IF;
2464 "output_row"."scope_out" := "delegating_voter_row"."scope";
2465 RETURN NEXT "output_row";
2466 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2467 "output_row"."scope_in" := "output_row"."scope_out";
2468 END LOOP;
2469 END;
2470 $$;
2472 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2473 ( "member"."id"%TYPE,
2474 "member"."id"%TYPE )
2475 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2478 CREATE FUNCTION "delegation_chain"
2479 ( "member_id_p" "member"."id"%TYPE,
2480 "unit_id_p" "unit"."id"%TYPE,
2481 "area_id_p" "area"."id"%TYPE,
2482 "issue_id_p" "issue"."id"%TYPE,
2483 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2484 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2485 RETURNS SETOF "delegation_chain_row"
2486 LANGUAGE 'plpgsql' STABLE AS $$
2487 DECLARE
2488 "scope_v" "delegation_scope";
2489 "unit_id_v" "unit"."id"%TYPE;
2490 "area_id_v" "area"."id"%TYPE;
2491 "issue_row" "issue"%ROWTYPE;
2492 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2493 "loop_member_id_v" "member"."id"%TYPE;
2494 "output_row" "delegation_chain_row";
2495 "output_rows" "delegation_chain_row"[];
2496 "simulate_v" BOOLEAN;
2497 "simulate_here_v" BOOLEAN;
2498 "delegation_row" "delegation"%ROWTYPE;
2499 "row_count" INT4;
2500 "i" INT4;
2501 "loop_v" BOOLEAN;
2502 BEGIN
2503 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2504 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2505 END IF;
2506 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2507 "simulate_v" := TRUE;
2508 ELSE
2509 "simulate_v" := FALSE;
2510 END IF;
2511 IF
2512 "unit_id_p" NOTNULL AND
2513 "area_id_p" ISNULL AND
2514 "issue_id_p" ISNULL
2515 THEN
2516 "scope_v" := 'unit';
2517 "unit_id_v" := "unit_id_p";
2518 ELSIF
2519 "unit_id_p" ISNULL AND
2520 "area_id_p" NOTNULL AND
2521 "issue_id_p" ISNULL
2522 THEN
2523 "scope_v" := 'area';
2524 "area_id_v" := "area_id_p";
2525 SELECT "unit_id" INTO "unit_id_v"
2526 FROM "area" WHERE "id" = "area_id_v";
2527 ELSIF
2528 "unit_id_p" ISNULL AND
2529 "area_id_p" ISNULL AND
2530 "issue_id_p" NOTNULL
2531 THEN
2532 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2533 IF "issue_row"."id" ISNULL THEN
2534 RETURN;
2535 END IF;
2536 IF "issue_row"."closed" NOTNULL THEN
2537 IF "simulate_v" THEN
2538 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2539 END IF;
2540 FOR "output_row" IN
2541 SELECT * FROM
2542 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2543 LOOP
2544 RETURN NEXT "output_row";
2545 END LOOP;
2546 RETURN;
2547 END IF;
2548 "scope_v" := 'issue';
2549 SELECT "area_id" INTO "area_id_v"
2550 FROM "issue" WHERE "id" = "issue_id_p";
2551 SELECT "unit_id" INTO "unit_id_v"
2552 FROM "area" WHERE "id" = "area_id_v";
2553 ELSE
2554 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2555 END IF;
2556 "visited_member_ids" := '{}';
2557 "loop_member_id_v" := NULL;
2558 "output_rows" := '{}';
2559 "output_row"."index" := 0;
2560 "output_row"."member_id" := "member_id_p";
2561 "output_row"."member_valid" := TRUE;
2562 "output_row"."participation" := FALSE;
2563 "output_row"."overridden" := FALSE;
2564 "output_row"."disabled_out" := FALSE;
2565 "output_row"."scope_out" := NULL;
2566 LOOP
2567 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2568 "loop_member_id_v" := "output_row"."member_id";
2569 ELSE
2570 "visited_member_ids" :=
2571 "visited_member_ids" || "output_row"."member_id";
2572 END IF;
2573 IF "output_row"."participation" ISNULL THEN
2574 "output_row"."overridden" := NULL;
2575 ELSIF "output_row"."participation" THEN
2576 "output_row"."overridden" := TRUE;
2577 END IF;
2578 "output_row"."scope_in" := "output_row"."scope_out";
2579 "output_row"."member_valid" := EXISTS (
2580 SELECT NULL FROM "member" JOIN "privilege"
2581 ON "privilege"."member_id" = "member"."id"
2582 AND "privilege"."unit_id" = "unit_id_v"
2583 WHERE "id" = "output_row"."member_id"
2584 AND "member"."active" AND "privilege"."voting_right"
2585 );
2586 "simulate_here_v" := (
2587 "simulate_v" AND
2588 "output_row"."member_id" = "member_id_p"
2589 );
2590 "delegation_row" := ROW(NULL);
2591 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2592 IF "scope_v" = 'unit' THEN
2593 IF NOT "simulate_here_v" THEN
2594 SELECT * INTO "delegation_row" FROM "delegation"
2595 WHERE "truster_id" = "output_row"."member_id"
2596 AND "unit_id" = "unit_id_v";
2597 END IF;
2598 ELSIF "scope_v" = 'area' THEN
2599 "output_row"."participation" := EXISTS (
2600 SELECT NULL FROM "membership"
2601 WHERE "area_id" = "area_id_p"
2602 AND "member_id" = "output_row"."member_id"
2603 );
2604 IF "simulate_here_v" THEN
2605 IF "simulate_trustee_id_p" ISNULL THEN
2606 SELECT * INTO "delegation_row" FROM "delegation"
2607 WHERE "truster_id" = "output_row"."member_id"
2608 AND "unit_id" = "unit_id_v";
2609 END IF;
2610 ELSE
2611 SELECT * INTO "delegation_row" FROM "delegation"
2612 WHERE "truster_id" = "output_row"."member_id"
2613 AND (
2614 "unit_id" = "unit_id_v" OR
2615 "area_id" = "area_id_v"
2617 ORDER BY "scope" DESC;
2618 END IF;
2619 ELSIF "scope_v" = 'issue' THEN
2620 IF "issue_row"."fully_frozen" ISNULL THEN
2621 "output_row"."participation" := EXISTS (
2622 SELECT NULL FROM "interest"
2623 WHERE "issue_id" = "issue_id_p"
2624 AND "member_id" = "output_row"."member_id"
2625 );
2626 ELSE
2627 IF "output_row"."member_id" = "member_id_p" THEN
2628 "output_row"."participation" := EXISTS (
2629 SELECT NULL FROM "direct_voter"
2630 WHERE "issue_id" = "issue_id_p"
2631 AND "member_id" = "output_row"."member_id"
2632 );
2633 ELSE
2634 "output_row"."participation" := NULL;
2635 END IF;
2636 END IF;
2637 IF "simulate_here_v" THEN
2638 IF "simulate_trustee_id_p" ISNULL THEN
2639 SELECT * INTO "delegation_row" FROM "delegation"
2640 WHERE "truster_id" = "output_row"."member_id"
2641 AND (
2642 "unit_id" = "unit_id_v" OR
2643 "area_id" = "area_id_v"
2645 ORDER BY "scope" DESC;
2646 END IF;
2647 ELSE
2648 SELECT * INTO "delegation_row" FROM "delegation"
2649 WHERE "truster_id" = "output_row"."member_id"
2650 AND (
2651 "unit_id" = "unit_id_v" OR
2652 "area_id" = "area_id_v" OR
2653 "issue_id" = "issue_id_p"
2655 ORDER BY "scope" DESC;
2656 END IF;
2657 END IF;
2658 ELSE
2659 "output_row"."participation" := FALSE;
2660 END IF;
2661 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2662 "output_row"."scope_out" := "scope_v";
2663 "output_rows" := "output_rows" || "output_row";
2664 "output_row"."member_id" := "simulate_trustee_id_p";
2665 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2666 "output_row"."scope_out" := "delegation_row"."scope";
2667 "output_rows" := "output_rows" || "output_row";
2668 "output_row"."member_id" := "delegation_row"."trustee_id";
2669 ELSIF "delegation_row"."scope" NOTNULL THEN
2670 "output_row"."scope_out" := "delegation_row"."scope";
2671 "output_row"."disabled_out" := TRUE;
2672 "output_rows" := "output_rows" || "output_row";
2673 EXIT;
2674 ELSE
2675 "output_row"."scope_out" := NULL;
2676 "output_rows" := "output_rows" || "output_row";
2677 EXIT;
2678 END IF;
2679 EXIT WHEN "loop_member_id_v" NOTNULL;
2680 "output_row"."index" := "output_row"."index" + 1;
2681 END LOOP;
2682 "row_count" := array_upper("output_rows", 1);
2683 "i" := 1;
2684 "loop_v" := FALSE;
2685 LOOP
2686 "output_row" := "output_rows"["i"];
2687 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2688 IF "loop_v" THEN
2689 IF "i" + 1 = "row_count" THEN
2690 "output_row"."loop" := 'last';
2691 ELSIF "i" = "row_count" THEN
2692 "output_row"."loop" := 'repetition';
2693 ELSE
2694 "output_row"."loop" := 'intermediate';
2695 END IF;
2696 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2697 "output_row"."loop" := 'first';
2698 "loop_v" := TRUE;
2699 END IF;
2700 IF "scope_v" = 'unit' THEN
2701 "output_row"."participation" := NULL;
2702 END IF;
2703 RETURN NEXT "output_row";
2704 "i" := "i" + 1;
2705 END LOOP;
2706 RETURN;
2707 END;
2708 $$;
2710 COMMENT ON FUNCTION "delegation_chain"
2711 ( "member"."id"%TYPE,
2712 "unit"."id"%TYPE,
2713 "area"."id"%TYPE,
2714 "issue"."id"%TYPE,
2715 "member"."id"%TYPE,
2716 BOOLEAN )
2717 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2721 ---------------------------------------------------------
2722 -- Single row returning function for delegation chains --
2723 ---------------------------------------------------------
2726 CREATE TYPE "delegation_info_loop_type" AS ENUM
2727 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2729 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''';
2732 CREATE TYPE "delegation_info_type" AS (
2733 "own_participation" BOOLEAN,
2734 "own_delegation_scope" "delegation_scope",
2735 "first_trustee_id" INT4,
2736 "first_trustee_participation" BOOLEAN,
2737 "first_trustee_ellipsis" BOOLEAN,
2738 "other_trustee_id" INT4,
2739 "other_trustee_participation" BOOLEAN,
2740 "other_trustee_ellipsis" BOOLEAN,
2741 "delegation_loop" "delegation_info_loop_type",
2742 "participating_member_id" INT4 );
2744 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';
2746 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2747 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2748 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2749 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2750 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2751 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2752 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)';
2753 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2754 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';
2755 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2758 CREATE FUNCTION "delegation_info"
2759 ( "member_id_p" "member"."id"%TYPE,
2760 "unit_id_p" "unit"."id"%TYPE,
2761 "area_id_p" "area"."id"%TYPE,
2762 "issue_id_p" "issue"."id"%TYPE,
2763 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2764 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2765 RETURNS "delegation_info_type"
2766 LANGUAGE 'plpgsql' STABLE AS $$
2767 DECLARE
2768 "current_row" "delegation_chain_row";
2769 "result" "delegation_info_type";
2770 BEGIN
2771 "result"."own_participation" := FALSE;
2772 FOR "current_row" IN
2773 SELECT * FROM "delegation_chain"(
2774 "member_id_p",
2775 "unit_id_p", "area_id_p", "issue_id_p",
2776 "simulate_trustee_id_p", "simulate_default_p")
2777 LOOP
2778 IF
2779 "result"."participating_member_id" ISNULL AND
2780 "current_row"."participation"
2781 THEN
2782 "result"."participating_member_id" := "current_row"."member_id";
2783 END IF;
2784 IF "current_row"."member_id" = "member_id_p" THEN
2785 "result"."own_participation" := "current_row"."participation";
2786 "result"."own_delegation_scope" := "current_row"."scope_out";
2787 IF "current_row"."loop" = 'first' THEN
2788 "result"."delegation_loop" := 'own';
2789 END IF;
2790 ELSIF
2791 "current_row"."member_valid" AND
2792 ( "current_row"."loop" ISNULL OR
2793 "current_row"."loop" != 'repetition' )
2794 THEN
2795 IF "result"."first_trustee_id" ISNULL THEN
2796 "result"."first_trustee_id" := "current_row"."member_id";
2797 "result"."first_trustee_participation" := "current_row"."participation";
2798 "result"."first_trustee_ellipsis" := FALSE;
2799 IF "current_row"."loop" = 'first' THEN
2800 "result"."delegation_loop" := 'first';
2801 END IF;
2802 ELSIF "result"."other_trustee_id" ISNULL THEN
2803 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2804 "result"."other_trustee_id" := "current_row"."member_id";
2805 "result"."other_trustee_participation" := TRUE;
2806 "result"."other_trustee_ellipsis" := FALSE;
2807 IF "current_row"."loop" = 'first' THEN
2808 "result"."delegation_loop" := 'other';
2809 END IF;
2810 ELSE
2811 "result"."first_trustee_ellipsis" := TRUE;
2812 IF "current_row"."loop" = 'first' THEN
2813 "result"."delegation_loop" := 'first_ellipsis';
2814 END IF;
2815 END IF;
2816 ELSE
2817 "result"."other_trustee_ellipsis" := TRUE;
2818 IF "current_row"."loop" = 'first' THEN
2819 "result"."delegation_loop" := 'other_ellipsis';
2820 END IF;
2821 END IF;
2822 END IF;
2823 END LOOP;
2824 RETURN "result";
2825 END;
2826 $$;
2828 COMMENT ON FUNCTION "delegation_info"
2829 ( "member"."id"%TYPE,
2830 "unit"."id"%TYPE,
2831 "area"."id"%TYPE,
2832 "issue"."id"%TYPE,
2833 "member"."id"%TYPE,
2834 BOOLEAN )
2835 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2839 ---------------------------
2840 -- Transaction isolation --
2841 ---------------------------
2844 CREATE FUNCTION "require_transaction_isolation"()
2845 RETURNS VOID
2846 LANGUAGE 'plpgsql' VOLATILE AS $$
2847 BEGIN
2848 IF
2849 current_setting('transaction_isolation') NOT IN
2850 ('repeatable read', 'serializable')
2851 THEN
2852 RAISE EXCEPTION 'Insufficient transaction isolation level';
2853 END IF;
2854 RETURN;
2855 END;
2856 $$;
2858 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
2861 CREATE FUNCTION "dont_require_transaction_isolation"()
2862 RETURNS VOID
2863 LANGUAGE 'plpgsql' VOLATILE AS $$
2864 BEGIN
2865 IF
2866 current_setting('transaction_isolation') IN
2867 ('repeatable read', 'serializable')
2868 THEN
2869 RAISE WARNING 'Unneccessary transaction isolation level: %',
2870 current_setting('transaction_isolation');
2871 END IF;
2872 RETURN;
2873 END;
2874 $$;
2876 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
2880 ------------------------------------------------------------------------
2881 -- Regular tasks, except calculcation of snapshots and voting results --
2882 ------------------------------------------------------------------------
2885 CREATE FUNCTION "check_activity"()
2886 RETURNS VOID
2887 LANGUAGE 'plpgsql' VOLATILE AS $$
2888 DECLARE
2889 "system_setting_row" "system_setting"%ROWTYPE;
2890 BEGIN
2891 PERFORM "dont_require_transaction_isolation"();
2892 SELECT * INTO "system_setting_row" FROM "system_setting";
2893 IF "system_setting_row"."member_ttl" NOTNULL THEN
2894 UPDATE "member" SET "active" = FALSE
2895 WHERE "active" = TRUE
2896 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2897 END IF;
2898 RETURN;
2899 END;
2900 $$;
2902 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2905 CREATE FUNCTION "calculate_member_counts"()
2906 RETURNS VOID
2907 LANGUAGE 'plpgsql' VOLATILE AS $$
2908 BEGIN
2909 PERFORM "require_transaction_isolation"();
2910 DELETE FROM "member_count";
2911 INSERT INTO "member_count" ("total_count")
2912 SELECT "total_count" FROM "member_count_view";
2913 UPDATE "unit" SET "member_count" = "view"."member_count"
2914 FROM "unit_member_count" AS "view"
2915 WHERE "view"."unit_id" = "unit"."id";
2916 UPDATE "area" SET
2917 "direct_member_count" = "view"."direct_member_count",
2918 "member_weight" = "view"."member_weight"
2919 FROM "area_member_count" AS "view"
2920 WHERE "view"."area_id" = "area"."id";
2921 RETURN;
2922 END;
2923 $$;
2925 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"';
2929 ------------------------------------
2930 -- Calculation of harmonic weight --
2931 ------------------------------------
2934 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2935 SELECT
2936 "direct_interest_snapshot"."issue_id",
2937 "direct_interest_snapshot"."event",
2938 "direct_interest_snapshot"."member_id",
2939 "direct_interest_snapshot"."weight" AS "weight_num",
2940 count("initiative"."id") AS "weight_den"
2941 FROM "issue"
2942 JOIN "direct_interest_snapshot"
2943 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
2944 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
2945 JOIN "initiative"
2946 ON "issue"."id" = "initiative"."issue_id"
2947 AND "initiative"."harmonic_weight" ISNULL
2948 JOIN "direct_supporter_snapshot"
2949 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2950 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
2951 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
2952 AND (
2953 "direct_supporter_snapshot"."satisfied" = TRUE OR
2954 coalesce("initiative"."admitted", FALSE) = FALSE
2956 GROUP BY
2957 "direct_interest_snapshot"."issue_id",
2958 "direct_interest_snapshot"."event",
2959 "direct_interest_snapshot"."member_id",
2960 "direct_interest_snapshot"."weight";
2962 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
2965 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
2966 SELECT
2967 "initiative"."issue_id",
2968 "initiative"."id" AS "initiative_id",
2969 "initiative"."admitted",
2970 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
2971 "remaining_harmonic_supporter_weight"."weight_den"
2972 FROM "remaining_harmonic_supporter_weight"
2973 JOIN "initiative"
2974 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
2975 AND "initiative"."harmonic_weight" ISNULL
2976 JOIN "direct_supporter_snapshot"
2977 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2978 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
2979 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
2980 AND (
2981 "direct_supporter_snapshot"."satisfied" = TRUE OR
2982 coalesce("initiative"."admitted", FALSE) = FALSE
2984 GROUP BY
2985 "initiative"."issue_id",
2986 "initiative"."id",
2987 "initiative"."admitted",
2988 "remaining_harmonic_supporter_weight"."weight_den";
2990 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
2993 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
2994 SELECT
2995 "issue_id",
2996 "id" AS "initiative_id",
2997 "admitted",
2998 0 AS "weight_num",
2999 1 AS "weight_den"
3000 FROM "initiative"
3001 WHERE "harmonic_weight" ISNULL;
3003 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';
3006 CREATE FUNCTION "set_harmonic_initiative_weights"
3007 ( "issue_id_p" "issue"."id"%TYPE )
3008 RETURNS VOID
3009 LANGUAGE 'plpgsql' VOLATILE AS $$
3010 DECLARE
3011 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
3012 "i" INT4;
3013 "count_v" INT4;
3014 "summand_v" FLOAT;
3015 "id_ary" INT4[];
3016 "weight_ary" FLOAT[];
3017 "min_weight_v" FLOAT;
3018 BEGIN
3019 PERFORM "require_transaction_isolation"();
3020 UPDATE "initiative" SET "harmonic_weight" = NULL
3021 WHERE "issue_id" = "issue_id_p";
3022 LOOP
3023 "min_weight_v" := NULL;
3024 "i" := 0;
3025 "count_v" := 0;
3026 FOR "weight_row" IN
3027 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
3028 WHERE "issue_id" = "issue_id_p"
3029 AND (
3030 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3031 SELECT NULL FROM "initiative"
3032 WHERE "issue_id" = "issue_id_p"
3033 AND "harmonic_weight" ISNULL
3034 AND coalesce("admitted", FALSE) = FALSE
3037 UNION ALL -- needed for corner cases
3038 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
3039 WHERE "issue_id" = "issue_id_p"
3040 AND (
3041 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3042 SELECT NULL FROM "initiative"
3043 WHERE "issue_id" = "issue_id_p"
3044 AND "harmonic_weight" ISNULL
3045 AND coalesce("admitted", FALSE) = FALSE
3048 ORDER BY "initiative_id" DESC, "weight_den" DESC
3049 -- NOTE: non-admitted initiatives placed first (at last positions),
3050 -- latest initiatives treated worse in case of tie
3051 LOOP
3052 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
3053 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
3054 "i" := "i" + 1;
3055 "count_v" := "i";
3056 "id_ary"["i"] := "weight_row"."initiative_id";
3057 "weight_ary"["i"] := "summand_v";
3058 ELSE
3059 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
3060 END IF;
3061 END LOOP;
3062 EXIT WHEN "count_v" = 0;
3063 "i" := 1;
3064 LOOP
3065 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
3066 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
3067 "min_weight_v" := "weight_ary"["i"];
3068 END IF;
3069 "i" := "i" + 1;
3070 EXIT WHEN "i" > "count_v";
3071 END LOOP;
3072 "i" := 1;
3073 LOOP
3074 IF "weight_ary"["i"] = "min_weight_v" THEN
3075 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
3076 WHERE "id" = "id_ary"["i"];
3077 EXIT;
3078 END IF;
3079 "i" := "i" + 1;
3080 END LOOP;
3081 END LOOP;
3082 UPDATE "initiative" SET "harmonic_weight" = 0
3083 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
3084 END;
3085 $$;
3087 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
3088 ( "issue"."id"%TYPE )
3089 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
3093 ------------------------------
3094 -- Calculation of snapshots --
3095 ------------------------------
3098 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3099 ( "issue_id_p" "issue"."id"%TYPE,
3100 "member_id_p" "member"."id"%TYPE,
3101 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3102 RETURNS "direct_population_snapshot"."weight"%TYPE
3103 LANGUAGE 'plpgsql' VOLATILE AS $$
3104 DECLARE
3105 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3106 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3107 "weight_v" INT4;
3108 "sub_weight_v" INT4;
3109 BEGIN
3110 PERFORM "require_transaction_isolation"();
3111 "weight_v" := 0;
3112 FOR "issue_delegation_row" IN
3113 SELECT * FROM "issue_delegation"
3114 WHERE "trustee_id" = "member_id_p"
3115 AND "issue_id" = "issue_id_p"
3116 LOOP
3117 IF NOT EXISTS (
3118 SELECT NULL FROM "direct_population_snapshot"
3119 WHERE "issue_id" = "issue_id_p"
3120 AND "event" = 'periodic'
3121 AND "member_id" = "issue_delegation_row"."truster_id"
3122 ) AND NOT EXISTS (
3123 SELECT NULL FROM "delegating_population_snapshot"
3124 WHERE "issue_id" = "issue_id_p"
3125 AND "event" = 'periodic'
3126 AND "member_id" = "issue_delegation_row"."truster_id"
3127 ) THEN
3128 "delegate_member_ids_v" :=
3129 "member_id_p" || "delegate_member_ids_p";
3130 INSERT INTO "delegating_population_snapshot" (
3131 "issue_id",
3132 "event",
3133 "member_id",
3134 "scope",
3135 "delegate_member_ids"
3136 ) VALUES (
3137 "issue_id_p",
3138 'periodic',
3139 "issue_delegation_row"."truster_id",
3140 "issue_delegation_row"."scope",
3141 "delegate_member_ids_v"
3142 );
3143 "sub_weight_v" := 1 +
3144 "weight_of_added_delegations_for_population_snapshot"(
3145 "issue_id_p",
3146 "issue_delegation_row"."truster_id",
3147 "delegate_member_ids_v"
3148 );
3149 UPDATE "delegating_population_snapshot"
3150 SET "weight" = "sub_weight_v"
3151 WHERE "issue_id" = "issue_id_p"
3152 AND "event" = 'periodic'
3153 AND "member_id" = "issue_delegation_row"."truster_id";
3154 "weight_v" := "weight_v" + "sub_weight_v";
3155 END IF;
3156 END LOOP;
3157 RETURN "weight_v";
3158 END;
3159 $$;
3161 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3162 ( "issue"."id"%TYPE,
3163 "member"."id"%TYPE,
3164 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3165 IS 'Helper function for "create_population_snapshot" function';
3168 CREATE FUNCTION "create_population_snapshot"
3169 ( "issue_id_p" "issue"."id"%TYPE )
3170 RETURNS VOID
3171 LANGUAGE 'plpgsql' VOLATILE AS $$
3172 DECLARE
3173 "member_id_v" "member"."id"%TYPE;
3174 BEGIN
3175 PERFORM "require_transaction_isolation"();
3176 DELETE FROM "direct_population_snapshot"
3177 WHERE "issue_id" = "issue_id_p"
3178 AND "event" = 'periodic';
3179 DELETE FROM "delegating_population_snapshot"
3180 WHERE "issue_id" = "issue_id_p"
3181 AND "event" = 'periodic';
3182 INSERT INTO "direct_population_snapshot"
3183 ("issue_id", "event", "member_id")
3184 SELECT
3185 "issue_id_p" AS "issue_id",
3186 'periodic'::"snapshot_event" AS "event",
3187 "member"."id" AS "member_id"
3188 FROM "issue"
3189 JOIN "area" ON "issue"."area_id" = "area"."id"
3190 JOIN "membership" ON "area"."id" = "membership"."area_id"
3191 JOIN "member" ON "membership"."member_id" = "member"."id"
3192 JOIN "privilege"
3193 ON "privilege"."unit_id" = "area"."unit_id"
3194 AND "privilege"."member_id" = "member"."id"
3195 WHERE "issue"."id" = "issue_id_p"
3196 AND "member"."active" AND "privilege"."voting_right"
3197 UNION
3198 SELECT
3199 "issue_id_p" AS "issue_id",
3200 'periodic'::"snapshot_event" AS "event",
3201 "member"."id" AS "member_id"
3202 FROM "issue"
3203 JOIN "area" ON "issue"."area_id" = "area"."id"
3204 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3205 JOIN "member" ON "interest"."member_id" = "member"."id"
3206 JOIN "privilege"
3207 ON "privilege"."unit_id" = "area"."unit_id"
3208 AND "privilege"."member_id" = "member"."id"
3209 WHERE "issue"."id" = "issue_id_p"
3210 AND "member"."active" AND "privilege"."voting_right";
3211 FOR "member_id_v" IN
3212 SELECT "member_id" FROM "direct_population_snapshot"
3213 WHERE "issue_id" = "issue_id_p"
3214 AND "event" = 'periodic'
3215 LOOP
3216 UPDATE "direct_population_snapshot" SET
3217 "weight" = 1 +
3218 "weight_of_added_delegations_for_population_snapshot"(
3219 "issue_id_p",
3220 "member_id_v",
3221 '{}'
3223 WHERE "issue_id" = "issue_id_p"
3224 AND "event" = 'periodic'
3225 AND "member_id" = "member_id_v";
3226 END LOOP;
3227 RETURN;
3228 END;
3229 $$;
3231 COMMENT ON FUNCTION "create_population_snapshot"
3232 ( "issue"."id"%TYPE )
3233 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.';
3236 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3237 ( "issue_id_p" "issue"."id"%TYPE,
3238 "member_id_p" "member"."id"%TYPE,
3239 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3240 RETURNS "direct_interest_snapshot"."weight"%TYPE
3241 LANGUAGE 'plpgsql' VOLATILE AS $$
3242 DECLARE
3243 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3244 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3245 "weight_v" INT4;
3246 "sub_weight_v" INT4;
3247 BEGIN
3248 PERFORM "require_transaction_isolation"();
3249 "weight_v" := 0;
3250 FOR "issue_delegation_row" IN
3251 SELECT * FROM "issue_delegation"
3252 WHERE "trustee_id" = "member_id_p"
3253 AND "issue_id" = "issue_id_p"
3254 LOOP
3255 IF NOT EXISTS (
3256 SELECT NULL FROM "direct_interest_snapshot"
3257 WHERE "issue_id" = "issue_id_p"
3258 AND "event" = 'periodic'
3259 AND "member_id" = "issue_delegation_row"."truster_id"
3260 ) AND NOT EXISTS (
3261 SELECT NULL FROM "delegating_interest_snapshot"
3262 WHERE "issue_id" = "issue_id_p"
3263 AND "event" = 'periodic'
3264 AND "member_id" = "issue_delegation_row"."truster_id"
3265 ) THEN
3266 "delegate_member_ids_v" :=
3267 "member_id_p" || "delegate_member_ids_p";
3268 INSERT INTO "delegating_interest_snapshot" (
3269 "issue_id",
3270 "event",
3271 "member_id",
3272 "scope",
3273 "delegate_member_ids"
3274 ) VALUES (
3275 "issue_id_p",
3276 'periodic',
3277 "issue_delegation_row"."truster_id",
3278 "issue_delegation_row"."scope",
3279 "delegate_member_ids_v"
3280 );
3281 "sub_weight_v" := 1 +
3282 "weight_of_added_delegations_for_interest_snapshot"(
3283 "issue_id_p",
3284 "issue_delegation_row"."truster_id",
3285 "delegate_member_ids_v"
3286 );
3287 UPDATE "delegating_interest_snapshot"
3288 SET "weight" = "sub_weight_v"
3289 WHERE "issue_id" = "issue_id_p"
3290 AND "event" = 'periodic'
3291 AND "member_id" = "issue_delegation_row"."truster_id";
3292 "weight_v" := "weight_v" + "sub_weight_v";
3293 END IF;
3294 END LOOP;
3295 RETURN "weight_v";
3296 END;
3297 $$;
3299 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3300 ( "issue"."id"%TYPE,
3301 "member"."id"%TYPE,
3302 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3303 IS 'Helper function for "create_interest_snapshot" function';
3306 CREATE FUNCTION "create_interest_snapshot"
3307 ( "issue_id_p" "issue"."id"%TYPE )
3308 RETURNS VOID
3309 LANGUAGE 'plpgsql' VOLATILE AS $$
3310 DECLARE
3311 "member_id_v" "member"."id"%TYPE;
3312 BEGIN
3313 PERFORM "require_transaction_isolation"();
3314 DELETE FROM "direct_interest_snapshot"
3315 WHERE "issue_id" = "issue_id_p"
3316 AND "event" = 'periodic';
3317 DELETE FROM "delegating_interest_snapshot"
3318 WHERE "issue_id" = "issue_id_p"
3319 AND "event" = 'periodic';
3320 DELETE FROM "direct_supporter_snapshot"
3321 USING "initiative" -- NOTE: due to missing index on issue_id
3322 WHERE "initiative"."issue_id" = "issue_id_p"
3323 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3324 AND "direct_supporter_snapshot"."event" = 'periodic';
3325 INSERT INTO "direct_interest_snapshot"
3326 ("issue_id", "event", "member_id")
3327 SELECT
3328 "issue_id_p" AS "issue_id",
3329 'periodic' AS "event",
3330 "member"."id" AS "member_id"
3331 FROM "issue"
3332 JOIN "area" ON "issue"."area_id" = "area"."id"
3333 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3334 JOIN "member" ON "interest"."member_id" = "member"."id"
3335 JOIN "privilege"
3336 ON "privilege"."unit_id" = "area"."unit_id"
3337 AND "privilege"."member_id" = "member"."id"
3338 WHERE "issue"."id" = "issue_id_p"
3339 AND "member"."active" AND "privilege"."voting_right";
3340 FOR "member_id_v" IN
3341 SELECT "member_id" FROM "direct_interest_snapshot"
3342 WHERE "issue_id" = "issue_id_p"
3343 AND "event" = 'periodic'
3344 LOOP
3345 UPDATE "direct_interest_snapshot" SET
3346 "weight" = 1 +
3347 "weight_of_added_delegations_for_interest_snapshot"(
3348 "issue_id_p",
3349 "member_id_v",
3350 '{}'
3352 WHERE "issue_id" = "issue_id_p"
3353 AND "event" = 'periodic'
3354 AND "member_id" = "member_id_v";
3355 END LOOP;
3356 INSERT INTO "direct_supporter_snapshot"
3357 ( "issue_id", "initiative_id", "event", "member_id",
3358 "draft_id", "informed", "satisfied" )
3359 SELECT
3360 "issue_id_p" AS "issue_id",
3361 "initiative"."id" AS "initiative_id",
3362 'periodic' AS "event",
3363 "supporter"."member_id" AS "member_id",
3364 "supporter"."draft_id" AS "draft_id",
3365 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3366 NOT EXISTS (
3367 SELECT NULL FROM "critical_opinion"
3368 WHERE "initiative_id" = "initiative"."id"
3369 AND "member_id" = "supporter"."member_id"
3370 ) AS "satisfied"
3371 FROM "initiative"
3372 JOIN "supporter"
3373 ON "supporter"."initiative_id" = "initiative"."id"
3374 JOIN "current_draft"
3375 ON "initiative"."id" = "current_draft"."initiative_id"
3376 JOIN "direct_interest_snapshot"
3377 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3378 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3379 AND "event" = 'periodic'
3380 WHERE "initiative"."issue_id" = "issue_id_p";
3381 RETURN;
3382 END;
3383 $$;
3385 COMMENT ON FUNCTION "create_interest_snapshot"
3386 ( "issue"."id"%TYPE )
3387 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.';
3390 CREATE FUNCTION "create_snapshot"
3391 ( "issue_id_p" "issue"."id"%TYPE )
3392 RETURNS VOID
3393 LANGUAGE 'plpgsql' VOLATILE AS $$
3394 DECLARE
3395 "initiative_id_v" "initiative"."id"%TYPE;
3396 "suggestion_id_v" "suggestion"."id"%TYPE;
3397 BEGIN
3398 PERFORM "require_transaction_isolation"();
3399 PERFORM "create_population_snapshot"("issue_id_p");
3400 PERFORM "create_interest_snapshot"("issue_id_p");
3401 UPDATE "issue" SET
3402 "snapshot" = coalesce("phase_finished", now()),
3403 "latest_snapshot_event" = 'periodic',
3404 "population" = (
3405 SELECT coalesce(sum("weight"), 0)
3406 FROM "direct_population_snapshot"
3407 WHERE "issue_id" = "issue_id_p"
3408 AND "event" = 'periodic'
3410 WHERE "id" = "issue_id_p";
3411 FOR "initiative_id_v" IN
3412 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3413 LOOP
3414 UPDATE "initiative" SET
3415 "supporter_count" = (
3416 SELECT coalesce(sum("di"."weight"), 0)
3417 FROM "direct_interest_snapshot" AS "di"
3418 JOIN "direct_supporter_snapshot" AS "ds"
3419 ON "di"."member_id" = "ds"."member_id"
3420 WHERE "di"."issue_id" = "issue_id_p"
3421 AND "di"."event" = 'periodic'
3422 AND "ds"."initiative_id" = "initiative_id_v"
3423 AND "ds"."event" = 'periodic'
3424 ),
3425 "informed_supporter_count" = (
3426 SELECT coalesce(sum("di"."weight"), 0)
3427 FROM "direct_interest_snapshot" AS "di"
3428 JOIN "direct_supporter_snapshot" AS "ds"
3429 ON "di"."member_id" = "ds"."member_id"
3430 WHERE "di"."issue_id" = "issue_id_p"
3431 AND "di"."event" = 'periodic'
3432 AND "ds"."initiative_id" = "initiative_id_v"
3433 AND "ds"."event" = 'periodic'
3434 AND "ds"."informed"
3435 ),
3436 "satisfied_supporter_count" = (
3437 SELECT coalesce(sum("di"."weight"), 0)
3438 FROM "direct_interest_snapshot" AS "di"
3439 JOIN "direct_supporter_snapshot" AS "ds"
3440 ON "di"."member_id" = "ds"."member_id"
3441 WHERE "di"."issue_id" = "issue_id_p"
3442 AND "di"."event" = 'periodic'
3443 AND "ds"."initiative_id" = "initiative_id_v"
3444 AND "ds"."event" = 'periodic'
3445 AND "ds"."satisfied"
3446 ),
3447 "satisfied_informed_supporter_count" = (
3448 SELECT coalesce(sum("di"."weight"), 0)
3449 FROM "direct_interest_snapshot" AS "di"
3450 JOIN "direct_supporter_snapshot" AS "ds"
3451 ON "di"."member_id" = "ds"."member_id"
3452 WHERE "di"."issue_id" = "issue_id_p"
3453 AND "di"."event" = 'periodic'
3454 AND "ds"."initiative_id" = "initiative_id_v"
3455 AND "ds"."event" = 'periodic'
3456 AND "ds"."informed"
3457 AND "ds"."satisfied"
3459 WHERE "id" = "initiative_id_v";
3460 FOR "suggestion_id_v" IN
3461 SELECT "id" FROM "suggestion"
3462 WHERE "initiative_id" = "initiative_id_v"
3463 LOOP
3464 UPDATE "suggestion" SET
3465 "minus2_unfulfilled_count" = (
3466 SELECT coalesce(sum("snapshot"."weight"), 0)
3467 FROM "issue" CROSS JOIN "opinion"
3468 JOIN "direct_interest_snapshot" AS "snapshot"
3469 ON "snapshot"."issue_id" = "issue"."id"
3470 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3471 AND "snapshot"."member_id" = "opinion"."member_id"
3472 WHERE "issue"."id" = "issue_id_p"
3473 AND "opinion"."suggestion_id" = "suggestion_id_v"
3474 AND "opinion"."degree" = -2
3475 AND "opinion"."fulfilled" = FALSE
3476 ),
3477 "minus2_fulfilled_count" = (
3478 SELECT coalesce(sum("snapshot"."weight"), 0)
3479 FROM "issue" CROSS JOIN "opinion"
3480 JOIN "direct_interest_snapshot" AS "snapshot"
3481 ON "snapshot"."issue_id" = "issue"."id"
3482 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3483 AND "snapshot"."member_id" = "opinion"."member_id"
3484 WHERE "issue"."id" = "issue_id_p"
3485 AND "opinion"."suggestion_id" = "suggestion_id_v"
3486 AND "opinion"."degree" = -2
3487 AND "opinion"."fulfilled" = TRUE
3488 ),
3489 "minus1_unfulfilled_count" = (
3490 SELECT coalesce(sum("snapshot"."weight"), 0)
3491 FROM "issue" CROSS JOIN "opinion"
3492 JOIN "direct_interest_snapshot" AS "snapshot"
3493 ON "snapshot"."issue_id" = "issue"."id"
3494 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3495 AND "snapshot"."member_id" = "opinion"."member_id"
3496 WHERE "issue"."id" = "issue_id_p"
3497 AND "opinion"."suggestion_id" = "suggestion_id_v"
3498 AND "opinion"."degree" = -1
3499 AND "opinion"."fulfilled" = FALSE
3500 ),
3501 "minus1_fulfilled_count" = (
3502 SELECT coalesce(sum("snapshot"."weight"), 0)
3503 FROM "issue" CROSS JOIN "opinion"
3504 JOIN "direct_interest_snapshot" AS "snapshot"
3505 ON "snapshot"."issue_id" = "issue"."id"
3506 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3507 AND "snapshot"."member_id" = "opinion"."member_id"
3508 WHERE "issue"."id" = "issue_id_p"
3509 AND "opinion"."suggestion_id" = "suggestion_id_v"
3510 AND "opinion"."degree" = -1
3511 AND "opinion"."fulfilled" = TRUE
3512 ),
3513 "plus1_unfulfilled_count" = (
3514 SELECT coalesce(sum("snapshot"."weight"), 0)
3515 FROM "issue" CROSS JOIN "opinion"
3516 JOIN "direct_interest_snapshot" AS "snapshot"
3517 ON "snapshot"."issue_id" = "issue"."id"
3518 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3519 AND "snapshot"."member_id" = "opinion"."member_id"
3520 WHERE "issue"."id" = "issue_id_p"
3521 AND "opinion"."suggestion_id" = "suggestion_id_v"
3522 AND "opinion"."degree" = 1
3523 AND "opinion"."fulfilled" = FALSE
3524 ),
3525 "plus1_fulfilled_count" = (
3526 SELECT coalesce(sum("snapshot"."weight"), 0)
3527 FROM "issue" CROSS JOIN "opinion"
3528 JOIN "direct_interest_snapshot" AS "snapshot"
3529 ON "snapshot"."issue_id" = "issue"."id"
3530 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3531 AND "snapshot"."member_id" = "opinion"."member_id"
3532 WHERE "issue"."id" = "issue_id_p"
3533 AND "opinion"."suggestion_id" = "suggestion_id_v"
3534 AND "opinion"."degree" = 1
3535 AND "opinion"."fulfilled" = TRUE
3536 ),
3537 "plus2_unfulfilled_count" = (
3538 SELECT coalesce(sum("snapshot"."weight"), 0)
3539 FROM "issue" CROSS JOIN "opinion"
3540 JOIN "direct_interest_snapshot" AS "snapshot"
3541 ON "snapshot"."issue_id" = "issue"."id"
3542 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3543 AND "snapshot"."member_id" = "opinion"."member_id"
3544 WHERE "issue"."id" = "issue_id_p"
3545 AND "opinion"."suggestion_id" = "suggestion_id_v"
3546 AND "opinion"."degree" = 2
3547 AND "opinion"."fulfilled" = FALSE
3548 ),
3549 "plus2_fulfilled_count" = (
3550 SELECT coalesce(sum("snapshot"."weight"), 0)
3551 FROM "issue" CROSS JOIN "opinion"
3552 JOIN "direct_interest_snapshot" AS "snapshot"
3553 ON "snapshot"."issue_id" = "issue"."id"
3554 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3555 AND "snapshot"."member_id" = "opinion"."member_id"
3556 WHERE "issue"."id" = "issue_id_p"
3557 AND "opinion"."suggestion_id" = "suggestion_id_v"
3558 AND "opinion"."degree" = 2
3559 AND "opinion"."fulfilled" = TRUE
3561 WHERE "suggestion"."id" = "suggestion_id_v";
3562 END LOOP;
3563 END LOOP;
3564 RETURN;
3565 END;
3566 $$;
3568 COMMENT ON FUNCTION "create_snapshot"
3569 ( "issue"."id"%TYPE )
3570 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.';
3573 CREATE FUNCTION "set_snapshot_event"
3574 ( "issue_id_p" "issue"."id"%TYPE,
3575 "event_p" "snapshot_event" )
3576 RETURNS VOID
3577 LANGUAGE 'plpgsql' VOLATILE AS $$
3578 DECLARE
3579 "event_v" "issue"."latest_snapshot_event"%TYPE;
3580 BEGIN
3581 PERFORM "require_transaction_isolation"();
3582 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3583 WHERE "id" = "issue_id_p" FOR UPDATE;
3584 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3585 WHERE "id" = "issue_id_p";
3586 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3587 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3588 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3589 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3590 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3591 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3592 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3593 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3594 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3595 FROM "initiative" -- NOTE: due to missing index on issue_id
3596 WHERE "initiative"."issue_id" = "issue_id_p"
3597 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3598 AND "direct_supporter_snapshot"."event" = "event_v";
3599 RETURN;
3600 END;
3601 $$;
3603 COMMENT ON FUNCTION "set_snapshot_event"
3604 ( "issue"."id"%TYPE,
3605 "snapshot_event" )
3606 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3610 -----------------------
3611 -- Counting of votes --
3612 -----------------------
3615 CREATE FUNCTION "weight_of_added_vote_delegations"
3616 ( "issue_id_p" "issue"."id"%TYPE,
3617 "member_id_p" "member"."id"%TYPE,
3618 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3619 RETURNS "direct_voter"."weight"%TYPE
3620 LANGUAGE 'plpgsql' VOLATILE AS $$
3621 DECLARE
3622 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3623 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3624 "weight_v" INT4;
3625 "sub_weight_v" INT4;
3626 BEGIN
3627 PERFORM "require_transaction_isolation"();
3628 "weight_v" := 0;
3629 FOR "issue_delegation_row" IN
3630 SELECT * FROM "issue_delegation"
3631 WHERE "trustee_id" = "member_id_p"
3632 AND "issue_id" = "issue_id_p"
3633 LOOP
3634 IF NOT EXISTS (
3635 SELECT NULL FROM "direct_voter"
3636 WHERE "member_id" = "issue_delegation_row"."truster_id"
3637 AND "issue_id" = "issue_id_p"
3638 ) AND NOT EXISTS (
3639 SELECT NULL FROM "delegating_voter"
3640 WHERE "member_id" = "issue_delegation_row"."truster_id"
3641 AND "issue_id" = "issue_id_p"
3642 ) THEN
3643 "delegate_member_ids_v" :=
3644 "member_id_p" || "delegate_member_ids_p";
3645 INSERT INTO "delegating_voter" (
3646 "issue_id",
3647 "member_id",
3648 "scope",
3649 "delegate_member_ids"
3650 ) VALUES (
3651 "issue_id_p",
3652 "issue_delegation_row"."truster_id",
3653 "issue_delegation_row"."scope",
3654 "delegate_member_ids_v"
3655 );
3656 "sub_weight_v" := 1 +
3657 "weight_of_added_vote_delegations"(
3658 "issue_id_p",
3659 "issue_delegation_row"."truster_id",
3660 "delegate_member_ids_v"
3661 );
3662 UPDATE "delegating_voter"
3663 SET "weight" = "sub_weight_v"
3664 WHERE "issue_id" = "issue_id_p"
3665 AND "member_id" = "issue_delegation_row"."truster_id";
3666 "weight_v" := "weight_v" + "sub_weight_v";
3667 END IF;
3668 END LOOP;
3669 RETURN "weight_v";
3670 END;
3671 $$;
3673 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3674 ( "issue"."id"%TYPE,
3675 "member"."id"%TYPE,
3676 "delegating_voter"."delegate_member_ids"%TYPE )
3677 IS 'Helper function for "add_vote_delegations" function';
3680 CREATE FUNCTION "add_vote_delegations"
3681 ( "issue_id_p" "issue"."id"%TYPE )
3682 RETURNS VOID
3683 LANGUAGE 'plpgsql' VOLATILE AS $$
3684 DECLARE
3685 "member_id_v" "member"."id"%TYPE;
3686 BEGIN
3687 PERFORM "require_transaction_isolation"();
3688 FOR "member_id_v" IN
3689 SELECT "member_id" FROM "direct_voter"
3690 WHERE "issue_id" = "issue_id_p"
3691 LOOP
3692 UPDATE "direct_voter" SET
3693 "weight" = "weight" + "weight_of_added_vote_delegations"(
3694 "issue_id_p",
3695 "member_id_v",
3696 '{}'
3698 WHERE "member_id" = "member_id_v"
3699 AND "issue_id" = "issue_id_p";
3700 END LOOP;
3701 RETURN;
3702 END;
3703 $$;
3705 COMMENT ON FUNCTION "add_vote_delegations"
3706 ( "issue_id_p" "issue"."id"%TYPE )
3707 IS 'Helper function for "close_voting" function';
3710 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3711 RETURNS VOID
3712 LANGUAGE 'plpgsql' VOLATILE AS $$
3713 DECLARE
3714 "area_id_v" "area"."id"%TYPE;
3715 "unit_id_v" "unit"."id"%TYPE;
3716 "member_id_v" "member"."id"%TYPE;
3717 BEGIN
3718 PERFORM "require_transaction_isolation"();
3719 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3720 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3721 -- override protection triggers:
3722 INSERT INTO "temporary_transaction_data" ("key", "value")
3723 VALUES ('override_protection_triggers', TRUE::TEXT);
3724 -- delete timestamp of voting comment:
3725 UPDATE "direct_voter" SET "comment_changed" = NULL
3726 WHERE "issue_id" = "issue_id_p";
3727 -- delete delegating votes (in cases of manual reset of issue state):
3728 DELETE FROM "delegating_voter"
3729 WHERE "issue_id" = "issue_id_p";
3730 -- delete votes from non-privileged voters:
3731 DELETE FROM "direct_voter"
3732 USING (
3733 SELECT
3734 "direct_voter"."member_id"
3735 FROM "direct_voter"
3736 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3737 LEFT JOIN "privilege"
3738 ON "privilege"."unit_id" = "unit_id_v"
3739 AND "privilege"."member_id" = "direct_voter"."member_id"
3740 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3741 "member"."active" = FALSE OR
3742 "privilege"."voting_right" ISNULL OR
3743 "privilege"."voting_right" = FALSE
3745 ) AS "subquery"
3746 WHERE "direct_voter"."issue_id" = "issue_id_p"
3747 AND "direct_voter"."member_id" = "subquery"."member_id";
3748 -- consider delegations:
3749 UPDATE "direct_voter" SET "weight" = 1
3750 WHERE "issue_id" = "issue_id_p";
3751 PERFORM "add_vote_delegations"("issue_id_p");
3752 -- mark first preferences:
3753 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
3754 FROM (
3755 SELECT
3756 "vote"."initiative_id",
3757 "vote"."member_id",
3758 CASE WHEN "vote"."grade" > 0 THEN
3759 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
3760 ELSE NULL
3761 END AS "first_preference"
3762 FROM "vote"
3763 JOIN "initiative" -- NOTE: due to missing index on issue_id
3764 ON "vote"."issue_id" = "initiative"."issue_id"
3765 JOIN "vote" AS "agg"
3766 ON "initiative"."id" = "agg"."initiative_id"
3767 AND "vote"."member_id" = "agg"."member_id"
3768 GROUP BY "vote"."initiative_id", "vote"."member_id"
3769 ) AS "subquery"
3770 WHERE "vote"."issue_id" = "issue_id_p"
3771 AND "vote"."initiative_id" = "subquery"."initiative_id"
3772 AND "vote"."member_id" = "subquery"."member_id";
3773 -- finish overriding protection triggers (avoids garbage):
3774 DELETE FROM "temporary_transaction_data"
3775 WHERE "key" = 'override_protection_triggers';
3776 -- materialize battle_view:
3777 -- NOTE: "closed" column of issue must be set at this point
3778 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3779 INSERT INTO "battle" (
3780 "issue_id",
3781 "winning_initiative_id", "losing_initiative_id",
3782 "count"
3783 ) SELECT
3784 "issue_id",
3785 "winning_initiative_id", "losing_initiative_id",
3786 "count"
3787 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3788 -- set voter count:
3789 UPDATE "issue" SET
3790 "voter_count" = (
3791 SELECT coalesce(sum("weight"), 0)
3792 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3794 WHERE "id" = "issue_id_p";
3795 -- calculate "first_preference_votes":
3796 UPDATE "initiative"
3797 SET "first_preference_votes" = coalesce("subquery"."sum", 0)
3798 FROM (
3799 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
3800 FROM "vote" JOIN "direct_voter"
3801 ON "vote"."issue_id" = "direct_voter"."issue_id"
3802 AND "vote"."member_id" = "direct_voter"."member_id"
3803 WHERE "vote"."first_preference"
3804 GROUP BY "vote"."initiative_id"
3805 ) AS "subquery"
3806 WHERE "initiative"."issue_id" = "issue_id_p"
3807 AND "initiative"."admitted"
3808 AND "initiative"."id" = "subquery"."initiative_id";
3809 -- copy "positive_votes" and "negative_votes" from "battle" table:
3810 UPDATE "initiative" SET
3811 "positive_votes" = "battle_win"."count",
3812 "negative_votes" = "battle_lose"."count"
3813 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3814 WHERE
3815 "battle_win"."issue_id" = "issue_id_p" AND
3816 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3817 "battle_win"."losing_initiative_id" ISNULL AND
3818 "battle_lose"."issue_id" = "issue_id_p" AND
3819 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3820 "battle_lose"."winning_initiative_id" ISNULL;
3821 END;
3822 $$;
3824 COMMENT ON FUNCTION "close_voting"
3825 ( "issue"."id"%TYPE )
3826 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.';
3829 CREATE FUNCTION "defeat_strength"
3830 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3831 RETURNS INT8
3832 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3833 BEGIN
3834 IF "positive_votes_p" > "negative_votes_p" THEN
3835 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3836 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3837 RETURN 0;
3838 ELSE
3839 RETURN -1;
3840 END IF;
3841 END;
3842 $$;
3844 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';
3847 CREATE FUNCTION "secondary_link_strength"
3848 ( "initiative_id1_p" "initiative"."id"%TYPE,
3849 "initiative_id2_p" "initiative"."id"%TYPE )
3850 RETURNS INT8
3851 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3852 BEGIN
3853 IF "initiative_id1_p" = "initiative_id2_p" THEN
3854 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
3855 END IF;
3856 RETURN (
3857 CASE WHEN "initiative_id1_p" < "initiative_id2_p" THEN
3858 1::INT8 << 62
3859 ELSE 0 END
3860 - ("initiative_id1_p"::INT8 << 31)
3861 + "initiative_id2_p"::INT8
3862 );
3863 END;
3864 $$;
3866 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4) IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
3869 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3870 RETURNS VOID
3871 LANGUAGE 'plpgsql' VOLATILE AS $$
3872 DECLARE
3873 "issue_row" "issue"%ROWTYPE;
3874 "policy_row" "policy"%ROWTYPE;
3875 "dimension_v" INTEGER;
3876 "vote_matrix" INT4[][]; -- absolute votes
3877 "matrix" INT8[][]; -- defeat strength / best paths
3878 "i" INTEGER;
3879 "j" INTEGER;
3880 "k" INTEGER;
3881 "battle_row" "battle"%ROWTYPE;
3882 "rank_ary" INT4[];
3883 "rank_v" INT4;
3884 "initiative_id_v" "initiative"."id"%TYPE;
3885 BEGIN
3886 PERFORM "require_transaction_isolation"();
3887 SELECT * INTO "issue_row"
3888 FROM "issue" WHERE "id" = "issue_id_p";
3889 SELECT * INTO "policy_row"
3890 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3891 SELECT count(1) INTO "dimension_v"
3892 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3893 -- Create "vote_matrix" with absolute number of votes in pairwise
3894 -- comparison:
3895 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3896 "i" := 1;
3897 "j" := 2;
3898 FOR "battle_row" IN
3899 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3900 ORDER BY
3901 "winning_initiative_id" NULLS FIRST,
3902 "losing_initiative_id" NULLS FIRST
3903 LOOP
3904 "vote_matrix"["i"]["j"] := "battle_row"."count";
3905 IF "j" = "dimension_v" THEN
3906 "i" := "i" + 1;
3907 "j" := 1;
3908 ELSE
3909 "j" := "j" + 1;
3910 IF "j" = "i" THEN
3911 "j" := "j" + 1;
3912 END IF;
3913 END IF;
3914 END LOOP;
3915 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3916 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3917 END IF;
3918 -- Store defeat strengths in "matrix" using "defeat_strength"
3919 -- function:
3920 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3921 "i" := 1;
3922 LOOP
3923 "j" := 1;
3924 LOOP
3925 IF "i" != "j" THEN
3926 "matrix"["i"]["j"] := "defeat_strength"(
3927 "vote_matrix"["i"]["j"],
3928 "vote_matrix"["j"]["i"]
3929 );
3930 END IF;
3931 EXIT WHEN "j" = "dimension_v";
3932 "j" := "j" + 1;
3933 END LOOP;
3934 EXIT WHEN "i" = "dimension_v";
3935 "i" := "i" + 1;
3936 END LOOP;
3937 -- Find best paths:
3938 "i" := 1;
3939 LOOP
3940 "j" := 1;
3941 LOOP
3942 IF "i" != "j" THEN
3943 "k" := 1;
3944 LOOP
3945 IF "i" != "k" AND "j" != "k" THEN
3946 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3947 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3948 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3949 END IF;
3950 ELSE
3951 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3952 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3953 END IF;
3954 END IF;
3955 END IF;
3956 EXIT WHEN "k" = "dimension_v";
3957 "k" := "k" + 1;
3958 END LOOP;
3959 END IF;
3960 EXIT WHEN "j" = "dimension_v";
3961 "j" := "j" + 1;
3962 END LOOP;
3963 EXIT WHEN "i" = "dimension_v";
3964 "i" := "i" + 1;
3965 END LOOP;
3966 -- Determine order of winners:
3967 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3968 "rank_v" := 1;
3969 LOOP
3970 "i" := 1;
3971 LOOP
3972 IF "rank_ary"["i"] ISNULL THEN
3973 "j" := 1;
3974 LOOP
3975 IF
3976 "i" != "j" AND
3977 "rank_ary"["j"] ISNULL AND
3978 ( "matrix"["j"]["i"] > "matrix"["i"]["j"] OR
3979 -- tie-breaking by "id"
3980 ( "matrix"["j"]["i"] = "matrix"["i"]["j"] AND
3981 "j" < "i" ) )
3982 THEN
3983 -- someone else is better
3984 EXIT;
3985 END IF;
3986 "j" := "j" + 1;
3987 IF "j" = "dimension_v" + 1 THEN
3988 -- noone is better
3989 "rank_ary"["i"] := "rank_v";
3990 EXIT;
3991 END IF;
3992 END LOOP;
3993 EXIT WHEN "j" = "dimension_v" + 1;
3994 END IF;
3995 "i" := "i" + 1;
3996 IF "i" > "dimension_v" THEN
3997 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
3998 END IF;
3999 END LOOP;
4000 EXIT WHEN "rank_v" = "dimension_v";
4001 "rank_v" := "rank_v" + 1;
4002 END LOOP;
4003 -- write preliminary results:
4004 "i" := 2; -- omit status quo with "i" = 1
4005 FOR "initiative_id_v" IN
4006 SELECT "id" FROM "initiative"
4007 WHERE "issue_id" = "issue_id_p" AND "admitted"
4008 ORDER BY "id"
4009 LOOP
4010 UPDATE "initiative" SET
4011 "direct_majority" =
4012 CASE WHEN "policy_row"."direct_majority_strict" THEN
4013 "positive_votes" * "policy_row"."direct_majority_den" >
4014 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4015 ELSE
4016 "positive_votes" * "policy_row"."direct_majority_den" >=
4017 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4018 END
4019 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4020 AND "issue_row"."voter_count"-"negative_votes" >=
4021 "policy_row"."direct_majority_non_negative",
4022 "indirect_majority" =
4023 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4024 "positive_votes" * "policy_row"."indirect_majority_den" >
4025 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4026 ELSE
4027 "positive_votes" * "policy_row"."indirect_majority_den" >=
4028 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4029 END
4030 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4031 AND "issue_row"."voter_count"-"negative_votes" >=
4032 "policy_row"."indirect_majority_non_negative",
4033 "schulze_rank" = "rank_ary"["i"],
4034 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
4035 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
4036 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
4037 "reverse_beat_path" = "matrix"[1]["i"] >= 0,
4038 "eligible" = FALSE,
4039 "winner" = FALSE,
4040 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4041 WHERE "id" = "initiative_id_v";
4042 "i" := "i" + 1;
4043 END LOOP;
4044 IF "i" != "dimension_v" + 1 THEN
4045 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4046 END IF;
4047 -- take indirect majorities into account:
4048 LOOP
4049 UPDATE "initiative" SET "indirect_majority" = TRUE
4050 FROM (
4051 SELECT "new_initiative"."id" AS "initiative_id"
4052 FROM "initiative" "old_initiative"
4053 JOIN "initiative" "new_initiative"
4054 ON "new_initiative"."issue_id" = "issue_id_p"
4055 AND "new_initiative"."indirect_majority" = FALSE
4056 JOIN "battle" "battle_win"
4057 ON "battle_win"."issue_id" = "issue_id_p"
4058 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4059 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4060 JOIN "battle" "battle_lose"
4061 ON "battle_lose"."issue_id" = "issue_id_p"
4062 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4063 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4064 WHERE "old_initiative"."issue_id" = "issue_id_p"
4065 AND "old_initiative"."indirect_majority" = TRUE
4066 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4067 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4068 "policy_row"."indirect_majority_num" *
4069 ("battle_win"."count"+"battle_lose"."count")
4070 ELSE
4071 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4072 "policy_row"."indirect_majority_num" *
4073 ("battle_win"."count"+"battle_lose"."count")
4074 END
4075 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4076 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4077 "policy_row"."indirect_majority_non_negative"
4078 ) AS "subquery"
4079 WHERE "id" = "subquery"."initiative_id";
4080 EXIT WHEN NOT FOUND;
4081 END LOOP;
4082 -- set "multistage_majority" for remaining matching initiatives:
4083 UPDATE "initiative" SET "multistage_majority" = TRUE
4084 FROM (
4085 SELECT "losing_initiative"."id" AS "initiative_id"
4086 FROM "initiative" "losing_initiative"
4087 JOIN "initiative" "winning_initiative"
4088 ON "winning_initiative"."issue_id" = "issue_id_p"
4089 AND "winning_initiative"."admitted"
4090 JOIN "battle" "battle_win"
4091 ON "battle_win"."issue_id" = "issue_id_p"
4092 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4093 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4094 JOIN "battle" "battle_lose"
4095 ON "battle_lose"."issue_id" = "issue_id_p"
4096 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4097 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4098 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4099 AND "losing_initiative"."admitted"
4100 AND "winning_initiative"."schulze_rank" <
4101 "losing_initiative"."schulze_rank"
4102 AND "battle_win"."count" > "battle_lose"."count"
4103 AND (
4104 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4105 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4106 ) AS "subquery"
4107 WHERE "id" = "subquery"."initiative_id";
4108 -- mark eligible initiatives:
4109 UPDATE "initiative" SET "eligible" = TRUE
4110 WHERE "issue_id" = "issue_id_p"
4111 AND "initiative"."direct_majority"
4112 AND "initiative"."indirect_majority"
4113 AND "initiative"."better_than_status_quo"
4114 AND (
4115 "policy_row"."no_multistage_majority" = FALSE OR
4116 "initiative"."multistage_majority" = FALSE )
4117 AND (
4118 "policy_row"."no_reverse_beat_path" = FALSE OR
4119 "initiative"."reverse_beat_path" = FALSE );
4120 -- mark final winner:
4121 UPDATE "initiative" SET "winner" = TRUE
4122 FROM (
4123 SELECT "id" AS "initiative_id"
4124 FROM "initiative"
4125 WHERE "issue_id" = "issue_id_p" AND "eligible"
4126 ORDER BY
4127 "schulze_rank",
4128 "id"
4129 LIMIT 1
4130 ) AS "subquery"
4131 WHERE "id" = "subquery"."initiative_id";
4132 -- write (final) ranks:
4133 "rank_v" := 1;
4134 FOR "initiative_id_v" IN
4135 SELECT "id"
4136 FROM "initiative"
4137 WHERE "issue_id" = "issue_id_p" AND "admitted"
4138 ORDER BY
4139 "winner" DESC,
4140 "eligible" DESC,
4141 "schulze_rank",
4142 "id"
4143 LOOP
4144 UPDATE "initiative" SET "rank" = "rank_v"
4145 WHERE "id" = "initiative_id_v";
4146 "rank_v" := "rank_v" + 1;
4147 END LOOP;
4148 -- set schulze rank of status quo and mark issue as finished:
4149 UPDATE "issue" SET
4150 "status_quo_schulze_rank" = "rank_ary"[1],
4151 "state" =
4152 CASE WHEN EXISTS (
4153 SELECT NULL FROM "initiative"
4154 WHERE "issue_id" = "issue_id_p" AND "winner"
4155 ) THEN
4156 'finished_with_winner'::"issue_state"
4157 ELSE
4158 'finished_without_winner'::"issue_state"
4159 END,
4160 "closed" = "phase_finished",
4161 "phase_finished" = NULL
4162 WHERE "id" = "issue_id_p";
4163 RETURN;
4164 END;
4165 $$;
4167 COMMENT ON FUNCTION "calculate_ranks"
4168 ( "issue"."id"%TYPE )
4169 IS 'Determine ranking (Votes have to be counted first)';
4173 -----------------------------
4174 -- Automatic state changes --
4175 -----------------------------
4178 CREATE TYPE "check_issue_persistence" AS (
4179 "state" "issue_state",
4180 "phase_finished" BOOLEAN,
4181 "issue_revoked" BOOLEAN,
4182 "snapshot_created" BOOLEAN,
4183 "harmonic_weights_set" BOOLEAN,
4184 "closed_voting" BOOLEAN );
4186 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';
4189 CREATE FUNCTION "check_issue"
4190 ( "issue_id_p" "issue"."id"%TYPE,
4191 "persist" "check_issue_persistence" )
4192 RETURNS "check_issue_persistence"
4193 LANGUAGE 'plpgsql' VOLATILE AS $$
4194 DECLARE
4195 "issue_row" "issue"%ROWTYPE;
4196 "policy_row" "policy"%ROWTYPE;
4197 "initiative_row" "initiative"%ROWTYPE;
4198 "state_v" "issue_state";
4199 BEGIN
4200 PERFORM "require_transaction_isolation"();
4201 IF "persist" ISNULL THEN
4202 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4203 FOR UPDATE;
4204 IF "issue_row"."closed" NOTNULL THEN
4205 RETURN NULL;
4206 END IF;
4207 "persist"."state" := "issue_row"."state";
4208 IF
4209 ( "issue_row"."state" = 'admission' AND now() >=
4210 "issue_row"."created" + "issue_row"."admission_time" ) OR
4211 ( "issue_row"."state" = 'discussion' AND now() >=
4212 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4213 ( "issue_row"."state" = 'verification' AND now() >=
4214 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4215 ( "issue_row"."state" = 'voting' AND now() >=
4216 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4217 THEN
4218 "persist"."phase_finished" := TRUE;
4219 ELSE
4220 "persist"."phase_finished" := FALSE;
4221 END IF;
4222 IF
4223 NOT EXISTS (
4224 -- all initiatives are revoked
4225 SELECT NULL FROM "initiative"
4226 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4227 ) AND (
4228 -- and issue has not been accepted yet
4229 "persist"."state" = 'admission' OR
4230 -- or verification time has elapsed
4231 ( "persist"."state" = 'verification' AND
4232 "persist"."phase_finished" ) OR
4233 -- or no initiatives have been revoked lately
4234 NOT EXISTS (
4235 SELECT NULL FROM "initiative"
4236 WHERE "issue_id" = "issue_id_p"
4237 AND now() < "revoked" + "issue_row"."verification_time"
4240 THEN
4241 "persist"."issue_revoked" := TRUE;
4242 ELSE
4243 "persist"."issue_revoked" := FALSE;
4244 END IF;
4245 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4246 UPDATE "issue" SET "phase_finished" = now()
4247 WHERE "id" = "issue_row"."id";
4248 RETURN "persist";
4249 ELSIF
4250 "persist"."state" IN ('admission', 'discussion', 'verification')
4251 THEN
4252 RETURN "persist";
4253 ELSE
4254 RETURN NULL;
4255 END IF;
4256 END IF;
4257 IF
4258 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4259 coalesce("persist"."snapshot_created", FALSE) = FALSE
4260 THEN
4261 PERFORM "create_snapshot"("issue_id_p");
4262 "persist"."snapshot_created" = TRUE;
4263 IF "persist"."phase_finished" THEN
4264 IF "persist"."state" = 'admission' THEN
4265 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4266 ELSIF "persist"."state" = 'discussion' THEN
4267 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4268 ELSIF "persist"."state" = 'verification' THEN
4269 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4270 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4271 SELECT * INTO "policy_row" FROM "policy"
4272 WHERE "id" = "issue_row"."policy_id";
4273 FOR "initiative_row" IN
4274 SELECT * FROM "initiative"
4275 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4276 FOR UPDATE
4277 LOOP
4278 IF
4279 "initiative_row"."polling" OR (
4280 "initiative_row"."satisfied_supporter_count" > 0 AND
4281 "initiative_row"."satisfied_supporter_count" *
4282 "policy_row"."initiative_quorum_den" >=
4283 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4285 THEN
4286 UPDATE "initiative" SET "admitted" = TRUE
4287 WHERE "id" = "initiative_row"."id";
4288 ELSE
4289 UPDATE "initiative" SET "admitted" = FALSE
4290 WHERE "id" = "initiative_row"."id";
4291 END IF;
4292 END LOOP;
4293 END IF;
4294 END IF;
4295 RETURN "persist";
4296 END IF;
4297 IF
4298 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4299 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4300 THEN
4301 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4302 "persist"."harmonic_weights_set" = TRUE;
4303 IF
4304 "persist"."phase_finished" OR
4305 "persist"."issue_revoked" OR
4306 "persist"."state" = 'admission'
4307 THEN
4308 RETURN "persist";
4309 ELSE
4310 RETURN NULL;
4311 END IF;
4312 END IF;
4313 IF "persist"."issue_revoked" THEN
4314 IF "persist"."state" = 'admission' THEN
4315 "state_v" := 'canceled_revoked_before_accepted';
4316 ELSIF "persist"."state" = 'discussion' THEN
4317 "state_v" := 'canceled_after_revocation_during_discussion';
4318 ELSIF "persist"."state" = 'verification' THEN
4319 "state_v" := 'canceled_after_revocation_during_verification';
4320 END IF;
4321 UPDATE "issue" SET
4322 "state" = "state_v",
4323 "closed" = "phase_finished",
4324 "phase_finished" = NULL
4325 WHERE "id" = "issue_id_p";
4326 RETURN NULL;
4327 END IF;
4328 IF "persist"."state" = 'admission' THEN
4329 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4330 FOR UPDATE;
4331 SELECT * INTO "policy_row"
4332 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4333 IF EXISTS (
4334 SELECT NULL FROM "initiative"
4335 WHERE "issue_id" = "issue_id_p"
4336 AND "supporter_count" > 0
4337 AND "supporter_count" * "policy_row"."issue_quorum_den"
4338 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4339 ) THEN
4340 UPDATE "issue" SET
4341 "state" = 'discussion',
4342 "accepted" = coalesce("phase_finished", now()),
4343 "phase_finished" = NULL
4344 WHERE "id" = "issue_id_p";
4345 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4346 UPDATE "issue" SET
4347 "state" = 'canceled_issue_not_accepted',
4348 "closed" = "phase_finished",
4349 "phase_finished" = NULL
4350 WHERE "id" = "issue_id_p";
4351 END IF;
4352 RETURN NULL;
4353 END IF;
4354 IF "persist"."phase_finished" THEN
4355 if "persist"."state" = 'discussion' THEN
4356 UPDATE "issue" SET
4357 "state" = 'verification',
4358 "half_frozen" = "phase_finished",
4359 "phase_finished" = NULL
4360 WHERE "id" = "issue_id_p";
4361 RETURN NULL;
4362 END IF;
4363 IF "persist"."state" = 'verification' THEN
4364 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4365 FOR UPDATE;
4366 SELECT * INTO "policy_row" FROM "policy"
4367 WHERE "id" = "issue_row"."policy_id";
4368 IF EXISTS (
4369 SELECT NULL FROM "initiative"
4370 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4371 ) THEN
4372 UPDATE "issue" SET
4373 "state" = 'voting',
4374 "fully_frozen" = "phase_finished",
4375 "phase_finished" = NULL
4376 WHERE "id" = "issue_id_p";
4377 ELSE
4378 UPDATE "issue" SET
4379 "state" = 'canceled_no_initiative_admitted',
4380 "fully_frozen" = "phase_finished",
4381 "closed" = "phase_finished",
4382 "phase_finished" = NULL
4383 WHERE "id" = "issue_id_p";
4384 -- NOTE: The following DELETE statements have effect only when
4385 -- issue state has been manipulated
4386 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4387 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4388 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4389 END IF;
4390 RETURN NULL;
4391 END IF;
4392 IF "persist"."state" = 'voting' THEN
4393 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4394 PERFORM "close_voting"("issue_id_p");
4395 "persist"."closed_voting" = TRUE;
4396 RETURN "persist";
4397 END IF;
4398 PERFORM "calculate_ranks"("issue_id_p");
4399 RETURN NULL;
4400 END IF;
4401 END IF;
4402 RAISE WARNING 'should not happen';
4403 RETURN NULL;
4404 END;
4405 $$;
4407 COMMENT ON FUNCTION "check_issue"
4408 ( "issue"."id"%TYPE,
4409 "check_issue_persistence" )
4410 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")';
4413 CREATE FUNCTION "check_everything"()
4414 RETURNS VOID
4415 LANGUAGE 'plpgsql' VOLATILE AS $$
4416 DECLARE
4417 "issue_id_v" "issue"."id"%TYPE;
4418 "persist_v" "check_issue_persistence";
4419 BEGIN
4420 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4421 DELETE FROM "expired_session";
4422 PERFORM "check_activity"();
4423 PERFORM "calculate_member_counts"();
4424 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4425 "persist_v" := NULL;
4426 LOOP
4427 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4428 EXIT WHEN "persist_v" ISNULL;
4429 END LOOP;
4430 END LOOP;
4431 RETURN;
4432 END;
4433 $$;
4435 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.';
4439 ----------------------
4440 -- Deletion of data --
4441 ----------------------
4444 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4445 RETURNS VOID
4446 LANGUAGE 'plpgsql' VOLATILE AS $$
4447 BEGIN
4448 IF EXISTS (
4449 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
4450 ) THEN
4451 -- override protection triggers:
4452 INSERT INTO "temporary_transaction_data" ("key", "value")
4453 VALUES ('override_protection_triggers', TRUE::TEXT);
4454 -- clean data:
4455 DELETE FROM "delegating_voter"
4456 WHERE "issue_id" = "issue_id_p";
4457 DELETE FROM "direct_voter"
4458 WHERE "issue_id" = "issue_id_p";
4459 DELETE FROM "delegating_interest_snapshot"
4460 WHERE "issue_id" = "issue_id_p";
4461 DELETE FROM "direct_interest_snapshot"
4462 WHERE "issue_id" = "issue_id_p";
4463 DELETE FROM "delegating_population_snapshot"
4464 WHERE "issue_id" = "issue_id_p";
4465 DELETE FROM "direct_population_snapshot"
4466 WHERE "issue_id" = "issue_id_p";
4467 DELETE FROM "non_voter"
4468 WHERE "issue_id" = "issue_id_p";
4469 DELETE FROM "delegation"
4470 WHERE "issue_id" = "issue_id_p";
4471 DELETE FROM "supporter"
4472 USING "initiative" -- NOTE: due to missing index on issue_id
4473 WHERE "initiative"."issue_id" = "issue_id_p"
4474 AND "supporter"."initiative_id" = "initiative_id";
4475 -- mark issue as cleaned:
4476 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
4477 -- finish overriding protection triggers (avoids garbage):
4478 DELETE FROM "temporary_transaction_data"
4479 WHERE "key" = 'override_protection_triggers';
4480 END IF;
4481 RETURN;
4482 END;
4483 $$;
4485 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4488 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4489 RETURNS VOID
4490 LANGUAGE 'plpgsql' VOLATILE AS $$
4491 BEGIN
4492 UPDATE "member" SET
4493 "last_login" = NULL,
4494 "last_delegation_check" = NULL,
4495 "login" = NULL,
4496 "password" = NULL,
4497 "locked" = TRUE,
4498 "active" = FALSE,
4499 "notify_email" = NULL,
4500 "notify_email_unconfirmed" = NULL,
4501 "notify_email_secret" = NULL,
4502 "notify_email_secret_expiry" = NULL,
4503 "notify_email_lock_expiry" = NULL,
4504 "login_recovery_expiry" = NULL,
4505 "password_reset_secret" = NULL,
4506 "password_reset_secret_expiry" = NULL,
4507 "organizational_unit" = NULL,
4508 "internal_posts" = NULL,
4509 "realname" = NULL,
4510 "birthday" = NULL,
4511 "address" = NULL,
4512 "email" = NULL,
4513 "xmpp_address" = NULL,
4514 "website" = NULL,
4515 "phone" = NULL,
4516 "mobile_phone" = NULL,
4517 "profession" = NULL,
4518 "external_memberships" = NULL,
4519 "external_posts" = NULL,
4520 "statement" = NULL
4521 WHERE "id" = "member_id_p";
4522 -- "text_search_data" is updated by triggers
4523 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4524 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4525 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4526 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4527 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4528 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4529 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4530 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4531 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4532 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4533 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4534 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4535 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4536 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4537 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4538 DELETE FROM "direct_voter" USING "issue"
4539 WHERE "direct_voter"."issue_id" = "issue"."id"
4540 AND "issue"."closed" ISNULL
4541 AND "member_id" = "member_id_p";
4542 RETURN;
4543 END;
4544 $$;
4546 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)';
4549 CREATE FUNCTION "delete_private_data"()
4550 RETURNS VOID
4551 LANGUAGE 'plpgsql' VOLATILE AS $$
4552 BEGIN
4553 DELETE FROM "temporary_transaction_data";
4554 DELETE FROM "member" WHERE "activated" ISNULL;
4555 UPDATE "member" SET
4556 "invite_code" = NULL,
4557 "invite_code_expiry" = NULL,
4558 "admin_comment" = NULL,
4559 "last_login" = NULL,
4560 "last_delegation_check" = NULL,
4561 "login" = NULL,
4562 "password" = NULL,
4563 "lang" = NULL,
4564 "notify_email" = NULL,
4565 "notify_email_unconfirmed" = NULL,
4566 "notify_email_secret" = NULL,
4567 "notify_email_secret_expiry" = NULL,
4568 "notify_email_lock_expiry" = NULL,
4569 "notify_level" = NULL,
4570 "login_recovery_expiry" = NULL,
4571 "password_reset_secret" = NULL,
4572 "password_reset_secret_expiry" = NULL,
4573 "organizational_unit" = NULL,
4574 "internal_posts" = NULL,
4575 "realname" = NULL,
4576 "birthday" = NULL,
4577 "address" = NULL,
4578 "email" = NULL,
4579 "xmpp_address" = NULL,
4580 "website" = NULL,
4581 "phone" = NULL,
4582 "mobile_phone" = NULL,
4583 "profession" = NULL,
4584 "external_memberships" = NULL,
4585 "external_posts" = NULL,
4586 "formatting_engine" = NULL,
4587 "statement" = NULL;
4588 -- "text_search_data" is updated by triggers
4589 DELETE FROM "setting";
4590 DELETE FROM "setting_map";
4591 DELETE FROM "member_relation_setting";
4592 DELETE FROM "member_image";
4593 DELETE FROM "contact";
4594 DELETE FROM "ignored_member";
4595 DELETE FROM "session";
4596 DELETE FROM "area_setting";
4597 DELETE FROM "issue_setting";
4598 DELETE FROM "ignored_initiative";
4599 DELETE FROM "initiative_setting";
4600 DELETE FROM "suggestion_setting";
4601 DELETE FROM "non_voter";
4602 DELETE FROM "direct_voter" USING "issue"
4603 WHERE "direct_voter"."issue_id" = "issue"."id"
4604 AND "issue"."closed" ISNULL;
4605 RETURN;
4606 END;
4607 $$;
4609 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.';
4613 COMMIT;

Impressum / About Us