liquid_feedback_core

view core.sql @ 325:6529e423f8eb

Bugfix regarding index usage (speeds up lf_update)
author jbe
date Sun Feb 10 18:47:40 2013 +0100 (2013-02-10)
parents 847d59f94ceb
children d59d0c3e4a18
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.1.0', 2, 1, 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 'calculation',
495 'canceled_no_initiative_admitted',
496 'finished_without_winner', 'finished_with_winner');
498 COMMENT ON TYPE "issue_state" IS 'State of issues';
501 CREATE TABLE "issue" (
502 "id" SERIAL4 PRIMARY KEY,
503 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
504 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
505 "state" "issue_state" NOT NULL DEFAULT 'admission',
506 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
507 "accepted" TIMESTAMPTZ,
508 "half_frozen" TIMESTAMPTZ,
509 "fully_frozen" TIMESTAMPTZ,
510 "closed" TIMESTAMPTZ,
511 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
512 "cleaned" TIMESTAMPTZ,
513 "admission_time" INTERVAL,
514 "discussion_time" INTERVAL NOT NULL,
515 "verification_time" INTERVAL NOT NULL,
516 "voting_time" INTERVAL NOT NULL,
517 "snapshot" TIMESTAMPTZ,
518 "latest_snapshot_event" "snapshot_event",
519 "population" INT4,
520 "voter_count" INT4,
521 "status_quo_schulze_rank" INT4,
522 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
523 "admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created") ),
524 CONSTRAINT "valid_state" CHECK ((
525 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
526 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
527 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
528 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
529 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
530 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
531 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
532 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
533 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
534 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
535 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
536 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
537 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
538 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
539 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
540 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
541 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
542 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
543 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
544 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
545 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
546 )),
547 CONSTRAINT "state_change_order" CHECK (
548 "created" <= "accepted" AND
549 "accepted" <= "half_frozen" AND
550 "half_frozen" <= "fully_frozen" AND
551 "fully_frozen" <= "closed" ),
552 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
553 "cleaned" ISNULL OR "closed" NOTNULL ),
554 CONSTRAINT "last_snapshot_on_full_freeze"
555 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
556 CONSTRAINT "freeze_requires_snapshot"
557 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
558 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
559 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
560 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
561 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
562 CREATE INDEX "issue_created_idx" ON "issue" ("created");
563 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
564 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
565 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
566 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
567 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
568 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
570 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
572 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
573 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.';
574 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.';
575 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.';
576 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
577 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
578 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
579 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
580 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
581 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
582 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
583 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';
584 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
585 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';
586 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
589 CREATE TABLE "issue_setting" (
590 PRIMARY KEY ("member_id", "key", "issue_id"),
591 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
592 "key" TEXT NOT NULL,
593 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
594 "value" TEXT NOT NULL );
596 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
599 CREATE TABLE "initiative" (
600 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
601 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
602 "id" SERIAL4 PRIMARY KEY,
603 "name" TEXT NOT NULL,
604 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
605 "discussion_url" TEXT,
606 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
607 "revoked" TIMESTAMPTZ,
608 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
609 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
610 "admitted" BOOLEAN,
611 "supporter_count" INT4,
612 "informed_supporter_count" INT4,
613 "satisfied_supporter_count" INT4,
614 "satisfied_informed_supporter_count" INT4,
615 "positive_votes" INT4,
616 "negative_votes" INT4,
617 "direct_majority" BOOLEAN,
618 "indirect_majority" BOOLEAN,
619 "schulze_rank" INT4,
620 "better_than_status_quo" BOOLEAN,
621 "worse_than_status_quo" BOOLEAN,
622 "reverse_beat_path" BOOLEAN,
623 "multistage_majority" BOOLEAN,
624 "eligible" BOOLEAN,
625 "winner" BOOLEAN,
626 "rank" INT4,
627 "text_search_data" TSVECTOR,
628 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
629 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
630 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
631 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
632 CONSTRAINT "revoked_initiatives_cant_be_admitted"
633 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
634 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
635 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
636 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
637 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
638 "schulze_rank" ISNULL AND
639 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
640 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
641 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
642 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
643 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
644 "eligible" = FALSE OR
645 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
646 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
647 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
648 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
649 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
650 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
651 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
652 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
653 CREATE TRIGGER "update_text_search_data"
654 BEFORE INSERT OR UPDATE ON "initiative"
655 FOR EACH ROW EXECUTE PROCEDURE
656 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
657 "name", "discussion_url");
659 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.';
661 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
662 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
663 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
664 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
665 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
666 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
667 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
668 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
669 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
670 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
671 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
672 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"';
673 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
674 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
675 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
676 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
677 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';
678 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';
679 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"';
680 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
681 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';
684 CREATE TABLE "battle" (
685 "issue_id" INT4 NOT NULL,
686 "winning_initiative_id" INT4,
687 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
688 "losing_initiative_id" INT4,
689 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
690 "count" INT4 NOT NULL,
691 CONSTRAINT "initiative_ids_not_equal" CHECK (
692 "winning_initiative_id" != "losing_initiative_id" OR
693 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
694 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
695 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
696 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
697 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
699 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';
702 CREATE TABLE "ignored_initiative" (
703 PRIMARY KEY ("initiative_id", "member_id"),
704 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
705 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
706 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
708 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
711 CREATE TABLE "initiative_setting" (
712 PRIMARY KEY ("member_id", "key", "initiative_id"),
713 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
714 "key" TEXT NOT NULL,
715 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
716 "value" TEXT NOT NULL );
718 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
721 CREATE TABLE "draft" (
722 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
723 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
724 "id" SERIAL8 PRIMARY KEY,
725 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
726 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
727 "formatting_engine" TEXT,
728 "content" TEXT NOT NULL,
729 "text_search_data" TSVECTOR );
730 CREATE INDEX "draft_created_idx" ON "draft" ("created");
731 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
732 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
733 CREATE TRIGGER "update_text_search_data"
734 BEFORE INSERT OR UPDATE ON "draft"
735 FOR EACH ROW EXECUTE PROCEDURE
736 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
738 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.';
740 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
741 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
744 CREATE TABLE "rendered_draft" (
745 PRIMARY KEY ("draft_id", "format"),
746 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
747 "format" TEXT,
748 "content" TEXT NOT NULL );
750 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)';
753 CREATE TABLE "suggestion" (
754 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
755 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
756 "id" SERIAL8 PRIMARY KEY,
757 "draft_id" INT8 NOT NULL,
758 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
759 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
760 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
761 "name" TEXT NOT NULL,
762 "formatting_engine" TEXT,
763 "content" TEXT NOT NULL DEFAULT '',
764 "text_search_data" TSVECTOR,
765 "minus2_unfulfilled_count" INT4,
766 "minus2_fulfilled_count" INT4,
767 "minus1_unfulfilled_count" INT4,
768 "minus1_fulfilled_count" INT4,
769 "plus1_unfulfilled_count" INT4,
770 "plus1_fulfilled_count" INT4,
771 "plus2_unfulfilled_count" INT4,
772 "plus2_fulfilled_count" INT4 );
773 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
774 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
775 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
776 CREATE TRIGGER "update_text_search_data"
777 BEFORE INSERT OR UPDATE ON "suggestion"
778 FOR EACH ROW EXECUTE PROCEDURE
779 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
780 "name", "content");
782 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';
784 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")';
785 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
786 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
787 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
788 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
789 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
790 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
791 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
792 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
795 CREATE TABLE "rendered_suggestion" (
796 PRIMARY KEY ("suggestion_id", "format"),
797 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
798 "format" TEXT,
799 "content" TEXT NOT NULL );
801 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)';
804 CREATE TABLE "suggestion_setting" (
805 PRIMARY KEY ("member_id", "key", "suggestion_id"),
806 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
807 "key" TEXT NOT NULL,
808 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
809 "value" TEXT NOT NULL );
811 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
814 CREATE TABLE "privilege" (
815 PRIMARY KEY ("unit_id", "member_id"),
816 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
817 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
818 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
819 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
820 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
821 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
822 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
823 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
824 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
826 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
828 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
829 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
830 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
831 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
832 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
833 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
834 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';
837 CREATE TABLE "membership" (
838 PRIMARY KEY ("area_id", "member_id"),
839 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
840 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
841 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
843 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
846 CREATE TABLE "interest" (
847 PRIMARY KEY ("issue_id", "member_id"),
848 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
849 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
850 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
852 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.';
855 CREATE TABLE "initiator" (
856 PRIMARY KEY ("initiative_id", "member_id"),
857 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
858 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
859 "accepted" BOOLEAN );
860 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
862 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.';
864 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.';
867 CREATE TABLE "supporter" (
868 "issue_id" INT4 NOT NULL,
869 PRIMARY KEY ("initiative_id", "member_id"),
870 "initiative_id" INT4,
871 "member_id" INT4,
872 "draft_id" INT8 NOT NULL,
873 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
874 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
875 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
877 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.';
879 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
880 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")';
883 CREATE TABLE "opinion" (
884 "initiative_id" INT4 NOT NULL,
885 PRIMARY KEY ("suggestion_id", "member_id"),
886 "suggestion_id" INT8,
887 "member_id" INT4,
888 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
889 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
890 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
891 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
892 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
894 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.';
896 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
899 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
901 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
904 CREATE TABLE "delegation" (
905 "id" SERIAL8 PRIMARY KEY,
906 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
907 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
908 "scope" "delegation_scope" NOT NULL,
909 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
910 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
911 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
912 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
913 CONSTRAINT "no_unit_delegation_to_null"
914 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
915 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
916 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
917 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
918 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
919 UNIQUE ("unit_id", "truster_id"),
920 UNIQUE ("area_id", "truster_id"),
921 UNIQUE ("issue_id", "truster_id") );
922 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
923 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
925 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
927 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
928 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
929 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
932 CREATE TABLE "direct_population_snapshot" (
933 PRIMARY KEY ("issue_id", "event", "member_id"),
934 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
935 "event" "snapshot_event",
936 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
937 "weight" INT4 );
938 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
940 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
942 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
943 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
946 CREATE TABLE "delegating_population_snapshot" (
947 PRIMARY KEY ("issue_id", "event", "member_id"),
948 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
949 "event" "snapshot_event",
950 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
951 "weight" INT4,
952 "scope" "delegation_scope" NOT NULL,
953 "delegate_member_ids" INT4[] NOT NULL );
954 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
956 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
958 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
959 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
960 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
961 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"';
964 CREATE TABLE "direct_interest_snapshot" (
965 PRIMARY KEY ("issue_id", "event", "member_id"),
966 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
967 "event" "snapshot_event",
968 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
969 "weight" INT4 );
970 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
972 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
974 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
975 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
978 CREATE TABLE "delegating_interest_snapshot" (
979 PRIMARY KEY ("issue_id", "event", "member_id"),
980 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
981 "event" "snapshot_event",
982 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
983 "weight" INT4,
984 "scope" "delegation_scope" NOT NULL,
985 "delegate_member_ids" INT4[] NOT NULL );
986 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
988 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
990 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
991 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
992 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
993 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"';
996 CREATE TABLE "direct_supporter_snapshot" (
997 "issue_id" INT4 NOT NULL,
998 PRIMARY KEY ("initiative_id", "event", "member_id"),
999 "initiative_id" INT4,
1000 "event" "snapshot_event",
1001 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1002 "draft_id" INT8 NOT NULL,
1003 "informed" BOOLEAN NOT NULL,
1004 "satisfied" BOOLEAN NOT NULL,
1005 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1006 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1007 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1008 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1010 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1012 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';
1013 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1014 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1015 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1018 CREATE TABLE "non_voter" (
1019 PRIMARY KEY ("issue_id", "member_id"),
1020 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1021 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1022 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1024 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1027 CREATE TABLE "direct_voter" (
1028 PRIMARY KEY ("issue_id", "member_id"),
1029 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1030 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1031 "weight" INT4,
1032 "comment_changed" TIMESTAMPTZ,
1033 "formatting_engine" TEXT,
1034 "comment" TEXT,
1035 "text_search_data" TSVECTOR );
1036 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1037 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1038 CREATE TRIGGER "update_text_search_data"
1039 BEFORE INSERT OR UPDATE ON "direct_voter"
1040 FOR EACH ROW EXECUTE PROCEDURE
1041 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1043 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.';
1045 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1046 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';
1047 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';
1048 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.';
1051 CREATE TABLE "rendered_voter_comment" (
1052 PRIMARY KEY ("issue_id", "member_id", "format"),
1053 FOREIGN KEY ("issue_id", "member_id")
1054 REFERENCES "direct_voter" ("issue_id", "member_id")
1055 ON DELETE CASCADE ON UPDATE CASCADE,
1056 "issue_id" INT4,
1057 "member_id" INT4,
1058 "format" TEXT,
1059 "content" TEXT NOT NULL );
1061 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)';
1064 CREATE TABLE "delegating_voter" (
1065 PRIMARY KEY ("issue_id", "member_id"),
1066 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1067 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1068 "weight" INT4,
1069 "scope" "delegation_scope" NOT NULL,
1070 "delegate_member_ids" INT4[] NOT NULL );
1071 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1073 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1075 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1076 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1077 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"';
1080 CREATE TABLE "vote" (
1081 "issue_id" INT4 NOT NULL,
1082 PRIMARY KEY ("initiative_id", "member_id"),
1083 "initiative_id" INT4,
1084 "member_id" INT4,
1085 "grade" INT4,
1086 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1087 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1088 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1090 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.';
1092 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1093 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.';
1096 CREATE TYPE "event_type" AS ENUM (
1097 'issue_state_changed',
1098 'initiative_created_in_new_issue',
1099 'initiative_created_in_existing_issue',
1100 'initiative_revoked',
1101 'new_draft_created',
1102 'suggestion_created');
1104 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1107 CREATE TABLE "event" (
1108 "id" SERIAL8 PRIMARY KEY,
1109 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1110 "event" "event_type" NOT NULL,
1111 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1112 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1113 "state" "issue_state" CHECK ("state" != 'calculation'),
1114 "initiative_id" INT4,
1115 "draft_id" INT8,
1116 "suggestion_id" INT8,
1117 FOREIGN KEY ("issue_id", "initiative_id")
1118 REFERENCES "initiative" ("issue_id", "id")
1119 ON DELETE CASCADE ON UPDATE CASCADE,
1120 FOREIGN KEY ("initiative_id", "draft_id")
1121 REFERENCES "draft" ("initiative_id", "id")
1122 ON DELETE CASCADE ON UPDATE CASCADE,
1123 FOREIGN KEY ("initiative_id", "suggestion_id")
1124 REFERENCES "suggestion" ("initiative_id", "id")
1125 ON DELETE CASCADE ON UPDATE CASCADE,
1126 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1127 "event" != 'issue_state_changed' OR (
1128 "member_id" ISNULL AND
1129 "issue_id" NOTNULL AND
1130 "state" NOTNULL AND
1131 "initiative_id" ISNULL AND
1132 "draft_id" ISNULL AND
1133 "suggestion_id" ISNULL )),
1134 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1135 "event" NOT IN (
1136 'initiative_created_in_new_issue',
1137 'initiative_created_in_existing_issue',
1138 'initiative_revoked',
1139 'new_draft_created'
1140 ) OR (
1141 "member_id" NOTNULL AND
1142 "issue_id" NOTNULL AND
1143 "state" NOTNULL AND
1144 "initiative_id" NOTNULL AND
1145 "draft_id" NOTNULL AND
1146 "suggestion_id" ISNULL )),
1147 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1148 "event" != 'suggestion_created' OR (
1149 "member_id" NOTNULL AND
1150 "issue_id" NOTNULL AND
1151 "state" NOTNULL AND
1152 "initiative_id" NOTNULL AND
1153 "draft_id" ISNULL AND
1154 "suggestion_id" NOTNULL )) );
1155 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1157 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1159 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1160 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1161 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1162 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1165 CREATE TABLE "notification_sent" (
1166 "event_id" INT8 NOT NULL );
1167 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1169 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1170 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1174 ----------------------------------------------
1175 -- Writing of history entries and event log --
1176 ----------------------------------------------
1179 CREATE FUNCTION "write_member_history_trigger"()
1180 RETURNS TRIGGER
1181 LANGUAGE 'plpgsql' VOLATILE AS $$
1182 BEGIN
1183 IF
1184 ( NEW."active" != OLD."active" OR
1185 NEW."name" != OLD."name" ) AND
1186 OLD."activated" NOTNULL
1187 THEN
1188 INSERT INTO "member_history"
1189 ("member_id", "active", "name")
1190 VALUES (NEW."id", OLD."active", OLD."name");
1191 END IF;
1192 RETURN NULL;
1193 END;
1194 $$;
1196 CREATE TRIGGER "write_member_history"
1197 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1198 "write_member_history_trigger"();
1200 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1201 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1204 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1205 RETURNS TRIGGER
1206 LANGUAGE 'plpgsql' VOLATILE AS $$
1207 BEGIN
1208 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1209 INSERT INTO "event" ("event", "issue_id", "state")
1210 VALUES ('issue_state_changed', NEW."id", NEW."state");
1211 END IF;
1212 RETURN NULL;
1213 END;
1214 $$;
1216 CREATE TRIGGER "write_event_issue_state_changed"
1217 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1218 "write_event_issue_state_changed_trigger"();
1220 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1221 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1224 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1225 RETURNS TRIGGER
1226 LANGUAGE 'plpgsql' VOLATILE AS $$
1227 DECLARE
1228 "initiative_row" "initiative"%ROWTYPE;
1229 "issue_row" "issue"%ROWTYPE;
1230 "event_v" "event_type";
1231 BEGIN
1232 SELECT * INTO "initiative_row" FROM "initiative"
1233 WHERE "id" = NEW."initiative_id";
1234 SELECT * INTO "issue_row" FROM "issue"
1235 WHERE "id" = "initiative_row"."issue_id";
1236 IF EXISTS (
1237 SELECT NULL FROM "draft"
1238 WHERE "initiative_id" = NEW."initiative_id"
1239 AND "id" != NEW."id"
1240 ) THEN
1241 "event_v" := 'new_draft_created';
1242 ELSE
1243 IF EXISTS (
1244 SELECT NULL FROM "initiative"
1245 WHERE "issue_id" = "initiative_row"."issue_id"
1246 AND "id" != "initiative_row"."id"
1247 ) THEN
1248 "event_v" := 'initiative_created_in_existing_issue';
1249 ELSE
1250 "event_v" := 'initiative_created_in_new_issue';
1251 END IF;
1252 END IF;
1253 INSERT INTO "event" (
1254 "event", "member_id",
1255 "issue_id", "state", "initiative_id", "draft_id"
1256 ) VALUES (
1257 "event_v",
1258 NEW."author_id",
1259 "initiative_row"."issue_id",
1260 "issue_row"."state",
1261 "initiative_row"."id",
1262 NEW."id" );
1263 RETURN NULL;
1264 END;
1265 $$;
1267 CREATE TRIGGER "write_event_initiative_or_draft_created"
1268 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1269 "write_event_initiative_or_draft_created_trigger"();
1271 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1272 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1275 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1276 RETURNS TRIGGER
1277 LANGUAGE 'plpgsql' VOLATILE AS $$
1278 DECLARE
1279 "issue_row" "issue"%ROWTYPE;
1280 "draft_id_v" "draft"."id"%TYPE;
1281 BEGIN
1282 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1283 SELECT * INTO "issue_row" FROM "issue"
1284 WHERE "id" = NEW."issue_id";
1285 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1286 WHERE "initiative_id" = NEW."id";
1287 INSERT INTO "event" (
1288 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1289 ) VALUES (
1290 'initiative_revoked',
1291 NEW."revoked_by_member_id",
1292 NEW."issue_id",
1293 "issue_row"."state",
1294 NEW."id",
1295 "draft_id_v");
1296 END IF;
1297 RETURN NULL;
1298 END;
1299 $$;
1301 CREATE TRIGGER "write_event_initiative_revoked"
1302 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1303 "write_event_initiative_revoked_trigger"();
1305 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1306 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1309 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1310 RETURNS TRIGGER
1311 LANGUAGE 'plpgsql' VOLATILE AS $$
1312 DECLARE
1313 "initiative_row" "initiative"%ROWTYPE;
1314 "issue_row" "issue"%ROWTYPE;
1315 BEGIN
1316 SELECT * INTO "initiative_row" FROM "initiative"
1317 WHERE "id" = NEW."initiative_id";
1318 SELECT * INTO "issue_row" FROM "issue"
1319 WHERE "id" = "initiative_row"."issue_id";
1320 INSERT INTO "event" (
1321 "event", "member_id",
1322 "issue_id", "state", "initiative_id", "suggestion_id"
1323 ) VALUES (
1324 'suggestion_created',
1325 NEW."author_id",
1326 "initiative_row"."issue_id",
1327 "issue_row"."state",
1328 "initiative_row"."id",
1329 NEW."id" );
1330 RETURN NULL;
1331 END;
1332 $$;
1334 CREATE TRIGGER "write_event_suggestion_created"
1335 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1336 "write_event_suggestion_created_trigger"();
1338 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1339 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1343 ----------------------------
1344 -- Additional constraints --
1345 ----------------------------
1348 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1349 RETURNS TRIGGER
1350 LANGUAGE 'plpgsql' VOLATILE AS $$
1351 BEGIN
1352 IF NOT EXISTS (
1353 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1354 ) THEN
1355 --RAISE 'Cannot create issue without an initial initiative.' USING
1356 -- ERRCODE = 'integrity_constraint_violation',
1357 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1358 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1359 END IF;
1360 RETURN NULL;
1361 END;
1362 $$;
1364 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1365 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1366 FOR EACH ROW EXECUTE PROCEDURE
1367 "issue_requires_first_initiative_trigger"();
1369 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1370 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1373 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1374 RETURNS TRIGGER
1375 LANGUAGE 'plpgsql' VOLATILE AS $$
1376 DECLARE
1377 "reference_lost" BOOLEAN;
1378 BEGIN
1379 IF TG_OP = 'DELETE' THEN
1380 "reference_lost" := TRUE;
1381 ELSE
1382 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1383 END IF;
1384 IF
1385 "reference_lost" AND NOT EXISTS (
1386 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1388 THEN
1389 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1390 END IF;
1391 RETURN NULL;
1392 END;
1393 $$;
1395 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1396 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1397 FOR EACH ROW EXECUTE PROCEDURE
1398 "last_initiative_deletes_issue_trigger"();
1400 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1401 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1404 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1405 RETURNS TRIGGER
1406 LANGUAGE 'plpgsql' VOLATILE AS $$
1407 BEGIN
1408 IF NOT EXISTS (
1409 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1410 ) THEN
1411 --RAISE 'Cannot create initiative without an initial draft.' USING
1412 -- ERRCODE = 'integrity_constraint_violation',
1413 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1414 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1415 END IF;
1416 RETURN NULL;
1417 END;
1418 $$;
1420 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1421 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1422 FOR EACH ROW EXECUTE PROCEDURE
1423 "initiative_requires_first_draft_trigger"();
1425 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1426 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1429 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1430 RETURNS TRIGGER
1431 LANGUAGE 'plpgsql' VOLATILE AS $$
1432 DECLARE
1433 "reference_lost" BOOLEAN;
1434 BEGIN
1435 IF TG_OP = 'DELETE' THEN
1436 "reference_lost" := TRUE;
1437 ELSE
1438 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1439 END IF;
1440 IF
1441 "reference_lost" AND NOT EXISTS (
1442 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1444 THEN
1445 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1446 END IF;
1447 RETURN NULL;
1448 END;
1449 $$;
1451 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1452 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1453 FOR EACH ROW EXECUTE PROCEDURE
1454 "last_draft_deletes_initiative_trigger"();
1456 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1457 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1460 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1461 RETURNS TRIGGER
1462 LANGUAGE 'plpgsql' VOLATILE AS $$
1463 BEGIN
1464 IF NOT EXISTS (
1465 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1466 ) THEN
1467 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1468 END IF;
1469 RETURN NULL;
1470 END;
1471 $$;
1473 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1474 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1475 FOR EACH ROW EXECUTE PROCEDURE
1476 "suggestion_requires_first_opinion_trigger"();
1478 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1479 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1482 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1483 RETURNS TRIGGER
1484 LANGUAGE 'plpgsql' VOLATILE AS $$
1485 DECLARE
1486 "reference_lost" BOOLEAN;
1487 BEGIN
1488 IF TG_OP = 'DELETE' THEN
1489 "reference_lost" := TRUE;
1490 ELSE
1491 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1492 END IF;
1493 IF
1494 "reference_lost" AND NOT EXISTS (
1495 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1497 THEN
1498 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1499 END IF;
1500 RETURN NULL;
1501 END;
1502 $$;
1504 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1505 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1506 FOR EACH ROW EXECUTE PROCEDURE
1507 "last_opinion_deletes_suggestion_trigger"();
1509 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1510 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1513 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1514 RETURNS TRIGGER
1515 LANGUAGE 'plpgsql' VOLATILE AS $$
1516 BEGIN
1517 DELETE FROM "direct_voter"
1518 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1519 RETURN NULL;
1520 END;
1521 $$;
1523 CREATE TRIGGER "non_voter_deletes_direct_voter"
1524 AFTER INSERT OR UPDATE ON "non_voter"
1525 FOR EACH ROW EXECUTE PROCEDURE
1526 "non_voter_deletes_direct_voter_trigger"();
1528 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1529 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")';
1532 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1533 RETURNS TRIGGER
1534 LANGUAGE 'plpgsql' VOLATILE AS $$
1535 BEGIN
1536 DELETE FROM "non_voter"
1537 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1538 RETURN NULL;
1539 END;
1540 $$;
1542 CREATE TRIGGER "direct_voter_deletes_non_voter"
1543 AFTER INSERT OR UPDATE ON "direct_voter"
1544 FOR EACH ROW EXECUTE PROCEDURE
1545 "direct_voter_deletes_non_voter_trigger"();
1547 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1548 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")';
1551 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1552 RETURNS TRIGGER
1553 LANGUAGE 'plpgsql' VOLATILE AS $$
1554 BEGIN
1555 IF NEW."comment" ISNULL THEN
1556 NEW."comment_changed" := NULL;
1557 NEW."formatting_engine" := NULL;
1558 END IF;
1559 RETURN NEW;
1560 END;
1561 $$;
1563 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1564 BEFORE INSERT OR UPDATE ON "direct_voter"
1565 FOR EACH ROW EXECUTE PROCEDURE
1566 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1568 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"';
1569 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.';
1572 ---------------------------------------------------------------
1573 -- Ensure that votes are not modified when issues are frozen --
1574 ---------------------------------------------------------------
1576 -- NOTE: Frontends should ensure this anyway, but in case of programming
1577 -- errors the following triggers ensure data integrity.
1580 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1581 RETURNS TRIGGER
1582 LANGUAGE 'plpgsql' VOLATILE AS $$
1583 DECLARE
1584 "issue_id_v" "issue"."id"%TYPE;
1585 "issue_row" "issue"%ROWTYPE;
1586 BEGIN
1587 IF TG_RELID = 'direct_voter'::regclass AND TG_OP = 'UPDATE' THEN
1588 IF
1589 OLD."issue_id" = NEW."issue_id" AND
1590 OLD."member_id" = NEW."member_id" AND
1591 OLD."weight" = NEW."weight"
1592 THEN
1593 RETURN NULL; -- allows changing of voter comment
1594 END IF;
1595 END IF;
1596 IF TG_OP = 'DELETE' THEN
1597 "issue_id_v" := OLD."issue_id";
1598 ELSE
1599 "issue_id_v" := NEW."issue_id";
1600 END IF;
1601 SELECT INTO "issue_row" * FROM "issue"
1602 WHERE "id" = "issue_id_v" FOR SHARE;
1603 IF "issue_row"."closed" NOTNULL THEN
1604 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1605 END IF;
1606 RETURN NULL;
1607 END;
1608 $$;
1610 CREATE TRIGGER "forbid_changes_on_closed_issue"
1611 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1612 FOR EACH ROW EXECUTE PROCEDURE
1613 "forbid_changes_on_closed_issue_trigger"();
1615 CREATE TRIGGER "forbid_changes_on_closed_issue"
1616 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1617 FOR EACH ROW EXECUTE PROCEDURE
1618 "forbid_changes_on_closed_issue_trigger"();
1620 CREATE TRIGGER "forbid_changes_on_closed_issue"
1621 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1622 FOR EACH ROW EXECUTE PROCEDURE
1623 "forbid_changes_on_closed_issue_trigger"();
1625 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"';
1626 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';
1627 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';
1628 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';
1632 --------------------------------------------------------------------
1633 -- Auto-retrieval of fields only needed for referential integrity --
1634 --------------------------------------------------------------------
1637 CREATE FUNCTION "autofill_issue_id_trigger"()
1638 RETURNS TRIGGER
1639 LANGUAGE 'plpgsql' VOLATILE AS $$
1640 BEGIN
1641 IF NEW."issue_id" ISNULL THEN
1642 SELECT "issue_id" INTO NEW."issue_id"
1643 FROM "initiative" WHERE "id" = NEW."initiative_id";
1644 END IF;
1645 RETURN NEW;
1646 END;
1647 $$;
1649 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1650 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1652 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1653 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1655 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1656 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1657 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1660 CREATE FUNCTION "autofill_initiative_id_trigger"()
1661 RETURNS TRIGGER
1662 LANGUAGE 'plpgsql' VOLATILE AS $$
1663 BEGIN
1664 IF NEW."initiative_id" ISNULL THEN
1665 SELECT "initiative_id" INTO NEW."initiative_id"
1666 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1667 END IF;
1668 RETURN NEW;
1669 END;
1670 $$;
1672 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1673 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1675 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1676 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1680 -----------------------------------------------------
1681 -- Automatic calculation of certain default values --
1682 -----------------------------------------------------
1685 CREATE FUNCTION "copy_timings_trigger"()
1686 RETURNS TRIGGER
1687 LANGUAGE 'plpgsql' VOLATILE AS $$
1688 DECLARE
1689 "policy_row" "policy"%ROWTYPE;
1690 BEGIN
1691 SELECT * INTO "policy_row" FROM "policy"
1692 WHERE "id" = NEW."policy_id";
1693 IF NEW."admission_time" ISNULL THEN
1694 NEW."admission_time" := "policy_row"."admission_time";
1695 END IF;
1696 IF NEW."discussion_time" ISNULL THEN
1697 NEW."discussion_time" := "policy_row"."discussion_time";
1698 END IF;
1699 IF NEW."verification_time" ISNULL THEN
1700 NEW."verification_time" := "policy_row"."verification_time";
1701 END IF;
1702 IF NEW."voting_time" ISNULL THEN
1703 NEW."voting_time" := "policy_row"."voting_time";
1704 END IF;
1705 RETURN NEW;
1706 END;
1707 $$;
1709 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1710 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1712 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1713 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1716 CREATE FUNCTION "default_for_draft_id_trigger"()
1717 RETURNS TRIGGER
1718 LANGUAGE 'plpgsql' VOLATILE AS $$
1719 BEGIN
1720 IF NEW."draft_id" ISNULL THEN
1721 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1722 WHERE "initiative_id" = NEW."initiative_id";
1723 END IF;
1724 RETURN NEW;
1725 END;
1726 $$;
1728 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1729 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1730 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1731 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1733 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1734 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';
1735 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';
1739 ----------------------------------------
1740 -- Automatic creation of dependencies --
1741 ----------------------------------------
1744 CREATE FUNCTION "autocreate_interest_trigger"()
1745 RETURNS TRIGGER
1746 LANGUAGE 'plpgsql' VOLATILE AS $$
1747 BEGIN
1748 IF NOT EXISTS (
1749 SELECT NULL FROM "initiative" JOIN "interest"
1750 ON "initiative"."issue_id" = "interest"."issue_id"
1751 WHERE "initiative"."id" = NEW."initiative_id"
1752 AND "interest"."member_id" = NEW."member_id"
1753 ) THEN
1754 BEGIN
1755 INSERT INTO "interest" ("issue_id", "member_id")
1756 SELECT "issue_id", NEW."member_id"
1757 FROM "initiative" WHERE "id" = NEW."initiative_id";
1758 EXCEPTION WHEN unique_violation THEN END;
1759 END IF;
1760 RETURN NEW;
1761 END;
1762 $$;
1764 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1765 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1767 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1768 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';
1771 CREATE FUNCTION "autocreate_supporter_trigger"()
1772 RETURNS TRIGGER
1773 LANGUAGE 'plpgsql' VOLATILE AS $$
1774 BEGIN
1775 IF NOT EXISTS (
1776 SELECT NULL FROM "suggestion" JOIN "supporter"
1777 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1778 WHERE "suggestion"."id" = NEW."suggestion_id"
1779 AND "supporter"."member_id" = NEW."member_id"
1780 ) THEN
1781 BEGIN
1782 INSERT INTO "supporter" ("initiative_id", "member_id")
1783 SELECT "initiative_id", NEW."member_id"
1784 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1785 EXCEPTION WHEN unique_violation THEN END;
1786 END IF;
1787 RETURN NEW;
1788 END;
1789 $$;
1791 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1792 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1794 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1795 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.';
1799 ------------------------------------------
1800 -- Views and helper functions for views --
1801 ------------------------------------------
1804 CREATE VIEW "unit_delegation" AS
1805 SELECT
1806 "unit"."id" AS "unit_id",
1807 "delegation"."id",
1808 "delegation"."truster_id",
1809 "delegation"."trustee_id",
1810 "delegation"."scope"
1811 FROM "unit"
1812 JOIN "delegation"
1813 ON "delegation"."unit_id" = "unit"."id"
1814 JOIN "member"
1815 ON "delegation"."truster_id" = "member"."id"
1816 JOIN "privilege"
1817 ON "delegation"."unit_id" = "privilege"."unit_id"
1818 AND "delegation"."truster_id" = "privilege"."member_id"
1819 WHERE "member"."active" AND "privilege"."voting_right";
1821 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1824 CREATE VIEW "area_delegation" AS
1825 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1826 "area"."id" AS "area_id",
1827 "delegation"."id",
1828 "delegation"."truster_id",
1829 "delegation"."trustee_id",
1830 "delegation"."scope"
1831 FROM "area"
1832 JOIN "delegation"
1833 ON "delegation"."unit_id" = "area"."unit_id"
1834 OR "delegation"."area_id" = "area"."id"
1835 JOIN "member"
1836 ON "delegation"."truster_id" = "member"."id"
1837 JOIN "privilege"
1838 ON "area"."unit_id" = "privilege"."unit_id"
1839 AND "delegation"."truster_id" = "privilege"."member_id"
1840 WHERE "member"."active" AND "privilege"."voting_right"
1841 ORDER BY
1842 "area"."id",
1843 "delegation"."truster_id",
1844 "delegation"."scope" DESC;
1846 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1849 CREATE VIEW "issue_delegation" AS
1850 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1851 "issue"."id" AS "issue_id",
1852 "delegation"."id",
1853 "delegation"."truster_id",
1854 "delegation"."trustee_id",
1855 "delegation"."scope"
1856 FROM "issue"
1857 JOIN "area"
1858 ON "area"."id" = "issue"."area_id"
1859 JOIN "delegation"
1860 ON "delegation"."unit_id" = "area"."unit_id"
1861 OR "delegation"."area_id" = "area"."id"
1862 OR "delegation"."issue_id" = "issue"."id"
1863 JOIN "member"
1864 ON "delegation"."truster_id" = "member"."id"
1865 JOIN "privilege"
1866 ON "area"."unit_id" = "privilege"."unit_id"
1867 AND "delegation"."truster_id" = "privilege"."member_id"
1868 WHERE "member"."active" AND "privilege"."voting_right"
1869 ORDER BY
1870 "issue"."id",
1871 "delegation"."truster_id",
1872 "delegation"."scope" DESC;
1874 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1877 CREATE FUNCTION "membership_weight_with_skipping"
1878 ( "area_id_p" "area"."id"%TYPE,
1879 "member_id_p" "member"."id"%TYPE,
1880 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1881 RETURNS INT4
1882 LANGUAGE 'plpgsql' STABLE AS $$
1883 DECLARE
1884 "sum_v" INT4;
1885 "delegation_row" "area_delegation"%ROWTYPE;
1886 BEGIN
1887 "sum_v" := 1;
1888 FOR "delegation_row" IN
1889 SELECT "area_delegation".*
1890 FROM "area_delegation" LEFT JOIN "membership"
1891 ON "membership"."area_id" = "area_id_p"
1892 AND "membership"."member_id" = "area_delegation"."truster_id"
1893 WHERE "area_delegation"."area_id" = "area_id_p"
1894 AND "area_delegation"."trustee_id" = "member_id_p"
1895 AND "membership"."member_id" ISNULL
1896 LOOP
1897 IF NOT
1898 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1899 THEN
1900 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1901 "area_id_p",
1902 "delegation_row"."truster_id",
1903 "skip_member_ids_p" || "delegation_row"."truster_id"
1904 );
1905 END IF;
1906 END LOOP;
1907 RETURN "sum_v";
1908 END;
1909 $$;
1911 COMMENT ON FUNCTION "membership_weight_with_skipping"
1912 ( "area"."id"%TYPE,
1913 "member"."id"%TYPE,
1914 INT4[] )
1915 IS 'Helper function for "membership_weight" function';
1918 CREATE FUNCTION "membership_weight"
1919 ( "area_id_p" "area"."id"%TYPE,
1920 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1921 RETURNS INT4
1922 LANGUAGE 'plpgsql' STABLE AS $$
1923 BEGIN
1924 RETURN "membership_weight_with_skipping"(
1925 "area_id_p",
1926 "member_id_p",
1927 ARRAY["member_id_p"]
1928 );
1929 END;
1930 $$;
1932 COMMENT ON FUNCTION "membership_weight"
1933 ( "area"."id"%TYPE,
1934 "member"."id"%TYPE )
1935 IS 'Calculates the potential voting weight of a member in a given area';
1938 CREATE VIEW "member_count_view" AS
1939 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1941 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1944 CREATE VIEW "unit_member_count" AS
1945 SELECT
1946 "unit"."id" AS "unit_id",
1947 count("member"."id") AS "member_count"
1948 FROM "unit"
1949 LEFT JOIN "privilege"
1950 ON "privilege"."unit_id" = "unit"."id"
1951 AND "privilege"."voting_right"
1952 LEFT JOIN "member"
1953 ON "member"."id" = "privilege"."member_id"
1954 AND "member"."active"
1955 GROUP BY "unit"."id";
1957 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1960 CREATE VIEW "area_member_count" AS
1961 SELECT
1962 "area"."id" AS "area_id",
1963 count("member"."id") AS "direct_member_count",
1964 coalesce(
1965 sum(
1966 CASE WHEN "member"."id" NOTNULL THEN
1967 "membership_weight"("area"."id", "member"."id")
1968 ELSE 0 END
1970 ) AS "member_weight"
1971 FROM "area"
1972 LEFT JOIN "membership"
1973 ON "area"."id" = "membership"."area_id"
1974 LEFT JOIN "privilege"
1975 ON "privilege"."unit_id" = "area"."unit_id"
1976 AND "privilege"."member_id" = "membership"."member_id"
1977 AND "privilege"."voting_right"
1978 LEFT JOIN "member"
1979 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1980 AND "member"."active"
1981 GROUP BY "area"."id";
1983 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1986 CREATE VIEW "opening_draft" AS
1987 SELECT "draft".* FROM (
1988 SELECT
1989 "initiative"."id" AS "initiative_id",
1990 min("draft"."id") AS "draft_id"
1991 FROM "initiative" JOIN "draft"
1992 ON "initiative"."id" = "draft"."initiative_id"
1993 GROUP BY "initiative"."id"
1994 ) AS "subquery"
1995 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1997 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2000 CREATE VIEW "current_draft" AS
2001 SELECT "draft".* FROM (
2002 SELECT
2003 "initiative"."id" AS "initiative_id",
2004 max("draft"."id") AS "draft_id"
2005 FROM "initiative" JOIN "draft"
2006 ON "initiative"."id" = "draft"."initiative_id"
2007 GROUP BY "initiative"."id"
2008 ) AS "subquery"
2009 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2011 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2014 CREATE VIEW "critical_opinion" AS
2015 SELECT * FROM "opinion"
2016 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2017 OR ("degree" = -2 AND "fulfilled" = TRUE);
2019 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2022 CREATE VIEW "battle_participant" AS
2023 SELECT "initiative"."id", "initiative"."issue_id"
2024 FROM "issue" JOIN "initiative"
2025 ON "issue"."id" = "initiative"."issue_id"
2026 WHERE "initiative"."admitted"
2027 UNION ALL
2028 SELECT NULL, "id" AS "issue_id"
2029 FROM "issue";
2031 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2034 CREATE VIEW "battle_view" AS
2035 SELECT
2036 "issue"."id" AS "issue_id",
2037 "winning_initiative"."id" AS "winning_initiative_id",
2038 "losing_initiative"."id" AS "losing_initiative_id",
2039 sum(
2040 CASE WHEN
2041 coalesce("better_vote"."grade", 0) >
2042 coalesce("worse_vote"."grade", 0)
2043 THEN "direct_voter"."weight" ELSE 0 END
2044 ) AS "count"
2045 FROM "issue"
2046 LEFT JOIN "direct_voter"
2047 ON "issue"."id" = "direct_voter"."issue_id"
2048 JOIN "battle_participant" AS "winning_initiative"
2049 ON "issue"."id" = "winning_initiative"."issue_id"
2050 JOIN "battle_participant" AS "losing_initiative"
2051 ON "issue"."id" = "losing_initiative"."issue_id"
2052 LEFT JOIN "vote" AS "better_vote"
2053 ON "direct_voter"."member_id" = "better_vote"."member_id"
2054 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2055 LEFT JOIN "vote" AS "worse_vote"
2056 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2057 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2058 WHERE "issue"."closed" NOTNULL
2059 AND "issue"."cleaned" ISNULL
2060 AND (
2061 "winning_initiative"."id" != "losing_initiative"."id" OR
2062 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2063 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2064 GROUP BY
2065 "issue"."id",
2066 "winning_initiative"."id",
2067 "losing_initiative"."id";
2069 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';
2072 CREATE VIEW "expired_session" AS
2073 SELECT * FROM "session" WHERE now() > "expiry";
2075 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2076 DELETE FROM "session" WHERE "ident" = OLD."ident";
2078 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2079 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2082 CREATE VIEW "open_issue" AS
2083 SELECT * FROM "issue" WHERE "closed" ISNULL;
2085 COMMENT ON VIEW "open_issue" IS 'All open issues';
2088 CREATE VIEW "issue_with_ranks_missing" AS
2089 SELECT * FROM "issue"
2090 WHERE "fully_frozen" NOTNULL
2091 AND "closed" NOTNULL
2092 AND "ranks_available" = FALSE;
2094 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
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"';
2283 CREATE TYPE "timeline_event" AS ENUM (
2284 'issue_created',
2285 'issue_canceled',
2286 'issue_accepted',
2287 'issue_half_frozen',
2288 'issue_finished_without_voting',
2289 'issue_voting_started',
2290 'issue_finished_after_voting',
2291 'initiative_created',
2292 'initiative_revoked',
2293 'draft_created',
2294 'suggestion_created');
2296 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2299 CREATE VIEW "timeline_issue" AS
2300 SELECT
2301 "created" AS "occurrence",
2302 'issue_created'::"timeline_event" AS "event",
2303 "id" AS "issue_id"
2304 FROM "issue"
2305 UNION ALL
2306 SELECT
2307 "closed" AS "occurrence",
2308 'issue_canceled'::"timeline_event" AS "event",
2309 "id" AS "issue_id"
2310 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2311 UNION ALL
2312 SELECT
2313 "accepted" AS "occurrence",
2314 'issue_accepted'::"timeline_event" AS "event",
2315 "id" AS "issue_id"
2316 FROM "issue" WHERE "accepted" NOTNULL
2317 UNION ALL
2318 SELECT
2319 "half_frozen" AS "occurrence",
2320 'issue_half_frozen'::"timeline_event" AS "event",
2321 "id" AS "issue_id"
2322 FROM "issue" WHERE "half_frozen" NOTNULL
2323 UNION ALL
2324 SELECT
2325 "fully_frozen" AS "occurrence",
2326 'issue_voting_started'::"timeline_event" AS "event",
2327 "id" AS "issue_id"
2328 FROM "issue"
2329 WHERE "fully_frozen" NOTNULL
2330 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2331 UNION ALL
2332 SELECT
2333 "closed" AS "occurrence",
2334 CASE WHEN "fully_frozen" = "closed" THEN
2335 'issue_finished_without_voting'::"timeline_event"
2336 ELSE
2337 'issue_finished_after_voting'::"timeline_event"
2338 END AS "event",
2339 "id" AS "issue_id"
2340 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2342 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2345 CREATE VIEW "timeline_initiative" AS
2346 SELECT
2347 "created" AS "occurrence",
2348 'initiative_created'::"timeline_event" AS "event",
2349 "id" AS "initiative_id"
2350 FROM "initiative"
2351 UNION ALL
2352 SELECT
2353 "revoked" AS "occurrence",
2354 'initiative_revoked'::"timeline_event" AS "event",
2355 "id" AS "initiative_id"
2356 FROM "initiative" WHERE "revoked" NOTNULL;
2358 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2361 CREATE VIEW "timeline_draft" AS
2362 SELECT
2363 "created" AS "occurrence",
2364 'draft_created'::"timeline_event" AS "event",
2365 "id" AS "draft_id"
2366 FROM "draft";
2368 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2371 CREATE VIEW "timeline_suggestion" AS
2372 SELECT
2373 "created" AS "occurrence",
2374 'suggestion_created'::"timeline_event" AS "event",
2375 "id" AS "suggestion_id"
2376 FROM "suggestion";
2378 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2381 CREATE VIEW "timeline" AS
2382 SELECT
2383 "occurrence",
2384 "event",
2385 "issue_id",
2386 NULL AS "initiative_id",
2387 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2388 NULL::INT8 AS "suggestion_id"
2389 FROM "timeline_issue"
2390 UNION ALL
2391 SELECT
2392 "occurrence",
2393 "event",
2394 NULL AS "issue_id",
2395 "initiative_id",
2396 NULL AS "draft_id",
2397 NULL AS "suggestion_id"
2398 FROM "timeline_initiative"
2399 UNION ALL
2400 SELECT
2401 "occurrence",
2402 "event",
2403 NULL AS "issue_id",
2404 NULL AS "initiative_id",
2405 "draft_id",
2406 NULL AS "suggestion_id"
2407 FROM "timeline_draft"
2408 UNION ALL
2409 SELECT
2410 "occurrence",
2411 "event",
2412 NULL AS "issue_id",
2413 NULL AS "initiative_id",
2414 NULL AS "draft_id",
2415 "suggestion_id"
2416 FROM "timeline_suggestion";
2418 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2422 ------------------------------------------------------
2423 -- Row set returning function for delegation chains --
2424 ------------------------------------------------------
2427 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2428 ('first', 'intermediate', 'last', 'repetition');
2430 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2433 CREATE TYPE "delegation_chain_row" AS (
2434 "index" INT4,
2435 "member_id" INT4,
2436 "member_valid" BOOLEAN,
2437 "participation" BOOLEAN,
2438 "overridden" BOOLEAN,
2439 "scope_in" "delegation_scope",
2440 "scope_out" "delegation_scope",
2441 "disabled_out" BOOLEAN,
2442 "loop" "delegation_chain_loop_tag" );
2444 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2446 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2447 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';
2448 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2449 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2450 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2451 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2452 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2455 CREATE FUNCTION "delegation_chain_for_closed_issue"
2456 ( "member_id_p" "member"."id"%TYPE,
2457 "issue_id_p" "issue"."id"%TYPE )
2458 RETURNS SETOF "delegation_chain_row"
2459 LANGUAGE 'plpgsql' STABLE AS $$
2460 DECLARE
2461 "output_row" "delegation_chain_row";
2462 "direct_voter_row" "direct_voter"%ROWTYPE;
2463 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2464 BEGIN
2465 "output_row"."index" := 0;
2466 "output_row"."member_id" := "member_id_p";
2467 "output_row"."member_valid" := TRUE;
2468 "output_row"."participation" := FALSE;
2469 "output_row"."overridden" := FALSE;
2470 "output_row"."disabled_out" := FALSE;
2471 LOOP
2472 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2473 WHERE "issue_id" = "issue_id_p"
2474 AND "member_id" = "output_row"."member_id";
2475 IF "direct_voter_row"."member_id" NOTNULL THEN
2476 "output_row"."participation" := TRUE;
2477 "output_row"."scope_out" := NULL;
2478 "output_row"."disabled_out" := NULL;
2479 RETURN NEXT "output_row";
2480 RETURN;
2481 END IF;
2482 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2483 WHERE "issue_id" = "issue_id_p"
2484 AND "member_id" = "output_row"."member_id";
2485 IF "delegating_voter_row"."member_id" ISNULL THEN
2486 RETURN;
2487 END IF;
2488 "output_row"."scope_out" := "delegating_voter_row"."scope";
2489 RETURN NEXT "output_row";
2490 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2491 "output_row"."scope_in" := "output_row"."scope_out";
2492 END LOOP;
2493 END;
2494 $$;
2496 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2497 ( "member"."id"%TYPE,
2498 "member"."id"%TYPE )
2499 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2502 CREATE FUNCTION "delegation_chain"
2503 ( "member_id_p" "member"."id"%TYPE,
2504 "unit_id_p" "unit"."id"%TYPE,
2505 "area_id_p" "area"."id"%TYPE,
2506 "issue_id_p" "issue"."id"%TYPE,
2507 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2508 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2509 RETURNS SETOF "delegation_chain_row"
2510 LANGUAGE 'plpgsql' STABLE AS $$
2511 DECLARE
2512 "scope_v" "delegation_scope";
2513 "unit_id_v" "unit"."id"%TYPE;
2514 "area_id_v" "area"."id"%TYPE;
2515 "issue_row" "issue"%ROWTYPE;
2516 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2517 "loop_member_id_v" "member"."id"%TYPE;
2518 "output_row" "delegation_chain_row";
2519 "output_rows" "delegation_chain_row"[];
2520 "simulate_v" BOOLEAN;
2521 "simulate_here_v" BOOLEAN;
2522 "delegation_row" "delegation"%ROWTYPE;
2523 "row_count" INT4;
2524 "i" INT4;
2525 "loop_v" BOOLEAN;
2526 BEGIN
2527 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2528 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2529 END IF;
2530 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2531 "simulate_v" := TRUE;
2532 ELSE
2533 "simulate_v" := FALSE;
2534 END IF;
2535 IF
2536 "unit_id_p" NOTNULL AND
2537 "area_id_p" ISNULL AND
2538 "issue_id_p" ISNULL
2539 THEN
2540 "scope_v" := 'unit';
2541 "unit_id_v" := "unit_id_p";
2542 ELSIF
2543 "unit_id_p" ISNULL AND
2544 "area_id_p" NOTNULL AND
2545 "issue_id_p" ISNULL
2546 THEN
2547 "scope_v" := 'area';
2548 "area_id_v" := "area_id_p";
2549 SELECT "unit_id" INTO "unit_id_v"
2550 FROM "area" WHERE "id" = "area_id_v";
2551 ELSIF
2552 "unit_id_p" ISNULL AND
2553 "area_id_p" ISNULL AND
2554 "issue_id_p" NOTNULL
2555 THEN
2556 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2557 IF "issue_row"."id" ISNULL THEN
2558 RETURN;
2559 END IF;
2560 IF "issue_row"."closed" NOTNULL THEN
2561 IF "simulate_v" THEN
2562 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2563 END IF;
2564 FOR "output_row" IN
2565 SELECT * FROM
2566 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2567 LOOP
2568 RETURN NEXT "output_row";
2569 END LOOP;
2570 RETURN;
2571 END IF;
2572 "scope_v" := 'issue';
2573 SELECT "area_id" INTO "area_id_v"
2574 FROM "issue" WHERE "id" = "issue_id_p";
2575 SELECT "unit_id" INTO "unit_id_v"
2576 FROM "area" WHERE "id" = "area_id_v";
2577 ELSE
2578 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2579 END IF;
2580 "visited_member_ids" := '{}';
2581 "loop_member_id_v" := NULL;
2582 "output_rows" := '{}';
2583 "output_row"."index" := 0;
2584 "output_row"."member_id" := "member_id_p";
2585 "output_row"."member_valid" := TRUE;
2586 "output_row"."participation" := FALSE;
2587 "output_row"."overridden" := FALSE;
2588 "output_row"."disabled_out" := FALSE;
2589 "output_row"."scope_out" := NULL;
2590 LOOP
2591 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2592 "loop_member_id_v" := "output_row"."member_id";
2593 ELSE
2594 "visited_member_ids" :=
2595 "visited_member_ids" || "output_row"."member_id";
2596 END IF;
2597 IF "output_row"."participation" ISNULL THEN
2598 "output_row"."overridden" := NULL;
2599 ELSIF "output_row"."participation" THEN
2600 "output_row"."overridden" := TRUE;
2601 END IF;
2602 "output_row"."scope_in" := "output_row"."scope_out";
2603 "output_row"."member_valid" := EXISTS (
2604 SELECT NULL FROM "member" JOIN "privilege"
2605 ON "privilege"."member_id" = "member"."id"
2606 AND "privilege"."unit_id" = "unit_id_v"
2607 WHERE "id" = "output_row"."member_id"
2608 AND "member"."active" AND "privilege"."voting_right"
2609 );
2610 "simulate_here_v" := (
2611 "simulate_v" AND
2612 "output_row"."member_id" = "member_id_p"
2613 );
2614 "delegation_row" := ROW(NULL);
2615 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2616 IF "scope_v" = 'unit' THEN
2617 IF NOT "simulate_here_v" THEN
2618 SELECT * INTO "delegation_row" FROM "delegation"
2619 WHERE "truster_id" = "output_row"."member_id"
2620 AND "unit_id" = "unit_id_v";
2621 END IF;
2622 ELSIF "scope_v" = 'area' THEN
2623 "output_row"."participation" := EXISTS (
2624 SELECT NULL FROM "membership"
2625 WHERE "area_id" = "area_id_p"
2626 AND "member_id" = "output_row"."member_id"
2627 );
2628 IF "simulate_here_v" THEN
2629 IF "simulate_trustee_id_p" ISNULL THEN
2630 SELECT * INTO "delegation_row" FROM "delegation"
2631 WHERE "truster_id" = "output_row"."member_id"
2632 AND "unit_id" = "unit_id_v";
2633 END IF;
2634 ELSE
2635 SELECT * INTO "delegation_row" FROM "delegation"
2636 WHERE "truster_id" = "output_row"."member_id"
2637 AND (
2638 "unit_id" = "unit_id_v" OR
2639 "area_id" = "area_id_v"
2641 ORDER BY "scope" DESC;
2642 END IF;
2643 ELSIF "scope_v" = 'issue' THEN
2644 IF "issue_row"."fully_frozen" ISNULL THEN
2645 "output_row"."participation" := EXISTS (
2646 SELECT NULL FROM "interest"
2647 WHERE "issue_id" = "issue_id_p"
2648 AND "member_id" = "output_row"."member_id"
2649 );
2650 ELSE
2651 IF "output_row"."member_id" = "member_id_p" THEN
2652 "output_row"."participation" := EXISTS (
2653 SELECT NULL FROM "direct_voter"
2654 WHERE "issue_id" = "issue_id_p"
2655 AND "member_id" = "output_row"."member_id"
2656 );
2657 ELSE
2658 "output_row"."participation" := NULL;
2659 END IF;
2660 END IF;
2661 IF "simulate_here_v" THEN
2662 IF "simulate_trustee_id_p" ISNULL THEN
2663 SELECT * INTO "delegation_row" FROM "delegation"
2664 WHERE "truster_id" = "output_row"."member_id"
2665 AND (
2666 "unit_id" = "unit_id_v" OR
2667 "area_id" = "area_id_v"
2669 ORDER BY "scope" DESC;
2670 END IF;
2671 ELSE
2672 SELECT * INTO "delegation_row" FROM "delegation"
2673 WHERE "truster_id" = "output_row"."member_id"
2674 AND (
2675 "unit_id" = "unit_id_v" OR
2676 "area_id" = "area_id_v" OR
2677 "issue_id" = "issue_id_p"
2679 ORDER BY "scope" DESC;
2680 END IF;
2681 END IF;
2682 ELSE
2683 "output_row"."participation" := FALSE;
2684 END IF;
2685 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2686 "output_row"."scope_out" := "scope_v";
2687 "output_rows" := "output_rows" || "output_row";
2688 "output_row"."member_id" := "simulate_trustee_id_p";
2689 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2690 "output_row"."scope_out" := "delegation_row"."scope";
2691 "output_rows" := "output_rows" || "output_row";
2692 "output_row"."member_id" := "delegation_row"."trustee_id";
2693 ELSIF "delegation_row"."scope" NOTNULL THEN
2694 "output_row"."scope_out" := "delegation_row"."scope";
2695 "output_row"."disabled_out" := TRUE;
2696 "output_rows" := "output_rows" || "output_row";
2697 EXIT;
2698 ELSE
2699 "output_row"."scope_out" := NULL;
2700 "output_rows" := "output_rows" || "output_row";
2701 EXIT;
2702 END IF;
2703 EXIT WHEN "loop_member_id_v" NOTNULL;
2704 "output_row"."index" := "output_row"."index" + 1;
2705 END LOOP;
2706 "row_count" := array_upper("output_rows", 1);
2707 "i" := 1;
2708 "loop_v" := FALSE;
2709 LOOP
2710 "output_row" := "output_rows"["i"];
2711 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2712 IF "loop_v" THEN
2713 IF "i" + 1 = "row_count" THEN
2714 "output_row"."loop" := 'last';
2715 ELSIF "i" = "row_count" THEN
2716 "output_row"."loop" := 'repetition';
2717 ELSE
2718 "output_row"."loop" := 'intermediate';
2719 END IF;
2720 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2721 "output_row"."loop" := 'first';
2722 "loop_v" := TRUE;
2723 END IF;
2724 IF "scope_v" = 'unit' THEN
2725 "output_row"."participation" := NULL;
2726 END IF;
2727 RETURN NEXT "output_row";
2728 "i" := "i" + 1;
2729 END LOOP;
2730 RETURN;
2731 END;
2732 $$;
2734 COMMENT ON FUNCTION "delegation_chain"
2735 ( "member"."id"%TYPE,
2736 "unit"."id"%TYPE,
2737 "area"."id"%TYPE,
2738 "issue"."id"%TYPE,
2739 "member"."id"%TYPE,
2740 BOOLEAN )
2741 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2745 ---------------------------------------------------------
2746 -- Single row returning function for delegation chains --
2747 ---------------------------------------------------------
2750 CREATE TYPE "delegation_info_loop_type" AS ENUM
2751 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2753 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''';
2756 CREATE TYPE "delegation_info_type" AS (
2757 "own_participation" BOOLEAN,
2758 "own_delegation_scope" "delegation_scope",
2759 "first_trustee_id" INT4,
2760 "first_trustee_participation" BOOLEAN,
2761 "first_trustee_ellipsis" BOOLEAN,
2762 "other_trustee_id" INT4,
2763 "other_trustee_participation" BOOLEAN,
2764 "other_trustee_ellipsis" BOOLEAN,
2765 "delegation_loop" "delegation_info_loop_type",
2766 "participating_member_id" INT4 );
2768 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';
2770 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2771 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2772 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2773 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2774 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2775 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2776 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)';
2777 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2778 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';
2779 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2782 CREATE FUNCTION "delegation_info"
2783 ( "member_id_p" "member"."id"%TYPE,
2784 "unit_id_p" "unit"."id"%TYPE,
2785 "area_id_p" "area"."id"%TYPE,
2786 "issue_id_p" "issue"."id"%TYPE,
2787 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2788 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2789 RETURNS "delegation_info_type"
2790 LANGUAGE 'plpgsql' STABLE AS $$
2791 DECLARE
2792 "current_row" "delegation_chain_row";
2793 "result" "delegation_info_type";
2794 BEGIN
2795 "result"."own_participation" := FALSE;
2796 FOR "current_row" IN
2797 SELECT * FROM "delegation_chain"(
2798 "member_id_p",
2799 "unit_id_p", "area_id_p", "issue_id_p",
2800 "simulate_trustee_id_p", "simulate_default_p")
2801 LOOP
2802 IF
2803 "result"."participating_member_id" ISNULL AND
2804 "current_row"."participation"
2805 THEN
2806 "result"."participating_member_id" := "current_row"."member_id";
2807 END IF;
2808 IF "current_row"."member_id" = "member_id_p" THEN
2809 "result"."own_participation" := "current_row"."participation";
2810 "result"."own_delegation_scope" := "current_row"."scope_out";
2811 IF "current_row"."loop" = 'first' THEN
2812 "result"."delegation_loop" := 'own';
2813 END IF;
2814 ELSIF
2815 "current_row"."member_valid" AND
2816 ( "current_row"."loop" ISNULL OR
2817 "current_row"."loop" != 'repetition' )
2818 THEN
2819 IF "result"."first_trustee_id" ISNULL THEN
2820 "result"."first_trustee_id" := "current_row"."member_id";
2821 "result"."first_trustee_participation" := "current_row"."participation";
2822 "result"."first_trustee_ellipsis" := FALSE;
2823 IF "current_row"."loop" = 'first' THEN
2824 "result"."delegation_loop" := 'first';
2825 END IF;
2826 ELSIF "result"."other_trustee_id" ISNULL THEN
2827 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2828 "result"."other_trustee_id" := "current_row"."member_id";
2829 "result"."other_trustee_participation" := TRUE;
2830 "result"."other_trustee_ellipsis" := FALSE;
2831 IF "current_row"."loop" = 'first' THEN
2832 "result"."delegation_loop" := 'other';
2833 END IF;
2834 ELSE
2835 "result"."first_trustee_ellipsis" := TRUE;
2836 IF "current_row"."loop" = 'first' THEN
2837 "result"."delegation_loop" := 'first_ellipsis';
2838 END IF;
2839 END IF;
2840 ELSE
2841 "result"."other_trustee_ellipsis" := TRUE;
2842 IF "current_row"."loop" = 'first' THEN
2843 "result"."delegation_loop" := 'other_ellipsis';
2844 END IF;
2845 END IF;
2846 END IF;
2847 END LOOP;
2848 RETURN "result";
2849 END;
2850 $$;
2852 COMMENT ON FUNCTION "delegation_info"
2853 ( "member"."id"%TYPE,
2854 "unit"."id"%TYPE,
2855 "area"."id"%TYPE,
2856 "issue"."id"%TYPE,
2857 "member"."id"%TYPE,
2858 BOOLEAN )
2859 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2863 ------------------------------------------------
2864 -- Locking for snapshots and voting procedure --
2865 ------------------------------------------------
2868 CREATE FUNCTION "share_row_lock_issue_trigger"()
2869 RETURNS TRIGGER
2870 LANGUAGE 'plpgsql' VOLATILE AS $$
2871 BEGIN
2872 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2873 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2874 END IF;
2875 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2876 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2877 RETURN NEW;
2878 ELSE
2879 RETURN OLD;
2880 END IF;
2881 END;
2882 $$;
2884 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2887 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2888 RETURNS TRIGGER
2889 LANGUAGE 'plpgsql' VOLATILE AS $$
2890 BEGIN
2891 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2892 PERFORM NULL FROM "issue"
2893 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2894 WHERE "initiative"."id" = OLD."initiative_id"
2895 FOR SHARE OF "issue";
2896 END IF;
2897 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2898 PERFORM NULL FROM "issue"
2899 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2900 WHERE "initiative"."id" = NEW."initiative_id"
2901 FOR SHARE OF "issue";
2902 RETURN NEW;
2903 ELSE
2904 RETURN OLD;
2905 END IF;
2906 END;
2907 $$;
2909 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2912 CREATE TRIGGER "share_row_lock_issue"
2913 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2914 FOR EACH ROW EXECUTE PROCEDURE
2915 "share_row_lock_issue_trigger"();
2917 CREATE TRIGGER "share_row_lock_issue"
2918 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2919 FOR EACH ROW EXECUTE PROCEDURE
2920 "share_row_lock_issue_trigger"();
2922 CREATE TRIGGER "share_row_lock_issue"
2923 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2924 FOR EACH ROW EXECUTE PROCEDURE
2925 "share_row_lock_issue_trigger"();
2927 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2928 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2929 FOR EACH ROW EXECUTE PROCEDURE
2930 "share_row_lock_issue_via_initiative_trigger"();
2932 CREATE TRIGGER "share_row_lock_issue"
2933 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2934 FOR EACH ROW EXECUTE PROCEDURE
2935 "share_row_lock_issue_trigger"();
2937 CREATE TRIGGER "share_row_lock_issue"
2938 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2939 FOR EACH ROW EXECUTE PROCEDURE
2940 "share_row_lock_issue_trigger"();
2942 CREATE TRIGGER "share_row_lock_issue"
2943 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2944 FOR EACH ROW EXECUTE PROCEDURE
2945 "share_row_lock_issue_trigger"();
2947 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2948 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2949 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2950 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2951 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2952 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2953 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2956 CREATE FUNCTION "lock_issue"
2957 ( "issue_id_p" "issue"."id"%TYPE )
2958 RETURNS VOID
2959 LANGUAGE 'plpgsql' VOLATILE AS $$
2960 BEGIN
2961 -- The following locking order is used:
2962 -- 1st) row-level lock on the issue
2963 -- 2nd) table-level locks in order of occurrence in the core.sql file
2964 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2965 -- NOTE: The row-level exclusive lock in combination with the
2966 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2967 -- acquire a row-level share lock on the issue) ensure that no data
2968 -- is changed, which could affect calculation of snapshots or
2969 -- counting of votes. Table "delegation" must be table-level-locked,
2970 -- as it also contains issue- and global-scope delegations.
2971 PERFORM NULL FROM "member" WHERE "active" FOR SHARE;
2972 -- NOTE: As we later cause implicit row-level share locks on many
2973 -- active members, we lock them before locking any other table
2974 -- to avoid deadlocks
2975 LOCK TABLE "member" IN SHARE MODE;
2976 LOCK TABLE "privilege" IN SHARE MODE;
2977 LOCK TABLE "membership" IN SHARE MODE;
2978 LOCK TABLE "policy" IN SHARE MODE;
2979 LOCK TABLE "delegation" IN SHARE MODE;
2980 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2981 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2982 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2983 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2984 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2985 RETURN;
2986 END;
2987 $$;
2989 COMMENT ON FUNCTION "lock_issue"
2990 ( "issue"."id"%TYPE )
2991 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2995 ------------------------------------------------------------------------
2996 -- Regular tasks, except calculcation of snapshots and voting results --
2997 ------------------------------------------------------------------------
2999 CREATE FUNCTION "check_activity"()
3000 RETURNS VOID
3001 LANGUAGE 'plpgsql' VOLATILE AS $$
3002 DECLARE
3003 "system_setting_row" "system_setting"%ROWTYPE;
3004 BEGIN
3005 SELECT * INTO "system_setting_row" FROM "system_setting";
3006 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
3007 IF "system_setting_row"."member_ttl" NOTNULL THEN
3008 UPDATE "member" SET "active" = FALSE
3009 WHERE "active" = TRUE
3010 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
3011 END IF;
3012 RETURN;
3013 END;
3014 $$;
3016 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
3019 CREATE FUNCTION "calculate_member_counts"()
3020 RETURNS VOID
3021 LANGUAGE 'plpgsql' VOLATILE AS $$
3022 BEGIN
3023 LOCK TABLE "member" IN SHARE MODE;
3024 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
3025 LOCK TABLE "unit" IN EXCLUSIVE MODE;
3026 LOCK TABLE "area" IN EXCLUSIVE MODE;
3027 LOCK TABLE "privilege" IN SHARE MODE;
3028 LOCK TABLE "membership" IN SHARE MODE;
3029 DELETE FROM "member_count";
3030 INSERT INTO "member_count" ("total_count")
3031 SELECT "total_count" FROM "member_count_view";
3032 UPDATE "unit" SET "member_count" = "view"."member_count"
3033 FROM "unit_member_count" AS "view"
3034 WHERE "view"."unit_id" = "unit"."id";
3035 UPDATE "area" SET
3036 "direct_member_count" = "view"."direct_member_count",
3037 "member_weight" = "view"."member_weight"
3038 FROM "area_member_count" AS "view"
3039 WHERE "view"."area_id" = "area"."id";
3040 RETURN;
3041 END;
3042 $$;
3044 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"';
3048 ------------------------------
3049 -- Calculation of snapshots --
3050 ------------------------------
3052 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3053 ( "issue_id_p" "issue"."id"%TYPE,
3054 "member_id_p" "member"."id"%TYPE,
3055 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3056 RETURNS "direct_population_snapshot"."weight"%TYPE
3057 LANGUAGE 'plpgsql' VOLATILE AS $$
3058 DECLARE
3059 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3060 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3061 "weight_v" INT4;
3062 "sub_weight_v" INT4;
3063 BEGIN
3064 "weight_v" := 0;
3065 FOR "issue_delegation_row" IN
3066 SELECT * FROM "issue_delegation"
3067 WHERE "trustee_id" = "member_id_p"
3068 AND "issue_id" = "issue_id_p"
3069 LOOP
3070 IF NOT EXISTS (
3071 SELECT NULL FROM "direct_population_snapshot"
3072 WHERE "issue_id" = "issue_id_p"
3073 AND "event" = 'periodic'
3074 AND "member_id" = "issue_delegation_row"."truster_id"
3075 ) AND NOT EXISTS (
3076 SELECT NULL FROM "delegating_population_snapshot"
3077 WHERE "issue_id" = "issue_id_p"
3078 AND "event" = 'periodic'
3079 AND "member_id" = "issue_delegation_row"."truster_id"
3080 ) THEN
3081 "delegate_member_ids_v" :=
3082 "member_id_p" || "delegate_member_ids_p";
3083 INSERT INTO "delegating_population_snapshot" (
3084 "issue_id",
3085 "event",
3086 "member_id",
3087 "scope",
3088 "delegate_member_ids"
3089 ) VALUES (
3090 "issue_id_p",
3091 'periodic',
3092 "issue_delegation_row"."truster_id",
3093 "issue_delegation_row"."scope",
3094 "delegate_member_ids_v"
3095 );
3096 "sub_weight_v" := 1 +
3097 "weight_of_added_delegations_for_population_snapshot"(
3098 "issue_id_p",
3099 "issue_delegation_row"."truster_id",
3100 "delegate_member_ids_v"
3101 );
3102 UPDATE "delegating_population_snapshot"
3103 SET "weight" = "sub_weight_v"
3104 WHERE "issue_id" = "issue_id_p"
3105 AND "event" = 'periodic'
3106 AND "member_id" = "issue_delegation_row"."truster_id";
3107 "weight_v" := "weight_v" + "sub_weight_v";
3108 END IF;
3109 END LOOP;
3110 RETURN "weight_v";
3111 END;
3112 $$;
3114 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3115 ( "issue"."id"%TYPE,
3116 "member"."id"%TYPE,
3117 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3118 IS 'Helper function for "create_population_snapshot" function';
3121 CREATE FUNCTION "create_population_snapshot"
3122 ( "issue_id_p" "issue"."id"%TYPE )
3123 RETURNS VOID
3124 LANGUAGE 'plpgsql' VOLATILE AS $$
3125 DECLARE
3126 "member_id_v" "member"."id"%TYPE;
3127 BEGIN
3128 DELETE FROM "direct_population_snapshot"
3129 WHERE "issue_id" = "issue_id_p"
3130 AND "event" = 'periodic';
3131 DELETE FROM "delegating_population_snapshot"
3132 WHERE "issue_id" = "issue_id_p"
3133 AND "event" = 'periodic';
3134 INSERT INTO "direct_population_snapshot"
3135 ("issue_id", "event", "member_id")
3136 SELECT
3137 "issue_id_p" AS "issue_id",
3138 'periodic'::"snapshot_event" AS "event",
3139 "member"."id" AS "member_id"
3140 FROM "issue"
3141 JOIN "area" ON "issue"."area_id" = "area"."id"
3142 JOIN "membership" ON "area"."id" = "membership"."area_id"
3143 JOIN "member" ON "membership"."member_id" = "member"."id"
3144 JOIN "privilege"
3145 ON "privilege"."unit_id" = "area"."unit_id"
3146 AND "privilege"."member_id" = "member"."id"
3147 WHERE "issue"."id" = "issue_id_p"
3148 AND "member"."active" AND "privilege"."voting_right"
3149 UNION
3150 SELECT
3151 "issue_id_p" AS "issue_id",
3152 'periodic'::"snapshot_event" AS "event",
3153 "member"."id" AS "member_id"
3154 FROM "issue"
3155 JOIN "area" ON "issue"."area_id" = "area"."id"
3156 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3157 JOIN "member" ON "interest"."member_id" = "member"."id"
3158 JOIN "privilege"
3159 ON "privilege"."unit_id" = "area"."unit_id"
3160 AND "privilege"."member_id" = "member"."id"
3161 WHERE "issue"."id" = "issue_id_p"
3162 AND "member"."active" AND "privilege"."voting_right";
3163 FOR "member_id_v" IN
3164 SELECT "member_id" FROM "direct_population_snapshot"
3165 WHERE "issue_id" = "issue_id_p"
3166 AND "event" = 'periodic'
3167 LOOP
3168 UPDATE "direct_population_snapshot" SET
3169 "weight" = 1 +
3170 "weight_of_added_delegations_for_population_snapshot"(
3171 "issue_id_p",
3172 "member_id_v",
3173 '{}'
3175 WHERE "issue_id" = "issue_id_p"
3176 AND "event" = 'periodic'
3177 AND "member_id" = "member_id_v";
3178 END LOOP;
3179 RETURN;
3180 END;
3181 $$;
3183 COMMENT ON FUNCTION "create_population_snapshot"
3184 ( "issue"."id"%TYPE )
3185 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.';
3188 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3189 ( "issue_id_p" "issue"."id"%TYPE,
3190 "member_id_p" "member"."id"%TYPE,
3191 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3192 RETURNS "direct_interest_snapshot"."weight"%TYPE
3193 LANGUAGE 'plpgsql' VOLATILE AS $$
3194 DECLARE
3195 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3196 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3197 "weight_v" INT4;
3198 "sub_weight_v" INT4;
3199 BEGIN
3200 "weight_v" := 0;
3201 FOR "issue_delegation_row" IN
3202 SELECT * FROM "issue_delegation"
3203 WHERE "trustee_id" = "member_id_p"
3204 AND "issue_id" = "issue_id_p"
3205 LOOP
3206 IF NOT EXISTS (
3207 SELECT NULL FROM "direct_interest_snapshot"
3208 WHERE "issue_id" = "issue_id_p"
3209 AND "event" = 'periodic'
3210 AND "member_id" = "issue_delegation_row"."truster_id"
3211 ) AND NOT EXISTS (
3212 SELECT NULL FROM "delegating_interest_snapshot"
3213 WHERE "issue_id" = "issue_id_p"
3214 AND "event" = 'periodic'
3215 AND "member_id" = "issue_delegation_row"."truster_id"
3216 ) THEN
3217 "delegate_member_ids_v" :=
3218 "member_id_p" || "delegate_member_ids_p";
3219 INSERT INTO "delegating_interest_snapshot" (
3220 "issue_id",
3221 "event",
3222 "member_id",
3223 "scope",
3224 "delegate_member_ids"
3225 ) VALUES (
3226 "issue_id_p",
3227 'periodic',
3228 "issue_delegation_row"."truster_id",
3229 "issue_delegation_row"."scope",
3230 "delegate_member_ids_v"
3231 );
3232 "sub_weight_v" := 1 +
3233 "weight_of_added_delegations_for_interest_snapshot"(
3234 "issue_id_p",
3235 "issue_delegation_row"."truster_id",
3236 "delegate_member_ids_v"
3237 );
3238 UPDATE "delegating_interest_snapshot"
3239 SET "weight" = "sub_weight_v"
3240 WHERE "issue_id" = "issue_id_p"
3241 AND "event" = 'periodic'
3242 AND "member_id" = "issue_delegation_row"."truster_id";
3243 "weight_v" := "weight_v" + "sub_weight_v";
3244 END IF;
3245 END LOOP;
3246 RETURN "weight_v";
3247 END;
3248 $$;
3250 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3251 ( "issue"."id"%TYPE,
3252 "member"."id"%TYPE,
3253 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3254 IS 'Helper function for "create_interest_snapshot" function';
3257 CREATE FUNCTION "create_interest_snapshot"
3258 ( "issue_id_p" "issue"."id"%TYPE )
3259 RETURNS VOID
3260 LANGUAGE 'plpgsql' VOLATILE AS $$
3261 DECLARE
3262 "member_id_v" "member"."id"%TYPE;
3263 BEGIN
3264 DELETE FROM "direct_interest_snapshot"
3265 WHERE "issue_id" = "issue_id_p"
3266 AND "event" = 'periodic';
3267 DELETE FROM "delegating_interest_snapshot"
3268 WHERE "issue_id" = "issue_id_p"
3269 AND "event" = 'periodic';
3270 DELETE FROM "direct_supporter_snapshot"
3271 USING "initiative" -- NOTE: due to missing index on issue_id
3272 WHERE "initiative"."issue_id" = "issue_id_p"
3273 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3274 AND "direct_supporter_snapshot"."event" = 'periodic';
3275 INSERT INTO "direct_interest_snapshot"
3276 ("issue_id", "event", "member_id")
3277 SELECT
3278 "issue_id_p" AS "issue_id",
3279 'periodic' AS "event",
3280 "member"."id" AS "member_id"
3281 FROM "issue"
3282 JOIN "area" ON "issue"."area_id" = "area"."id"
3283 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3284 JOIN "member" ON "interest"."member_id" = "member"."id"
3285 JOIN "privilege"
3286 ON "privilege"."unit_id" = "area"."unit_id"
3287 AND "privilege"."member_id" = "member"."id"
3288 WHERE "issue"."id" = "issue_id_p"
3289 AND "member"."active" AND "privilege"."voting_right";
3290 FOR "member_id_v" IN
3291 SELECT "member_id" FROM "direct_interest_snapshot"
3292 WHERE "issue_id" = "issue_id_p"
3293 AND "event" = 'periodic'
3294 LOOP
3295 UPDATE "direct_interest_snapshot" SET
3296 "weight" = 1 +
3297 "weight_of_added_delegations_for_interest_snapshot"(
3298 "issue_id_p",
3299 "member_id_v",
3300 '{}'
3302 WHERE "issue_id" = "issue_id_p"
3303 AND "event" = 'periodic'
3304 AND "member_id" = "member_id_v";
3305 END LOOP;
3306 INSERT INTO "direct_supporter_snapshot"
3307 ( "issue_id", "initiative_id", "event", "member_id",
3308 "draft_id", "informed", "satisfied" )
3309 SELECT
3310 "issue_id_p" AS "issue_id",
3311 "initiative"."id" AS "initiative_id",
3312 'periodic' AS "event",
3313 "supporter"."member_id" AS "member_id",
3314 "supporter"."draft_id" AS "draft_id",
3315 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3316 NOT EXISTS (
3317 SELECT NULL FROM "critical_opinion"
3318 WHERE "initiative_id" = "initiative"."id"
3319 AND "member_id" = "supporter"."member_id"
3320 ) AS "satisfied"
3321 FROM "initiative"
3322 JOIN "supporter"
3323 ON "supporter"."initiative_id" = "initiative"."id"
3324 JOIN "current_draft"
3325 ON "initiative"."id" = "current_draft"."initiative_id"
3326 JOIN "direct_interest_snapshot"
3327 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3328 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3329 AND "event" = 'periodic'
3330 WHERE "initiative"."issue_id" = "issue_id_p";
3331 RETURN;
3332 END;
3333 $$;
3335 COMMENT ON FUNCTION "create_interest_snapshot"
3336 ( "issue"."id"%TYPE )
3337 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.';
3340 CREATE FUNCTION "create_snapshot"
3341 ( "issue_id_p" "issue"."id"%TYPE )
3342 RETURNS VOID
3343 LANGUAGE 'plpgsql' VOLATILE AS $$
3344 DECLARE
3345 "initiative_id_v" "initiative"."id"%TYPE;
3346 "suggestion_id_v" "suggestion"."id"%TYPE;
3347 BEGIN
3348 PERFORM "lock_issue"("issue_id_p");
3349 PERFORM "create_population_snapshot"("issue_id_p");
3350 PERFORM "create_interest_snapshot"("issue_id_p");
3351 UPDATE "issue" SET
3352 "snapshot" = now(),
3353 "latest_snapshot_event" = 'periodic',
3354 "population" = (
3355 SELECT coalesce(sum("weight"), 0)
3356 FROM "direct_population_snapshot"
3357 WHERE "issue_id" = "issue_id_p"
3358 AND "event" = 'periodic'
3360 WHERE "id" = "issue_id_p";
3361 FOR "initiative_id_v" IN
3362 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3363 LOOP
3364 UPDATE "initiative" SET
3365 "supporter_count" = (
3366 SELECT coalesce(sum("di"."weight"), 0)
3367 FROM "direct_interest_snapshot" AS "di"
3368 JOIN "direct_supporter_snapshot" AS "ds"
3369 ON "di"."member_id" = "ds"."member_id"
3370 WHERE "di"."issue_id" = "issue_id_p"
3371 AND "di"."event" = 'periodic'
3372 AND "ds"."initiative_id" = "initiative_id_v"
3373 AND "ds"."event" = 'periodic'
3374 ),
3375 "informed_supporter_count" = (
3376 SELECT coalesce(sum("di"."weight"), 0)
3377 FROM "direct_interest_snapshot" AS "di"
3378 JOIN "direct_supporter_snapshot" AS "ds"
3379 ON "di"."member_id" = "ds"."member_id"
3380 WHERE "di"."issue_id" = "issue_id_p"
3381 AND "di"."event" = 'periodic'
3382 AND "ds"."initiative_id" = "initiative_id_v"
3383 AND "ds"."event" = 'periodic'
3384 AND "ds"."informed"
3385 ),
3386 "satisfied_supporter_count" = (
3387 SELECT coalesce(sum("di"."weight"), 0)
3388 FROM "direct_interest_snapshot" AS "di"
3389 JOIN "direct_supporter_snapshot" AS "ds"
3390 ON "di"."member_id" = "ds"."member_id"
3391 WHERE "di"."issue_id" = "issue_id_p"
3392 AND "di"."event" = 'periodic'
3393 AND "ds"."initiative_id" = "initiative_id_v"
3394 AND "ds"."event" = 'periodic'
3395 AND "ds"."satisfied"
3396 ),
3397 "satisfied_informed_supporter_count" = (
3398 SELECT coalesce(sum("di"."weight"), 0)
3399 FROM "direct_interest_snapshot" AS "di"
3400 JOIN "direct_supporter_snapshot" AS "ds"
3401 ON "di"."member_id" = "ds"."member_id"
3402 WHERE "di"."issue_id" = "issue_id_p"
3403 AND "di"."event" = 'periodic'
3404 AND "ds"."initiative_id" = "initiative_id_v"
3405 AND "ds"."event" = 'periodic'
3406 AND "ds"."informed"
3407 AND "ds"."satisfied"
3409 WHERE "id" = "initiative_id_v";
3410 FOR "suggestion_id_v" IN
3411 SELECT "id" FROM "suggestion"
3412 WHERE "initiative_id" = "initiative_id_v"
3413 LOOP
3414 UPDATE "suggestion" SET
3415 "minus2_unfulfilled_count" = (
3416 SELECT coalesce(sum("snapshot"."weight"), 0)
3417 FROM "issue" CROSS JOIN "opinion"
3418 JOIN "direct_interest_snapshot" AS "snapshot"
3419 ON "snapshot"."issue_id" = "issue"."id"
3420 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3421 AND "snapshot"."member_id" = "opinion"."member_id"
3422 WHERE "issue"."id" = "issue_id_p"
3423 AND "opinion"."suggestion_id" = "suggestion_id_v"
3424 AND "opinion"."degree" = -2
3425 AND "opinion"."fulfilled" = FALSE
3426 ),
3427 "minus2_fulfilled_count" = (
3428 SELECT coalesce(sum("snapshot"."weight"), 0)
3429 FROM "issue" CROSS JOIN "opinion"
3430 JOIN "direct_interest_snapshot" AS "snapshot"
3431 ON "snapshot"."issue_id" = "issue"."id"
3432 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3433 AND "snapshot"."member_id" = "opinion"."member_id"
3434 WHERE "issue"."id" = "issue_id_p"
3435 AND "opinion"."suggestion_id" = "suggestion_id_v"
3436 AND "opinion"."degree" = -2
3437 AND "opinion"."fulfilled" = TRUE
3438 ),
3439 "minus1_unfulfilled_count" = (
3440 SELECT coalesce(sum("snapshot"."weight"), 0)
3441 FROM "issue" CROSS JOIN "opinion"
3442 JOIN "direct_interest_snapshot" AS "snapshot"
3443 ON "snapshot"."issue_id" = "issue"."id"
3444 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3445 AND "snapshot"."member_id" = "opinion"."member_id"
3446 WHERE "issue"."id" = "issue_id_p"
3447 AND "opinion"."suggestion_id" = "suggestion_id_v"
3448 AND "opinion"."degree" = -1
3449 AND "opinion"."fulfilled" = FALSE
3450 ),
3451 "minus1_fulfilled_count" = (
3452 SELECT coalesce(sum("snapshot"."weight"), 0)
3453 FROM "issue" CROSS JOIN "opinion"
3454 JOIN "direct_interest_snapshot" AS "snapshot"
3455 ON "snapshot"."issue_id" = "issue"."id"
3456 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3457 AND "snapshot"."member_id" = "opinion"."member_id"
3458 WHERE "issue"."id" = "issue_id_p"
3459 AND "opinion"."suggestion_id" = "suggestion_id_v"
3460 AND "opinion"."degree" = -1
3461 AND "opinion"."fulfilled" = TRUE
3462 ),
3463 "plus1_unfulfilled_count" = (
3464 SELECT coalesce(sum("snapshot"."weight"), 0)
3465 FROM "issue" CROSS JOIN "opinion"
3466 JOIN "direct_interest_snapshot" AS "snapshot"
3467 ON "snapshot"."issue_id" = "issue"."id"
3468 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3469 AND "snapshot"."member_id" = "opinion"."member_id"
3470 WHERE "issue"."id" = "issue_id_p"
3471 AND "opinion"."suggestion_id" = "suggestion_id_v"
3472 AND "opinion"."degree" = 1
3473 AND "opinion"."fulfilled" = FALSE
3474 ),
3475 "plus1_fulfilled_count" = (
3476 SELECT coalesce(sum("snapshot"."weight"), 0)
3477 FROM "issue" CROSS JOIN "opinion"
3478 JOIN "direct_interest_snapshot" AS "snapshot"
3479 ON "snapshot"."issue_id" = "issue"."id"
3480 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3481 AND "snapshot"."member_id" = "opinion"."member_id"
3482 WHERE "issue"."id" = "issue_id_p"
3483 AND "opinion"."suggestion_id" = "suggestion_id_v"
3484 AND "opinion"."degree" = 1
3485 AND "opinion"."fulfilled" = TRUE
3486 ),
3487 "plus2_unfulfilled_count" = (
3488 SELECT coalesce(sum("snapshot"."weight"), 0)
3489 FROM "issue" CROSS JOIN "opinion"
3490 JOIN "direct_interest_snapshot" AS "snapshot"
3491 ON "snapshot"."issue_id" = "issue"."id"
3492 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3493 AND "snapshot"."member_id" = "opinion"."member_id"
3494 WHERE "issue"."id" = "issue_id_p"
3495 AND "opinion"."suggestion_id" = "suggestion_id_v"
3496 AND "opinion"."degree" = 2
3497 AND "opinion"."fulfilled" = FALSE
3498 ),
3499 "plus2_fulfilled_count" = (
3500 SELECT coalesce(sum("snapshot"."weight"), 0)
3501 FROM "issue" CROSS JOIN "opinion"
3502 JOIN "direct_interest_snapshot" AS "snapshot"
3503 ON "snapshot"."issue_id" = "issue"."id"
3504 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3505 AND "snapshot"."member_id" = "opinion"."member_id"
3506 WHERE "issue"."id" = "issue_id_p"
3507 AND "opinion"."suggestion_id" = "suggestion_id_v"
3508 AND "opinion"."degree" = 2
3509 AND "opinion"."fulfilled" = TRUE
3511 WHERE "suggestion"."id" = "suggestion_id_v";
3512 END LOOP;
3513 END LOOP;
3514 RETURN;
3515 END;
3516 $$;
3518 COMMENT ON FUNCTION "create_snapshot"
3519 ( "issue"."id"%TYPE )
3520 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.';
3523 CREATE FUNCTION "set_snapshot_event"
3524 ( "issue_id_p" "issue"."id"%TYPE,
3525 "event_p" "snapshot_event" )
3526 RETURNS VOID
3527 LANGUAGE 'plpgsql' VOLATILE AS $$
3528 DECLARE
3529 "event_v" "issue"."latest_snapshot_event"%TYPE;
3530 BEGIN
3531 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3532 WHERE "id" = "issue_id_p" FOR UPDATE;
3533 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3534 WHERE "id" = "issue_id_p";
3535 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3536 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3537 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3538 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3539 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3540 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3541 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3542 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3543 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3544 FROM "initiative" -- NOTE: due to missing index on issue_id
3545 WHERE "initiative"."issue_id" = "issue_id_p"
3546 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3547 AND "direct_supporter_snapshot"."event" = "event_v";
3548 RETURN;
3549 END;
3550 $$;
3552 COMMENT ON FUNCTION "set_snapshot_event"
3553 ( "issue"."id"%TYPE,
3554 "snapshot_event" )
3555 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3559 ---------------------
3560 -- Freezing issues --
3561 ---------------------
3563 CREATE FUNCTION "freeze_after_snapshot"
3564 ( "issue_id_p" "issue"."id"%TYPE )
3565 RETURNS VOID
3566 LANGUAGE 'plpgsql' VOLATILE AS $$
3567 DECLARE
3568 "issue_row" "issue"%ROWTYPE;
3569 "policy_row" "policy"%ROWTYPE;
3570 "initiative_row" "initiative"%ROWTYPE;
3571 BEGIN
3572 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3573 SELECT * INTO "policy_row"
3574 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3575 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3576 FOR "initiative_row" IN
3577 SELECT * FROM "initiative"
3578 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3579 LOOP
3580 IF
3581 "initiative_row"."polling" OR (
3582 "initiative_row"."satisfied_supporter_count" > 0 AND
3583 "initiative_row"."satisfied_supporter_count" *
3584 "policy_row"."initiative_quorum_den" >=
3585 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3587 THEN
3588 UPDATE "initiative" SET "admitted" = TRUE
3589 WHERE "id" = "initiative_row"."id";
3590 ELSE
3591 UPDATE "initiative" SET "admitted" = FALSE
3592 WHERE "id" = "initiative_row"."id";
3593 END IF;
3594 END LOOP;
3595 IF EXISTS (
3596 SELECT NULL FROM "initiative"
3597 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3598 ) THEN
3599 UPDATE "issue" SET
3600 "state" = 'voting',
3601 "accepted" = coalesce("accepted", now()),
3602 "half_frozen" = coalesce("half_frozen", now()),
3603 "fully_frozen" = now()
3604 WHERE "id" = "issue_id_p";
3605 ELSE
3606 UPDATE "issue" SET
3607 "state" = 'canceled_no_initiative_admitted',
3608 "accepted" = coalesce("accepted", now()),
3609 "half_frozen" = coalesce("half_frozen", now()),
3610 "fully_frozen" = now(),
3611 "closed" = now(),
3612 "ranks_available" = TRUE
3613 WHERE "id" = "issue_id_p";
3614 -- NOTE: The following DELETE statements have effect only when
3615 -- issue state has been manipulated
3616 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3617 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3618 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3619 END IF;
3620 RETURN;
3621 END;
3622 $$;
3624 COMMENT ON FUNCTION "freeze_after_snapshot"
3625 ( "issue"."id"%TYPE )
3626 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3629 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3630 RETURNS VOID
3631 LANGUAGE 'plpgsql' VOLATILE AS $$
3632 DECLARE
3633 "issue_row" "issue"%ROWTYPE;
3634 BEGIN
3635 PERFORM "create_snapshot"("issue_id_p");
3636 PERFORM "freeze_after_snapshot"("issue_id_p");
3637 RETURN;
3638 END;
3639 $$;
3641 COMMENT ON FUNCTION "manual_freeze"
3642 ( "issue"."id"%TYPE )
3643 IS 'Freeze an issue manually (fully) and start voting';
3647 -----------------------
3648 -- Counting of votes --
3649 -----------------------
3652 CREATE FUNCTION "weight_of_added_vote_delegations"
3653 ( "issue_id_p" "issue"."id"%TYPE,
3654 "member_id_p" "member"."id"%TYPE,
3655 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3656 RETURNS "direct_voter"."weight"%TYPE
3657 LANGUAGE 'plpgsql' VOLATILE AS $$
3658 DECLARE
3659 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3660 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3661 "weight_v" INT4;
3662 "sub_weight_v" INT4;
3663 BEGIN
3664 "weight_v" := 0;
3665 FOR "issue_delegation_row" IN
3666 SELECT * FROM "issue_delegation"
3667 WHERE "trustee_id" = "member_id_p"
3668 AND "issue_id" = "issue_id_p"
3669 LOOP
3670 IF NOT EXISTS (
3671 SELECT NULL FROM "direct_voter"
3672 WHERE "member_id" = "issue_delegation_row"."truster_id"
3673 AND "issue_id" = "issue_id_p"
3674 ) AND NOT EXISTS (
3675 SELECT NULL FROM "delegating_voter"
3676 WHERE "member_id" = "issue_delegation_row"."truster_id"
3677 AND "issue_id" = "issue_id_p"
3678 ) THEN
3679 "delegate_member_ids_v" :=
3680 "member_id_p" || "delegate_member_ids_p";
3681 INSERT INTO "delegating_voter" (
3682 "issue_id",
3683 "member_id",
3684 "scope",
3685 "delegate_member_ids"
3686 ) VALUES (
3687 "issue_id_p",
3688 "issue_delegation_row"."truster_id",
3689 "issue_delegation_row"."scope",
3690 "delegate_member_ids_v"
3691 );
3692 "sub_weight_v" := 1 +
3693 "weight_of_added_vote_delegations"(
3694 "issue_id_p",
3695 "issue_delegation_row"."truster_id",
3696 "delegate_member_ids_v"
3697 );
3698 UPDATE "delegating_voter"
3699 SET "weight" = "sub_weight_v"
3700 WHERE "issue_id" = "issue_id_p"
3701 AND "member_id" = "issue_delegation_row"."truster_id";
3702 "weight_v" := "weight_v" + "sub_weight_v";
3703 END IF;
3704 END LOOP;
3705 RETURN "weight_v";
3706 END;
3707 $$;
3709 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3710 ( "issue"."id"%TYPE,
3711 "member"."id"%TYPE,
3712 "delegating_voter"."delegate_member_ids"%TYPE )
3713 IS 'Helper function for "add_vote_delegations" function';
3716 CREATE FUNCTION "add_vote_delegations"
3717 ( "issue_id_p" "issue"."id"%TYPE )
3718 RETURNS VOID
3719 LANGUAGE 'plpgsql' VOLATILE AS $$
3720 DECLARE
3721 "member_id_v" "member"."id"%TYPE;
3722 BEGIN
3723 FOR "member_id_v" IN
3724 SELECT "member_id" FROM "direct_voter"
3725 WHERE "issue_id" = "issue_id_p"
3726 LOOP
3727 UPDATE "direct_voter" SET
3728 "weight" = "weight" + "weight_of_added_vote_delegations"(
3729 "issue_id_p",
3730 "member_id_v",
3731 '{}'
3733 WHERE "member_id" = "member_id_v"
3734 AND "issue_id" = "issue_id_p";
3735 END LOOP;
3736 RETURN;
3737 END;
3738 $$;
3740 COMMENT ON FUNCTION "add_vote_delegations"
3741 ( "issue_id_p" "issue"."id"%TYPE )
3742 IS 'Helper function for "close_voting" function';
3745 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3746 RETURNS VOID
3747 LANGUAGE 'plpgsql' VOLATILE AS $$
3748 DECLARE
3749 "area_id_v" "area"."id"%TYPE;
3750 "unit_id_v" "unit"."id"%TYPE;
3751 "member_id_v" "member"."id"%TYPE;
3752 BEGIN
3753 PERFORM "lock_issue"("issue_id_p");
3754 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3755 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3756 -- delete timestamp of voting comment:
3757 UPDATE "direct_voter" SET "comment_changed" = NULL
3758 WHERE "issue_id" = "issue_id_p";
3759 -- delete delegating votes (in cases of manual reset of issue state):
3760 DELETE FROM "delegating_voter"
3761 WHERE "issue_id" = "issue_id_p";
3762 -- delete votes from non-privileged voters:
3763 DELETE FROM "direct_voter"
3764 USING (
3765 SELECT
3766 "direct_voter"."member_id"
3767 FROM "direct_voter"
3768 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3769 LEFT JOIN "privilege"
3770 ON "privilege"."unit_id" = "unit_id_v"
3771 AND "privilege"."member_id" = "direct_voter"."member_id"
3772 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3773 "member"."active" = FALSE OR
3774 "privilege"."voting_right" ISNULL OR
3775 "privilege"."voting_right" = FALSE
3777 ) AS "subquery"
3778 WHERE "direct_voter"."issue_id" = "issue_id_p"
3779 AND "direct_voter"."member_id" = "subquery"."member_id";
3780 -- consider delegations:
3781 UPDATE "direct_voter" SET "weight" = 1
3782 WHERE "issue_id" = "issue_id_p";
3783 PERFORM "add_vote_delegations"("issue_id_p");
3784 -- set voter count and mark issue as being calculated:
3785 UPDATE "issue" SET
3786 "state" = 'calculation',
3787 "closed" = now(),
3788 "voter_count" = (
3789 SELECT coalesce(sum("weight"), 0)
3790 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3792 WHERE "id" = "issue_id_p";
3793 -- materialize battle_view:
3794 -- NOTE: "closed" column of issue must be set at this point
3795 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3796 INSERT INTO "battle" (
3797 "issue_id",
3798 "winning_initiative_id", "losing_initiative_id",
3799 "count"
3800 ) SELECT
3801 "issue_id",
3802 "winning_initiative_id", "losing_initiative_id",
3803 "count"
3804 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3805 -- copy "positive_votes" and "negative_votes" from "battle" table:
3806 UPDATE "initiative" SET
3807 "positive_votes" = "battle_win"."count",
3808 "negative_votes" = "battle_lose"."count"
3809 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3810 WHERE
3811 "battle_win"."issue_id" = "issue_id_p" AND
3812 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3813 "battle_win"."losing_initiative_id" ISNULL AND
3814 "battle_lose"."issue_id" = "issue_id_p" AND
3815 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3816 "battle_lose"."winning_initiative_id" ISNULL;
3817 END;
3818 $$;
3820 COMMENT ON FUNCTION "close_voting"
3821 ( "issue"."id"%TYPE )
3822 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.';
3825 CREATE FUNCTION "defeat_strength"
3826 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3827 RETURNS INT8
3828 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3829 BEGIN
3830 IF "positive_votes_p" > "negative_votes_p" THEN
3831 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3832 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3833 RETURN 0;
3834 ELSE
3835 RETURN -1;
3836 END IF;
3837 END;
3838 $$;
3840 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';
3843 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3844 RETURNS VOID
3845 LANGUAGE 'plpgsql' VOLATILE AS $$
3846 DECLARE
3847 "issue_row" "issue"%ROWTYPE;
3848 "policy_row" "policy"%ROWTYPE;
3849 "dimension_v" INTEGER;
3850 "vote_matrix" INT4[][]; -- absolute votes
3851 "matrix" INT8[][]; -- defeat strength / best paths
3852 "i" INTEGER;
3853 "j" INTEGER;
3854 "k" INTEGER;
3855 "battle_row" "battle"%ROWTYPE;
3856 "rank_ary" INT4[];
3857 "rank_v" INT4;
3858 "done_v" INTEGER;
3859 "winners_ary" INTEGER[];
3860 "initiative_id_v" "initiative"."id"%TYPE;
3861 BEGIN
3862 SELECT * INTO "issue_row"
3863 FROM "issue" WHERE "id" = "issue_id_p"
3864 FOR UPDATE;
3865 SELECT * INTO "policy_row"
3866 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3867 SELECT count(1) INTO "dimension_v"
3868 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3869 -- Create "vote_matrix" with absolute number of votes in pairwise
3870 -- comparison:
3871 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3872 "i" := 1;
3873 "j" := 2;
3874 FOR "battle_row" IN
3875 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3876 ORDER BY
3877 "winning_initiative_id" NULLS LAST,
3878 "losing_initiative_id" NULLS LAST
3879 LOOP
3880 "vote_matrix"["i"]["j"] := "battle_row"."count";
3881 IF "j" = "dimension_v" THEN
3882 "i" := "i" + 1;
3883 "j" := 1;
3884 ELSE
3885 "j" := "j" + 1;
3886 IF "j" = "i" THEN
3887 "j" := "j" + 1;
3888 END IF;
3889 END IF;
3890 END LOOP;
3891 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3892 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3893 END IF;
3894 -- Store defeat strengths in "matrix" using "defeat_strength"
3895 -- function:
3896 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3897 "i" := 1;
3898 LOOP
3899 "j" := 1;
3900 LOOP
3901 IF "i" != "j" THEN
3902 "matrix"["i"]["j"] := "defeat_strength"(
3903 "vote_matrix"["i"]["j"],
3904 "vote_matrix"["j"]["i"]
3905 );
3906 END IF;
3907 EXIT WHEN "j" = "dimension_v";
3908 "j" := "j" + 1;
3909 END LOOP;
3910 EXIT WHEN "i" = "dimension_v";
3911 "i" := "i" + 1;
3912 END LOOP;
3913 -- Find best paths:
3914 "i" := 1;
3915 LOOP
3916 "j" := 1;
3917 LOOP
3918 IF "i" != "j" THEN
3919 "k" := 1;
3920 LOOP
3921 IF "i" != "k" AND "j" != "k" THEN
3922 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3923 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3924 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3925 END IF;
3926 ELSE
3927 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3928 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3929 END IF;
3930 END IF;
3931 END IF;
3932 EXIT WHEN "k" = "dimension_v";
3933 "k" := "k" + 1;
3934 END LOOP;
3935 END IF;
3936 EXIT WHEN "j" = "dimension_v";
3937 "j" := "j" + 1;
3938 END LOOP;
3939 EXIT WHEN "i" = "dimension_v";
3940 "i" := "i" + 1;
3941 END LOOP;
3942 -- Determine order of winners:
3943 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3944 "rank_v" := 1;
3945 "done_v" := 0;
3946 LOOP
3947 "winners_ary" := '{}';
3948 "i" := 1;
3949 LOOP
3950 IF "rank_ary"["i"] ISNULL THEN
3951 "j" := 1;
3952 LOOP
3953 IF
3954 "i" != "j" AND
3955 "rank_ary"["j"] ISNULL AND
3956 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3957 THEN
3958 -- someone else is better
3959 EXIT;
3960 END IF;
3961 IF "j" = "dimension_v" THEN
3962 -- noone is better
3963 "winners_ary" := "winners_ary" || "i";
3964 EXIT;
3965 END IF;
3966 "j" := "j" + 1;
3967 END LOOP;
3968 END IF;
3969 EXIT WHEN "i" = "dimension_v";
3970 "i" := "i" + 1;
3971 END LOOP;
3972 "i" := 1;
3973 LOOP
3974 "rank_ary"["winners_ary"["i"]] := "rank_v";
3975 "done_v" := "done_v" + 1;
3976 EXIT WHEN "i" = array_upper("winners_ary", 1);
3977 "i" := "i" + 1;
3978 END LOOP;
3979 EXIT WHEN "done_v" = "dimension_v";
3980 "rank_v" := "rank_v" + 1;
3981 END LOOP;
3982 -- write preliminary results:
3983 "i" := 1;
3984 FOR "initiative_id_v" IN
3985 SELECT "id" FROM "initiative"
3986 WHERE "issue_id" = "issue_id_p" AND "admitted"
3987 ORDER BY "id"
3988 LOOP
3989 UPDATE "initiative" SET
3990 "direct_majority" =
3991 CASE WHEN "policy_row"."direct_majority_strict" THEN
3992 "positive_votes" * "policy_row"."direct_majority_den" >
3993 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3994 ELSE
3995 "positive_votes" * "policy_row"."direct_majority_den" >=
3996 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3997 END
3998 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3999 AND "issue_row"."voter_count"-"negative_votes" >=
4000 "policy_row"."direct_majority_non_negative",
4001 "indirect_majority" =
4002 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4003 "positive_votes" * "policy_row"."indirect_majority_den" >
4004 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4005 ELSE
4006 "positive_votes" * "policy_row"."indirect_majority_den" >=
4007 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4008 END
4009 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4010 AND "issue_row"."voter_count"-"negative_votes" >=
4011 "policy_row"."indirect_majority_non_negative",
4012 "schulze_rank" = "rank_ary"["i"],
4013 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
4014 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
4015 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
4016 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
4017 "eligible" = FALSE,
4018 "winner" = FALSE,
4019 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4020 WHERE "id" = "initiative_id_v";
4021 "i" := "i" + 1;
4022 END LOOP;
4023 IF "i" != "dimension_v" THEN
4024 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4025 END IF;
4026 -- take indirect majorities into account:
4027 LOOP
4028 UPDATE "initiative" SET "indirect_majority" = TRUE
4029 FROM (
4030 SELECT "new_initiative"."id" AS "initiative_id"
4031 FROM "initiative" "old_initiative"
4032 JOIN "initiative" "new_initiative"
4033 ON "new_initiative"."issue_id" = "issue_id_p"
4034 AND "new_initiative"."indirect_majority" = FALSE
4035 JOIN "battle" "battle_win"
4036 ON "battle_win"."issue_id" = "issue_id_p"
4037 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4038 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4039 JOIN "battle" "battle_lose"
4040 ON "battle_lose"."issue_id" = "issue_id_p"
4041 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4042 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4043 WHERE "old_initiative"."issue_id" = "issue_id_p"
4044 AND "old_initiative"."indirect_majority" = TRUE
4045 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4046 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4047 "policy_row"."indirect_majority_num" *
4048 ("battle_win"."count"+"battle_lose"."count")
4049 ELSE
4050 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4051 "policy_row"."indirect_majority_num" *
4052 ("battle_win"."count"+"battle_lose"."count")
4053 END
4054 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4055 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4056 "policy_row"."indirect_majority_non_negative"
4057 ) AS "subquery"
4058 WHERE "id" = "subquery"."initiative_id";
4059 EXIT WHEN NOT FOUND;
4060 END LOOP;
4061 -- set "multistage_majority" for remaining matching initiatives:
4062 UPDATE "initiative" SET "multistage_majority" = TRUE
4063 FROM (
4064 SELECT "losing_initiative"."id" AS "initiative_id"
4065 FROM "initiative" "losing_initiative"
4066 JOIN "initiative" "winning_initiative"
4067 ON "winning_initiative"."issue_id" = "issue_id_p"
4068 AND "winning_initiative"."admitted"
4069 JOIN "battle" "battle_win"
4070 ON "battle_win"."issue_id" = "issue_id_p"
4071 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4072 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4073 JOIN "battle" "battle_lose"
4074 ON "battle_lose"."issue_id" = "issue_id_p"
4075 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4076 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4077 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4078 AND "losing_initiative"."admitted"
4079 AND "winning_initiative"."schulze_rank" <
4080 "losing_initiative"."schulze_rank"
4081 AND "battle_win"."count" > "battle_lose"."count"
4082 AND (
4083 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4084 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4085 ) AS "subquery"
4086 WHERE "id" = "subquery"."initiative_id";
4087 -- mark eligible initiatives:
4088 UPDATE "initiative" SET "eligible" = TRUE
4089 WHERE "issue_id" = "issue_id_p"
4090 AND "initiative"."direct_majority"
4091 AND "initiative"."indirect_majority"
4092 AND "initiative"."better_than_status_quo"
4093 AND (
4094 "policy_row"."no_multistage_majority" = FALSE OR
4095 "initiative"."multistage_majority" = FALSE )
4096 AND (
4097 "policy_row"."no_reverse_beat_path" = FALSE OR
4098 "initiative"."reverse_beat_path" = FALSE );
4099 -- mark final winner:
4100 UPDATE "initiative" SET "winner" = TRUE
4101 FROM (
4102 SELECT "id" AS "initiative_id"
4103 FROM "initiative"
4104 WHERE "issue_id" = "issue_id_p" AND "eligible"
4105 ORDER BY
4106 "schulze_rank",
4107 "id"
4108 LIMIT 1
4109 ) AS "subquery"
4110 WHERE "id" = "subquery"."initiative_id";
4111 -- write (final) ranks:
4112 "rank_v" := 1;
4113 FOR "initiative_id_v" IN
4114 SELECT "id"
4115 FROM "initiative"
4116 WHERE "issue_id" = "issue_id_p" AND "admitted"
4117 ORDER BY
4118 "winner" DESC,
4119 "eligible" DESC,
4120 "schulze_rank",
4121 "id"
4122 LOOP
4123 UPDATE "initiative" SET "rank" = "rank_v"
4124 WHERE "id" = "initiative_id_v";
4125 "rank_v" := "rank_v" + 1;
4126 END LOOP;
4127 -- set schulze rank of status quo and mark issue as finished:
4128 UPDATE "issue" SET
4129 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4130 "state" =
4131 CASE WHEN EXISTS (
4132 SELECT NULL FROM "initiative"
4133 WHERE "issue_id" = "issue_id_p" AND "winner"
4134 ) THEN
4135 'finished_with_winner'::"issue_state"
4136 ELSE
4137 'finished_without_winner'::"issue_state"
4138 END,
4139 "ranks_available" = TRUE
4140 WHERE "id" = "issue_id_p";
4141 RETURN;
4142 END;
4143 $$;
4145 COMMENT ON FUNCTION "calculate_ranks"
4146 ( "issue"."id"%TYPE )
4147 IS 'Determine ranking (Votes have to be counted first)';
4151 -----------------------------
4152 -- Automatic state changes --
4153 -----------------------------
4156 CREATE FUNCTION "check_issue"
4157 ( "issue_id_p" "issue"."id"%TYPE )
4158 RETURNS VOID
4159 LANGUAGE 'plpgsql' VOLATILE AS $$
4160 DECLARE
4161 "issue_row" "issue"%ROWTYPE;
4162 "policy_row" "policy"%ROWTYPE;
4163 BEGIN
4164 PERFORM "lock_issue"("issue_id_p");
4165 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4166 -- only process open issues:
4167 IF "issue_row"."closed" ISNULL THEN
4168 SELECT * INTO "policy_row" FROM "policy"
4169 WHERE "id" = "issue_row"."policy_id";
4170 -- create a snapshot, unless issue is already fully frozen:
4171 IF "issue_row"."fully_frozen" ISNULL THEN
4172 PERFORM "create_snapshot"("issue_id_p");
4173 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4174 END IF;
4175 -- eventually close or accept issues, which have not been accepted:
4176 IF "issue_row"."accepted" ISNULL THEN
4177 IF EXISTS (
4178 SELECT NULL FROM "initiative"
4179 WHERE "issue_id" = "issue_id_p"
4180 AND "supporter_count" > 0
4181 AND "supporter_count" * "policy_row"."issue_quorum_den"
4182 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4183 ) THEN
4184 -- accept issues, if supporter count is high enough
4185 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4186 -- NOTE: "issue_row" used later
4187 "issue_row"."state" := 'discussion';
4188 "issue_row"."accepted" := now();
4189 UPDATE "issue" SET
4190 "state" = "issue_row"."state",
4191 "accepted" = "issue_row"."accepted"
4192 WHERE "id" = "issue_row"."id";
4193 ELSIF
4194 now() >= "issue_row"."created" + "issue_row"."admission_time"
4195 THEN
4196 -- close issues, if admission time has expired
4197 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4198 UPDATE "issue" SET
4199 "state" = 'canceled_issue_not_accepted',
4200 "closed" = now()
4201 WHERE "id" = "issue_row"."id";
4202 END IF;
4203 END IF;
4204 -- eventually half freeze issues:
4205 IF
4206 -- NOTE: issue can't be closed at this point, if it has been accepted
4207 "issue_row"."accepted" NOTNULL AND
4208 "issue_row"."half_frozen" ISNULL
4209 THEN
4210 IF
4211 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4212 THEN
4213 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4214 -- NOTE: "issue_row" used later
4215 "issue_row"."state" := 'verification';
4216 "issue_row"."half_frozen" := now();
4217 UPDATE "issue" SET
4218 "state" = "issue_row"."state",
4219 "half_frozen" = "issue_row"."half_frozen"
4220 WHERE "id" = "issue_row"."id";
4221 END IF;
4222 END IF;
4223 -- close issues after some time, if all initiatives have been revoked:
4224 IF
4225 "issue_row"."closed" ISNULL AND
4226 NOT EXISTS (
4227 -- all initiatives are revoked
4228 SELECT NULL FROM "initiative"
4229 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4230 ) AND (
4231 -- and issue has not been accepted yet
4232 "issue_row"."accepted" ISNULL OR
4233 NOT EXISTS (
4234 -- or no initiatives have been revoked lately
4235 SELECT NULL FROM "initiative"
4236 WHERE "issue_id" = "issue_id_p"
4237 AND now() < "revoked" + "issue_row"."verification_time"
4238 ) OR (
4239 -- or verification time has elapsed
4240 "issue_row"."half_frozen" NOTNULL AND
4241 "issue_row"."fully_frozen" ISNULL AND
4242 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4245 THEN
4246 -- NOTE: "issue_row" used later
4247 IF "issue_row"."accepted" ISNULL THEN
4248 "issue_row"."state" := 'canceled_revoked_before_accepted';
4249 ELSIF "issue_row"."half_frozen" ISNULL THEN
4250 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4251 ELSE
4252 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4253 END IF;
4254 "issue_row"."closed" := now();
4255 UPDATE "issue" SET
4256 "state" = "issue_row"."state",
4257 "closed" = "issue_row"."closed"
4258 WHERE "id" = "issue_row"."id";
4259 END IF;
4260 -- fully freeze issue after verification time:
4261 IF
4262 "issue_row"."half_frozen" NOTNULL AND
4263 "issue_row"."fully_frozen" ISNULL AND
4264 "issue_row"."closed" ISNULL AND
4265 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4266 THEN
4267 PERFORM "freeze_after_snapshot"("issue_id_p");
4268 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4269 END IF;
4270 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4271 -- close issue by calling close_voting(...) after voting time:
4272 IF
4273 "issue_row"."closed" ISNULL AND
4274 "issue_row"."fully_frozen" NOTNULL AND
4275 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4276 THEN
4277 PERFORM "close_voting"("issue_id_p");
4278 -- calculate ranks will not consume much time and can be done now
4279 PERFORM "calculate_ranks"("issue_id_p");
4280 END IF;
4281 END IF;
4282 RETURN;
4283 END;
4284 $$;
4286 COMMENT ON FUNCTION "check_issue"
4287 ( "issue"."id"%TYPE )
4288 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required; At end of voting the ranking is not calculated by this function, but must be calculated in a seperate transaction using the "calculate_ranks" function.';
4291 CREATE FUNCTION "check_everything"()
4292 RETURNS VOID
4293 LANGUAGE 'plpgsql' VOLATILE AS $$
4294 DECLARE
4295 "issue_id_v" "issue"."id"%TYPE;
4296 BEGIN
4297 DELETE FROM "expired_session";
4298 PERFORM "check_activity"();
4299 PERFORM "calculate_member_counts"();
4300 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4301 PERFORM "check_issue"("issue_id_v");
4302 END LOOP;
4303 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4304 PERFORM "calculate_ranks"("issue_id_v");
4305 END LOOP;
4306 RETURN;
4307 END;
4308 $$;
4310 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue, and if possible, automatically calculates ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result. In productive environments you should call the lf_update program instead.';
4314 ----------------------
4315 -- Deletion of data --
4316 ----------------------
4319 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4320 RETURNS VOID
4321 LANGUAGE 'plpgsql' VOLATILE AS $$
4322 DECLARE
4323 "issue_row" "issue"%ROWTYPE;
4324 BEGIN
4325 SELECT * INTO "issue_row"
4326 FROM "issue" WHERE "id" = "issue_id_p"
4327 FOR UPDATE;
4328 IF "issue_row"."cleaned" ISNULL THEN
4329 UPDATE "issue" SET
4330 "state" = 'voting',
4331 "closed" = NULL,
4332 "ranks_available" = FALSE
4333 WHERE "id" = "issue_id_p";
4334 DELETE FROM "delegating_voter"
4335 WHERE "issue_id" = "issue_id_p";
4336 DELETE FROM "direct_voter"
4337 WHERE "issue_id" = "issue_id_p";
4338 DELETE FROM "delegating_interest_snapshot"
4339 WHERE "issue_id" = "issue_id_p";
4340 DELETE FROM "direct_interest_snapshot"
4341 WHERE "issue_id" = "issue_id_p";
4342 DELETE FROM "delegating_population_snapshot"
4343 WHERE "issue_id" = "issue_id_p";
4344 DELETE FROM "direct_population_snapshot"
4345 WHERE "issue_id" = "issue_id_p";
4346 DELETE FROM "non_voter"
4347 WHERE "issue_id" = "issue_id_p";
4348 DELETE FROM "delegation"
4349 WHERE "issue_id" = "issue_id_p";
4350 DELETE FROM "supporter"
4351 USING "initiative"
4352 WHERE "initiative"."issue_id" = "issue_id_p"
4353 AND "supporter"."initiative_id" = "initiative_id";
4354 UPDATE "issue" SET
4355 "state" = "issue_row"."state",
4356 "closed" = "issue_row"."closed",
4357 "ranks_available" = "issue_row"."ranks_available",
4358 "cleaned" = now()
4359 WHERE "id" = "issue_id_p";
4360 END IF;
4361 RETURN;
4362 END;
4363 $$;
4365 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4368 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4369 RETURNS VOID
4370 LANGUAGE 'plpgsql' VOLATILE AS $$
4371 BEGIN
4372 UPDATE "member" SET
4373 "last_login" = NULL,
4374 "login" = NULL,
4375 "password" = NULL,
4376 "locked" = TRUE,
4377 "active" = FALSE,
4378 "notify_email" = NULL,
4379 "notify_email_unconfirmed" = NULL,
4380 "notify_email_secret" = NULL,
4381 "notify_email_secret_expiry" = NULL,
4382 "notify_email_lock_expiry" = NULL,
4383 "password_reset_secret" = NULL,
4384 "password_reset_secret_expiry" = NULL,
4385 "organizational_unit" = NULL,
4386 "internal_posts" = NULL,
4387 "realname" = NULL,
4388 "birthday" = NULL,
4389 "address" = NULL,
4390 "email" = NULL,
4391 "xmpp_address" = NULL,
4392 "website" = NULL,
4393 "phone" = NULL,
4394 "mobile_phone" = NULL,
4395 "profession" = NULL,
4396 "external_memberships" = NULL,
4397 "external_posts" = NULL,
4398 "statement" = NULL
4399 WHERE "id" = "member_id_p";
4400 -- "text_search_data" is updated by triggers
4401 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4402 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4403 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4404 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4405 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4406 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4407 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4408 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4409 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4410 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4411 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4412 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4413 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4414 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4415 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4416 DELETE FROM "direct_voter" USING "issue"
4417 WHERE "direct_voter"."issue_id" = "issue"."id"
4418 AND "issue"."closed" ISNULL
4419 AND "member_id" = "member_id_p";
4420 RETURN;
4421 END;
4422 $$;
4424 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)';
4427 CREATE FUNCTION "delete_private_data"()
4428 RETURNS VOID
4429 LANGUAGE 'plpgsql' VOLATILE AS $$
4430 BEGIN
4431 DELETE FROM "member" WHERE "activated" ISNULL;
4432 UPDATE "member" SET
4433 "invite_code" = NULL,
4434 "invite_code_expiry" = NULL,
4435 "admin_comment" = NULL,
4436 "last_login" = NULL,
4437 "login" = NULL,
4438 "password" = NULL,
4439 "lang" = NULL,
4440 "notify_email" = NULL,
4441 "notify_email_unconfirmed" = NULL,
4442 "notify_email_secret" = NULL,
4443 "notify_email_secret_expiry" = NULL,
4444 "notify_email_lock_expiry" = NULL,
4445 "notify_level" = NULL,
4446 "password_reset_secret" = NULL,
4447 "password_reset_secret_expiry" = NULL,
4448 "organizational_unit" = NULL,
4449 "internal_posts" = NULL,
4450 "realname" = NULL,
4451 "birthday" = NULL,
4452 "address" = NULL,
4453 "email" = NULL,
4454 "xmpp_address" = NULL,
4455 "website" = NULL,
4456 "phone" = NULL,
4457 "mobile_phone" = NULL,
4458 "profession" = NULL,
4459 "external_memberships" = NULL,
4460 "external_posts" = NULL,
4461 "formatting_engine" = NULL,
4462 "statement" = NULL;
4463 -- "text_search_data" is updated by triggers
4464 DELETE FROM "setting";
4465 DELETE FROM "setting_map";
4466 DELETE FROM "member_relation_setting";
4467 DELETE FROM "member_image";
4468 DELETE FROM "contact";
4469 DELETE FROM "ignored_member";
4470 DELETE FROM "session";
4471 DELETE FROM "area_setting";
4472 DELETE FROM "issue_setting";
4473 DELETE FROM "ignored_initiative";
4474 DELETE FROM "initiative_setting";
4475 DELETE FROM "suggestion_setting";
4476 DELETE FROM "non_voter";
4477 DELETE FROM "direct_voter" USING "issue"
4478 WHERE "direct_voter"."issue_id" = "issue"."id"
4479 AND "issue"."closed" ISNULL;
4480 RETURN;
4481 END;
4482 $$;
4484 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.';
4488 COMMIT;

Impressum / About Us