liquid_feedback_core

view core.sql @ 332:f17ee916711a

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

Impressum / About Us