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