liquid_feedback_core

view core.sql @ 350:49c25dbc27bc

Added reminder to make backups before installing updates
author jbe
date Sun Mar 10 19:50:18 2013 +0100 (2013-03-10)
parents a5d4df7f4e22
children 98c14d8d07f1
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 (
525 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
526 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
527 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
528 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
529 ) AND (
530 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
531 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
532 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
533 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
534 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
535 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
536 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
537 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
538 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
539 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
540 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
541 )),
542 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
543 "phase_finished" ISNULL OR "closed" ISNULL ),
544 CONSTRAINT "state_change_order" CHECK (
545 "created" <= "accepted" AND
546 "accepted" <= "half_frozen" AND
547 "half_frozen" <= "fully_frozen" AND
548 "fully_frozen" <= "closed" ),
549 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
550 "cleaned" ISNULL OR "closed" NOTNULL ),
551 CONSTRAINT "last_snapshot_on_full_freeze"
552 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
553 CONSTRAINT "freeze_requires_snapshot"
554 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
555 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
556 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
557 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
558 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
559 CREATE INDEX "issue_created_idx" ON "issue" ("created");
560 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
561 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
562 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
563 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
564 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
565 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
567 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
569 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';
570 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
571 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.';
572 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.';
573 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.';
574 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
575 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
576 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
577 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
578 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
579 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
580 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';
581 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
582 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';
583 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
586 CREATE TABLE "issue_setting" (
587 PRIMARY KEY ("member_id", "key", "issue_id"),
588 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
589 "key" TEXT NOT NULL,
590 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
591 "value" TEXT NOT NULL );
593 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
596 CREATE TABLE "initiative" (
597 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
598 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
599 "id" SERIAL4 PRIMARY KEY,
600 "name" TEXT NOT NULL,
601 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
602 "discussion_url" TEXT,
603 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
604 "revoked" TIMESTAMPTZ,
605 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
606 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
607 "admitted" BOOLEAN,
608 "supporter_count" INT4,
609 "informed_supporter_count" INT4,
610 "satisfied_supporter_count" INT4,
611 "satisfied_informed_supporter_count" INT4,
612 "harmonic_weight" NUMERIC(12, 3),
613 "positive_votes" INT4,
614 "negative_votes" INT4,
615 "direct_majority" BOOLEAN,
616 "indirect_majority" BOOLEAN,
617 "schulze_rank" INT4,
618 "better_than_status_quo" BOOLEAN,
619 "worse_than_status_quo" BOOLEAN,
620 "reverse_beat_path" BOOLEAN,
621 "multistage_majority" BOOLEAN,
622 "eligible" BOOLEAN,
623 "winner" BOOLEAN,
624 "rank" INT4,
625 "text_search_data" TSVECTOR,
626 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
627 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
628 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
629 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
630 CONSTRAINT "revoked_initiatives_cant_be_admitted"
631 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
632 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
633 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
634 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
635 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
636 "schulze_rank" ISNULL AND
637 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
638 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
639 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
640 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
641 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
642 "eligible" = FALSE OR
643 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
644 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
645 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
646 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
647 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
648 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
649 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
650 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
651 CREATE TRIGGER "update_text_search_data"
652 BEFORE INSERT OR UPDATE ON "initiative"
653 FOR EACH ROW EXECUTE PROCEDURE
654 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
655 "name", "discussion_url");
657 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.';
659 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
660 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
661 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
662 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
663 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
664 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
665 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
666 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
667 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
668 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';
669 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
670 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
671 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"';
672 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
673 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
674 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
675 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
676 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';
677 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';
678 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"';
679 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
680 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';
683 CREATE TABLE "battle" (
684 "issue_id" INT4 NOT NULL,
685 "winning_initiative_id" INT4,
686 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
687 "losing_initiative_id" INT4,
688 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
689 "count" INT4 NOT NULL,
690 CONSTRAINT "initiative_ids_not_equal" CHECK (
691 "winning_initiative_id" != "losing_initiative_id" OR
692 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
693 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
694 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
695 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
696 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
698 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';
701 CREATE TABLE "ignored_initiative" (
702 PRIMARY KEY ("initiative_id", "member_id"),
703 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
704 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
705 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
707 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
710 CREATE TABLE "initiative_setting" (
711 PRIMARY KEY ("member_id", "key", "initiative_id"),
712 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
713 "key" TEXT NOT NULL,
714 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
715 "value" TEXT NOT NULL );
717 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
720 CREATE TABLE "draft" (
721 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
722 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
723 "id" SERIAL8 PRIMARY KEY,
724 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
725 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
726 "formatting_engine" TEXT,
727 "content" TEXT NOT NULL,
728 "text_search_data" TSVECTOR );
729 CREATE INDEX "draft_created_idx" ON "draft" ("created");
730 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
731 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
732 CREATE TRIGGER "update_text_search_data"
733 BEFORE INSERT OR UPDATE ON "draft"
734 FOR EACH ROW EXECUTE PROCEDURE
735 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
737 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.';
739 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
740 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
743 CREATE TABLE "rendered_draft" (
744 PRIMARY KEY ("draft_id", "format"),
745 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
746 "format" TEXT,
747 "content" TEXT NOT NULL );
749 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)';
752 CREATE TABLE "suggestion" (
753 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
754 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
755 "id" SERIAL8 PRIMARY KEY,
756 "draft_id" INT8 NOT NULL,
757 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
758 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
759 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
760 "name" TEXT NOT NULL,
761 "formatting_engine" TEXT,
762 "content" TEXT NOT NULL DEFAULT '',
763 "text_search_data" TSVECTOR,
764 "minus2_unfulfilled_count" INT4,
765 "minus2_fulfilled_count" INT4,
766 "minus1_unfulfilled_count" INT4,
767 "minus1_fulfilled_count" INT4,
768 "plus1_unfulfilled_count" INT4,
769 "plus1_fulfilled_count" INT4,
770 "plus2_unfulfilled_count" INT4,
771 "plus2_fulfilled_count" INT4 );
772 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
773 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
774 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
775 CREATE TRIGGER "update_text_search_data"
776 BEFORE INSERT OR UPDATE ON "suggestion"
777 FOR EACH ROW EXECUTE PROCEDURE
778 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
779 "name", "content");
781 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';
783 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")';
784 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
785 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
786 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
787 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
788 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
789 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
790 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
791 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
794 CREATE TABLE "rendered_suggestion" (
795 PRIMARY KEY ("suggestion_id", "format"),
796 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
797 "format" TEXT,
798 "content" TEXT NOT NULL );
800 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)';
803 CREATE TABLE "suggestion_setting" (
804 PRIMARY KEY ("member_id", "key", "suggestion_id"),
805 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
806 "key" TEXT NOT NULL,
807 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
808 "value" TEXT NOT NULL );
810 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
813 CREATE TABLE "privilege" (
814 PRIMARY KEY ("unit_id", "member_id"),
815 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
816 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
817 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
818 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
819 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
820 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
821 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
822 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
823 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
825 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
827 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
828 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
829 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
830 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
831 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
832 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
833 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';
836 CREATE TABLE "membership" (
837 PRIMARY KEY ("area_id", "member_id"),
838 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
839 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
840 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
842 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
845 CREATE TABLE "interest" (
846 PRIMARY KEY ("issue_id", "member_id"),
847 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
848 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
849 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
851 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.';
854 CREATE TABLE "initiator" (
855 PRIMARY KEY ("initiative_id", "member_id"),
856 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
857 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
858 "accepted" BOOLEAN );
859 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
861 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.';
863 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.';
866 CREATE TABLE "supporter" (
867 "issue_id" INT4 NOT NULL,
868 PRIMARY KEY ("initiative_id", "member_id"),
869 "initiative_id" INT4,
870 "member_id" INT4,
871 "draft_id" INT8 NOT NULL,
872 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
873 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
874 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
876 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.';
878 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
879 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")';
882 CREATE TABLE "opinion" (
883 "initiative_id" INT4 NOT NULL,
884 PRIMARY KEY ("suggestion_id", "member_id"),
885 "suggestion_id" INT8,
886 "member_id" INT4,
887 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
888 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
889 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
890 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
891 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
893 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.';
895 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
898 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
900 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
903 CREATE TABLE "delegation" (
904 "id" SERIAL8 PRIMARY KEY,
905 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
906 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
907 "scope" "delegation_scope" NOT NULL,
908 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
909 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
910 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
911 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
912 CONSTRAINT "no_unit_delegation_to_null"
913 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
914 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
915 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
916 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
917 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
918 UNIQUE ("unit_id", "truster_id"),
919 UNIQUE ("area_id", "truster_id"),
920 UNIQUE ("issue_id", "truster_id") );
921 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
922 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
924 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
926 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
927 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
928 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
931 CREATE TABLE "direct_population_snapshot" (
932 PRIMARY KEY ("issue_id", "event", "member_id"),
933 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
934 "event" "snapshot_event",
935 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
936 "weight" INT4 );
937 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
939 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
941 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
942 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
945 CREATE TABLE "delegating_population_snapshot" (
946 PRIMARY KEY ("issue_id", "event", "member_id"),
947 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
948 "event" "snapshot_event",
949 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
950 "weight" INT4,
951 "scope" "delegation_scope" NOT NULL,
952 "delegate_member_ids" INT4[] NOT NULL );
953 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
955 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
957 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
958 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
959 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
960 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"';
963 CREATE TABLE "direct_interest_snapshot" (
964 PRIMARY KEY ("issue_id", "event", "member_id"),
965 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
966 "event" "snapshot_event",
967 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
968 "weight" INT4 );
969 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
971 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
973 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
974 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
977 CREATE TABLE "delegating_interest_snapshot" (
978 PRIMARY KEY ("issue_id", "event", "member_id"),
979 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
980 "event" "snapshot_event",
981 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
982 "weight" INT4,
983 "scope" "delegation_scope" NOT NULL,
984 "delegate_member_ids" INT4[] NOT NULL );
985 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
987 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
989 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
990 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
991 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
992 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"';
995 CREATE TABLE "direct_supporter_snapshot" (
996 "issue_id" INT4 NOT NULL,
997 PRIMARY KEY ("initiative_id", "event", "member_id"),
998 "initiative_id" INT4,
999 "event" "snapshot_event",
1000 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1001 "draft_id" INT8 NOT NULL,
1002 "informed" BOOLEAN NOT NULL,
1003 "satisfied" BOOLEAN NOT NULL,
1004 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1005 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1006 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1007 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1009 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1011 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';
1012 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1013 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1014 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1017 CREATE TABLE "non_voter" (
1018 PRIMARY KEY ("issue_id", "member_id"),
1019 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1020 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1021 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1023 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1026 CREATE TABLE "direct_voter" (
1027 PRIMARY KEY ("issue_id", "member_id"),
1028 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1029 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1030 "weight" INT4,
1031 "comment_changed" TIMESTAMPTZ,
1032 "formatting_engine" TEXT,
1033 "comment" TEXT,
1034 "text_search_data" TSVECTOR );
1035 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1036 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1037 CREATE TRIGGER "update_text_search_data"
1038 BEFORE INSERT OR UPDATE ON "direct_voter"
1039 FOR EACH ROW EXECUTE PROCEDURE
1040 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1042 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.';
1044 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1045 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';
1046 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';
1047 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.';
1050 CREATE TABLE "rendered_voter_comment" (
1051 PRIMARY KEY ("issue_id", "member_id", "format"),
1052 FOREIGN KEY ("issue_id", "member_id")
1053 REFERENCES "direct_voter" ("issue_id", "member_id")
1054 ON DELETE CASCADE ON UPDATE CASCADE,
1055 "issue_id" INT4,
1056 "member_id" INT4,
1057 "format" TEXT,
1058 "content" TEXT NOT NULL );
1060 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)';
1063 CREATE TABLE "delegating_voter" (
1064 PRIMARY KEY ("issue_id", "member_id"),
1065 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1066 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1067 "weight" INT4,
1068 "scope" "delegation_scope" NOT NULL,
1069 "delegate_member_ids" INT4[] NOT NULL );
1070 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1072 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1074 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1075 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1076 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"';
1079 CREATE TABLE "vote" (
1080 "issue_id" INT4 NOT NULL,
1081 PRIMARY KEY ("initiative_id", "member_id"),
1082 "initiative_id" INT4,
1083 "member_id" INT4,
1084 "grade" INT4,
1085 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1086 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1087 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1089 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.';
1091 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1092 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.';
1095 CREATE TYPE "event_type" AS ENUM (
1096 'issue_state_changed',
1097 'initiative_created_in_new_issue',
1098 'initiative_created_in_existing_issue',
1099 'initiative_revoked',
1100 'new_draft_created',
1101 'suggestion_created');
1103 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1106 CREATE TABLE "event" (
1107 "id" SERIAL8 PRIMARY KEY,
1108 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1109 "event" "event_type" NOT NULL,
1110 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1111 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1112 "state" "issue_state",
1113 "initiative_id" INT4,
1114 "draft_id" INT8,
1115 "suggestion_id" INT8,
1116 FOREIGN KEY ("issue_id", "initiative_id")
1117 REFERENCES "initiative" ("issue_id", "id")
1118 ON DELETE CASCADE ON UPDATE CASCADE,
1119 FOREIGN KEY ("initiative_id", "draft_id")
1120 REFERENCES "draft" ("initiative_id", "id")
1121 ON DELETE CASCADE ON UPDATE CASCADE,
1122 FOREIGN KEY ("initiative_id", "suggestion_id")
1123 REFERENCES "suggestion" ("initiative_id", "id")
1124 ON DELETE CASCADE ON UPDATE CASCADE,
1125 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1126 "event" != 'issue_state_changed' OR (
1127 "member_id" ISNULL AND
1128 "issue_id" NOTNULL AND
1129 "state" NOTNULL AND
1130 "initiative_id" ISNULL AND
1131 "draft_id" ISNULL AND
1132 "suggestion_id" ISNULL )),
1133 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1134 "event" NOT IN (
1135 'initiative_created_in_new_issue',
1136 'initiative_created_in_existing_issue',
1137 'initiative_revoked',
1138 'new_draft_created'
1139 ) OR (
1140 "member_id" NOTNULL AND
1141 "issue_id" NOTNULL AND
1142 "state" NOTNULL AND
1143 "initiative_id" NOTNULL AND
1144 "draft_id" NOTNULL AND
1145 "suggestion_id" ISNULL )),
1146 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1147 "event" != 'suggestion_created' OR (
1148 "member_id" NOTNULL AND
1149 "issue_id" NOTNULL AND
1150 "state" NOTNULL AND
1151 "initiative_id" NOTNULL AND
1152 "draft_id" ISNULL AND
1153 "suggestion_id" NOTNULL )) );
1154 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1156 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1158 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1159 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1160 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1161 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1164 CREATE TABLE "notification_sent" (
1165 "event_id" INT8 NOT NULL );
1166 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1168 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1169 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1173 ----------------------------------------------
1174 -- Writing of history entries and event log --
1175 ----------------------------------------------
1178 CREATE FUNCTION "write_member_history_trigger"()
1179 RETURNS TRIGGER
1180 LANGUAGE 'plpgsql' VOLATILE AS $$
1181 BEGIN
1182 IF
1183 ( NEW."active" != OLD."active" OR
1184 NEW."name" != OLD."name" ) AND
1185 OLD."activated" NOTNULL
1186 THEN
1187 INSERT INTO "member_history"
1188 ("member_id", "active", "name")
1189 VALUES (NEW."id", OLD."active", OLD."name");
1190 END IF;
1191 RETURN NULL;
1192 END;
1193 $$;
1195 CREATE TRIGGER "write_member_history"
1196 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1197 "write_member_history_trigger"();
1199 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1200 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1203 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1204 RETURNS TRIGGER
1205 LANGUAGE 'plpgsql' VOLATILE AS $$
1206 BEGIN
1207 IF NEW."state" != OLD."state" THEN
1208 INSERT INTO "event" ("event", "issue_id", "state")
1209 VALUES ('issue_state_changed', NEW."id", NEW."state");
1210 END IF;
1211 RETURN NULL;
1212 END;
1213 $$;
1215 CREATE TRIGGER "write_event_issue_state_changed"
1216 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1217 "write_event_issue_state_changed_trigger"();
1219 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1220 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1223 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1224 RETURNS TRIGGER
1225 LANGUAGE 'plpgsql' VOLATILE AS $$
1226 DECLARE
1227 "initiative_row" "initiative"%ROWTYPE;
1228 "issue_row" "issue"%ROWTYPE;
1229 "event_v" "event_type";
1230 BEGIN
1231 SELECT * INTO "initiative_row" FROM "initiative"
1232 WHERE "id" = NEW."initiative_id";
1233 SELECT * INTO "issue_row" FROM "issue"
1234 WHERE "id" = "initiative_row"."issue_id";
1235 IF EXISTS (
1236 SELECT NULL FROM "draft"
1237 WHERE "initiative_id" = NEW."initiative_id"
1238 AND "id" != NEW."id"
1239 ) THEN
1240 "event_v" := 'new_draft_created';
1241 ELSE
1242 IF EXISTS (
1243 SELECT NULL FROM "initiative"
1244 WHERE "issue_id" = "initiative_row"."issue_id"
1245 AND "id" != "initiative_row"."id"
1246 ) THEN
1247 "event_v" := 'initiative_created_in_existing_issue';
1248 ELSE
1249 "event_v" := 'initiative_created_in_new_issue';
1250 END IF;
1251 END IF;
1252 INSERT INTO "event" (
1253 "event", "member_id",
1254 "issue_id", "state", "initiative_id", "draft_id"
1255 ) VALUES (
1256 "event_v",
1257 NEW."author_id",
1258 "initiative_row"."issue_id",
1259 "issue_row"."state",
1260 "initiative_row"."id",
1261 NEW."id" );
1262 RETURN NULL;
1263 END;
1264 $$;
1266 CREATE TRIGGER "write_event_initiative_or_draft_created"
1267 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1268 "write_event_initiative_or_draft_created_trigger"();
1270 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1271 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1274 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1275 RETURNS TRIGGER
1276 LANGUAGE 'plpgsql' VOLATILE AS $$
1277 DECLARE
1278 "issue_row" "issue"%ROWTYPE;
1279 "draft_id_v" "draft"."id"%TYPE;
1280 BEGIN
1281 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1282 SELECT * INTO "issue_row" FROM "issue"
1283 WHERE "id" = NEW."issue_id";
1284 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1285 WHERE "initiative_id" = NEW."id";
1286 INSERT INTO "event" (
1287 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1288 ) VALUES (
1289 'initiative_revoked',
1290 NEW."revoked_by_member_id",
1291 NEW."issue_id",
1292 "issue_row"."state",
1293 NEW."id",
1294 "draft_id_v");
1295 END IF;
1296 RETURN NULL;
1297 END;
1298 $$;
1300 CREATE TRIGGER "write_event_initiative_revoked"
1301 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1302 "write_event_initiative_revoked_trigger"();
1304 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1305 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1308 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1309 RETURNS TRIGGER
1310 LANGUAGE 'plpgsql' VOLATILE AS $$
1311 DECLARE
1312 "initiative_row" "initiative"%ROWTYPE;
1313 "issue_row" "issue"%ROWTYPE;
1314 BEGIN
1315 SELECT * INTO "initiative_row" FROM "initiative"
1316 WHERE "id" = NEW."initiative_id";
1317 SELECT * INTO "issue_row" FROM "issue"
1318 WHERE "id" = "initiative_row"."issue_id";
1319 INSERT INTO "event" (
1320 "event", "member_id",
1321 "issue_id", "state", "initiative_id", "suggestion_id"
1322 ) VALUES (
1323 'suggestion_created',
1324 NEW."author_id",
1325 "initiative_row"."issue_id",
1326 "issue_row"."state",
1327 "initiative_row"."id",
1328 NEW."id" );
1329 RETURN NULL;
1330 END;
1331 $$;
1333 CREATE TRIGGER "write_event_suggestion_created"
1334 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1335 "write_event_suggestion_created_trigger"();
1337 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1338 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1342 ----------------------------
1343 -- Additional constraints --
1344 ----------------------------
1347 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1348 RETURNS TRIGGER
1349 LANGUAGE 'plpgsql' VOLATILE AS $$
1350 BEGIN
1351 IF NOT EXISTS (
1352 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1353 ) THEN
1354 --RAISE 'Cannot create issue without an initial initiative.' USING
1355 -- ERRCODE = 'integrity_constraint_violation',
1356 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1357 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1358 END IF;
1359 RETURN NULL;
1360 END;
1361 $$;
1363 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1364 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1365 FOR EACH ROW EXECUTE PROCEDURE
1366 "issue_requires_first_initiative_trigger"();
1368 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1369 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1372 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1373 RETURNS TRIGGER
1374 LANGUAGE 'plpgsql' VOLATILE AS $$
1375 DECLARE
1376 "reference_lost" BOOLEAN;
1377 BEGIN
1378 IF TG_OP = 'DELETE' THEN
1379 "reference_lost" := TRUE;
1380 ELSE
1381 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1382 END IF;
1383 IF
1384 "reference_lost" AND NOT EXISTS (
1385 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1387 THEN
1388 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1389 END IF;
1390 RETURN NULL;
1391 END;
1392 $$;
1394 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1395 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1396 FOR EACH ROW EXECUTE PROCEDURE
1397 "last_initiative_deletes_issue_trigger"();
1399 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1400 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1403 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1404 RETURNS TRIGGER
1405 LANGUAGE 'plpgsql' VOLATILE AS $$
1406 BEGIN
1407 IF NOT EXISTS (
1408 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1409 ) THEN
1410 --RAISE 'Cannot create initiative without an initial draft.' USING
1411 -- ERRCODE = 'integrity_constraint_violation',
1412 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1413 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1414 END IF;
1415 RETURN NULL;
1416 END;
1417 $$;
1419 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1420 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1421 FOR EACH ROW EXECUTE PROCEDURE
1422 "initiative_requires_first_draft_trigger"();
1424 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1425 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1428 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1429 RETURNS TRIGGER
1430 LANGUAGE 'plpgsql' VOLATILE AS $$
1431 DECLARE
1432 "reference_lost" BOOLEAN;
1433 BEGIN
1434 IF TG_OP = 'DELETE' THEN
1435 "reference_lost" := TRUE;
1436 ELSE
1437 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1438 END IF;
1439 IF
1440 "reference_lost" AND NOT EXISTS (
1441 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1443 THEN
1444 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1445 END IF;
1446 RETURN NULL;
1447 END;
1448 $$;
1450 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1451 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1452 FOR EACH ROW EXECUTE PROCEDURE
1453 "last_draft_deletes_initiative_trigger"();
1455 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1456 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1459 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1460 RETURNS TRIGGER
1461 LANGUAGE 'plpgsql' VOLATILE AS $$
1462 BEGIN
1463 IF NOT EXISTS (
1464 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1465 ) THEN
1466 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1467 END IF;
1468 RETURN NULL;
1469 END;
1470 $$;
1472 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1473 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1474 FOR EACH ROW EXECUTE PROCEDURE
1475 "suggestion_requires_first_opinion_trigger"();
1477 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1478 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1481 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1482 RETURNS TRIGGER
1483 LANGUAGE 'plpgsql' VOLATILE AS $$
1484 DECLARE
1485 "reference_lost" BOOLEAN;
1486 BEGIN
1487 IF TG_OP = 'DELETE' THEN
1488 "reference_lost" := TRUE;
1489 ELSE
1490 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1491 END IF;
1492 IF
1493 "reference_lost" AND NOT EXISTS (
1494 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1496 THEN
1497 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1498 END IF;
1499 RETURN NULL;
1500 END;
1501 $$;
1503 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1504 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1505 FOR EACH ROW EXECUTE PROCEDURE
1506 "last_opinion_deletes_suggestion_trigger"();
1508 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1509 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1512 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1513 RETURNS TRIGGER
1514 LANGUAGE 'plpgsql' VOLATILE AS $$
1515 BEGIN
1516 DELETE FROM "direct_voter"
1517 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1518 RETURN NULL;
1519 END;
1520 $$;
1522 CREATE TRIGGER "non_voter_deletes_direct_voter"
1523 AFTER INSERT OR UPDATE ON "non_voter"
1524 FOR EACH ROW EXECUTE PROCEDURE
1525 "non_voter_deletes_direct_voter_trigger"();
1527 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1528 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")';
1531 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1532 RETURNS TRIGGER
1533 LANGUAGE 'plpgsql' VOLATILE AS $$
1534 BEGIN
1535 DELETE FROM "non_voter"
1536 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1537 RETURN NULL;
1538 END;
1539 $$;
1541 CREATE TRIGGER "direct_voter_deletes_non_voter"
1542 AFTER INSERT OR UPDATE ON "direct_voter"
1543 FOR EACH ROW EXECUTE PROCEDURE
1544 "direct_voter_deletes_non_voter_trigger"();
1546 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1547 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")';
1550 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1551 RETURNS TRIGGER
1552 LANGUAGE 'plpgsql' VOLATILE AS $$
1553 BEGIN
1554 IF NEW."comment" ISNULL THEN
1555 NEW."comment_changed" := NULL;
1556 NEW."formatting_engine" := NULL;
1557 END IF;
1558 RETURN NEW;
1559 END;
1560 $$;
1562 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1563 BEFORE INSERT OR UPDATE ON "direct_voter"
1564 FOR EACH ROW EXECUTE PROCEDURE
1565 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1567 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"';
1568 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.';
1571 ---------------------------------------------------------------
1572 -- Ensure that votes are not modified when issues are closed --
1573 ---------------------------------------------------------------
1575 -- NOTE: Frontends should ensure this anyway, but in case of programming
1576 -- errors the following triggers ensure data integrity.
1579 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1580 RETURNS TRIGGER
1581 LANGUAGE 'plpgsql' VOLATILE AS $$
1582 DECLARE
1583 "issue_id_v" "issue"."id"%TYPE;
1584 "issue_row" "issue"%ROWTYPE;
1585 BEGIN
1586 IF TG_OP = 'DELETE' THEN
1587 "issue_id_v" := OLD."issue_id";
1588 ELSE
1589 "issue_id_v" := NEW."issue_id";
1590 END IF;
1591 SELECT INTO "issue_row" * FROM "issue"
1592 WHERE "id" = "issue_id_v" FOR SHARE;
1593 IF "issue_row"."closed" NOTNULL THEN
1594 IF
1595 TG_RELID = 'direct_voter'::regclass AND
1596 TG_OP = 'UPDATE'
1597 THEN
1598 IF
1599 OLD."issue_id" = NEW."issue_id" AND
1600 OLD."member_id" = NEW."member_id" AND
1601 OLD."weight" = NEW."weight"
1602 THEN
1603 RETURN NULL; -- allows changing of voter comment
1604 END IF;
1605 END IF;
1606 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1607 ELSIF
1608 "issue_row"."state" = 'voting' AND
1609 "issue_row"."phase_finished" NOTNULL
1610 THEN
1611 IF TG_RELID = 'vote'::regclass THEN
1612 RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
1613 END IF;
1614 END IF;
1615 RETURN NULL;
1616 END;
1617 $$;
1619 CREATE TRIGGER "forbid_changes_on_closed_issue"
1620 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1621 FOR EACH ROW EXECUTE PROCEDURE
1622 "forbid_changes_on_closed_issue_trigger"();
1624 CREATE TRIGGER "forbid_changes_on_closed_issue"
1625 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1626 FOR EACH ROW EXECUTE PROCEDURE
1627 "forbid_changes_on_closed_issue_trigger"();
1629 CREATE TRIGGER "forbid_changes_on_closed_issue"
1630 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1631 FOR EACH ROW EXECUTE PROCEDURE
1632 "forbid_changes_on_closed_issue_trigger"();
1634 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"';
1635 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';
1636 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';
1637 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';
1641 --------------------------------------------------------------------
1642 -- Auto-retrieval of fields only needed for referential integrity --
1643 --------------------------------------------------------------------
1646 CREATE FUNCTION "autofill_issue_id_trigger"()
1647 RETURNS TRIGGER
1648 LANGUAGE 'plpgsql' VOLATILE AS $$
1649 BEGIN
1650 IF NEW."issue_id" ISNULL THEN
1651 SELECT "issue_id" INTO NEW."issue_id"
1652 FROM "initiative" WHERE "id" = NEW."initiative_id";
1653 END IF;
1654 RETURN NEW;
1655 END;
1656 $$;
1658 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1659 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1661 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1662 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1664 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1665 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1666 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1669 CREATE FUNCTION "autofill_initiative_id_trigger"()
1670 RETURNS TRIGGER
1671 LANGUAGE 'plpgsql' VOLATILE AS $$
1672 BEGIN
1673 IF NEW."initiative_id" ISNULL THEN
1674 SELECT "initiative_id" INTO NEW."initiative_id"
1675 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1676 END IF;
1677 RETURN NEW;
1678 END;
1679 $$;
1681 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1682 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1684 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1685 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1689 -----------------------------------------------------
1690 -- Automatic calculation of certain default values --
1691 -----------------------------------------------------
1694 CREATE FUNCTION "copy_timings_trigger"()
1695 RETURNS TRIGGER
1696 LANGUAGE 'plpgsql' VOLATILE AS $$
1697 DECLARE
1698 "policy_row" "policy"%ROWTYPE;
1699 BEGIN
1700 SELECT * INTO "policy_row" FROM "policy"
1701 WHERE "id" = NEW."policy_id";
1702 IF NEW."admission_time" ISNULL THEN
1703 NEW."admission_time" := "policy_row"."admission_time";
1704 END IF;
1705 IF NEW."discussion_time" ISNULL THEN
1706 NEW."discussion_time" := "policy_row"."discussion_time";
1707 END IF;
1708 IF NEW."verification_time" ISNULL THEN
1709 NEW."verification_time" := "policy_row"."verification_time";
1710 END IF;
1711 IF NEW."voting_time" ISNULL THEN
1712 NEW."voting_time" := "policy_row"."voting_time";
1713 END IF;
1714 RETURN NEW;
1715 END;
1716 $$;
1718 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1719 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1721 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1722 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1725 CREATE FUNCTION "default_for_draft_id_trigger"()
1726 RETURNS TRIGGER
1727 LANGUAGE 'plpgsql' VOLATILE AS $$
1728 BEGIN
1729 IF NEW."draft_id" ISNULL THEN
1730 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1731 WHERE "initiative_id" = NEW."initiative_id";
1732 END IF;
1733 RETURN NEW;
1734 END;
1735 $$;
1737 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1738 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1739 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1740 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1742 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1743 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';
1744 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';
1748 ----------------------------------------
1749 -- Automatic creation of dependencies --
1750 ----------------------------------------
1753 CREATE FUNCTION "autocreate_interest_trigger"()
1754 RETURNS TRIGGER
1755 LANGUAGE 'plpgsql' VOLATILE AS $$
1756 BEGIN
1757 IF NOT EXISTS (
1758 SELECT NULL FROM "initiative" JOIN "interest"
1759 ON "initiative"."issue_id" = "interest"."issue_id"
1760 WHERE "initiative"."id" = NEW."initiative_id"
1761 AND "interest"."member_id" = NEW."member_id"
1762 ) THEN
1763 BEGIN
1764 INSERT INTO "interest" ("issue_id", "member_id")
1765 SELECT "issue_id", NEW."member_id"
1766 FROM "initiative" WHERE "id" = NEW."initiative_id";
1767 EXCEPTION WHEN unique_violation THEN END;
1768 END IF;
1769 RETURN NEW;
1770 END;
1771 $$;
1773 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1774 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1776 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1777 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';
1780 CREATE FUNCTION "autocreate_supporter_trigger"()
1781 RETURNS TRIGGER
1782 LANGUAGE 'plpgsql' VOLATILE AS $$
1783 BEGIN
1784 IF NOT EXISTS (
1785 SELECT NULL FROM "suggestion" JOIN "supporter"
1786 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1787 WHERE "suggestion"."id" = NEW."suggestion_id"
1788 AND "supporter"."member_id" = NEW."member_id"
1789 ) THEN
1790 BEGIN
1791 INSERT INTO "supporter" ("initiative_id", "member_id")
1792 SELECT "initiative_id", NEW."member_id"
1793 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1794 EXCEPTION WHEN unique_violation THEN END;
1795 END IF;
1796 RETURN NEW;
1797 END;
1798 $$;
1800 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1801 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1803 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1804 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.';
1808 ------------------------------------------
1809 -- Views and helper functions for views --
1810 ------------------------------------------
1813 CREATE VIEW "unit_delegation" AS
1814 SELECT
1815 "unit"."id" AS "unit_id",
1816 "delegation"."id",
1817 "delegation"."truster_id",
1818 "delegation"."trustee_id",
1819 "delegation"."scope"
1820 FROM "unit"
1821 JOIN "delegation"
1822 ON "delegation"."unit_id" = "unit"."id"
1823 JOIN "member"
1824 ON "delegation"."truster_id" = "member"."id"
1825 JOIN "privilege"
1826 ON "delegation"."unit_id" = "privilege"."unit_id"
1827 AND "delegation"."truster_id" = "privilege"."member_id"
1828 WHERE "member"."active" AND "privilege"."voting_right";
1830 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1833 CREATE VIEW "area_delegation" AS
1834 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1835 "area"."id" AS "area_id",
1836 "delegation"."id",
1837 "delegation"."truster_id",
1838 "delegation"."trustee_id",
1839 "delegation"."scope"
1840 FROM "area"
1841 JOIN "delegation"
1842 ON "delegation"."unit_id" = "area"."unit_id"
1843 OR "delegation"."area_id" = "area"."id"
1844 JOIN "member"
1845 ON "delegation"."truster_id" = "member"."id"
1846 JOIN "privilege"
1847 ON "area"."unit_id" = "privilege"."unit_id"
1848 AND "delegation"."truster_id" = "privilege"."member_id"
1849 WHERE "member"."active" AND "privilege"."voting_right"
1850 ORDER BY
1851 "area"."id",
1852 "delegation"."truster_id",
1853 "delegation"."scope" DESC;
1855 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1858 CREATE VIEW "issue_delegation" AS
1859 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1860 "issue"."id" AS "issue_id",
1861 "delegation"."id",
1862 "delegation"."truster_id",
1863 "delegation"."trustee_id",
1864 "delegation"."scope"
1865 FROM "issue"
1866 JOIN "area"
1867 ON "area"."id" = "issue"."area_id"
1868 JOIN "delegation"
1869 ON "delegation"."unit_id" = "area"."unit_id"
1870 OR "delegation"."area_id" = "area"."id"
1871 OR "delegation"."issue_id" = "issue"."id"
1872 JOIN "member"
1873 ON "delegation"."truster_id" = "member"."id"
1874 JOIN "privilege"
1875 ON "area"."unit_id" = "privilege"."unit_id"
1876 AND "delegation"."truster_id" = "privilege"."member_id"
1877 WHERE "member"."active" AND "privilege"."voting_right"
1878 ORDER BY
1879 "issue"."id",
1880 "delegation"."truster_id",
1881 "delegation"."scope" DESC;
1883 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1886 CREATE FUNCTION "membership_weight_with_skipping"
1887 ( "area_id_p" "area"."id"%TYPE,
1888 "member_id_p" "member"."id"%TYPE,
1889 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1890 RETURNS INT4
1891 LANGUAGE 'plpgsql' STABLE AS $$
1892 DECLARE
1893 "sum_v" INT4;
1894 "delegation_row" "area_delegation"%ROWTYPE;
1895 BEGIN
1896 "sum_v" := 1;
1897 FOR "delegation_row" IN
1898 SELECT "area_delegation".*
1899 FROM "area_delegation" LEFT JOIN "membership"
1900 ON "membership"."area_id" = "area_id_p"
1901 AND "membership"."member_id" = "area_delegation"."truster_id"
1902 WHERE "area_delegation"."area_id" = "area_id_p"
1903 AND "area_delegation"."trustee_id" = "member_id_p"
1904 AND "membership"."member_id" ISNULL
1905 LOOP
1906 IF NOT
1907 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1908 THEN
1909 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1910 "area_id_p",
1911 "delegation_row"."truster_id",
1912 "skip_member_ids_p" || "delegation_row"."truster_id"
1913 );
1914 END IF;
1915 END LOOP;
1916 RETURN "sum_v";
1917 END;
1918 $$;
1920 COMMENT ON FUNCTION "membership_weight_with_skipping"
1921 ( "area"."id"%TYPE,
1922 "member"."id"%TYPE,
1923 INT4[] )
1924 IS 'Helper function for "membership_weight" function';
1927 CREATE FUNCTION "membership_weight"
1928 ( "area_id_p" "area"."id"%TYPE,
1929 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1930 RETURNS INT4
1931 LANGUAGE 'plpgsql' STABLE AS $$
1932 BEGIN
1933 RETURN "membership_weight_with_skipping"(
1934 "area_id_p",
1935 "member_id_p",
1936 ARRAY["member_id_p"]
1937 );
1938 END;
1939 $$;
1941 COMMENT ON FUNCTION "membership_weight"
1942 ( "area"."id"%TYPE,
1943 "member"."id"%TYPE )
1944 IS 'Calculates the potential voting weight of a member in a given area';
1947 CREATE VIEW "member_count_view" AS
1948 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1950 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1953 CREATE VIEW "unit_member_count" AS
1954 SELECT
1955 "unit"."id" AS "unit_id",
1956 count("member"."id") AS "member_count"
1957 FROM "unit"
1958 LEFT JOIN "privilege"
1959 ON "privilege"."unit_id" = "unit"."id"
1960 AND "privilege"."voting_right"
1961 LEFT JOIN "member"
1962 ON "member"."id" = "privilege"."member_id"
1963 AND "member"."active"
1964 GROUP BY "unit"."id";
1966 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1969 CREATE VIEW "area_member_count" AS
1970 SELECT
1971 "area"."id" AS "area_id",
1972 count("member"."id") AS "direct_member_count",
1973 coalesce(
1974 sum(
1975 CASE WHEN "member"."id" NOTNULL THEN
1976 "membership_weight"("area"."id", "member"."id")
1977 ELSE 0 END
1979 ) AS "member_weight"
1980 FROM "area"
1981 LEFT JOIN "membership"
1982 ON "area"."id" = "membership"."area_id"
1983 LEFT JOIN "privilege"
1984 ON "privilege"."unit_id" = "area"."unit_id"
1985 AND "privilege"."member_id" = "membership"."member_id"
1986 AND "privilege"."voting_right"
1987 LEFT JOIN "member"
1988 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1989 AND "member"."active"
1990 GROUP BY "area"."id";
1992 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1995 CREATE VIEW "opening_draft" AS
1996 SELECT "draft".* FROM (
1997 SELECT
1998 "initiative"."id" AS "initiative_id",
1999 min("draft"."id") AS "draft_id"
2000 FROM "initiative" JOIN "draft"
2001 ON "initiative"."id" = "draft"."initiative_id"
2002 GROUP BY "initiative"."id"
2003 ) AS "subquery"
2004 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2006 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2009 CREATE VIEW "current_draft" AS
2010 SELECT "draft".* FROM (
2011 SELECT
2012 "initiative"."id" AS "initiative_id",
2013 max("draft"."id") AS "draft_id"
2014 FROM "initiative" JOIN "draft"
2015 ON "initiative"."id" = "draft"."initiative_id"
2016 GROUP BY "initiative"."id"
2017 ) AS "subquery"
2018 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2020 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2023 CREATE VIEW "critical_opinion" AS
2024 SELECT * FROM "opinion"
2025 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2026 OR ("degree" = -2 AND "fulfilled" = TRUE);
2028 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2031 CREATE VIEW "battle_participant" AS
2032 SELECT "initiative"."id", "initiative"."issue_id"
2033 FROM "issue" JOIN "initiative"
2034 ON "issue"."id" = "initiative"."issue_id"
2035 WHERE "initiative"."admitted"
2036 UNION ALL
2037 SELECT NULL, "id" AS "issue_id"
2038 FROM "issue";
2040 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2043 CREATE VIEW "battle_view" AS
2044 SELECT
2045 "issue"."id" AS "issue_id",
2046 "winning_initiative"."id" AS "winning_initiative_id",
2047 "losing_initiative"."id" AS "losing_initiative_id",
2048 sum(
2049 CASE WHEN
2050 coalesce("better_vote"."grade", 0) >
2051 coalesce("worse_vote"."grade", 0)
2052 THEN "direct_voter"."weight" ELSE 0 END
2053 ) AS "count"
2054 FROM "issue"
2055 LEFT JOIN "direct_voter"
2056 ON "issue"."id" = "direct_voter"."issue_id"
2057 JOIN "battle_participant" AS "winning_initiative"
2058 ON "issue"."id" = "winning_initiative"."issue_id"
2059 JOIN "battle_participant" AS "losing_initiative"
2060 ON "issue"."id" = "losing_initiative"."issue_id"
2061 LEFT JOIN "vote" AS "better_vote"
2062 ON "direct_voter"."member_id" = "better_vote"."member_id"
2063 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2064 LEFT JOIN "vote" AS "worse_vote"
2065 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2066 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2067 WHERE "issue"."state" = 'voting'
2068 AND "issue"."phase_finished" NOTNULL
2069 AND (
2070 "winning_initiative"."id" != "losing_initiative"."id" OR
2071 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2072 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2073 GROUP BY
2074 "issue"."id",
2075 "winning_initiative"."id",
2076 "losing_initiative"."id";
2078 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';
2081 CREATE VIEW "expired_session" AS
2082 SELECT * FROM "session" WHERE now() > "expiry";
2084 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2085 DELETE FROM "session" WHERE "ident" = OLD."ident";
2087 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2088 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2091 CREATE VIEW "open_issue" AS
2092 SELECT * FROM "issue" WHERE "closed" ISNULL;
2094 COMMENT ON VIEW "open_issue" IS 'All open issues';
2097 CREATE VIEW "member_contingent" AS
2098 SELECT
2099 "member"."id" AS "member_id",
2100 "contingent"."polling",
2101 "contingent"."time_frame",
2102 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2104 SELECT count(1) FROM "draft"
2105 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2106 WHERE "draft"."author_id" = "member"."id"
2107 AND "initiative"."polling" = "contingent"."polling"
2108 AND "draft"."created" > now() - "contingent"."time_frame"
2109 ) + (
2110 SELECT count(1) FROM "suggestion"
2111 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2112 WHERE "suggestion"."author_id" = "member"."id"
2113 AND "contingent"."polling" = FALSE
2114 AND "suggestion"."created" > now() - "contingent"."time_frame"
2116 ELSE NULL END AS "text_entry_count",
2117 "contingent"."text_entry_limit",
2118 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2119 SELECT count(1) FROM "opening_draft" AS "draft"
2120 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2121 WHERE "draft"."author_id" = "member"."id"
2122 AND "initiative"."polling" = "contingent"."polling"
2123 AND "draft"."created" > now() - "contingent"."time_frame"
2124 ) ELSE NULL END AS "initiative_count",
2125 "contingent"."initiative_limit"
2126 FROM "member" CROSS JOIN "contingent";
2128 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2130 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2131 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2134 CREATE VIEW "member_contingent_left" AS
2135 SELECT
2136 "member_id",
2137 "polling",
2138 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2139 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2140 FROM "member_contingent" GROUP BY "member_id", "polling";
2142 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.';
2145 CREATE VIEW "event_seen_by_member" AS
2146 SELECT
2147 "member"."id" AS "seen_by_member_id",
2148 CASE WHEN "event"."state" IN (
2149 'voting',
2150 'finished_without_winner',
2151 'finished_with_winner'
2152 ) THEN
2153 'voting'::"notify_level"
2154 ELSE
2155 CASE WHEN "event"."state" IN (
2156 'verification',
2157 'canceled_after_revocation_during_verification',
2158 'canceled_no_initiative_admitted'
2159 ) THEN
2160 'verification'::"notify_level"
2161 ELSE
2162 CASE WHEN "event"."state" IN (
2163 'discussion',
2164 'canceled_after_revocation_during_discussion'
2165 ) THEN
2166 'discussion'::"notify_level"
2167 ELSE
2168 'all'::"notify_level"
2169 END
2170 END
2171 END AS "notify_level",
2172 "event".*
2173 FROM "member" CROSS JOIN "event"
2174 LEFT JOIN "issue"
2175 ON "event"."issue_id" = "issue"."id"
2176 LEFT JOIN "membership"
2177 ON "member"."id" = "membership"."member_id"
2178 AND "issue"."area_id" = "membership"."area_id"
2179 LEFT JOIN "interest"
2180 ON "member"."id" = "interest"."member_id"
2181 AND "event"."issue_id" = "interest"."issue_id"
2182 LEFT JOIN "supporter"
2183 ON "member"."id" = "supporter"."member_id"
2184 AND "event"."initiative_id" = "supporter"."initiative_id"
2185 LEFT JOIN "ignored_member"
2186 ON "member"."id" = "ignored_member"."member_id"
2187 AND "event"."member_id" = "ignored_member"."other_member_id"
2188 LEFT JOIN "ignored_initiative"
2189 ON "member"."id" = "ignored_initiative"."member_id"
2190 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2191 WHERE (
2192 "supporter"."member_id" NOTNULL OR
2193 "interest"."member_id" NOTNULL OR
2194 ( "membership"."member_id" NOTNULL AND
2195 "event"."event" IN (
2196 'issue_state_changed',
2197 'initiative_created_in_new_issue',
2198 'initiative_created_in_existing_issue',
2199 'initiative_revoked' ) ) )
2200 AND "ignored_member"."member_id" ISNULL
2201 AND "ignored_initiative"."member_id" ISNULL;
2203 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"';
2206 CREATE VIEW "selected_event_seen_by_member" AS
2207 SELECT
2208 "member"."id" AS "seen_by_member_id",
2209 CASE WHEN "event"."state" IN (
2210 'voting',
2211 'finished_without_winner',
2212 'finished_with_winner'
2213 ) THEN
2214 'voting'::"notify_level"
2215 ELSE
2216 CASE WHEN "event"."state" IN (
2217 'verification',
2218 'canceled_after_revocation_during_verification',
2219 'canceled_no_initiative_admitted'
2220 ) THEN
2221 'verification'::"notify_level"
2222 ELSE
2223 CASE WHEN "event"."state" IN (
2224 'discussion',
2225 'canceled_after_revocation_during_discussion'
2226 ) THEN
2227 'discussion'::"notify_level"
2228 ELSE
2229 'all'::"notify_level"
2230 END
2231 END
2232 END AS "notify_level",
2233 "event".*
2234 FROM "member" CROSS JOIN "event"
2235 LEFT JOIN "issue"
2236 ON "event"."issue_id" = "issue"."id"
2237 LEFT JOIN "membership"
2238 ON "member"."id" = "membership"."member_id"
2239 AND "issue"."area_id" = "membership"."area_id"
2240 LEFT JOIN "interest"
2241 ON "member"."id" = "interest"."member_id"
2242 AND "event"."issue_id" = "interest"."issue_id"
2243 LEFT JOIN "supporter"
2244 ON "member"."id" = "supporter"."member_id"
2245 AND "event"."initiative_id" = "supporter"."initiative_id"
2246 LEFT JOIN "ignored_member"
2247 ON "member"."id" = "ignored_member"."member_id"
2248 AND "event"."member_id" = "ignored_member"."other_member_id"
2249 LEFT JOIN "ignored_initiative"
2250 ON "member"."id" = "ignored_initiative"."member_id"
2251 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2252 WHERE (
2253 ( "member"."notify_level" >= 'all' ) OR
2254 ( "member"."notify_level" >= 'voting' AND
2255 "event"."state" IN (
2256 'voting',
2257 'finished_without_winner',
2258 'finished_with_winner' ) ) OR
2259 ( "member"."notify_level" >= 'verification' AND
2260 "event"."state" IN (
2261 'verification',
2262 'canceled_after_revocation_during_verification',
2263 'canceled_no_initiative_admitted' ) ) OR
2264 ( "member"."notify_level" >= 'discussion' AND
2265 "event"."state" IN (
2266 'discussion',
2267 'canceled_after_revocation_during_discussion' ) ) )
2268 AND (
2269 "supporter"."member_id" NOTNULL OR
2270 "interest"."member_id" NOTNULL OR
2271 ( "membership"."member_id" NOTNULL AND
2272 "event"."event" IN (
2273 'issue_state_changed',
2274 'initiative_created_in_new_issue',
2275 'initiative_created_in_existing_issue',
2276 'initiative_revoked' ) ) )
2277 AND "ignored_member"."member_id" ISNULL
2278 AND "ignored_initiative"."member_id" ISNULL;
2280 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"';
2284 ------------------------------------------------------
2285 -- Row set returning function for delegation chains --
2286 ------------------------------------------------------
2289 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2290 ('first', 'intermediate', 'last', 'repetition');
2292 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2295 CREATE TYPE "delegation_chain_row" AS (
2296 "index" INT4,
2297 "member_id" INT4,
2298 "member_valid" BOOLEAN,
2299 "participation" BOOLEAN,
2300 "overridden" BOOLEAN,
2301 "scope_in" "delegation_scope",
2302 "scope_out" "delegation_scope",
2303 "disabled_out" BOOLEAN,
2304 "loop" "delegation_chain_loop_tag" );
2306 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2308 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2309 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';
2310 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2311 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2312 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2313 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2314 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2317 CREATE FUNCTION "delegation_chain_for_closed_issue"
2318 ( "member_id_p" "member"."id"%TYPE,
2319 "issue_id_p" "issue"."id"%TYPE )
2320 RETURNS SETOF "delegation_chain_row"
2321 LANGUAGE 'plpgsql' STABLE AS $$
2322 DECLARE
2323 "output_row" "delegation_chain_row";
2324 "direct_voter_row" "direct_voter"%ROWTYPE;
2325 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2326 BEGIN
2327 "output_row"."index" := 0;
2328 "output_row"."member_id" := "member_id_p";
2329 "output_row"."member_valid" := TRUE;
2330 "output_row"."participation" := FALSE;
2331 "output_row"."overridden" := FALSE;
2332 "output_row"."disabled_out" := FALSE;
2333 LOOP
2334 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2335 WHERE "issue_id" = "issue_id_p"
2336 AND "member_id" = "output_row"."member_id";
2337 IF "direct_voter_row"."member_id" NOTNULL THEN
2338 "output_row"."participation" := TRUE;
2339 "output_row"."scope_out" := NULL;
2340 "output_row"."disabled_out" := NULL;
2341 RETURN NEXT "output_row";
2342 RETURN;
2343 END IF;
2344 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2345 WHERE "issue_id" = "issue_id_p"
2346 AND "member_id" = "output_row"."member_id";
2347 IF "delegating_voter_row"."member_id" ISNULL THEN
2348 RETURN;
2349 END IF;
2350 "output_row"."scope_out" := "delegating_voter_row"."scope";
2351 RETURN NEXT "output_row";
2352 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2353 "output_row"."scope_in" := "output_row"."scope_out";
2354 END LOOP;
2355 END;
2356 $$;
2358 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2359 ( "member"."id"%TYPE,
2360 "member"."id"%TYPE )
2361 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2364 CREATE FUNCTION "delegation_chain"
2365 ( "member_id_p" "member"."id"%TYPE,
2366 "unit_id_p" "unit"."id"%TYPE,
2367 "area_id_p" "area"."id"%TYPE,
2368 "issue_id_p" "issue"."id"%TYPE,
2369 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2370 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2371 RETURNS SETOF "delegation_chain_row"
2372 LANGUAGE 'plpgsql' STABLE AS $$
2373 DECLARE
2374 "scope_v" "delegation_scope";
2375 "unit_id_v" "unit"."id"%TYPE;
2376 "area_id_v" "area"."id"%TYPE;
2377 "issue_row" "issue"%ROWTYPE;
2378 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2379 "loop_member_id_v" "member"."id"%TYPE;
2380 "output_row" "delegation_chain_row";
2381 "output_rows" "delegation_chain_row"[];
2382 "simulate_v" BOOLEAN;
2383 "simulate_here_v" BOOLEAN;
2384 "delegation_row" "delegation"%ROWTYPE;
2385 "row_count" INT4;
2386 "i" INT4;
2387 "loop_v" BOOLEAN;
2388 BEGIN
2389 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2390 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2391 END IF;
2392 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2393 "simulate_v" := TRUE;
2394 ELSE
2395 "simulate_v" := FALSE;
2396 END IF;
2397 IF
2398 "unit_id_p" NOTNULL AND
2399 "area_id_p" ISNULL AND
2400 "issue_id_p" ISNULL
2401 THEN
2402 "scope_v" := 'unit';
2403 "unit_id_v" := "unit_id_p";
2404 ELSIF
2405 "unit_id_p" ISNULL AND
2406 "area_id_p" NOTNULL AND
2407 "issue_id_p" ISNULL
2408 THEN
2409 "scope_v" := 'area';
2410 "area_id_v" := "area_id_p";
2411 SELECT "unit_id" INTO "unit_id_v"
2412 FROM "area" WHERE "id" = "area_id_v";
2413 ELSIF
2414 "unit_id_p" ISNULL AND
2415 "area_id_p" ISNULL AND
2416 "issue_id_p" NOTNULL
2417 THEN
2418 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2419 IF "issue_row"."id" ISNULL THEN
2420 RETURN;
2421 END IF;
2422 IF "issue_row"."closed" NOTNULL THEN
2423 IF "simulate_v" THEN
2424 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2425 END IF;
2426 FOR "output_row" IN
2427 SELECT * FROM
2428 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2429 LOOP
2430 RETURN NEXT "output_row";
2431 END LOOP;
2432 RETURN;
2433 END IF;
2434 "scope_v" := 'issue';
2435 SELECT "area_id" INTO "area_id_v"
2436 FROM "issue" WHERE "id" = "issue_id_p";
2437 SELECT "unit_id" INTO "unit_id_v"
2438 FROM "area" WHERE "id" = "area_id_v";
2439 ELSE
2440 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2441 END IF;
2442 "visited_member_ids" := '{}';
2443 "loop_member_id_v" := NULL;
2444 "output_rows" := '{}';
2445 "output_row"."index" := 0;
2446 "output_row"."member_id" := "member_id_p";
2447 "output_row"."member_valid" := TRUE;
2448 "output_row"."participation" := FALSE;
2449 "output_row"."overridden" := FALSE;
2450 "output_row"."disabled_out" := FALSE;
2451 "output_row"."scope_out" := NULL;
2452 LOOP
2453 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2454 "loop_member_id_v" := "output_row"."member_id";
2455 ELSE
2456 "visited_member_ids" :=
2457 "visited_member_ids" || "output_row"."member_id";
2458 END IF;
2459 IF "output_row"."participation" ISNULL THEN
2460 "output_row"."overridden" := NULL;
2461 ELSIF "output_row"."participation" THEN
2462 "output_row"."overridden" := TRUE;
2463 END IF;
2464 "output_row"."scope_in" := "output_row"."scope_out";
2465 "output_row"."member_valid" := EXISTS (
2466 SELECT NULL FROM "member" JOIN "privilege"
2467 ON "privilege"."member_id" = "member"."id"
2468 AND "privilege"."unit_id" = "unit_id_v"
2469 WHERE "id" = "output_row"."member_id"
2470 AND "member"."active" AND "privilege"."voting_right"
2471 );
2472 "simulate_here_v" := (
2473 "simulate_v" AND
2474 "output_row"."member_id" = "member_id_p"
2475 );
2476 "delegation_row" := ROW(NULL);
2477 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2478 IF "scope_v" = 'unit' THEN
2479 IF NOT "simulate_here_v" THEN
2480 SELECT * INTO "delegation_row" FROM "delegation"
2481 WHERE "truster_id" = "output_row"."member_id"
2482 AND "unit_id" = "unit_id_v";
2483 END IF;
2484 ELSIF "scope_v" = 'area' THEN
2485 "output_row"."participation" := EXISTS (
2486 SELECT NULL FROM "membership"
2487 WHERE "area_id" = "area_id_p"
2488 AND "member_id" = "output_row"."member_id"
2489 );
2490 IF "simulate_here_v" THEN
2491 IF "simulate_trustee_id_p" ISNULL THEN
2492 SELECT * INTO "delegation_row" FROM "delegation"
2493 WHERE "truster_id" = "output_row"."member_id"
2494 AND "unit_id" = "unit_id_v";
2495 END IF;
2496 ELSE
2497 SELECT * INTO "delegation_row" FROM "delegation"
2498 WHERE "truster_id" = "output_row"."member_id"
2499 AND (
2500 "unit_id" = "unit_id_v" OR
2501 "area_id" = "area_id_v"
2503 ORDER BY "scope" DESC;
2504 END IF;
2505 ELSIF "scope_v" = 'issue' THEN
2506 IF "issue_row"."fully_frozen" ISNULL THEN
2507 "output_row"."participation" := EXISTS (
2508 SELECT NULL FROM "interest"
2509 WHERE "issue_id" = "issue_id_p"
2510 AND "member_id" = "output_row"."member_id"
2511 );
2512 ELSE
2513 IF "output_row"."member_id" = "member_id_p" THEN
2514 "output_row"."participation" := EXISTS (
2515 SELECT NULL FROM "direct_voter"
2516 WHERE "issue_id" = "issue_id_p"
2517 AND "member_id" = "output_row"."member_id"
2518 );
2519 ELSE
2520 "output_row"."participation" := NULL;
2521 END IF;
2522 END IF;
2523 IF "simulate_here_v" THEN
2524 IF "simulate_trustee_id_p" ISNULL THEN
2525 SELECT * INTO "delegation_row" FROM "delegation"
2526 WHERE "truster_id" = "output_row"."member_id"
2527 AND (
2528 "unit_id" = "unit_id_v" OR
2529 "area_id" = "area_id_v"
2531 ORDER BY "scope" DESC;
2532 END IF;
2533 ELSE
2534 SELECT * INTO "delegation_row" FROM "delegation"
2535 WHERE "truster_id" = "output_row"."member_id"
2536 AND (
2537 "unit_id" = "unit_id_v" OR
2538 "area_id" = "area_id_v" OR
2539 "issue_id" = "issue_id_p"
2541 ORDER BY "scope" DESC;
2542 END IF;
2543 END IF;
2544 ELSE
2545 "output_row"."participation" := FALSE;
2546 END IF;
2547 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2548 "output_row"."scope_out" := "scope_v";
2549 "output_rows" := "output_rows" || "output_row";
2550 "output_row"."member_id" := "simulate_trustee_id_p";
2551 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2552 "output_row"."scope_out" := "delegation_row"."scope";
2553 "output_rows" := "output_rows" || "output_row";
2554 "output_row"."member_id" := "delegation_row"."trustee_id";
2555 ELSIF "delegation_row"."scope" NOTNULL THEN
2556 "output_row"."scope_out" := "delegation_row"."scope";
2557 "output_row"."disabled_out" := TRUE;
2558 "output_rows" := "output_rows" || "output_row";
2559 EXIT;
2560 ELSE
2561 "output_row"."scope_out" := NULL;
2562 "output_rows" := "output_rows" || "output_row";
2563 EXIT;
2564 END IF;
2565 EXIT WHEN "loop_member_id_v" NOTNULL;
2566 "output_row"."index" := "output_row"."index" + 1;
2567 END LOOP;
2568 "row_count" := array_upper("output_rows", 1);
2569 "i" := 1;
2570 "loop_v" := FALSE;
2571 LOOP
2572 "output_row" := "output_rows"["i"];
2573 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2574 IF "loop_v" THEN
2575 IF "i" + 1 = "row_count" THEN
2576 "output_row"."loop" := 'last';
2577 ELSIF "i" = "row_count" THEN
2578 "output_row"."loop" := 'repetition';
2579 ELSE
2580 "output_row"."loop" := 'intermediate';
2581 END IF;
2582 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2583 "output_row"."loop" := 'first';
2584 "loop_v" := TRUE;
2585 END IF;
2586 IF "scope_v" = 'unit' THEN
2587 "output_row"."participation" := NULL;
2588 END IF;
2589 RETURN NEXT "output_row";
2590 "i" := "i" + 1;
2591 END LOOP;
2592 RETURN;
2593 END;
2594 $$;
2596 COMMENT ON FUNCTION "delegation_chain"
2597 ( "member"."id"%TYPE,
2598 "unit"."id"%TYPE,
2599 "area"."id"%TYPE,
2600 "issue"."id"%TYPE,
2601 "member"."id"%TYPE,
2602 BOOLEAN )
2603 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2607 ---------------------------------------------------------
2608 -- Single row returning function for delegation chains --
2609 ---------------------------------------------------------
2612 CREATE TYPE "delegation_info_loop_type" AS ENUM
2613 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2615 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''';
2618 CREATE TYPE "delegation_info_type" AS (
2619 "own_participation" BOOLEAN,
2620 "own_delegation_scope" "delegation_scope",
2621 "first_trustee_id" INT4,
2622 "first_trustee_participation" BOOLEAN,
2623 "first_trustee_ellipsis" BOOLEAN,
2624 "other_trustee_id" INT4,
2625 "other_trustee_participation" BOOLEAN,
2626 "other_trustee_ellipsis" BOOLEAN,
2627 "delegation_loop" "delegation_info_loop_type",
2628 "participating_member_id" INT4 );
2630 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';
2632 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2633 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2634 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2635 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2636 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2637 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2638 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)';
2639 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2640 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';
2641 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2644 CREATE FUNCTION "delegation_info"
2645 ( "member_id_p" "member"."id"%TYPE,
2646 "unit_id_p" "unit"."id"%TYPE,
2647 "area_id_p" "area"."id"%TYPE,
2648 "issue_id_p" "issue"."id"%TYPE,
2649 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2650 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2651 RETURNS "delegation_info_type"
2652 LANGUAGE 'plpgsql' STABLE AS $$
2653 DECLARE
2654 "current_row" "delegation_chain_row";
2655 "result" "delegation_info_type";
2656 BEGIN
2657 "result"."own_participation" := FALSE;
2658 FOR "current_row" IN
2659 SELECT * FROM "delegation_chain"(
2660 "member_id_p",
2661 "unit_id_p", "area_id_p", "issue_id_p",
2662 "simulate_trustee_id_p", "simulate_default_p")
2663 LOOP
2664 IF
2665 "result"."participating_member_id" ISNULL AND
2666 "current_row"."participation"
2667 THEN
2668 "result"."participating_member_id" := "current_row"."member_id";
2669 END IF;
2670 IF "current_row"."member_id" = "member_id_p" THEN
2671 "result"."own_participation" := "current_row"."participation";
2672 "result"."own_delegation_scope" := "current_row"."scope_out";
2673 IF "current_row"."loop" = 'first' THEN
2674 "result"."delegation_loop" := 'own';
2675 END IF;
2676 ELSIF
2677 "current_row"."member_valid" AND
2678 ( "current_row"."loop" ISNULL OR
2679 "current_row"."loop" != 'repetition' )
2680 THEN
2681 IF "result"."first_trustee_id" ISNULL THEN
2682 "result"."first_trustee_id" := "current_row"."member_id";
2683 "result"."first_trustee_participation" := "current_row"."participation";
2684 "result"."first_trustee_ellipsis" := FALSE;
2685 IF "current_row"."loop" = 'first' THEN
2686 "result"."delegation_loop" := 'first';
2687 END IF;
2688 ELSIF "result"."other_trustee_id" ISNULL THEN
2689 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2690 "result"."other_trustee_id" := "current_row"."member_id";
2691 "result"."other_trustee_participation" := TRUE;
2692 "result"."other_trustee_ellipsis" := FALSE;
2693 IF "current_row"."loop" = 'first' THEN
2694 "result"."delegation_loop" := 'other';
2695 END IF;
2696 ELSE
2697 "result"."first_trustee_ellipsis" := TRUE;
2698 IF "current_row"."loop" = 'first' THEN
2699 "result"."delegation_loop" := 'first_ellipsis';
2700 END IF;
2701 END IF;
2702 ELSE
2703 "result"."other_trustee_ellipsis" := TRUE;
2704 IF "current_row"."loop" = 'first' THEN
2705 "result"."delegation_loop" := 'other_ellipsis';
2706 END IF;
2707 END IF;
2708 END IF;
2709 END LOOP;
2710 RETURN "result";
2711 END;
2712 $$;
2714 COMMENT ON FUNCTION "delegation_info"
2715 ( "member"."id"%TYPE,
2716 "unit"."id"%TYPE,
2717 "area"."id"%TYPE,
2718 "issue"."id"%TYPE,
2719 "member"."id"%TYPE,
2720 BOOLEAN )
2721 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2725 ---------------------------
2726 -- Transaction isolation --
2727 ---------------------------
2730 CREATE FUNCTION "require_transaction_isolation"()
2731 RETURNS VOID
2732 LANGUAGE 'plpgsql' VOLATILE AS $$
2733 BEGIN
2734 IF
2735 current_setting('transaction_isolation') NOT IN
2736 ('repeatable read', 'serializable')
2737 THEN
2738 RAISE EXCEPTION 'Insufficient transaction isolation level';
2739 END IF;
2740 RETURN;
2741 END;
2742 $$;
2744 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
2747 CREATE FUNCTION "dont_require_transaction_isolation"()
2748 RETURNS VOID
2749 LANGUAGE 'plpgsql' VOLATILE AS $$
2750 BEGIN
2751 IF
2752 current_setting('transaction_isolation') IN
2753 ('repeatable read', 'serializable')
2754 THEN
2755 RAISE WARNING 'Unneccessary transaction isolation level: %',
2756 current_setting('transaction_isolation');
2757 END IF;
2758 RETURN;
2759 END;
2760 $$;
2762 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
2766 ------------------------------------------------------------------------
2767 -- Regular tasks, except calculcation of snapshots and voting results --
2768 ------------------------------------------------------------------------
2771 CREATE FUNCTION "check_activity"()
2772 RETURNS VOID
2773 LANGUAGE 'plpgsql' VOLATILE AS $$
2774 DECLARE
2775 "system_setting_row" "system_setting"%ROWTYPE;
2776 BEGIN
2777 PERFORM "dont_require_transaction_isolation"();
2778 SELECT * INTO "system_setting_row" FROM "system_setting";
2779 IF "system_setting_row"."member_ttl" NOTNULL THEN
2780 UPDATE "member" SET "active" = FALSE
2781 WHERE "active" = TRUE
2782 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2783 END IF;
2784 RETURN;
2785 END;
2786 $$;
2788 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2791 CREATE FUNCTION "calculate_member_counts"()
2792 RETURNS VOID
2793 LANGUAGE 'plpgsql' VOLATILE AS $$
2794 BEGIN
2795 PERFORM "require_transaction_isolation"();
2796 DELETE FROM "member_count";
2797 INSERT INTO "member_count" ("total_count")
2798 SELECT "total_count" FROM "member_count_view";
2799 UPDATE "unit" SET "member_count" = "view"."member_count"
2800 FROM "unit_member_count" AS "view"
2801 WHERE "view"."unit_id" = "unit"."id";
2802 UPDATE "area" SET
2803 "direct_member_count" = "view"."direct_member_count",
2804 "member_weight" = "view"."member_weight"
2805 FROM "area_member_count" AS "view"
2806 WHERE "view"."area_id" = "area"."id";
2807 RETURN;
2808 END;
2809 $$;
2811 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"';
2815 ------------------------------------
2816 -- Calculation of harmonic weight --
2817 ------------------------------------
2820 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2821 SELECT
2822 "direct_interest_snapshot"."issue_id",
2823 "direct_interest_snapshot"."event",
2824 "direct_interest_snapshot"."member_id",
2825 "direct_interest_snapshot"."weight" AS "weight_num",
2826 count("initiative"."id") AS "weight_den"
2827 FROM "issue"
2828 JOIN "direct_interest_snapshot"
2829 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
2830 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
2831 JOIN "initiative"
2832 ON "issue"."id" = "initiative"."issue_id"
2833 AND "initiative"."harmonic_weight" ISNULL
2834 JOIN "direct_supporter_snapshot"
2835 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2836 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
2837 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
2838 AND (
2839 "direct_supporter_snapshot"."satisfied" = TRUE OR
2840 coalesce("initiative"."admitted", FALSE) = FALSE
2842 GROUP BY
2843 "direct_interest_snapshot"."issue_id",
2844 "direct_interest_snapshot"."event",
2845 "direct_interest_snapshot"."member_id",
2846 "direct_interest_snapshot"."weight";
2848 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
2851 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
2852 SELECT
2853 "initiative"."issue_id",
2854 "initiative"."id" AS "initiative_id",
2855 "initiative"."admitted",
2856 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
2857 "remaining_harmonic_supporter_weight"."weight_den"
2858 FROM "remaining_harmonic_supporter_weight"
2859 JOIN "initiative"
2860 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
2861 AND "initiative"."harmonic_weight" ISNULL
2862 JOIN "direct_supporter_snapshot"
2863 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2864 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
2865 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
2866 AND (
2867 "direct_supporter_snapshot"."satisfied" = TRUE OR
2868 coalesce("initiative"."admitted", FALSE) = FALSE
2870 GROUP BY
2871 "initiative"."issue_id",
2872 "initiative"."id",
2873 "initiative"."admitted",
2874 "remaining_harmonic_supporter_weight"."weight_den";
2876 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
2879 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
2880 SELECT
2881 "issue_id",
2882 "id" AS "initiative_id",
2883 "admitted",
2884 0 AS "weight_num",
2885 1 AS "weight_den"
2886 FROM "initiative"
2887 WHERE "harmonic_weight" ISNULL;
2889 COMMENT ON VIEW "remaining_harmonic_initiative_weight_dummies" IS 'Helper view for function "set_harmonic_initiative_weights" providing dummy weights of zero value, which are needed for corner cases where there are no supporters for an initiative at all';
2892 CREATE FUNCTION "set_harmonic_initiative_weights"
2893 ( "issue_id_p" "issue"."id"%TYPE )
2894 RETURNS VOID
2895 LANGUAGE 'plpgsql' VOLATILE AS $$
2896 DECLARE
2897 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
2898 "i" INT4;
2899 "count_v" INT4;
2900 "summand_v" FLOAT;
2901 "id_ary" INT4[];
2902 "weight_ary" FLOAT[];
2903 "min_weight_v" FLOAT;
2904 BEGIN
2905 PERFORM "require_transaction_isolation"();
2906 UPDATE "initiative" SET "harmonic_weight" = NULL
2907 WHERE "issue_id" = "issue_id_p";
2908 LOOP
2909 "min_weight_v" := NULL;
2910 "i" := 0;
2911 "count_v" := 0;
2912 FOR "weight_row" IN
2913 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
2914 WHERE "issue_id" = "issue_id_p"
2915 AND (
2916 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
2917 SELECT NULL FROM "initiative"
2918 WHERE "issue_id" = "issue_id_p"
2919 AND "harmonic_weight" ISNULL
2920 AND coalesce("admitted", FALSE) = FALSE
2923 UNION ALL -- needed for corner cases
2924 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
2925 WHERE "issue_id" = "issue_id_p"
2926 AND (
2927 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
2928 SELECT NULL FROM "initiative"
2929 WHERE "issue_id" = "issue_id_p"
2930 AND "harmonic_weight" ISNULL
2931 AND coalesce("admitted", FALSE) = FALSE
2934 ORDER BY "initiative_id" DESC, "weight_den" DESC
2935 -- NOTE: non-admitted initiatives placed first (at last positions),
2936 -- latest initiatives treated worse in case of tie
2937 LOOP
2938 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
2939 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
2940 "i" := "i" + 1;
2941 "count_v" := "i";
2942 "id_ary"["i"] := "weight_row"."initiative_id";
2943 "weight_ary"["i"] := "summand_v";
2944 ELSE
2945 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
2946 END IF;
2947 END LOOP;
2948 EXIT WHEN "count_v" = 0;
2949 "i" := 1;
2950 LOOP
2951 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
2952 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
2953 "min_weight_v" := "weight_ary"["i"];
2954 END IF;
2955 "i" := "i" + 1;
2956 EXIT WHEN "i" > "count_v";
2957 END LOOP;
2958 "i" := 1;
2959 LOOP
2960 IF "weight_ary"["i"] = "min_weight_v" THEN
2961 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
2962 WHERE "id" = "id_ary"["i"];
2963 EXIT;
2964 END IF;
2965 "i" := "i" + 1;
2966 END LOOP;
2967 END LOOP;
2968 UPDATE "initiative" SET "harmonic_weight" = 0
2969 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
2970 END;
2971 $$;
2973 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
2974 ( "issue"."id"%TYPE )
2975 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
2979 ------------------------------
2980 -- Calculation of snapshots --
2981 ------------------------------
2984 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2985 ( "issue_id_p" "issue"."id"%TYPE,
2986 "member_id_p" "member"."id"%TYPE,
2987 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2988 RETURNS "direct_population_snapshot"."weight"%TYPE
2989 LANGUAGE 'plpgsql' VOLATILE AS $$
2990 DECLARE
2991 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2992 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2993 "weight_v" INT4;
2994 "sub_weight_v" INT4;
2995 BEGIN
2996 PERFORM "require_transaction_isolation"();
2997 "weight_v" := 0;
2998 FOR "issue_delegation_row" IN
2999 SELECT * FROM "issue_delegation"
3000 WHERE "trustee_id" = "member_id_p"
3001 AND "issue_id" = "issue_id_p"
3002 LOOP
3003 IF NOT EXISTS (
3004 SELECT NULL FROM "direct_population_snapshot"
3005 WHERE "issue_id" = "issue_id_p"
3006 AND "event" = 'periodic'
3007 AND "member_id" = "issue_delegation_row"."truster_id"
3008 ) AND NOT EXISTS (
3009 SELECT NULL FROM "delegating_population_snapshot"
3010 WHERE "issue_id" = "issue_id_p"
3011 AND "event" = 'periodic'
3012 AND "member_id" = "issue_delegation_row"."truster_id"
3013 ) THEN
3014 "delegate_member_ids_v" :=
3015 "member_id_p" || "delegate_member_ids_p";
3016 INSERT INTO "delegating_population_snapshot" (
3017 "issue_id",
3018 "event",
3019 "member_id",
3020 "scope",
3021 "delegate_member_ids"
3022 ) VALUES (
3023 "issue_id_p",
3024 'periodic',
3025 "issue_delegation_row"."truster_id",
3026 "issue_delegation_row"."scope",
3027 "delegate_member_ids_v"
3028 );
3029 "sub_weight_v" := 1 +
3030 "weight_of_added_delegations_for_population_snapshot"(
3031 "issue_id_p",
3032 "issue_delegation_row"."truster_id",
3033 "delegate_member_ids_v"
3034 );
3035 UPDATE "delegating_population_snapshot"
3036 SET "weight" = "sub_weight_v"
3037 WHERE "issue_id" = "issue_id_p"
3038 AND "event" = 'periodic'
3039 AND "member_id" = "issue_delegation_row"."truster_id";
3040 "weight_v" := "weight_v" + "sub_weight_v";
3041 END IF;
3042 END LOOP;
3043 RETURN "weight_v";
3044 END;
3045 $$;
3047 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3048 ( "issue"."id"%TYPE,
3049 "member"."id"%TYPE,
3050 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3051 IS 'Helper function for "create_population_snapshot" function';
3054 CREATE FUNCTION "create_population_snapshot"
3055 ( "issue_id_p" "issue"."id"%TYPE )
3056 RETURNS VOID
3057 LANGUAGE 'plpgsql' VOLATILE AS $$
3058 DECLARE
3059 "member_id_v" "member"."id"%TYPE;
3060 BEGIN
3061 PERFORM "require_transaction_isolation"();
3062 DELETE FROM "direct_population_snapshot"
3063 WHERE "issue_id" = "issue_id_p"
3064 AND "event" = 'periodic';
3065 DELETE FROM "delegating_population_snapshot"
3066 WHERE "issue_id" = "issue_id_p"
3067 AND "event" = 'periodic';
3068 INSERT INTO "direct_population_snapshot"
3069 ("issue_id", "event", "member_id")
3070 SELECT
3071 "issue_id_p" AS "issue_id",
3072 'periodic'::"snapshot_event" AS "event",
3073 "member"."id" AS "member_id"
3074 FROM "issue"
3075 JOIN "area" ON "issue"."area_id" = "area"."id"
3076 JOIN "membership" ON "area"."id" = "membership"."area_id"
3077 JOIN "member" ON "membership"."member_id" = "member"."id"
3078 JOIN "privilege"
3079 ON "privilege"."unit_id" = "area"."unit_id"
3080 AND "privilege"."member_id" = "member"."id"
3081 WHERE "issue"."id" = "issue_id_p"
3082 AND "member"."active" AND "privilege"."voting_right"
3083 UNION
3084 SELECT
3085 "issue_id_p" AS "issue_id",
3086 'periodic'::"snapshot_event" AS "event",
3087 "member"."id" AS "member_id"
3088 FROM "issue"
3089 JOIN "area" ON "issue"."area_id" = "area"."id"
3090 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3091 JOIN "member" ON "interest"."member_id" = "member"."id"
3092 JOIN "privilege"
3093 ON "privilege"."unit_id" = "area"."unit_id"
3094 AND "privilege"."member_id" = "member"."id"
3095 WHERE "issue"."id" = "issue_id_p"
3096 AND "member"."active" AND "privilege"."voting_right";
3097 FOR "member_id_v" IN
3098 SELECT "member_id" FROM "direct_population_snapshot"
3099 WHERE "issue_id" = "issue_id_p"
3100 AND "event" = 'periodic'
3101 LOOP
3102 UPDATE "direct_population_snapshot" SET
3103 "weight" = 1 +
3104 "weight_of_added_delegations_for_population_snapshot"(
3105 "issue_id_p",
3106 "member_id_v",
3107 '{}'
3109 WHERE "issue_id" = "issue_id_p"
3110 AND "event" = 'periodic'
3111 AND "member_id" = "member_id_v";
3112 END LOOP;
3113 RETURN;
3114 END;
3115 $$;
3117 COMMENT ON FUNCTION "create_population_snapshot"
3118 ( "issue"."id"%TYPE )
3119 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.';
3122 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3123 ( "issue_id_p" "issue"."id"%TYPE,
3124 "member_id_p" "member"."id"%TYPE,
3125 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3126 RETURNS "direct_interest_snapshot"."weight"%TYPE
3127 LANGUAGE 'plpgsql' VOLATILE AS $$
3128 DECLARE
3129 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3130 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3131 "weight_v" INT4;
3132 "sub_weight_v" INT4;
3133 BEGIN
3134 PERFORM "require_transaction_isolation"();
3135 "weight_v" := 0;
3136 FOR "issue_delegation_row" IN
3137 SELECT * FROM "issue_delegation"
3138 WHERE "trustee_id" = "member_id_p"
3139 AND "issue_id" = "issue_id_p"
3140 LOOP
3141 IF NOT EXISTS (
3142 SELECT NULL FROM "direct_interest_snapshot"
3143 WHERE "issue_id" = "issue_id_p"
3144 AND "event" = 'periodic'
3145 AND "member_id" = "issue_delegation_row"."truster_id"
3146 ) AND NOT EXISTS (
3147 SELECT NULL FROM "delegating_interest_snapshot"
3148 WHERE "issue_id" = "issue_id_p"
3149 AND "event" = 'periodic'
3150 AND "member_id" = "issue_delegation_row"."truster_id"
3151 ) THEN
3152 "delegate_member_ids_v" :=
3153 "member_id_p" || "delegate_member_ids_p";
3154 INSERT INTO "delegating_interest_snapshot" (
3155 "issue_id",
3156 "event",
3157 "member_id",
3158 "scope",
3159 "delegate_member_ids"
3160 ) VALUES (
3161 "issue_id_p",
3162 'periodic',
3163 "issue_delegation_row"."truster_id",
3164 "issue_delegation_row"."scope",
3165 "delegate_member_ids_v"
3166 );
3167 "sub_weight_v" := 1 +
3168 "weight_of_added_delegations_for_interest_snapshot"(
3169 "issue_id_p",
3170 "issue_delegation_row"."truster_id",
3171 "delegate_member_ids_v"
3172 );
3173 UPDATE "delegating_interest_snapshot"
3174 SET "weight" = "sub_weight_v"
3175 WHERE "issue_id" = "issue_id_p"
3176 AND "event" = 'periodic'
3177 AND "member_id" = "issue_delegation_row"."truster_id";
3178 "weight_v" := "weight_v" + "sub_weight_v";
3179 END IF;
3180 END LOOP;
3181 RETURN "weight_v";
3182 END;
3183 $$;
3185 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3186 ( "issue"."id"%TYPE,
3187 "member"."id"%TYPE,
3188 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3189 IS 'Helper function for "create_interest_snapshot" function';
3192 CREATE FUNCTION "create_interest_snapshot"
3193 ( "issue_id_p" "issue"."id"%TYPE )
3194 RETURNS VOID
3195 LANGUAGE 'plpgsql' VOLATILE AS $$
3196 DECLARE
3197 "member_id_v" "member"."id"%TYPE;
3198 BEGIN
3199 PERFORM "require_transaction_isolation"();
3200 DELETE FROM "direct_interest_snapshot"
3201 WHERE "issue_id" = "issue_id_p"
3202 AND "event" = 'periodic';
3203 DELETE FROM "delegating_interest_snapshot"
3204 WHERE "issue_id" = "issue_id_p"
3205 AND "event" = 'periodic';
3206 DELETE FROM "direct_supporter_snapshot"
3207 USING "initiative" -- NOTE: due to missing index on issue_id
3208 WHERE "initiative"."issue_id" = "issue_id_p"
3209 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3210 AND "direct_supporter_snapshot"."event" = 'periodic';
3211 INSERT INTO "direct_interest_snapshot"
3212 ("issue_id", "event", "member_id")
3213 SELECT
3214 "issue_id_p" AS "issue_id",
3215 'periodic' AS "event",
3216 "member"."id" AS "member_id"
3217 FROM "issue"
3218 JOIN "area" ON "issue"."area_id" = "area"."id"
3219 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3220 JOIN "member" ON "interest"."member_id" = "member"."id"
3221 JOIN "privilege"
3222 ON "privilege"."unit_id" = "area"."unit_id"
3223 AND "privilege"."member_id" = "member"."id"
3224 WHERE "issue"."id" = "issue_id_p"
3225 AND "member"."active" AND "privilege"."voting_right";
3226 FOR "member_id_v" IN
3227 SELECT "member_id" FROM "direct_interest_snapshot"
3228 WHERE "issue_id" = "issue_id_p"
3229 AND "event" = 'periodic'
3230 LOOP
3231 UPDATE "direct_interest_snapshot" SET
3232 "weight" = 1 +
3233 "weight_of_added_delegations_for_interest_snapshot"(
3234 "issue_id_p",
3235 "member_id_v",
3236 '{}'
3238 WHERE "issue_id" = "issue_id_p"
3239 AND "event" = 'periodic'
3240 AND "member_id" = "member_id_v";
3241 END LOOP;
3242 INSERT INTO "direct_supporter_snapshot"
3243 ( "issue_id", "initiative_id", "event", "member_id",
3244 "draft_id", "informed", "satisfied" )
3245 SELECT
3246 "issue_id_p" AS "issue_id",
3247 "initiative"."id" AS "initiative_id",
3248 'periodic' AS "event",
3249 "supporter"."member_id" AS "member_id",
3250 "supporter"."draft_id" AS "draft_id",
3251 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3252 NOT EXISTS (
3253 SELECT NULL FROM "critical_opinion"
3254 WHERE "initiative_id" = "initiative"."id"
3255 AND "member_id" = "supporter"."member_id"
3256 ) AS "satisfied"
3257 FROM "initiative"
3258 JOIN "supporter"
3259 ON "supporter"."initiative_id" = "initiative"."id"
3260 JOIN "current_draft"
3261 ON "initiative"."id" = "current_draft"."initiative_id"
3262 JOIN "direct_interest_snapshot"
3263 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3264 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3265 AND "event" = 'periodic'
3266 WHERE "initiative"."issue_id" = "issue_id_p";
3267 RETURN;
3268 END;
3269 $$;
3271 COMMENT ON FUNCTION "create_interest_snapshot"
3272 ( "issue"."id"%TYPE )
3273 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.';
3276 CREATE FUNCTION "create_snapshot"
3277 ( "issue_id_p" "issue"."id"%TYPE )
3278 RETURNS VOID
3279 LANGUAGE 'plpgsql' VOLATILE AS $$
3280 DECLARE
3281 "initiative_id_v" "initiative"."id"%TYPE;
3282 "suggestion_id_v" "suggestion"."id"%TYPE;
3283 BEGIN
3284 PERFORM "require_transaction_isolation"();
3285 PERFORM "create_population_snapshot"("issue_id_p");
3286 PERFORM "create_interest_snapshot"("issue_id_p");
3287 UPDATE "issue" SET
3288 "snapshot" = coalesce("phase_finished", now()),
3289 "latest_snapshot_event" = 'periodic',
3290 "population" = (
3291 SELECT coalesce(sum("weight"), 0)
3292 FROM "direct_population_snapshot"
3293 WHERE "issue_id" = "issue_id_p"
3294 AND "event" = 'periodic'
3296 WHERE "id" = "issue_id_p";
3297 FOR "initiative_id_v" IN
3298 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3299 LOOP
3300 UPDATE "initiative" SET
3301 "supporter_count" = (
3302 SELECT coalesce(sum("di"."weight"), 0)
3303 FROM "direct_interest_snapshot" AS "di"
3304 JOIN "direct_supporter_snapshot" AS "ds"
3305 ON "di"."member_id" = "ds"."member_id"
3306 WHERE "di"."issue_id" = "issue_id_p"
3307 AND "di"."event" = 'periodic'
3308 AND "ds"."initiative_id" = "initiative_id_v"
3309 AND "ds"."event" = 'periodic'
3310 ),
3311 "informed_supporter_count" = (
3312 SELECT coalesce(sum("di"."weight"), 0)
3313 FROM "direct_interest_snapshot" AS "di"
3314 JOIN "direct_supporter_snapshot" AS "ds"
3315 ON "di"."member_id" = "ds"."member_id"
3316 WHERE "di"."issue_id" = "issue_id_p"
3317 AND "di"."event" = 'periodic'
3318 AND "ds"."initiative_id" = "initiative_id_v"
3319 AND "ds"."event" = 'periodic'
3320 AND "ds"."informed"
3321 ),
3322 "satisfied_supporter_count" = (
3323 SELECT coalesce(sum("di"."weight"), 0)
3324 FROM "direct_interest_snapshot" AS "di"
3325 JOIN "direct_supporter_snapshot" AS "ds"
3326 ON "di"."member_id" = "ds"."member_id"
3327 WHERE "di"."issue_id" = "issue_id_p"
3328 AND "di"."event" = 'periodic'
3329 AND "ds"."initiative_id" = "initiative_id_v"
3330 AND "ds"."event" = 'periodic'
3331 AND "ds"."satisfied"
3332 ),
3333 "satisfied_informed_supporter_count" = (
3334 SELECT coalesce(sum("di"."weight"), 0)
3335 FROM "direct_interest_snapshot" AS "di"
3336 JOIN "direct_supporter_snapshot" AS "ds"
3337 ON "di"."member_id" = "ds"."member_id"
3338 WHERE "di"."issue_id" = "issue_id_p"
3339 AND "di"."event" = 'periodic'
3340 AND "ds"."initiative_id" = "initiative_id_v"
3341 AND "ds"."event" = 'periodic'
3342 AND "ds"."informed"
3343 AND "ds"."satisfied"
3345 WHERE "id" = "initiative_id_v";
3346 FOR "suggestion_id_v" IN
3347 SELECT "id" FROM "suggestion"
3348 WHERE "initiative_id" = "initiative_id_v"
3349 LOOP
3350 UPDATE "suggestion" SET
3351 "minus2_unfulfilled_count" = (
3352 SELECT coalesce(sum("snapshot"."weight"), 0)
3353 FROM "issue" CROSS JOIN "opinion"
3354 JOIN "direct_interest_snapshot" AS "snapshot"
3355 ON "snapshot"."issue_id" = "issue"."id"
3356 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3357 AND "snapshot"."member_id" = "opinion"."member_id"
3358 WHERE "issue"."id" = "issue_id_p"
3359 AND "opinion"."suggestion_id" = "suggestion_id_v"
3360 AND "opinion"."degree" = -2
3361 AND "opinion"."fulfilled" = FALSE
3362 ),
3363 "minus2_fulfilled_count" = (
3364 SELECT coalesce(sum("snapshot"."weight"), 0)
3365 FROM "issue" CROSS JOIN "opinion"
3366 JOIN "direct_interest_snapshot" AS "snapshot"
3367 ON "snapshot"."issue_id" = "issue"."id"
3368 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3369 AND "snapshot"."member_id" = "opinion"."member_id"
3370 WHERE "issue"."id" = "issue_id_p"
3371 AND "opinion"."suggestion_id" = "suggestion_id_v"
3372 AND "opinion"."degree" = -2
3373 AND "opinion"."fulfilled" = TRUE
3374 ),
3375 "minus1_unfulfilled_count" = (
3376 SELECT coalesce(sum("snapshot"."weight"), 0)
3377 FROM "issue" CROSS JOIN "opinion"
3378 JOIN "direct_interest_snapshot" AS "snapshot"
3379 ON "snapshot"."issue_id" = "issue"."id"
3380 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3381 AND "snapshot"."member_id" = "opinion"."member_id"
3382 WHERE "issue"."id" = "issue_id_p"
3383 AND "opinion"."suggestion_id" = "suggestion_id_v"
3384 AND "opinion"."degree" = -1
3385 AND "opinion"."fulfilled" = FALSE
3386 ),
3387 "minus1_fulfilled_count" = (
3388 SELECT coalesce(sum("snapshot"."weight"), 0)
3389 FROM "issue" CROSS JOIN "opinion"
3390 JOIN "direct_interest_snapshot" AS "snapshot"
3391 ON "snapshot"."issue_id" = "issue"."id"
3392 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3393 AND "snapshot"."member_id" = "opinion"."member_id"
3394 WHERE "issue"."id" = "issue_id_p"
3395 AND "opinion"."suggestion_id" = "suggestion_id_v"
3396 AND "opinion"."degree" = -1
3397 AND "opinion"."fulfilled" = TRUE
3398 ),
3399 "plus1_unfulfilled_count" = (
3400 SELECT coalesce(sum("snapshot"."weight"), 0)
3401 FROM "issue" CROSS JOIN "opinion"
3402 JOIN "direct_interest_snapshot" AS "snapshot"
3403 ON "snapshot"."issue_id" = "issue"."id"
3404 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3405 AND "snapshot"."member_id" = "opinion"."member_id"
3406 WHERE "issue"."id" = "issue_id_p"
3407 AND "opinion"."suggestion_id" = "suggestion_id_v"
3408 AND "opinion"."degree" = 1
3409 AND "opinion"."fulfilled" = FALSE
3410 ),
3411 "plus1_fulfilled_count" = (
3412 SELECT coalesce(sum("snapshot"."weight"), 0)
3413 FROM "issue" CROSS JOIN "opinion"
3414 JOIN "direct_interest_snapshot" AS "snapshot"
3415 ON "snapshot"."issue_id" = "issue"."id"
3416 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3417 AND "snapshot"."member_id" = "opinion"."member_id"
3418 WHERE "issue"."id" = "issue_id_p"
3419 AND "opinion"."suggestion_id" = "suggestion_id_v"
3420 AND "opinion"."degree" = 1
3421 AND "opinion"."fulfilled" = TRUE
3422 ),
3423 "plus2_unfulfilled_count" = (
3424 SELECT coalesce(sum("snapshot"."weight"), 0)
3425 FROM "issue" CROSS JOIN "opinion"
3426 JOIN "direct_interest_snapshot" AS "snapshot"
3427 ON "snapshot"."issue_id" = "issue"."id"
3428 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3429 AND "snapshot"."member_id" = "opinion"."member_id"
3430 WHERE "issue"."id" = "issue_id_p"
3431 AND "opinion"."suggestion_id" = "suggestion_id_v"
3432 AND "opinion"."degree" = 2
3433 AND "opinion"."fulfilled" = FALSE
3434 ),
3435 "plus2_fulfilled_count" = (
3436 SELECT coalesce(sum("snapshot"."weight"), 0)
3437 FROM "issue" CROSS JOIN "opinion"
3438 JOIN "direct_interest_snapshot" AS "snapshot"
3439 ON "snapshot"."issue_id" = "issue"."id"
3440 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3441 AND "snapshot"."member_id" = "opinion"."member_id"
3442 WHERE "issue"."id" = "issue_id_p"
3443 AND "opinion"."suggestion_id" = "suggestion_id_v"
3444 AND "opinion"."degree" = 2
3445 AND "opinion"."fulfilled" = TRUE
3447 WHERE "suggestion"."id" = "suggestion_id_v";
3448 END LOOP;
3449 END LOOP;
3450 RETURN;
3451 END;
3452 $$;
3454 COMMENT ON FUNCTION "create_snapshot"
3455 ( "issue"."id"%TYPE )
3456 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.';
3459 CREATE FUNCTION "set_snapshot_event"
3460 ( "issue_id_p" "issue"."id"%TYPE,
3461 "event_p" "snapshot_event" )
3462 RETURNS VOID
3463 LANGUAGE 'plpgsql' VOLATILE AS $$
3464 DECLARE
3465 "event_v" "issue"."latest_snapshot_event"%TYPE;
3466 BEGIN
3467 PERFORM "require_transaction_isolation"();
3468 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3469 WHERE "id" = "issue_id_p" FOR UPDATE;
3470 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3471 WHERE "id" = "issue_id_p";
3472 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3473 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3474 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3475 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3476 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3477 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3478 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3479 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3480 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3481 FROM "initiative" -- NOTE: due to missing index on issue_id
3482 WHERE "initiative"."issue_id" = "issue_id_p"
3483 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3484 AND "direct_supporter_snapshot"."event" = "event_v";
3485 RETURN;
3486 END;
3487 $$;
3489 COMMENT ON FUNCTION "set_snapshot_event"
3490 ( "issue"."id"%TYPE,
3491 "snapshot_event" )
3492 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3496 -----------------------
3497 -- Counting of votes --
3498 -----------------------
3501 CREATE FUNCTION "weight_of_added_vote_delegations"
3502 ( "issue_id_p" "issue"."id"%TYPE,
3503 "member_id_p" "member"."id"%TYPE,
3504 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3505 RETURNS "direct_voter"."weight"%TYPE
3506 LANGUAGE 'plpgsql' VOLATILE AS $$
3507 DECLARE
3508 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3509 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3510 "weight_v" INT4;
3511 "sub_weight_v" INT4;
3512 BEGIN
3513 PERFORM "require_transaction_isolation"();
3514 "weight_v" := 0;
3515 FOR "issue_delegation_row" IN
3516 SELECT * FROM "issue_delegation"
3517 WHERE "trustee_id" = "member_id_p"
3518 AND "issue_id" = "issue_id_p"
3519 LOOP
3520 IF NOT EXISTS (
3521 SELECT NULL FROM "direct_voter"
3522 WHERE "member_id" = "issue_delegation_row"."truster_id"
3523 AND "issue_id" = "issue_id_p"
3524 ) AND NOT EXISTS (
3525 SELECT NULL FROM "delegating_voter"
3526 WHERE "member_id" = "issue_delegation_row"."truster_id"
3527 AND "issue_id" = "issue_id_p"
3528 ) THEN
3529 "delegate_member_ids_v" :=
3530 "member_id_p" || "delegate_member_ids_p";
3531 INSERT INTO "delegating_voter" (
3532 "issue_id",
3533 "member_id",
3534 "scope",
3535 "delegate_member_ids"
3536 ) VALUES (
3537 "issue_id_p",
3538 "issue_delegation_row"."truster_id",
3539 "issue_delegation_row"."scope",
3540 "delegate_member_ids_v"
3541 );
3542 "sub_weight_v" := 1 +
3543 "weight_of_added_vote_delegations"(
3544 "issue_id_p",
3545 "issue_delegation_row"."truster_id",
3546 "delegate_member_ids_v"
3547 );
3548 UPDATE "delegating_voter"
3549 SET "weight" = "sub_weight_v"
3550 WHERE "issue_id" = "issue_id_p"
3551 AND "member_id" = "issue_delegation_row"."truster_id";
3552 "weight_v" := "weight_v" + "sub_weight_v";
3553 END IF;
3554 END LOOP;
3555 RETURN "weight_v";
3556 END;
3557 $$;
3559 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3560 ( "issue"."id"%TYPE,
3561 "member"."id"%TYPE,
3562 "delegating_voter"."delegate_member_ids"%TYPE )
3563 IS 'Helper function for "add_vote_delegations" function';
3566 CREATE FUNCTION "add_vote_delegations"
3567 ( "issue_id_p" "issue"."id"%TYPE )
3568 RETURNS VOID
3569 LANGUAGE 'plpgsql' VOLATILE AS $$
3570 DECLARE
3571 "member_id_v" "member"."id"%TYPE;
3572 BEGIN
3573 PERFORM "require_transaction_isolation"();
3574 FOR "member_id_v" IN
3575 SELECT "member_id" FROM "direct_voter"
3576 WHERE "issue_id" = "issue_id_p"
3577 LOOP
3578 UPDATE "direct_voter" SET
3579 "weight" = "weight" + "weight_of_added_vote_delegations"(
3580 "issue_id_p",
3581 "member_id_v",
3582 '{}'
3584 WHERE "member_id" = "member_id_v"
3585 AND "issue_id" = "issue_id_p";
3586 END LOOP;
3587 RETURN;
3588 END;
3589 $$;
3591 COMMENT ON FUNCTION "add_vote_delegations"
3592 ( "issue_id_p" "issue"."id"%TYPE )
3593 IS 'Helper function for "close_voting" function';
3596 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3597 RETURNS VOID
3598 LANGUAGE 'plpgsql' VOLATILE AS $$
3599 DECLARE
3600 "area_id_v" "area"."id"%TYPE;
3601 "unit_id_v" "unit"."id"%TYPE;
3602 "member_id_v" "member"."id"%TYPE;
3603 BEGIN
3604 PERFORM "require_transaction_isolation"();
3605 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3606 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3607 -- delete timestamp of voting comment:
3608 UPDATE "direct_voter" SET "comment_changed" = NULL
3609 WHERE "issue_id" = "issue_id_p";
3610 -- delete delegating votes (in cases of manual reset of issue state):
3611 DELETE FROM "delegating_voter"
3612 WHERE "issue_id" = "issue_id_p";
3613 -- delete votes from non-privileged voters:
3614 DELETE FROM "direct_voter"
3615 USING (
3616 SELECT
3617 "direct_voter"."member_id"
3618 FROM "direct_voter"
3619 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3620 LEFT JOIN "privilege"
3621 ON "privilege"."unit_id" = "unit_id_v"
3622 AND "privilege"."member_id" = "direct_voter"."member_id"
3623 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3624 "member"."active" = FALSE OR
3625 "privilege"."voting_right" ISNULL OR
3626 "privilege"."voting_right" = FALSE
3628 ) AS "subquery"
3629 WHERE "direct_voter"."issue_id" = "issue_id_p"
3630 AND "direct_voter"."member_id" = "subquery"."member_id";
3631 -- consider delegations:
3632 UPDATE "direct_voter" SET "weight" = 1
3633 WHERE "issue_id" = "issue_id_p";
3634 PERFORM "add_vote_delegations"("issue_id_p");
3635 -- materialize battle_view:
3636 -- NOTE: "closed" column of issue must be set at this point
3637 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3638 INSERT INTO "battle" (
3639 "issue_id",
3640 "winning_initiative_id", "losing_initiative_id",
3641 "count"
3642 ) SELECT
3643 "issue_id",
3644 "winning_initiative_id", "losing_initiative_id",
3645 "count"
3646 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3647 -- set voter count:
3648 UPDATE "issue" SET
3649 "voter_count" = (
3650 SELECT coalesce(sum("weight"), 0)
3651 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3653 WHERE "id" = "issue_id_p";
3654 -- copy "positive_votes" and "negative_votes" from "battle" table:
3655 UPDATE "initiative" SET
3656 "positive_votes" = "battle_win"."count",
3657 "negative_votes" = "battle_lose"."count"
3658 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3659 WHERE
3660 "battle_win"."issue_id" = "issue_id_p" AND
3661 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3662 "battle_win"."losing_initiative_id" ISNULL AND
3663 "battle_lose"."issue_id" = "issue_id_p" AND
3664 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3665 "battle_lose"."winning_initiative_id" ISNULL;
3666 END;
3667 $$;
3669 COMMENT ON FUNCTION "close_voting"
3670 ( "issue"."id"%TYPE )
3671 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.';
3674 CREATE FUNCTION "defeat_strength"
3675 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3676 RETURNS INT8
3677 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3678 BEGIN
3679 IF "positive_votes_p" > "negative_votes_p" THEN
3680 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3681 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3682 RETURN 0;
3683 ELSE
3684 RETURN -1;
3685 END IF;
3686 END;
3687 $$;
3689 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';
3692 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3693 RETURNS VOID
3694 LANGUAGE 'plpgsql' VOLATILE AS $$
3695 DECLARE
3696 "issue_row" "issue"%ROWTYPE;
3697 "policy_row" "policy"%ROWTYPE;
3698 "dimension_v" INTEGER;
3699 "vote_matrix" INT4[][]; -- absolute votes
3700 "matrix" INT8[][]; -- defeat strength / best paths
3701 "i" INTEGER;
3702 "j" INTEGER;
3703 "k" INTEGER;
3704 "battle_row" "battle"%ROWTYPE;
3705 "rank_ary" INT4[];
3706 "rank_v" INT4;
3707 "done_v" INTEGER;
3708 "winners_ary" INTEGER[];
3709 "initiative_id_v" "initiative"."id"%TYPE;
3710 BEGIN
3711 PERFORM "require_transaction_isolation"();
3712 SELECT * INTO "issue_row"
3713 FROM "issue" WHERE "id" = "issue_id_p";
3714 SELECT * INTO "policy_row"
3715 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3716 SELECT count(1) INTO "dimension_v"
3717 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3718 -- Create "vote_matrix" with absolute number of votes in pairwise
3719 -- comparison:
3720 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3721 "i" := 1;
3722 "j" := 2;
3723 FOR "battle_row" IN
3724 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3725 ORDER BY
3726 "winning_initiative_id" NULLS LAST,
3727 "losing_initiative_id" NULLS LAST
3728 LOOP
3729 "vote_matrix"["i"]["j"] := "battle_row"."count";
3730 IF "j" = "dimension_v" THEN
3731 "i" := "i" + 1;
3732 "j" := 1;
3733 ELSE
3734 "j" := "j" + 1;
3735 IF "j" = "i" THEN
3736 "j" := "j" + 1;
3737 END IF;
3738 END IF;
3739 END LOOP;
3740 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3741 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3742 END IF;
3743 -- Store defeat strengths in "matrix" using "defeat_strength"
3744 -- function:
3745 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3746 "i" := 1;
3747 LOOP
3748 "j" := 1;
3749 LOOP
3750 IF "i" != "j" THEN
3751 "matrix"["i"]["j"] := "defeat_strength"(
3752 "vote_matrix"["i"]["j"],
3753 "vote_matrix"["j"]["i"]
3754 );
3755 END IF;
3756 EXIT WHEN "j" = "dimension_v";
3757 "j" := "j" + 1;
3758 END LOOP;
3759 EXIT WHEN "i" = "dimension_v";
3760 "i" := "i" + 1;
3761 END LOOP;
3762 -- Find best paths:
3763 "i" := 1;
3764 LOOP
3765 "j" := 1;
3766 LOOP
3767 IF "i" != "j" THEN
3768 "k" := 1;
3769 LOOP
3770 IF "i" != "k" AND "j" != "k" THEN
3771 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3772 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3773 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3774 END IF;
3775 ELSE
3776 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3777 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3778 END IF;
3779 END IF;
3780 END IF;
3781 EXIT WHEN "k" = "dimension_v";
3782 "k" := "k" + 1;
3783 END LOOP;
3784 END IF;
3785 EXIT WHEN "j" = "dimension_v";
3786 "j" := "j" + 1;
3787 END LOOP;
3788 EXIT WHEN "i" = "dimension_v";
3789 "i" := "i" + 1;
3790 END LOOP;
3791 -- Determine order of winners:
3792 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3793 "rank_v" := 1;
3794 "done_v" := 0;
3795 LOOP
3796 "winners_ary" := '{}';
3797 "i" := 1;
3798 LOOP
3799 IF "rank_ary"["i"] ISNULL THEN
3800 "j" := 1;
3801 LOOP
3802 IF
3803 "i" != "j" AND
3804 "rank_ary"["j"] ISNULL AND
3805 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3806 THEN
3807 -- someone else is better
3808 EXIT;
3809 END IF;
3810 IF "j" = "dimension_v" THEN
3811 -- noone is better
3812 "winners_ary" := "winners_ary" || "i";
3813 EXIT;
3814 END IF;
3815 "j" := "j" + 1;
3816 END LOOP;
3817 END IF;
3818 EXIT WHEN "i" = "dimension_v";
3819 "i" := "i" + 1;
3820 END LOOP;
3821 "i" := 1;
3822 LOOP
3823 "rank_ary"["winners_ary"["i"]] := "rank_v";
3824 "done_v" := "done_v" + 1;
3825 EXIT WHEN "i" = array_upper("winners_ary", 1);
3826 "i" := "i" + 1;
3827 END LOOP;
3828 EXIT WHEN "done_v" = "dimension_v";
3829 "rank_v" := "rank_v" + 1;
3830 END LOOP;
3831 -- write preliminary results:
3832 "i" := 1;
3833 FOR "initiative_id_v" IN
3834 SELECT "id" FROM "initiative"
3835 WHERE "issue_id" = "issue_id_p" AND "admitted"
3836 ORDER BY "id"
3837 LOOP
3838 UPDATE "initiative" SET
3839 "direct_majority" =
3840 CASE WHEN "policy_row"."direct_majority_strict" THEN
3841 "positive_votes" * "policy_row"."direct_majority_den" >
3842 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3843 ELSE
3844 "positive_votes" * "policy_row"."direct_majority_den" >=
3845 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3846 END
3847 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3848 AND "issue_row"."voter_count"-"negative_votes" >=
3849 "policy_row"."direct_majority_non_negative",
3850 "indirect_majority" =
3851 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3852 "positive_votes" * "policy_row"."indirect_majority_den" >
3853 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3854 ELSE
3855 "positive_votes" * "policy_row"."indirect_majority_den" >=
3856 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3857 END
3858 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3859 AND "issue_row"."voter_count"-"negative_votes" >=
3860 "policy_row"."indirect_majority_non_negative",
3861 "schulze_rank" = "rank_ary"["i"],
3862 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3863 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3864 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3865 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3866 "eligible" = FALSE,
3867 "winner" = FALSE,
3868 "rank" = NULL -- NOTE: in cases of manual reset of issue state
3869 WHERE "id" = "initiative_id_v";
3870 "i" := "i" + 1;
3871 END LOOP;
3872 IF "i" != "dimension_v" THEN
3873 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3874 END IF;
3875 -- take indirect majorities into account:
3876 LOOP
3877 UPDATE "initiative" SET "indirect_majority" = TRUE
3878 FROM (
3879 SELECT "new_initiative"."id" AS "initiative_id"
3880 FROM "initiative" "old_initiative"
3881 JOIN "initiative" "new_initiative"
3882 ON "new_initiative"."issue_id" = "issue_id_p"
3883 AND "new_initiative"."indirect_majority" = FALSE
3884 JOIN "battle" "battle_win"
3885 ON "battle_win"."issue_id" = "issue_id_p"
3886 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3887 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3888 JOIN "battle" "battle_lose"
3889 ON "battle_lose"."issue_id" = "issue_id_p"
3890 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3891 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3892 WHERE "old_initiative"."issue_id" = "issue_id_p"
3893 AND "old_initiative"."indirect_majority" = TRUE
3894 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3895 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3896 "policy_row"."indirect_majority_num" *
3897 ("battle_win"."count"+"battle_lose"."count")
3898 ELSE
3899 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3900 "policy_row"."indirect_majority_num" *
3901 ("battle_win"."count"+"battle_lose"."count")
3902 END
3903 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3904 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3905 "policy_row"."indirect_majority_non_negative"
3906 ) AS "subquery"
3907 WHERE "id" = "subquery"."initiative_id";
3908 EXIT WHEN NOT FOUND;
3909 END LOOP;
3910 -- set "multistage_majority" for remaining matching initiatives:
3911 UPDATE "initiative" SET "multistage_majority" = TRUE
3912 FROM (
3913 SELECT "losing_initiative"."id" AS "initiative_id"
3914 FROM "initiative" "losing_initiative"
3915 JOIN "initiative" "winning_initiative"
3916 ON "winning_initiative"."issue_id" = "issue_id_p"
3917 AND "winning_initiative"."admitted"
3918 JOIN "battle" "battle_win"
3919 ON "battle_win"."issue_id" = "issue_id_p"
3920 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3921 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3922 JOIN "battle" "battle_lose"
3923 ON "battle_lose"."issue_id" = "issue_id_p"
3924 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3925 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3926 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3927 AND "losing_initiative"."admitted"
3928 AND "winning_initiative"."schulze_rank" <
3929 "losing_initiative"."schulze_rank"
3930 AND "battle_win"."count" > "battle_lose"."count"
3931 AND (
3932 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3933 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3934 ) AS "subquery"
3935 WHERE "id" = "subquery"."initiative_id";
3936 -- mark eligible initiatives:
3937 UPDATE "initiative" SET "eligible" = TRUE
3938 WHERE "issue_id" = "issue_id_p"
3939 AND "initiative"."direct_majority"
3940 AND "initiative"."indirect_majority"
3941 AND "initiative"."better_than_status_quo"
3942 AND (
3943 "policy_row"."no_multistage_majority" = FALSE OR
3944 "initiative"."multistage_majority" = FALSE )
3945 AND (
3946 "policy_row"."no_reverse_beat_path" = FALSE OR
3947 "initiative"."reverse_beat_path" = FALSE );
3948 -- mark final winner:
3949 UPDATE "initiative" SET "winner" = TRUE
3950 FROM (
3951 SELECT "id" AS "initiative_id"
3952 FROM "initiative"
3953 WHERE "issue_id" = "issue_id_p" AND "eligible"
3954 ORDER BY
3955 "schulze_rank",
3956 "id"
3957 LIMIT 1
3958 ) AS "subquery"
3959 WHERE "id" = "subquery"."initiative_id";
3960 -- write (final) ranks:
3961 "rank_v" := 1;
3962 FOR "initiative_id_v" IN
3963 SELECT "id"
3964 FROM "initiative"
3965 WHERE "issue_id" = "issue_id_p" AND "admitted"
3966 ORDER BY
3967 "winner" DESC,
3968 "eligible" DESC,
3969 "schulze_rank",
3970 "id"
3971 LOOP
3972 UPDATE "initiative" SET "rank" = "rank_v"
3973 WHERE "id" = "initiative_id_v";
3974 "rank_v" := "rank_v" + 1;
3975 END LOOP;
3976 -- set schulze rank of status quo and mark issue as finished:
3977 UPDATE "issue" SET
3978 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
3979 "state" =
3980 CASE WHEN EXISTS (
3981 SELECT NULL FROM "initiative"
3982 WHERE "issue_id" = "issue_id_p" AND "winner"
3983 ) THEN
3984 'finished_with_winner'::"issue_state"
3985 ELSE
3986 'finished_without_winner'::"issue_state"
3987 END,
3988 "closed" = "phase_finished",
3989 "phase_finished" = NULL
3990 WHERE "id" = "issue_id_p";
3991 RETURN;
3992 END;
3993 $$;
3995 COMMENT ON FUNCTION "calculate_ranks"
3996 ( "issue"."id"%TYPE )
3997 IS 'Determine ranking (Votes have to be counted first)';
4001 -----------------------------
4002 -- Automatic state changes --
4003 -----------------------------
4006 CREATE TYPE "check_issue_persistence" AS (
4007 "state" "issue_state",
4008 "phase_finished" BOOLEAN,
4009 "issue_revoked" BOOLEAN,
4010 "snapshot_created" BOOLEAN,
4011 "harmonic_weights_set" BOOLEAN,
4012 "closed_voting" BOOLEAN );
4014 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';
4017 CREATE FUNCTION "check_issue"
4018 ( "issue_id_p" "issue"."id"%TYPE,
4019 "persist" "check_issue_persistence" )
4020 RETURNS "check_issue_persistence"
4021 LANGUAGE 'plpgsql' VOLATILE AS $$
4022 DECLARE
4023 "issue_row" "issue"%ROWTYPE;
4024 "policy_row" "policy"%ROWTYPE;
4025 "initiative_row" "initiative"%ROWTYPE;
4026 "state_v" "issue_state";
4027 BEGIN
4028 PERFORM "require_transaction_isolation"();
4029 IF "persist" ISNULL THEN
4030 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4031 FOR UPDATE;
4032 IF "issue_row"."closed" NOTNULL THEN
4033 RETURN NULL;
4034 END IF;
4035 "persist"."state" := "issue_row"."state";
4036 IF
4037 ( "issue_row"."state" = 'admission' AND now() >=
4038 "issue_row"."created" + "issue_row"."admission_time" ) OR
4039 ( "issue_row"."state" = 'discussion' AND now() >=
4040 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4041 ( "issue_row"."state" = 'verification' AND now() >=
4042 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4043 ( "issue_row"."state" = 'voting' AND now() >=
4044 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4045 THEN
4046 "persist"."phase_finished" := TRUE;
4047 ELSE
4048 "persist"."phase_finished" := FALSE;
4049 END IF;
4050 IF
4051 NOT EXISTS (
4052 -- all initiatives are revoked
4053 SELECT NULL FROM "initiative"
4054 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4055 ) AND (
4056 -- and issue has not been accepted yet
4057 "persist"."state" = 'admission' OR
4058 -- or verification time has elapsed
4059 ( "persist"."state" = 'verification' AND
4060 "persist"."phase_finished" ) OR
4061 -- or no initiatives have been revoked lately
4062 NOT EXISTS (
4063 SELECT NULL FROM "initiative"
4064 WHERE "issue_id" = "issue_id_p"
4065 AND now() < "revoked" + "issue_row"."verification_time"
4068 THEN
4069 "persist"."issue_revoked" := TRUE;
4070 ELSE
4071 "persist"."issue_revoked" := FALSE;
4072 END IF;
4073 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4074 UPDATE "issue" SET "phase_finished" = now()
4075 WHERE "id" = "issue_row"."id";
4076 RETURN "persist";
4077 ELSIF
4078 "persist"."state" IN ('admission', 'discussion', 'verification')
4079 THEN
4080 RETURN "persist";
4081 ELSE
4082 RETURN NULL;
4083 END IF;
4084 END IF;
4085 IF
4086 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4087 coalesce("persist"."snapshot_created", FALSE) = FALSE
4088 THEN
4089 PERFORM "create_snapshot"("issue_id_p");
4090 "persist"."snapshot_created" = TRUE;
4091 IF "persist"."phase_finished" THEN
4092 IF "persist"."state" = 'admission' THEN
4093 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4094 ELSIF "persist"."state" = 'discussion' THEN
4095 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4096 ELSIF "persist"."state" = 'verification' THEN
4097 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4098 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4099 SELECT * INTO "policy_row" FROM "policy"
4100 WHERE "id" = "issue_row"."policy_id";
4101 FOR "initiative_row" IN
4102 SELECT * FROM "initiative"
4103 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4104 FOR UPDATE
4105 LOOP
4106 IF
4107 "initiative_row"."polling" OR (
4108 "initiative_row"."satisfied_supporter_count" > 0 AND
4109 "initiative_row"."satisfied_supporter_count" *
4110 "policy_row"."initiative_quorum_den" >=
4111 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4113 THEN
4114 UPDATE "initiative" SET "admitted" = TRUE
4115 WHERE "id" = "initiative_row"."id";
4116 ELSE
4117 UPDATE "initiative" SET "admitted" = FALSE
4118 WHERE "id" = "initiative_row"."id";
4119 END IF;
4120 END LOOP;
4121 END IF;
4122 END IF;
4123 RETURN "persist";
4124 END IF;
4125 IF
4126 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4127 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4128 THEN
4129 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4130 "persist"."harmonic_weights_set" = TRUE;
4131 IF
4132 "persist"."phase_finished" OR
4133 "persist"."issue_revoked" OR
4134 "persist"."state" = 'admission'
4135 THEN
4136 RETURN "persist";
4137 ELSE
4138 RETURN NULL;
4139 END IF;
4140 END IF;
4141 IF "persist"."issue_revoked" THEN
4142 IF "persist"."state" = 'admission' THEN
4143 "state_v" := 'canceled_revoked_before_accepted';
4144 ELSIF "persist"."state" = 'discussion' THEN
4145 "state_v" := 'canceled_after_revocation_during_discussion';
4146 ELSIF "persist"."state" = 'verification' THEN
4147 "state_v" := 'canceled_after_revocation_during_verification';
4148 END IF;
4149 UPDATE "issue" SET
4150 "state" = "state_v",
4151 "closed" = "phase_finished",
4152 "phase_finished" = NULL
4153 WHERE "id" = "issue_id_p";
4154 RETURN NULL;
4155 END IF;
4156 IF "persist"."state" = 'admission' THEN
4157 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4158 FOR UPDATE;
4159 SELECT * INTO "policy_row"
4160 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4161 IF EXISTS (
4162 SELECT NULL FROM "initiative"
4163 WHERE "issue_id" = "issue_id_p"
4164 AND "supporter_count" > 0
4165 AND "supporter_count" * "policy_row"."issue_quorum_den"
4166 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4167 ) THEN
4168 UPDATE "issue" SET
4169 "state" = 'discussion',
4170 "accepted" = coalesce("phase_finished", now()),
4171 "phase_finished" = NULL
4172 WHERE "id" = "issue_id_p";
4173 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4174 UPDATE "issue" SET
4175 "state" = 'canceled_issue_not_accepted',
4176 "closed" = "phase_finished",
4177 "phase_finished" = NULL
4178 WHERE "id" = "issue_id_p";
4179 END IF;
4180 RETURN NULL;
4181 END IF;
4182 IF "persist"."phase_finished" THEN
4183 if "persist"."state" = 'discussion' THEN
4184 UPDATE "issue" SET
4185 "state" = 'verification',
4186 "half_frozen" = "phase_finished",
4187 "phase_finished" = NULL
4188 WHERE "id" = "issue_id_p";
4189 RETURN NULL;
4190 END IF;
4191 IF "persist"."state" = 'verification' THEN
4192 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4193 FOR UPDATE;
4194 SELECT * INTO "policy_row" FROM "policy"
4195 WHERE "id" = "issue_row"."policy_id";
4196 IF EXISTS (
4197 SELECT NULL FROM "initiative"
4198 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4199 ) THEN
4200 UPDATE "issue" SET
4201 "state" = 'voting',
4202 "fully_frozen" = "phase_finished",
4203 "phase_finished" = NULL
4204 WHERE "id" = "issue_id_p";
4205 ELSE
4206 UPDATE "issue" SET
4207 "state" = 'canceled_no_initiative_admitted',
4208 "fully_frozen" = "phase_finished",
4209 "closed" = "phase_finished",
4210 "phase_finished" = NULL
4211 WHERE "id" = "issue_id_p";
4212 -- NOTE: The following DELETE statements have effect only when
4213 -- issue state has been manipulated
4214 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4215 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4216 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4217 END IF;
4218 RETURN NULL;
4219 END IF;
4220 IF "persist"."state" = 'voting' THEN
4221 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4222 PERFORM "close_voting"("issue_id_p");
4223 "persist"."closed_voting" = TRUE;
4224 RETURN "persist";
4225 END IF;
4226 PERFORM "calculate_ranks"("issue_id_p");
4227 RETURN NULL;
4228 END IF;
4229 END IF;
4230 RAISE WARNING 'should not happen';
4231 RETURN NULL;
4232 END;
4233 $$;
4235 COMMENT ON FUNCTION "check_issue"
4236 ( "issue"."id"%TYPE,
4237 "check_issue_persistence" )
4238 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")';
4241 CREATE FUNCTION "check_everything"()
4242 RETURNS VOID
4243 LANGUAGE 'plpgsql' VOLATILE AS $$
4244 DECLARE
4245 "issue_id_v" "issue"."id"%TYPE;
4246 "persist_v" "check_issue_persistence";
4247 BEGIN
4248 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4249 DELETE FROM "expired_session";
4250 PERFORM "check_activity"();
4251 PERFORM "calculate_member_counts"();
4252 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4253 "persist_v" := NULL;
4254 LOOP
4255 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4256 EXIT WHEN "persist_v" ISNULL;
4257 END LOOP;
4258 END LOOP;
4259 RETURN;
4260 END;
4261 $$;
4263 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.';
4267 ----------------------
4268 -- Deletion of data --
4269 ----------------------
4272 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4273 RETURNS VOID
4274 LANGUAGE 'plpgsql' VOLATILE AS $$
4275 DECLARE
4276 "issue_row" "issue"%ROWTYPE;
4277 BEGIN
4278 SELECT * INTO "issue_row"
4279 FROM "issue" WHERE "id" = "issue_id_p"
4280 FOR UPDATE;
4281 IF "issue_row"."cleaned" ISNULL THEN
4282 UPDATE "issue" SET
4283 "state" = 'voting',
4284 "closed" = NULL
4285 WHERE "id" = "issue_id_p";
4286 DELETE FROM "delegating_voter"
4287 WHERE "issue_id" = "issue_id_p";
4288 DELETE FROM "direct_voter"
4289 WHERE "issue_id" = "issue_id_p";
4290 DELETE FROM "delegating_interest_snapshot"
4291 WHERE "issue_id" = "issue_id_p";
4292 DELETE FROM "direct_interest_snapshot"
4293 WHERE "issue_id" = "issue_id_p";
4294 DELETE FROM "delegating_population_snapshot"
4295 WHERE "issue_id" = "issue_id_p";
4296 DELETE FROM "direct_population_snapshot"
4297 WHERE "issue_id" = "issue_id_p";
4298 DELETE FROM "non_voter"
4299 WHERE "issue_id" = "issue_id_p";
4300 DELETE FROM "delegation"
4301 WHERE "issue_id" = "issue_id_p";
4302 DELETE FROM "supporter"
4303 USING "initiative" -- NOTE: due to missing index on issue_id
4304 WHERE "initiative"."issue_id" = "issue_id_p"
4305 AND "supporter"."initiative_id" = "initiative_id";
4306 UPDATE "issue" SET
4307 "state" = "issue_row"."state",
4308 "closed" = "issue_row"."closed",
4309 "cleaned" = now()
4310 WHERE "id" = "issue_id_p";
4311 END IF;
4312 RETURN;
4313 END;
4314 $$;
4316 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4319 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4320 RETURNS VOID
4321 LANGUAGE 'plpgsql' VOLATILE AS $$
4322 BEGIN
4323 UPDATE "member" SET
4324 "last_login" = NULL,
4325 "login" = NULL,
4326 "password" = NULL,
4327 "locked" = TRUE,
4328 "active" = FALSE,
4329 "notify_email" = NULL,
4330 "notify_email_unconfirmed" = NULL,
4331 "notify_email_secret" = NULL,
4332 "notify_email_secret_expiry" = NULL,
4333 "notify_email_lock_expiry" = NULL,
4334 "password_reset_secret" = NULL,
4335 "password_reset_secret_expiry" = NULL,
4336 "organizational_unit" = NULL,
4337 "internal_posts" = NULL,
4338 "realname" = NULL,
4339 "birthday" = NULL,
4340 "address" = NULL,
4341 "email" = NULL,
4342 "xmpp_address" = NULL,
4343 "website" = NULL,
4344 "phone" = NULL,
4345 "mobile_phone" = NULL,
4346 "profession" = NULL,
4347 "external_memberships" = NULL,
4348 "external_posts" = NULL,
4349 "statement" = NULL
4350 WHERE "id" = "member_id_p";
4351 -- "text_search_data" is updated by triggers
4352 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4353 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4354 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4355 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4356 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4357 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4358 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4359 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4360 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4361 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4362 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4363 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4364 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4365 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4366 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4367 DELETE FROM "direct_voter" USING "issue"
4368 WHERE "direct_voter"."issue_id" = "issue"."id"
4369 AND "issue"."closed" ISNULL
4370 AND "member_id" = "member_id_p";
4371 RETURN;
4372 END;
4373 $$;
4375 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)';
4378 CREATE FUNCTION "delete_private_data"()
4379 RETURNS VOID
4380 LANGUAGE 'plpgsql' VOLATILE AS $$
4381 BEGIN
4382 DELETE FROM "member" WHERE "activated" ISNULL;
4383 UPDATE "member" SET
4384 "invite_code" = NULL,
4385 "invite_code_expiry" = NULL,
4386 "admin_comment" = NULL,
4387 "last_login" = NULL,
4388 "login" = NULL,
4389 "password" = NULL,
4390 "lang" = NULL,
4391 "notify_email" = NULL,
4392 "notify_email_unconfirmed" = NULL,
4393 "notify_email_secret" = NULL,
4394 "notify_email_secret_expiry" = NULL,
4395 "notify_email_lock_expiry" = NULL,
4396 "notify_level" = NULL,
4397 "password_reset_secret" = NULL,
4398 "password_reset_secret_expiry" = NULL,
4399 "organizational_unit" = NULL,
4400 "internal_posts" = NULL,
4401 "realname" = NULL,
4402 "birthday" = NULL,
4403 "address" = NULL,
4404 "email" = NULL,
4405 "xmpp_address" = NULL,
4406 "website" = NULL,
4407 "phone" = NULL,
4408 "mobile_phone" = NULL,
4409 "profession" = NULL,
4410 "external_memberships" = NULL,
4411 "external_posts" = NULL,
4412 "formatting_engine" = NULL,
4413 "statement" = NULL;
4414 -- "text_search_data" is updated by triggers
4415 DELETE FROM "setting";
4416 DELETE FROM "setting_map";
4417 DELETE FROM "member_relation_setting";
4418 DELETE FROM "member_image";
4419 DELETE FROM "contact";
4420 DELETE FROM "ignored_member";
4421 DELETE FROM "session";
4422 DELETE FROM "area_setting";
4423 DELETE FROM "issue_setting";
4424 DELETE FROM "ignored_initiative";
4425 DELETE FROM "initiative_setting";
4426 DELETE FROM "suggestion_setting";
4427 DELETE FROM "non_voter";
4428 DELETE FROM "direct_voter" USING "issue"
4429 WHERE "direct_voter"."issue_id" = "issue"."id"
4430 AND "issue"."closed" ISNULL;
4431 RETURN;
4432 END;
4433 $$;
4435 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.';
4439 COMMIT;

Impressum / About Us