liquid_feedback_core

view core.sql @ 290:2301a1f2acfa

Modified function "forbid_changes_on_closed_issue_trigger" to allow voting comments to be changed after voting has finished
author jbe
date Sun Aug 19 23:37:37 2012 +0200 (2012-08-19)
parents f2292b94fc58
children 86f231bd6906
line source
2 -- Execute the following command manually for PostgreSQL prior version 9.0:
3 -- CREATE LANGUAGE plpgsql;
5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
7 BEGIN;
9 CREATE VIEW "liquid_feedback_version" AS
10 SELECT * FROM (VALUES ('2.1.0', 2, 1, 0))
11 AS "subquery"("string", "major", "minor", "revision");
15 ----------------------
16 -- Full text search --
17 ----------------------
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
21 RETURNS TSQUERY
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
23 BEGIN
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
25 END;
26 $$;
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
31 CREATE FUNCTION "highlight"
32 ( "body_p" TEXT,
33 "query_text_p" TEXT )
34 RETURNS TEXT
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
36 BEGIN
37 RETURN ts_headline(
38 'pg_catalog.simple',
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
40 "text_search_query"("query_text_p"),
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
42 END;
43 $$;
45 COMMENT ON FUNCTION "highlight"
46 ( "body_p" TEXT,
47 "query_text_p" TEXT )
48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
52 -------------------------
53 -- Tables and indicies --
54 -------------------------
57 CREATE TABLE "system_setting" (
58 "member_ttl" INTERVAL );
59 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
61 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
62 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
64 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
67 CREATE TABLE "contingent" (
68 "time_frame" INTERVAL PRIMARY KEY,
69 "text_entry_limit" INT4,
70 "initiative_limit" INT4 );
72 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.';
74 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';
75 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
78 CREATE TYPE "notify_level" AS ENUM
79 ('none', 'voting', 'verification', 'discussion', 'all');
81 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';
84 CREATE TABLE "member" (
85 "id" SERIAL4 PRIMARY KEY,
86 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
87 "invite_code" TEXT UNIQUE,
88 "invite_code_expiry" TIMESTAMPTZ,
89 "admin_comment" TEXT,
90 "activated" TIMESTAMPTZ,
91 "last_activity" DATE,
92 "last_login" TIMESTAMPTZ,
93 "login" TEXT UNIQUE,
94 "password" TEXT,
95 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
96 "active" BOOLEAN NOT NULL DEFAULT FALSE,
97 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
98 "lang" TEXT,
99 "notify_email" TEXT,
100 "notify_email_unconfirmed" TEXT,
101 "notify_email_secret" TEXT UNIQUE,
102 "notify_email_secret_expiry" TIMESTAMPTZ,
103 "notify_email_lock_expiry" TIMESTAMPTZ,
104 "notify_level" "notify_level",
105 "password_reset_secret" TEXT UNIQUE,
106 "password_reset_secret_expiry" TIMESTAMPTZ,
107 "name" TEXT UNIQUE,
108 "identification" TEXT UNIQUE,
109 "authentication" TEXT,
110 "organizational_unit" TEXT,
111 "internal_posts" TEXT,
112 "realname" TEXT,
113 "birthday" DATE,
114 "address" TEXT,
115 "email" TEXT,
116 "xmpp_address" TEXT,
117 "website" TEXT,
118 "phone" TEXT,
119 "mobile_phone" TEXT,
120 "profession" TEXT,
121 "external_memberships" TEXT,
122 "external_posts" TEXT,
123 "formatting_engine" TEXT,
124 "statement" TEXT,
125 "text_search_data" TSVECTOR,
126 CONSTRAINT "active_requires_activated_and_last_activity"
127 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
128 CONSTRAINT "name_not_null_if_activated"
129 CHECK ("activated" ISNULL OR "name" NOTNULL) );
130 CREATE INDEX "member_active_idx" ON "member" ("active");
131 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
132 CREATE TRIGGER "update_text_search_data"
133 BEFORE INSERT OR UPDATE ON "member"
134 FOR EACH ROW EXECUTE PROCEDURE
135 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
136 "name", "identification", "organizational_unit", "internal_posts",
137 "realname", "external_memberships", "external_posts", "statement" );
139 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
141 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
142 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
143 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
144 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
145 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';
146 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
147 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
148 COMMENT ON COLUMN "member"."login" IS 'Login name';
149 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
150 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
151 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".';
152 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
153 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
154 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
155 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
156 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
157 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
158 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
159 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';
160 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
161 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
162 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
163 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
164 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
165 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
166 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
167 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
168 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
169 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
170 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
173 -- DEPRECATED API TABLES --
175 CREATE TYPE "application_access_level" AS ENUM
176 ('member', 'full', 'pseudonymous', 'anonymous');
178 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
181 CREATE TABLE "member_application" (
182 "id" SERIAL8 PRIMARY KEY,
183 UNIQUE ("member_id", "name"),
184 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
185 ON DELETE CASCADE ON UPDATE CASCADE,
186 "name" TEXT NOT NULL,
187 "comment" TEXT,
188 "access_level" "application_access_level" NOT NULL,
189 "key" TEXT NOT NULL UNIQUE,
190 "last_usage" TIMESTAMPTZ );
192 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
194 -- END OF DEPRECARED API TABLES --
197 CREATE TABLE "member_history" (
198 "id" SERIAL8 PRIMARY KEY,
199 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
200 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
201 "active" BOOLEAN NOT NULL,
202 "name" TEXT NOT NULL );
203 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
205 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
207 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
208 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
211 CREATE TABLE "rendered_member_statement" (
212 PRIMARY KEY ("member_id", "format"),
213 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
214 "format" TEXT,
215 "content" TEXT NOT NULL );
217 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)';
220 CREATE TABLE "setting" (
221 PRIMARY KEY ("member_id", "key"),
222 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
223 "key" TEXT NOT NULL,
224 "value" TEXT NOT NULL );
225 CREATE INDEX "setting_key_idx" ON "setting" ("key");
227 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
229 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
232 CREATE TABLE "setting_map" (
233 PRIMARY KEY ("member_id", "key", "subkey"),
234 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
235 "key" TEXT NOT NULL,
236 "subkey" TEXT NOT NULL,
237 "value" TEXT NOT NULL );
238 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
240 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
242 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
243 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
244 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
247 CREATE TABLE "member_relation_setting" (
248 PRIMARY KEY ("member_id", "key", "other_member_id"),
249 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
250 "key" TEXT NOT NULL,
251 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
252 "value" TEXT NOT NULL );
254 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
257 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
259 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
262 CREATE TABLE "member_image" (
263 PRIMARY KEY ("member_id", "image_type", "scaled"),
264 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
265 "image_type" "member_image_type",
266 "scaled" BOOLEAN,
267 "content_type" TEXT,
268 "data" BYTEA NOT NULL );
270 COMMENT ON TABLE "member_image" IS 'Images of members';
272 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
275 CREATE TABLE "member_count" (
276 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
277 "total_count" INT4 NOT NULL );
279 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';
281 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
282 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
285 CREATE TABLE "contact" (
286 PRIMARY KEY ("member_id", "other_member_id"),
287 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
288 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
289 "public" BOOLEAN NOT NULL DEFAULT FALSE,
290 CONSTRAINT "cant_save_yourself_as_contact"
291 CHECK ("member_id" != "other_member_id") );
292 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
294 COMMENT ON TABLE "contact" IS 'Contact lists';
296 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
297 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
298 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
301 CREATE TABLE "ignored_member" (
302 PRIMARY KEY ("member_id", "other_member_id"),
303 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
304 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
305 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
307 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
309 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
310 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
313 CREATE TABLE "session" (
314 "ident" TEXT PRIMARY KEY,
315 "additional_secret" TEXT,
316 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
317 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
318 "lang" TEXT );
319 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
321 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
323 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
324 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
325 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
326 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
329 CREATE TABLE "policy" (
330 "id" SERIAL4 PRIMARY KEY,
331 "index" INT4 NOT NULL,
332 "active" BOOLEAN NOT NULL DEFAULT TRUE,
333 "name" TEXT NOT NULL UNIQUE,
334 "description" TEXT NOT NULL DEFAULT '',
335 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
336 "admission_time" INTERVAL,
337 "discussion_time" INTERVAL,
338 "verification_time" INTERVAL,
339 "voting_time" INTERVAL,
340 "issue_quorum_num" INT4 NOT NULL,
341 "issue_quorum_den" INT4 NOT NULL,
342 "initiative_quorum_num" INT4 NOT NULL,
343 "initiative_quorum_den" INT4 NOT NULL,
344 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
345 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
346 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
347 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
348 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
349 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
350 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
351 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
352 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
353 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
354 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
355 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
356 CONSTRAINT "timing" CHECK (
357 ( "polling" = FALSE AND
358 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
359 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
360 ( "polling" = TRUE AND
361 "admission_time" ISNULL 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" ISNULL AND
365 "verification_time" ISNULL AND "voting_time" ISNULL ) ) );
366 CREATE INDEX "policy_active_idx" ON "policy" ("active");
368 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
370 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
371 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
372 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';
373 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
374 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
375 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"';
376 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'')';
377 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''';
378 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''';
379 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
380 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
381 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
382 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
383 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.';
384 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
385 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';
386 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';
387 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';
388 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.';
389 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';
390 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';
391 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.';
392 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").';
395 CREATE TABLE "unit" (
396 "id" SERIAL4 PRIMARY KEY,
397 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
398 "active" BOOLEAN NOT NULL DEFAULT TRUE,
399 "name" TEXT NOT NULL,
400 "description" TEXT NOT NULL DEFAULT '',
401 "member_count" INT4,
402 "text_search_data" TSVECTOR );
403 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
404 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
405 CREATE INDEX "unit_active_idx" ON "unit" ("active");
406 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
407 CREATE TRIGGER "update_text_search_data"
408 BEFORE INSERT OR UPDATE ON "unit"
409 FOR EACH ROW EXECUTE PROCEDURE
410 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
411 "name", "description" );
413 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
415 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
416 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
417 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
420 CREATE TABLE "unit_setting" (
421 PRIMARY KEY ("member_id", "key", "unit_id"),
422 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
423 "key" TEXT NOT NULL,
424 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
425 "value" TEXT NOT NULL );
427 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
430 CREATE TABLE "area" (
431 "id" SERIAL4 PRIMARY KEY,
432 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
433 "active" BOOLEAN NOT NULL DEFAULT TRUE,
434 "name" TEXT NOT NULL,
435 "description" TEXT NOT NULL DEFAULT '',
436 "direct_member_count" INT4,
437 "member_weight" INT4,
438 "text_search_data" TSVECTOR );
439 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
440 CREATE INDEX "area_active_idx" ON "area" ("active");
441 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
442 CREATE TRIGGER "update_text_search_data"
443 BEFORE INSERT OR UPDATE ON "area"
444 FOR EACH ROW EXECUTE PROCEDURE
445 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
446 "name", "description" );
448 COMMENT ON TABLE "area" IS 'Subject areas';
450 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
451 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"';
452 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
455 CREATE TABLE "area_setting" (
456 PRIMARY KEY ("member_id", "key", "area_id"),
457 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
458 "key" TEXT NOT NULL,
459 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
460 "value" TEXT NOT NULL );
462 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
465 CREATE TABLE "allowed_policy" (
466 PRIMARY KEY ("area_id", "policy_id"),
467 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
468 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
469 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
470 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
472 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
474 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
477 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
479 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';
482 CREATE TYPE "issue_state" AS ENUM (
483 'admission', 'discussion', 'verification', 'voting',
484 'canceled_revoked_before_accepted',
485 'canceled_issue_not_accepted',
486 'canceled_after_revocation_during_discussion',
487 'canceled_after_revocation_during_verification',
488 'calculation',
489 'canceled_no_initiative_admitted',
490 'finished_without_winner', 'finished_with_winner');
492 COMMENT ON TYPE "issue_state" IS 'State of issues';
495 CREATE TABLE "issue" (
496 "id" SERIAL4 PRIMARY KEY,
497 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
498 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
499 "state" "issue_state" NOT NULL DEFAULT 'admission',
500 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
501 "accepted" TIMESTAMPTZ,
502 "half_frozen" TIMESTAMPTZ,
503 "fully_frozen" TIMESTAMPTZ,
504 "closed" TIMESTAMPTZ,
505 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
506 "cleaned" TIMESTAMPTZ,
507 "admission_time" INTERVAL NOT NULL,
508 "discussion_time" INTERVAL NOT NULL,
509 "verification_time" INTERVAL NOT NULL,
510 "voting_time" INTERVAL NOT NULL,
511 "snapshot" TIMESTAMPTZ,
512 "latest_snapshot_event" "snapshot_event",
513 "population" INT4,
514 "voter_count" INT4,
515 "status_quo_schulze_rank" INT4,
516 CONSTRAINT "valid_state" CHECK ((
517 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
518 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
519 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
520 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
521 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
522 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
523 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
524 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
525 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
526 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
527 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
528 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
529 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
530 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
531 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
532 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
533 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
534 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
535 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
536 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
537 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
538 )),
539 CONSTRAINT "state_change_order" CHECK (
540 "created" <= "accepted" AND
541 "accepted" <= "half_frozen" AND
542 "half_frozen" <= "fully_frozen" AND
543 "fully_frozen" <= "closed" ),
544 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
545 "cleaned" ISNULL OR "closed" NOTNULL ),
546 CONSTRAINT "last_snapshot_on_full_freeze"
547 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
548 CONSTRAINT "freeze_requires_snapshot"
549 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
550 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
551 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
552 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
553 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
554 CREATE INDEX "issue_created_idx" ON "issue" ("created");
555 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
556 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
557 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
558 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
559 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
560 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
562 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
564 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
565 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.';
566 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.';
567 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.';
568 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
569 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
570 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
571 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
572 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
573 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
574 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
575 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';
576 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
577 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';
578 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
581 CREATE TABLE "issue_setting" (
582 PRIMARY KEY ("member_id", "key", "issue_id"),
583 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
584 "key" TEXT NOT NULL,
585 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
586 "value" TEXT NOT NULL );
588 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
591 CREATE TABLE "initiative" (
592 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
593 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
594 "id" SERIAL4 PRIMARY KEY,
595 "name" TEXT NOT NULL,
596 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
597 "discussion_url" TEXT,
598 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
599 "revoked" TIMESTAMPTZ,
600 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
601 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
602 "admitted" BOOLEAN,
603 "supporter_count" INT4,
604 "informed_supporter_count" INT4,
605 "satisfied_supporter_count" INT4,
606 "satisfied_informed_supporter_count" INT4,
607 "positive_votes" INT4,
608 "negative_votes" INT4,
609 "direct_majority" BOOLEAN,
610 "indirect_majority" BOOLEAN,
611 "schulze_rank" INT4,
612 "better_than_status_quo" BOOLEAN,
613 "worse_than_status_quo" BOOLEAN,
614 "reverse_beat_path" BOOLEAN,
615 "multistage_majority" BOOLEAN,
616 "eligible" BOOLEAN,
617 "winner" BOOLEAN,
618 "rank" INT4,
619 "text_search_data" TSVECTOR,
620 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
621 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
622 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
623 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
624 CONSTRAINT "revoked_initiatives_cant_be_admitted"
625 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
626 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
627 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
628 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
629 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
630 "schulze_rank" ISNULL AND
631 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
632 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
633 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
634 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
635 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
636 "eligible" = FALSE OR
637 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
638 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
639 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
640 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
641 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
642 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
643 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
644 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
645 CREATE TRIGGER "update_text_search_data"
646 BEFORE INSERT OR UPDATE ON "initiative"
647 FOR EACH ROW EXECUTE PROCEDURE
648 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
649 "name", "discussion_url");
651 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.';
653 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
654 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
655 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
656 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
657 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
658 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
659 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
660 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
661 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
662 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
663 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
664 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"';
665 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
666 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
667 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
668 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
669 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';
670 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';
671 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"';
672 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
673 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';
676 CREATE TABLE "battle" (
677 "issue_id" INT4 NOT NULL,
678 "winning_initiative_id" INT4,
679 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
680 "losing_initiative_id" INT4,
681 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
682 "count" INT4 NOT NULL,
683 CONSTRAINT "initiative_ids_not_equal" CHECK (
684 "winning_initiative_id" != "losing_initiative_id" OR
685 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
686 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
687 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
688 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
689 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
691 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';
694 CREATE TABLE "ignored_initiative" (
695 PRIMARY KEY ("initiative_id", "member_id"),
696 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
697 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
698 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
700 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
703 CREATE TABLE "initiative_setting" (
704 PRIMARY KEY ("member_id", "key", "initiative_id"),
705 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
706 "key" TEXT NOT NULL,
707 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
708 "value" TEXT NOT NULL );
710 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
713 CREATE TABLE "draft" (
714 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
715 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
716 "id" SERIAL8 PRIMARY KEY,
717 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
718 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
719 "formatting_engine" TEXT,
720 "content" TEXT NOT NULL,
721 "text_search_data" TSVECTOR );
722 CREATE INDEX "draft_created_idx" ON "draft" ("created");
723 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
724 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
725 CREATE TRIGGER "update_text_search_data"
726 BEFORE INSERT OR UPDATE ON "draft"
727 FOR EACH ROW EXECUTE PROCEDURE
728 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
730 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.';
732 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
733 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
736 CREATE TABLE "rendered_draft" (
737 PRIMARY KEY ("draft_id", "format"),
738 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
739 "format" TEXT,
740 "content" TEXT NOT NULL );
742 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)';
745 CREATE TABLE "suggestion" (
746 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
747 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
748 "id" SERIAL8 PRIMARY KEY,
749 "draft_id" INT8 NOT NULL,
750 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
751 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
752 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
753 "name" TEXT NOT NULL,
754 "formatting_engine" TEXT,
755 "content" TEXT NOT NULL DEFAULT '',
756 "text_search_data" TSVECTOR,
757 "minus2_unfulfilled_count" INT4,
758 "minus2_fulfilled_count" INT4,
759 "minus1_unfulfilled_count" INT4,
760 "minus1_fulfilled_count" INT4,
761 "plus1_unfulfilled_count" INT4,
762 "plus1_fulfilled_count" INT4,
763 "plus2_unfulfilled_count" INT4,
764 "plus2_fulfilled_count" INT4 );
765 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
766 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
767 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
768 CREATE TRIGGER "update_text_search_data"
769 BEFORE INSERT OR UPDATE ON "suggestion"
770 FOR EACH ROW EXECUTE PROCEDURE
771 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
772 "name", "content");
774 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';
776 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")';
777 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
778 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
779 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
780 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
781 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
782 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
783 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
784 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
787 CREATE TABLE "rendered_suggestion" (
788 PRIMARY KEY ("suggestion_id", "format"),
789 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
790 "format" TEXT,
791 "content" TEXT NOT NULL );
793 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)';
796 CREATE TABLE "suggestion_setting" (
797 PRIMARY KEY ("member_id", "key", "suggestion_id"),
798 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
799 "key" TEXT NOT NULL,
800 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "value" TEXT NOT NULL );
803 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
806 CREATE TABLE "privilege" (
807 PRIMARY KEY ("unit_id", "member_id"),
808 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
809 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
810 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
811 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
812 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
813 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
814 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
815 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
816 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
818 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
820 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
821 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
822 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
823 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
824 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
825 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
826 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';
829 CREATE TABLE "membership" (
830 PRIMARY KEY ("area_id", "member_id"),
831 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
832 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
833 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
835 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
838 CREATE TABLE "interest" (
839 PRIMARY KEY ("issue_id", "member_id"),
840 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
841 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
842 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
844 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.';
847 CREATE TABLE "initiator" (
848 PRIMARY KEY ("initiative_id", "member_id"),
849 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
850 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
851 "accepted" BOOLEAN );
852 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
854 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.';
856 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.';
859 CREATE TABLE "supporter" (
860 "issue_id" INT4 NOT NULL,
861 PRIMARY KEY ("initiative_id", "member_id"),
862 "initiative_id" INT4,
863 "member_id" INT4,
864 "draft_id" INT8 NOT NULL,
865 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
866 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
867 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
869 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.';
871 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
872 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")';
875 CREATE TABLE "opinion" (
876 "initiative_id" INT4 NOT NULL,
877 PRIMARY KEY ("suggestion_id", "member_id"),
878 "suggestion_id" INT8,
879 "member_id" INT4,
880 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
881 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
882 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
883 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
884 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
886 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.';
888 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
891 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
893 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
896 CREATE TABLE "delegation" (
897 "id" SERIAL8 PRIMARY KEY,
898 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
899 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
900 "scope" "delegation_scope" NOT NULL,
901 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
902 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
903 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
904 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
905 CONSTRAINT "no_unit_delegation_to_null"
906 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
907 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
908 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
909 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
910 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
911 UNIQUE ("unit_id", "truster_id"),
912 UNIQUE ("area_id", "truster_id"),
913 UNIQUE ("issue_id", "truster_id") );
914 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
915 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
917 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
919 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
920 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
921 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
924 CREATE TABLE "direct_population_snapshot" (
925 PRIMARY KEY ("issue_id", "event", "member_id"),
926 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
927 "event" "snapshot_event",
928 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
929 "weight" INT4 );
930 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
932 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
934 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
935 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
938 CREATE TABLE "delegating_population_snapshot" (
939 PRIMARY KEY ("issue_id", "event", "member_id"),
940 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
941 "event" "snapshot_event",
942 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
943 "weight" INT4,
944 "scope" "delegation_scope" NOT NULL,
945 "delegate_member_ids" INT4[] NOT NULL );
946 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
948 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
950 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
951 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
952 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
953 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"';
956 CREATE TABLE "direct_interest_snapshot" (
957 PRIMARY KEY ("issue_id", "event", "member_id"),
958 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
959 "event" "snapshot_event",
960 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
961 "weight" INT4 );
962 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
964 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
966 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
967 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
970 CREATE TABLE "delegating_interest_snapshot" (
971 PRIMARY KEY ("issue_id", "event", "member_id"),
972 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
973 "event" "snapshot_event",
974 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
975 "weight" INT4,
976 "scope" "delegation_scope" NOT NULL,
977 "delegate_member_ids" INT4[] NOT NULL );
978 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
980 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
982 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
983 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
984 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
985 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"';
988 CREATE TABLE "direct_supporter_snapshot" (
989 "issue_id" INT4 NOT NULL,
990 PRIMARY KEY ("initiative_id", "event", "member_id"),
991 "initiative_id" INT4,
992 "event" "snapshot_event",
993 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
994 "draft_id" INT8 NOT NULL,
995 "informed" BOOLEAN NOT NULL,
996 "satisfied" BOOLEAN NOT NULL,
997 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
998 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
999 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1000 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1002 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1004 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';
1005 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1006 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1007 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1010 CREATE TABLE "non_voter" (
1011 PRIMARY KEY ("issue_id", "member_id"),
1012 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1013 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1014 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1016 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1019 CREATE TABLE "direct_voter" (
1020 PRIMARY KEY ("issue_id", "member_id"),
1021 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1022 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1023 "weight" INT4,
1024 "comment_changed" TIMESTAMPTZ,
1025 "formatting_engine" TEXT,
1026 "comment" TEXT,
1027 "text_search_data" TSVECTOR );
1028 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1029 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1030 CREATE TRIGGER "update_text_search_data"
1031 BEFORE INSERT OR UPDATE ON "direct_voter"
1032 FOR EACH ROW EXECUTE PROCEDURE
1033 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1035 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.';
1037 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1038 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';
1039 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';
1040 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.';
1043 CREATE TABLE "rendered_voter_comment" (
1044 PRIMARY KEY ("issue_id", "member_id", "format"),
1045 FOREIGN KEY ("issue_id", "member_id")
1046 REFERENCES "direct_voter" ("issue_id", "member_id")
1047 ON DELETE CASCADE ON UPDATE CASCADE,
1048 "issue_id" INT4,
1049 "member_id" INT4,
1050 "format" TEXT,
1051 "content" TEXT NOT NULL );
1053 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)';
1056 CREATE TABLE "delegating_voter" (
1057 PRIMARY KEY ("issue_id", "member_id"),
1058 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1059 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1060 "weight" INT4,
1061 "scope" "delegation_scope" NOT NULL,
1062 "delegate_member_ids" INT4[] NOT NULL );
1063 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1065 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1067 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1068 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1069 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"';
1072 CREATE TABLE "vote" (
1073 "issue_id" INT4 NOT NULL,
1074 PRIMARY KEY ("initiative_id", "member_id"),
1075 "initiative_id" INT4,
1076 "member_id" INT4,
1077 "grade" INT4,
1078 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1079 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1080 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1082 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.';
1084 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1085 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.';
1088 CREATE TYPE "event_type" AS ENUM (
1089 'issue_state_changed',
1090 'initiative_created_in_new_issue',
1091 'initiative_created_in_existing_issue',
1092 'initiative_revoked',
1093 'new_draft_created',
1094 'suggestion_created');
1096 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1099 CREATE TABLE "event" (
1100 "id" SERIAL8 PRIMARY KEY,
1101 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1102 "event" "event_type" NOT NULL,
1103 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1104 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1105 "state" "issue_state" CHECK ("state" != 'calculation'),
1106 "initiative_id" INT4,
1107 "draft_id" INT8,
1108 "suggestion_id" INT8,
1109 FOREIGN KEY ("issue_id", "initiative_id")
1110 REFERENCES "initiative" ("issue_id", "id")
1111 ON DELETE CASCADE ON UPDATE CASCADE,
1112 FOREIGN KEY ("initiative_id", "draft_id")
1113 REFERENCES "draft" ("initiative_id", "id")
1114 ON DELETE CASCADE ON UPDATE CASCADE,
1115 FOREIGN KEY ("initiative_id", "suggestion_id")
1116 REFERENCES "suggestion" ("initiative_id", "id")
1117 ON DELETE CASCADE ON UPDATE CASCADE,
1118 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1119 "event" != 'issue_state_changed' OR (
1120 "member_id" ISNULL AND
1121 "issue_id" NOTNULL AND
1122 "state" NOTNULL AND
1123 "initiative_id" ISNULL AND
1124 "draft_id" ISNULL AND
1125 "suggestion_id" ISNULL )),
1126 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1127 "event" NOT IN (
1128 'initiative_created_in_new_issue',
1129 'initiative_created_in_existing_issue',
1130 'initiative_revoked',
1131 'new_draft_created'
1132 ) OR (
1133 "member_id" NOTNULL AND
1134 "issue_id" NOTNULL AND
1135 "state" NOTNULL AND
1136 "initiative_id" NOTNULL AND
1137 "draft_id" NOTNULL AND
1138 "suggestion_id" ISNULL )),
1139 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1140 "event" != 'suggestion_created' OR (
1141 "member_id" NOTNULL AND
1142 "issue_id" NOTNULL AND
1143 "state" NOTNULL AND
1144 "initiative_id" NOTNULL AND
1145 "draft_id" ISNULL AND
1146 "suggestion_id" NOTNULL )) );
1147 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1149 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1151 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1152 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1153 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1154 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1157 CREATE TABLE "notification_sent" (
1158 "event_id" INT8 NOT NULL );
1159 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1161 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1162 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1166 ----------------------------------------------
1167 -- Writing of history entries and event log --
1168 ----------------------------------------------
1171 CREATE FUNCTION "write_member_history_trigger"()
1172 RETURNS TRIGGER
1173 LANGUAGE 'plpgsql' VOLATILE AS $$
1174 BEGIN
1175 IF
1176 ( NEW."active" != OLD."active" OR
1177 NEW."name" != OLD."name" ) AND
1178 OLD."activated" NOTNULL
1179 THEN
1180 INSERT INTO "member_history"
1181 ("member_id", "active", "name")
1182 VALUES (NEW."id", OLD."active", OLD."name");
1183 END IF;
1184 RETURN NULL;
1185 END;
1186 $$;
1188 CREATE TRIGGER "write_member_history"
1189 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1190 "write_member_history_trigger"();
1192 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1193 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1196 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1197 RETURNS TRIGGER
1198 LANGUAGE 'plpgsql' VOLATILE AS $$
1199 BEGIN
1200 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1201 INSERT INTO "event" ("event", "issue_id", "state")
1202 VALUES ('issue_state_changed', NEW."id", NEW."state");
1203 END IF;
1204 RETURN NULL;
1205 END;
1206 $$;
1208 CREATE TRIGGER "write_event_issue_state_changed"
1209 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1210 "write_event_issue_state_changed_trigger"();
1212 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1213 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1216 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1217 RETURNS TRIGGER
1218 LANGUAGE 'plpgsql' VOLATILE AS $$
1219 DECLARE
1220 "initiative_row" "initiative"%ROWTYPE;
1221 "issue_row" "issue"%ROWTYPE;
1222 "event_v" "event_type";
1223 BEGIN
1224 SELECT * INTO "initiative_row" FROM "initiative"
1225 WHERE "id" = NEW."initiative_id";
1226 SELECT * INTO "issue_row" FROM "issue"
1227 WHERE "id" = "initiative_row"."issue_id";
1228 IF EXISTS (
1229 SELECT NULL FROM "draft"
1230 WHERE "initiative_id" = NEW."initiative_id"
1231 AND "id" != NEW."id"
1232 ) THEN
1233 "event_v" := 'new_draft_created';
1234 ELSE
1235 IF EXISTS (
1236 SELECT NULL FROM "initiative"
1237 WHERE "issue_id" = "initiative_row"."issue_id"
1238 AND "id" != "initiative_row"."id"
1239 ) THEN
1240 "event_v" := 'initiative_created_in_existing_issue';
1241 ELSE
1242 "event_v" := 'initiative_created_in_new_issue';
1243 END IF;
1244 END IF;
1245 INSERT INTO "event" (
1246 "event", "member_id",
1247 "issue_id", "state", "initiative_id", "draft_id"
1248 ) VALUES (
1249 "event_v",
1250 NEW."author_id",
1251 "initiative_row"."issue_id",
1252 "issue_row"."state",
1253 "initiative_row"."id",
1254 NEW."id" );
1255 RETURN NULL;
1256 END;
1257 $$;
1259 CREATE TRIGGER "write_event_initiative_or_draft_created"
1260 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1261 "write_event_initiative_or_draft_created_trigger"();
1263 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1264 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1267 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1268 RETURNS TRIGGER
1269 LANGUAGE 'plpgsql' VOLATILE AS $$
1270 DECLARE
1271 "issue_row" "issue"%ROWTYPE;
1272 "draft_id_v" "draft"."id"%TYPE;
1273 BEGIN
1274 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1275 SELECT * INTO "issue_row" FROM "issue"
1276 WHERE "id" = NEW."issue_id";
1277 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1278 WHERE "initiative_id" = NEW."id";
1279 INSERT INTO "event" (
1280 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1281 ) VALUES (
1282 'initiative_revoked',
1283 NEW."revoked_by_member_id",
1284 NEW."issue_id",
1285 "issue_row"."state",
1286 NEW."id",
1287 "draft_id_v");
1288 END IF;
1289 RETURN NULL;
1290 END;
1291 $$;
1293 CREATE TRIGGER "write_event_initiative_revoked"
1294 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1295 "write_event_initiative_revoked_trigger"();
1297 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1298 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1301 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1302 RETURNS TRIGGER
1303 LANGUAGE 'plpgsql' VOLATILE AS $$
1304 DECLARE
1305 "initiative_row" "initiative"%ROWTYPE;
1306 "issue_row" "issue"%ROWTYPE;
1307 BEGIN
1308 SELECT * INTO "initiative_row" FROM "initiative"
1309 WHERE "id" = NEW."initiative_id";
1310 SELECT * INTO "issue_row" FROM "issue"
1311 WHERE "id" = "initiative_row"."issue_id";
1312 INSERT INTO "event" (
1313 "event", "member_id",
1314 "issue_id", "state", "initiative_id", "suggestion_id"
1315 ) VALUES (
1316 'suggestion_created',
1317 NEW."author_id",
1318 "initiative_row"."issue_id",
1319 "issue_row"."state",
1320 "initiative_row"."id",
1321 NEW."id" );
1322 RETURN NULL;
1323 END;
1324 $$;
1326 CREATE TRIGGER "write_event_suggestion_created"
1327 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1328 "write_event_suggestion_created_trigger"();
1330 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1331 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1335 ----------------------------
1336 -- Additional constraints --
1337 ----------------------------
1340 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1341 RETURNS TRIGGER
1342 LANGUAGE 'plpgsql' VOLATILE AS $$
1343 BEGIN
1344 IF NOT EXISTS (
1345 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1346 ) THEN
1347 --RAISE 'Cannot create issue without an initial initiative.' USING
1348 -- ERRCODE = 'integrity_constraint_violation',
1349 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1350 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1351 END IF;
1352 RETURN NULL;
1353 END;
1354 $$;
1356 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1357 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1358 FOR EACH ROW EXECUTE PROCEDURE
1359 "issue_requires_first_initiative_trigger"();
1361 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1362 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1365 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1366 RETURNS TRIGGER
1367 LANGUAGE 'plpgsql' VOLATILE AS $$
1368 DECLARE
1369 "reference_lost" BOOLEAN;
1370 BEGIN
1371 IF TG_OP = 'DELETE' THEN
1372 "reference_lost" := TRUE;
1373 ELSE
1374 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1375 END IF;
1376 IF
1377 "reference_lost" AND NOT EXISTS (
1378 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1380 THEN
1381 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1382 END IF;
1383 RETURN NULL;
1384 END;
1385 $$;
1387 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1388 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1389 FOR EACH ROW EXECUTE PROCEDURE
1390 "last_initiative_deletes_issue_trigger"();
1392 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1393 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1396 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1397 RETURNS TRIGGER
1398 LANGUAGE 'plpgsql' VOLATILE AS $$
1399 BEGIN
1400 IF NOT EXISTS (
1401 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1402 ) THEN
1403 --RAISE 'Cannot create initiative without an initial draft.' USING
1404 -- ERRCODE = 'integrity_constraint_violation',
1405 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1406 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1407 END IF;
1408 RETURN NULL;
1409 END;
1410 $$;
1412 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1413 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1414 FOR EACH ROW EXECUTE PROCEDURE
1415 "initiative_requires_first_draft_trigger"();
1417 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1418 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1421 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1422 RETURNS TRIGGER
1423 LANGUAGE 'plpgsql' VOLATILE AS $$
1424 DECLARE
1425 "reference_lost" BOOLEAN;
1426 BEGIN
1427 IF TG_OP = 'DELETE' THEN
1428 "reference_lost" := TRUE;
1429 ELSE
1430 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1431 END IF;
1432 IF
1433 "reference_lost" AND NOT EXISTS (
1434 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1436 THEN
1437 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1438 END IF;
1439 RETURN NULL;
1440 END;
1441 $$;
1443 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1444 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1445 FOR EACH ROW EXECUTE PROCEDURE
1446 "last_draft_deletes_initiative_trigger"();
1448 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1449 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1452 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1453 RETURNS TRIGGER
1454 LANGUAGE 'plpgsql' VOLATILE AS $$
1455 BEGIN
1456 IF NOT EXISTS (
1457 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1458 ) THEN
1459 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1460 END IF;
1461 RETURN NULL;
1462 END;
1463 $$;
1465 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1466 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1467 FOR EACH ROW EXECUTE PROCEDURE
1468 "suggestion_requires_first_opinion_trigger"();
1470 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1471 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1474 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1475 RETURNS TRIGGER
1476 LANGUAGE 'plpgsql' VOLATILE AS $$
1477 DECLARE
1478 "reference_lost" BOOLEAN;
1479 BEGIN
1480 IF TG_OP = 'DELETE' THEN
1481 "reference_lost" := TRUE;
1482 ELSE
1483 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1484 END IF;
1485 IF
1486 "reference_lost" AND NOT EXISTS (
1487 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1489 THEN
1490 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1491 END IF;
1492 RETURN NULL;
1493 END;
1494 $$;
1496 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1497 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1498 FOR EACH ROW EXECUTE PROCEDURE
1499 "last_opinion_deletes_suggestion_trigger"();
1501 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1502 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1505 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1506 RETURNS TRIGGER
1507 LANGUAGE 'plpgsql' VOLATILE AS $$
1508 BEGIN
1509 DELETE FROM "direct_voter"
1510 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1511 RETURN NULL;
1512 END;
1513 $$;
1515 CREATE TRIGGER "non_voter_deletes_direct_voter"
1516 AFTER INSERT OR UPDATE ON "non_voter"
1517 FOR EACH ROW EXECUTE PROCEDURE
1518 "non_voter_deletes_direct_voter_trigger"();
1520 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1521 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")';
1524 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1525 RETURNS TRIGGER
1526 LANGUAGE 'plpgsql' VOLATILE AS $$
1527 BEGIN
1528 DELETE FROM "non_voter"
1529 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1530 RETURN NULL;
1531 END;
1532 $$;
1534 CREATE TRIGGER "direct_voter_deletes_non_voter"
1535 AFTER INSERT OR UPDATE ON "direct_voter"
1536 FOR EACH ROW EXECUTE PROCEDURE
1537 "direct_voter_deletes_non_voter_trigger"();
1539 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1540 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")';
1543 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1544 RETURNS TRIGGER
1545 LANGUAGE 'plpgsql' VOLATILE AS $$
1546 BEGIN
1547 IF NEW."comment" ISNULL THEN
1548 NEW."comment_changed" := NULL;
1549 NEW."formatting_engine" := NULL;
1550 END IF;
1551 RETURN NEW;
1552 END;
1553 $$;
1555 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1556 BEFORE INSERT OR UPDATE ON "direct_voter"
1557 FOR EACH ROW EXECUTE PROCEDURE
1558 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1560 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"';
1561 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.';
1564 ---------------------------------------------------------------
1565 -- Ensure that votes are not modified when issues are frozen --
1566 ---------------------------------------------------------------
1568 -- NOTE: Frontends should ensure this anyway, but in case of programming
1569 -- errors the following triggers ensure data integrity.
1572 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1573 RETURNS TRIGGER
1574 LANGUAGE 'plpgsql' VOLATILE AS $$
1575 DECLARE
1576 "issue_id_v" "issue"."id"%TYPE;
1577 "issue_row" "issue"%ROWTYPE;
1578 BEGIN
1579 IF TG_RELID = 'direct_voter'::regclass AND TG_OP = 'UPDATE' THEN
1580 IF
1581 OLD."issue_id" = NEW."issue_id" AND
1582 OLD."member_id" = NEW."member_id" AND
1583 OLD."weight" = NEW."weight"
1584 THEN
1585 RETURN NULL; -- allows changing of voter comment
1586 END IF;
1587 END IF;
1588 IF TG_OP = 'DELETE' THEN
1589 "issue_id_v" := OLD."issue_id";
1590 ELSE
1591 "issue_id_v" := NEW."issue_id";
1592 END IF;
1593 SELECT INTO "issue_row" * FROM "issue"
1594 WHERE "id" = "issue_id_v" FOR SHARE;
1595 IF "issue_row"."closed" NOTNULL THEN
1596 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1597 END IF;
1598 RETURN NULL;
1599 END;
1600 $$;
1602 CREATE TRIGGER "forbid_changes_on_closed_issue"
1603 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1604 FOR EACH ROW EXECUTE PROCEDURE
1605 "forbid_changes_on_closed_issue_trigger"();
1607 CREATE TRIGGER "forbid_changes_on_closed_issue"
1608 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1609 FOR EACH ROW EXECUTE PROCEDURE
1610 "forbid_changes_on_closed_issue_trigger"();
1612 CREATE TRIGGER "forbid_changes_on_closed_issue"
1613 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1614 FOR EACH ROW EXECUTE PROCEDURE
1615 "forbid_changes_on_closed_issue_trigger"();
1617 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"';
1618 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';
1619 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';
1620 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';
1624 --------------------------------------------------------------------
1625 -- Auto-retrieval of fields only needed for referential integrity --
1626 --------------------------------------------------------------------
1629 CREATE FUNCTION "autofill_issue_id_trigger"()
1630 RETURNS TRIGGER
1631 LANGUAGE 'plpgsql' VOLATILE AS $$
1632 BEGIN
1633 IF NEW."issue_id" ISNULL THEN
1634 SELECT "issue_id" INTO NEW."issue_id"
1635 FROM "initiative" WHERE "id" = NEW."initiative_id";
1636 END IF;
1637 RETURN NEW;
1638 END;
1639 $$;
1641 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1642 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1644 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1645 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1647 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1648 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1649 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1652 CREATE FUNCTION "autofill_initiative_id_trigger"()
1653 RETURNS TRIGGER
1654 LANGUAGE 'plpgsql' VOLATILE AS $$
1655 BEGIN
1656 IF NEW."initiative_id" ISNULL THEN
1657 SELECT "initiative_id" INTO NEW."initiative_id"
1658 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1659 END IF;
1660 RETURN NEW;
1661 END;
1662 $$;
1664 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1665 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1667 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1668 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1672 -----------------------------------------------------
1673 -- Automatic calculation of certain default values --
1674 -----------------------------------------------------
1677 CREATE FUNCTION "copy_timings_trigger"()
1678 RETURNS TRIGGER
1679 LANGUAGE 'plpgsql' VOLATILE AS $$
1680 DECLARE
1681 "policy_row" "policy"%ROWTYPE;
1682 BEGIN
1683 SELECT * INTO "policy_row" FROM "policy"
1684 WHERE "id" = NEW."policy_id";
1685 IF NEW."admission_time" ISNULL THEN
1686 NEW."admission_time" := "policy_row"."admission_time";
1687 END IF;
1688 IF NEW."discussion_time" ISNULL THEN
1689 NEW."discussion_time" := "policy_row"."discussion_time";
1690 END IF;
1691 IF NEW."verification_time" ISNULL THEN
1692 NEW."verification_time" := "policy_row"."verification_time";
1693 END IF;
1694 IF NEW."voting_time" ISNULL THEN
1695 NEW."voting_time" := "policy_row"."voting_time";
1696 END IF;
1697 RETURN NEW;
1698 END;
1699 $$;
1701 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1702 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1704 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1705 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1708 CREATE FUNCTION "default_for_draft_id_trigger"()
1709 RETURNS TRIGGER
1710 LANGUAGE 'plpgsql' VOLATILE AS $$
1711 BEGIN
1712 IF NEW."draft_id" ISNULL THEN
1713 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1714 WHERE "initiative_id" = NEW."initiative_id";
1715 END IF;
1716 RETURN NEW;
1717 END;
1718 $$;
1720 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1721 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1722 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1723 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1725 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1726 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';
1727 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';
1731 ----------------------------------------
1732 -- Automatic creation of dependencies --
1733 ----------------------------------------
1736 CREATE FUNCTION "autocreate_interest_trigger"()
1737 RETURNS TRIGGER
1738 LANGUAGE 'plpgsql' VOLATILE AS $$
1739 BEGIN
1740 IF NOT EXISTS (
1741 SELECT NULL FROM "initiative" JOIN "interest"
1742 ON "initiative"."issue_id" = "interest"."issue_id"
1743 WHERE "initiative"."id" = NEW."initiative_id"
1744 AND "interest"."member_id" = NEW."member_id"
1745 ) THEN
1746 BEGIN
1747 INSERT INTO "interest" ("issue_id", "member_id")
1748 SELECT "issue_id", NEW."member_id"
1749 FROM "initiative" WHERE "id" = NEW."initiative_id";
1750 EXCEPTION WHEN unique_violation THEN END;
1751 END IF;
1752 RETURN NEW;
1753 END;
1754 $$;
1756 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1757 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1759 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1760 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';
1763 CREATE FUNCTION "autocreate_supporter_trigger"()
1764 RETURNS TRIGGER
1765 LANGUAGE 'plpgsql' VOLATILE AS $$
1766 BEGIN
1767 IF NOT EXISTS (
1768 SELECT NULL FROM "suggestion" JOIN "supporter"
1769 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1770 WHERE "suggestion"."id" = NEW."suggestion_id"
1771 AND "supporter"."member_id" = NEW."member_id"
1772 ) THEN
1773 BEGIN
1774 INSERT INTO "supporter" ("initiative_id", "member_id")
1775 SELECT "initiative_id", NEW."member_id"
1776 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1777 EXCEPTION WHEN unique_violation THEN END;
1778 END IF;
1779 RETURN NEW;
1780 END;
1781 $$;
1783 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1784 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1786 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1787 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.';
1791 ------------------------------------------
1792 -- Views and helper functions for views --
1793 ------------------------------------------
1796 CREATE VIEW "unit_delegation" AS
1797 SELECT
1798 "unit"."id" AS "unit_id",
1799 "delegation"."id",
1800 "delegation"."truster_id",
1801 "delegation"."trustee_id",
1802 "delegation"."scope"
1803 FROM "unit"
1804 JOIN "delegation"
1805 ON "delegation"."unit_id" = "unit"."id"
1806 JOIN "member"
1807 ON "delegation"."truster_id" = "member"."id"
1808 JOIN "privilege"
1809 ON "delegation"."unit_id" = "privilege"."unit_id"
1810 AND "delegation"."truster_id" = "privilege"."member_id"
1811 WHERE "member"."active" AND "privilege"."voting_right";
1813 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1816 CREATE VIEW "area_delegation" AS
1817 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1818 "area"."id" AS "area_id",
1819 "delegation"."id",
1820 "delegation"."truster_id",
1821 "delegation"."trustee_id",
1822 "delegation"."scope"
1823 FROM "area"
1824 JOIN "delegation"
1825 ON "delegation"."unit_id" = "area"."unit_id"
1826 OR "delegation"."area_id" = "area"."id"
1827 JOIN "member"
1828 ON "delegation"."truster_id" = "member"."id"
1829 JOIN "privilege"
1830 ON "area"."unit_id" = "privilege"."unit_id"
1831 AND "delegation"."truster_id" = "privilege"."member_id"
1832 WHERE "member"."active" AND "privilege"."voting_right"
1833 ORDER BY
1834 "area"."id",
1835 "delegation"."truster_id",
1836 "delegation"."scope" DESC;
1838 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1841 CREATE VIEW "issue_delegation" AS
1842 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1843 "issue"."id" AS "issue_id",
1844 "delegation"."id",
1845 "delegation"."truster_id",
1846 "delegation"."trustee_id",
1847 "delegation"."scope"
1848 FROM "issue"
1849 JOIN "area"
1850 ON "area"."id" = "issue"."area_id"
1851 JOIN "delegation"
1852 ON "delegation"."unit_id" = "area"."unit_id"
1853 OR "delegation"."area_id" = "area"."id"
1854 OR "delegation"."issue_id" = "issue"."id"
1855 JOIN "member"
1856 ON "delegation"."truster_id" = "member"."id"
1857 JOIN "privilege"
1858 ON "area"."unit_id" = "privilege"."unit_id"
1859 AND "delegation"."truster_id" = "privilege"."member_id"
1860 WHERE "member"."active" AND "privilege"."voting_right"
1861 ORDER BY
1862 "issue"."id",
1863 "delegation"."truster_id",
1864 "delegation"."scope" DESC;
1866 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1869 CREATE FUNCTION "membership_weight_with_skipping"
1870 ( "area_id_p" "area"."id"%TYPE,
1871 "member_id_p" "member"."id"%TYPE,
1872 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1873 RETURNS INT4
1874 LANGUAGE 'plpgsql' STABLE AS $$
1875 DECLARE
1876 "sum_v" INT4;
1877 "delegation_row" "area_delegation"%ROWTYPE;
1878 BEGIN
1879 "sum_v" := 1;
1880 FOR "delegation_row" IN
1881 SELECT "area_delegation".*
1882 FROM "area_delegation" LEFT JOIN "membership"
1883 ON "membership"."area_id" = "area_id_p"
1884 AND "membership"."member_id" = "area_delegation"."truster_id"
1885 WHERE "area_delegation"."area_id" = "area_id_p"
1886 AND "area_delegation"."trustee_id" = "member_id_p"
1887 AND "membership"."member_id" ISNULL
1888 LOOP
1889 IF NOT
1890 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1891 THEN
1892 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1893 "area_id_p",
1894 "delegation_row"."truster_id",
1895 "skip_member_ids_p" || "delegation_row"."truster_id"
1896 );
1897 END IF;
1898 END LOOP;
1899 RETURN "sum_v";
1900 END;
1901 $$;
1903 COMMENT ON FUNCTION "membership_weight_with_skipping"
1904 ( "area"."id"%TYPE,
1905 "member"."id"%TYPE,
1906 INT4[] )
1907 IS 'Helper function for "membership_weight" function';
1910 CREATE FUNCTION "membership_weight"
1911 ( "area_id_p" "area"."id"%TYPE,
1912 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1913 RETURNS INT4
1914 LANGUAGE 'plpgsql' STABLE AS $$
1915 BEGIN
1916 RETURN "membership_weight_with_skipping"(
1917 "area_id_p",
1918 "member_id_p",
1919 ARRAY["member_id_p"]
1920 );
1921 END;
1922 $$;
1924 COMMENT ON FUNCTION "membership_weight"
1925 ( "area"."id"%TYPE,
1926 "member"."id"%TYPE )
1927 IS 'Calculates the potential voting weight of a member in a given area';
1930 CREATE VIEW "member_count_view" AS
1931 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1933 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1936 CREATE VIEW "unit_member_count" AS
1937 SELECT
1938 "unit"."id" AS "unit_id",
1939 count("member"."id") AS "member_count"
1940 FROM "unit"
1941 LEFT JOIN "privilege"
1942 ON "privilege"."unit_id" = "unit"."id"
1943 AND "privilege"."voting_right"
1944 LEFT JOIN "member"
1945 ON "member"."id" = "privilege"."member_id"
1946 AND "member"."active"
1947 GROUP BY "unit"."id";
1949 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1952 CREATE VIEW "area_member_count" AS
1953 SELECT
1954 "area"."id" AS "area_id",
1955 count("member"."id") AS "direct_member_count",
1956 coalesce(
1957 sum(
1958 CASE WHEN "member"."id" NOTNULL THEN
1959 "membership_weight"("area"."id", "member"."id")
1960 ELSE 0 END
1962 ) AS "member_weight"
1963 FROM "area"
1964 LEFT JOIN "membership"
1965 ON "area"."id" = "membership"."area_id"
1966 LEFT JOIN "privilege"
1967 ON "privilege"."unit_id" = "area"."unit_id"
1968 AND "privilege"."member_id" = "membership"."member_id"
1969 AND "privilege"."voting_right"
1970 LEFT JOIN "member"
1971 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1972 AND "member"."active"
1973 GROUP BY "area"."id";
1975 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1978 CREATE VIEW "opening_draft" AS
1979 SELECT "draft".* FROM (
1980 SELECT
1981 "initiative"."id" AS "initiative_id",
1982 min("draft"."id") AS "draft_id"
1983 FROM "initiative" JOIN "draft"
1984 ON "initiative"."id" = "draft"."initiative_id"
1985 GROUP BY "initiative"."id"
1986 ) AS "subquery"
1987 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1989 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1992 CREATE VIEW "current_draft" AS
1993 SELECT "draft".* FROM (
1994 SELECT
1995 "initiative"."id" AS "initiative_id",
1996 max("draft"."id") AS "draft_id"
1997 FROM "initiative" JOIN "draft"
1998 ON "initiative"."id" = "draft"."initiative_id"
1999 GROUP BY "initiative"."id"
2000 ) AS "subquery"
2001 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2003 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2006 CREATE VIEW "critical_opinion" AS
2007 SELECT * FROM "opinion"
2008 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2009 OR ("degree" = -2 AND "fulfilled" = TRUE);
2011 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2014 CREATE VIEW "battle_participant" AS
2015 SELECT "initiative"."id", "initiative"."issue_id"
2016 FROM "issue" JOIN "initiative"
2017 ON "issue"."id" = "initiative"."issue_id"
2018 WHERE "initiative"."admitted"
2019 UNION ALL
2020 SELECT NULL, "id" AS "issue_id"
2021 FROM "issue";
2023 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2026 CREATE VIEW "battle_view" AS
2027 SELECT
2028 "issue"."id" AS "issue_id",
2029 "winning_initiative"."id" AS "winning_initiative_id",
2030 "losing_initiative"."id" AS "losing_initiative_id",
2031 sum(
2032 CASE WHEN
2033 coalesce("better_vote"."grade", 0) >
2034 coalesce("worse_vote"."grade", 0)
2035 THEN "direct_voter"."weight" ELSE 0 END
2036 ) AS "count"
2037 FROM "issue"
2038 LEFT JOIN "direct_voter"
2039 ON "issue"."id" = "direct_voter"."issue_id"
2040 JOIN "battle_participant" AS "winning_initiative"
2041 ON "issue"."id" = "winning_initiative"."issue_id"
2042 JOIN "battle_participant" AS "losing_initiative"
2043 ON "issue"."id" = "losing_initiative"."issue_id"
2044 LEFT JOIN "vote" AS "better_vote"
2045 ON "direct_voter"."member_id" = "better_vote"."member_id"
2046 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2047 LEFT JOIN "vote" AS "worse_vote"
2048 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2049 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2050 WHERE "issue"."closed" NOTNULL
2051 AND "issue"."cleaned" ISNULL
2052 AND (
2053 "winning_initiative"."id" != "losing_initiative"."id" OR
2054 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2055 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2056 GROUP BY
2057 "issue"."id",
2058 "winning_initiative"."id",
2059 "losing_initiative"."id";
2061 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';
2064 CREATE VIEW "expired_session" AS
2065 SELECT * FROM "session" WHERE now() > "expiry";
2067 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2068 DELETE FROM "session" WHERE "ident" = OLD."ident";
2070 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2071 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2074 CREATE VIEW "open_issue" AS
2075 SELECT * FROM "issue" WHERE "closed" ISNULL;
2077 COMMENT ON VIEW "open_issue" IS 'All open issues';
2080 CREATE VIEW "issue_with_ranks_missing" AS
2081 SELECT * FROM "issue"
2082 WHERE "fully_frozen" NOTNULL
2083 AND "closed" NOTNULL
2084 AND "ranks_available" = FALSE;
2086 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2089 CREATE VIEW "member_contingent" AS
2090 SELECT
2091 "member"."id" AS "member_id",
2092 "contingent"."time_frame",
2093 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2095 SELECT count(1) FROM "draft"
2096 WHERE "draft"."author_id" = "member"."id"
2097 AND "draft"."created" > now() - "contingent"."time_frame"
2098 ) + (
2099 SELECT count(1) FROM "suggestion"
2100 WHERE "suggestion"."author_id" = "member"."id"
2101 AND "suggestion"."created" > now() - "contingent"."time_frame"
2103 ELSE NULL END AS "text_entry_count",
2104 "contingent"."text_entry_limit",
2105 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2106 SELECT count(1) FROM "opening_draft"
2107 WHERE "opening_draft"."author_id" = "member"."id"
2108 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2109 ) ELSE NULL END AS "initiative_count",
2110 "contingent"."initiative_limit"
2111 FROM "member" CROSS JOIN "contingent";
2113 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2115 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2116 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2119 CREATE VIEW "member_contingent_left" AS
2120 SELECT
2121 "member_id",
2122 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2123 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2124 FROM "member_contingent" GROUP BY "member_id";
2126 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.';
2129 CREATE VIEW "event_seen_by_member" AS
2130 SELECT
2131 "member"."id" AS "seen_by_member_id",
2132 CASE WHEN "event"."state" IN (
2133 'voting',
2134 'finished_without_winner',
2135 'finished_with_winner'
2136 ) THEN
2137 'voting'::"notify_level"
2138 ELSE
2139 CASE WHEN "event"."state" IN (
2140 'verification',
2141 'canceled_after_revocation_during_verification',
2142 'canceled_no_initiative_admitted'
2143 ) THEN
2144 'verification'::"notify_level"
2145 ELSE
2146 CASE WHEN "event"."state" IN (
2147 'discussion',
2148 'canceled_after_revocation_during_discussion'
2149 ) THEN
2150 'discussion'::"notify_level"
2151 ELSE
2152 'all'::"notify_level"
2153 END
2154 END
2155 END AS "notify_level",
2156 "event".*
2157 FROM "member" CROSS JOIN "event"
2158 LEFT JOIN "issue"
2159 ON "event"."issue_id" = "issue"."id"
2160 LEFT JOIN "membership"
2161 ON "member"."id" = "membership"."member_id"
2162 AND "issue"."area_id" = "membership"."area_id"
2163 LEFT JOIN "interest"
2164 ON "member"."id" = "interest"."member_id"
2165 AND "event"."issue_id" = "interest"."issue_id"
2166 LEFT JOIN "supporter"
2167 ON "member"."id" = "supporter"."member_id"
2168 AND "event"."initiative_id" = "supporter"."initiative_id"
2169 LEFT JOIN "ignored_member"
2170 ON "member"."id" = "ignored_member"."member_id"
2171 AND "event"."member_id" = "ignored_member"."other_member_id"
2172 LEFT JOIN "ignored_initiative"
2173 ON "member"."id" = "ignored_initiative"."member_id"
2174 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2175 WHERE (
2176 "supporter"."member_id" NOTNULL OR
2177 "interest"."member_id" NOTNULL OR
2178 ( "membership"."member_id" NOTNULL AND
2179 "event"."event" IN (
2180 'issue_state_changed',
2181 'initiative_created_in_new_issue',
2182 'initiative_created_in_existing_issue',
2183 'initiative_revoked' ) ) )
2184 AND "ignored_member"."member_id" ISNULL
2185 AND "ignored_initiative"."member_id" ISNULL;
2187 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"';
2190 CREATE VIEW "selected_event_seen_by_member" AS
2191 SELECT
2192 "member"."id" AS "seen_by_member_id",
2193 CASE WHEN "event"."state" IN (
2194 'voting',
2195 'finished_without_winner',
2196 'finished_with_winner'
2197 ) THEN
2198 'voting'::"notify_level"
2199 ELSE
2200 CASE WHEN "event"."state" IN (
2201 'verification',
2202 'canceled_after_revocation_during_verification',
2203 'canceled_no_initiative_admitted'
2204 ) THEN
2205 'verification'::"notify_level"
2206 ELSE
2207 CASE WHEN "event"."state" IN (
2208 'discussion',
2209 'canceled_after_revocation_during_discussion'
2210 ) THEN
2211 'discussion'::"notify_level"
2212 ELSE
2213 'all'::"notify_level"
2214 END
2215 END
2216 END AS "notify_level",
2217 "event".*
2218 FROM "member" CROSS JOIN "event"
2219 LEFT JOIN "issue"
2220 ON "event"."issue_id" = "issue"."id"
2221 LEFT JOIN "membership"
2222 ON "member"."id" = "membership"."member_id"
2223 AND "issue"."area_id" = "membership"."area_id"
2224 LEFT JOIN "interest"
2225 ON "member"."id" = "interest"."member_id"
2226 AND "event"."issue_id" = "interest"."issue_id"
2227 LEFT JOIN "supporter"
2228 ON "member"."id" = "supporter"."member_id"
2229 AND "event"."initiative_id" = "supporter"."initiative_id"
2230 LEFT JOIN "ignored_member"
2231 ON "member"."id" = "ignored_member"."member_id"
2232 AND "event"."member_id" = "ignored_member"."other_member_id"
2233 LEFT JOIN "ignored_initiative"
2234 ON "member"."id" = "ignored_initiative"."member_id"
2235 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2236 WHERE (
2237 ( "member"."notify_level" >= 'all' ) OR
2238 ( "member"."notify_level" >= 'voting' AND
2239 "event"."state" IN (
2240 'voting',
2241 'finished_without_winner',
2242 'finished_with_winner' ) ) OR
2243 ( "member"."notify_level" >= 'verification' AND
2244 "event"."state" IN (
2245 'verification',
2246 'canceled_after_revocation_during_verification',
2247 'canceled_no_initiative_admitted' ) ) OR
2248 ( "member"."notify_level" >= 'discussion' AND
2249 "event"."state" IN (
2250 'discussion',
2251 'canceled_after_revocation_during_discussion' ) ) )
2252 AND (
2253 "supporter"."member_id" NOTNULL OR
2254 "interest"."member_id" NOTNULL OR
2255 ( "membership"."member_id" NOTNULL AND
2256 "event"."event" IN (
2257 'issue_state_changed',
2258 'initiative_created_in_new_issue',
2259 'initiative_created_in_existing_issue',
2260 'initiative_revoked' ) ) )
2261 AND "ignored_member"."member_id" ISNULL
2262 AND "ignored_initiative"."member_id" ISNULL;
2264 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"';
2267 CREATE TYPE "timeline_event" AS ENUM (
2268 'issue_created',
2269 'issue_canceled',
2270 'issue_accepted',
2271 'issue_half_frozen',
2272 'issue_finished_without_voting',
2273 'issue_voting_started',
2274 'issue_finished_after_voting',
2275 'initiative_created',
2276 'initiative_revoked',
2277 'draft_created',
2278 'suggestion_created');
2280 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2283 CREATE VIEW "timeline_issue" AS
2284 SELECT
2285 "created" AS "occurrence",
2286 'issue_created'::"timeline_event" AS "event",
2287 "id" AS "issue_id"
2288 FROM "issue"
2289 UNION ALL
2290 SELECT
2291 "closed" AS "occurrence",
2292 'issue_canceled'::"timeline_event" AS "event",
2293 "id" AS "issue_id"
2294 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2295 UNION ALL
2296 SELECT
2297 "accepted" AS "occurrence",
2298 'issue_accepted'::"timeline_event" AS "event",
2299 "id" AS "issue_id"
2300 FROM "issue" WHERE "accepted" NOTNULL
2301 UNION ALL
2302 SELECT
2303 "half_frozen" AS "occurrence",
2304 'issue_half_frozen'::"timeline_event" AS "event",
2305 "id" AS "issue_id"
2306 FROM "issue" WHERE "half_frozen" NOTNULL
2307 UNION ALL
2308 SELECT
2309 "fully_frozen" AS "occurrence",
2310 'issue_voting_started'::"timeline_event" AS "event",
2311 "id" AS "issue_id"
2312 FROM "issue"
2313 WHERE "fully_frozen" NOTNULL
2314 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2315 UNION ALL
2316 SELECT
2317 "closed" AS "occurrence",
2318 CASE WHEN "fully_frozen" = "closed" THEN
2319 'issue_finished_without_voting'::"timeline_event"
2320 ELSE
2321 'issue_finished_after_voting'::"timeline_event"
2322 END AS "event",
2323 "id" AS "issue_id"
2324 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2326 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2329 CREATE VIEW "timeline_initiative" AS
2330 SELECT
2331 "created" AS "occurrence",
2332 'initiative_created'::"timeline_event" AS "event",
2333 "id" AS "initiative_id"
2334 FROM "initiative"
2335 UNION ALL
2336 SELECT
2337 "revoked" AS "occurrence",
2338 'initiative_revoked'::"timeline_event" AS "event",
2339 "id" AS "initiative_id"
2340 FROM "initiative" WHERE "revoked" NOTNULL;
2342 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2345 CREATE VIEW "timeline_draft" AS
2346 SELECT
2347 "created" AS "occurrence",
2348 'draft_created'::"timeline_event" AS "event",
2349 "id" AS "draft_id"
2350 FROM "draft";
2352 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2355 CREATE VIEW "timeline_suggestion" AS
2356 SELECT
2357 "created" AS "occurrence",
2358 'suggestion_created'::"timeline_event" AS "event",
2359 "id" AS "suggestion_id"
2360 FROM "suggestion";
2362 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2365 CREATE VIEW "timeline" AS
2366 SELECT
2367 "occurrence",
2368 "event",
2369 "issue_id",
2370 NULL AS "initiative_id",
2371 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2372 NULL::INT8 AS "suggestion_id"
2373 FROM "timeline_issue"
2374 UNION ALL
2375 SELECT
2376 "occurrence",
2377 "event",
2378 NULL AS "issue_id",
2379 "initiative_id",
2380 NULL AS "draft_id",
2381 NULL AS "suggestion_id"
2382 FROM "timeline_initiative"
2383 UNION ALL
2384 SELECT
2385 "occurrence",
2386 "event",
2387 NULL AS "issue_id",
2388 NULL AS "initiative_id",
2389 "draft_id",
2390 NULL AS "suggestion_id"
2391 FROM "timeline_draft"
2392 UNION ALL
2393 SELECT
2394 "occurrence",
2395 "event",
2396 NULL AS "issue_id",
2397 NULL AS "initiative_id",
2398 NULL AS "draft_id",
2399 "suggestion_id"
2400 FROM "timeline_suggestion";
2402 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2406 ------------------------------------------------------
2407 -- Row set returning function for delegation chains --
2408 ------------------------------------------------------
2411 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2412 ('first', 'intermediate', 'last', 'repetition');
2414 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2417 CREATE TYPE "delegation_chain_row" AS (
2418 "index" INT4,
2419 "member_id" INT4,
2420 "member_valid" BOOLEAN,
2421 "participation" BOOLEAN,
2422 "overridden" BOOLEAN,
2423 "scope_in" "delegation_scope",
2424 "scope_out" "delegation_scope",
2425 "disabled_out" BOOLEAN,
2426 "loop" "delegation_chain_loop_tag" );
2428 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2430 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2431 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';
2432 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2433 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2434 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2435 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2436 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2439 CREATE FUNCTION "delegation_chain_for_closed_issue"
2440 ( "member_id_p" "member"."id"%TYPE,
2441 "issue_id_p" "issue"."id"%TYPE )
2442 RETURNS SETOF "delegation_chain_row"
2443 LANGUAGE 'plpgsql' STABLE AS $$
2444 DECLARE
2445 "output_row" "delegation_chain_row";
2446 "direct_voter_row" "direct_voter"%ROWTYPE;
2447 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2448 BEGIN
2449 "output_row"."index" := 0;
2450 "output_row"."member_id" := "member_id_p";
2451 "output_row"."member_valid" := TRUE;
2452 "output_row"."participation" := FALSE;
2453 "output_row"."overridden" := FALSE;
2454 "output_row"."disabled_out" := FALSE;
2455 LOOP
2456 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2457 WHERE "issue_id" = "issue_id_p"
2458 AND "member_id" = "output_row"."member_id";
2459 IF "direct_voter_row"."member_id" NOTNULL THEN
2460 "output_row"."participation" := TRUE;
2461 "output_row"."scope_out" := NULL;
2462 "output_row"."disabled_out" := NULL;
2463 RETURN NEXT "output_row";
2464 RETURN;
2465 END IF;
2466 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2467 WHERE "issue_id" = "issue_id_p"
2468 AND "member_id" = "output_row"."member_id";
2469 IF "delegating_voter_row"."member_id" ISNULL THEN
2470 RETURN;
2471 END IF;
2472 "output_row"."scope_out" := "delegating_voter_row"."scope";
2473 RETURN NEXT "output_row";
2474 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2475 "output_row"."scope_in" := "output_row"."scope_out";
2476 END LOOP;
2477 END;
2478 $$;
2480 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2481 ( "member"."id"%TYPE,
2482 "member"."id"%TYPE )
2483 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2486 CREATE FUNCTION "delegation_chain"
2487 ( "member_id_p" "member"."id"%TYPE,
2488 "unit_id_p" "unit"."id"%TYPE,
2489 "area_id_p" "area"."id"%TYPE,
2490 "issue_id_p" "issue"."id"%TYPE,
2491 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2492 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2493 RETURNS SETOF "delegation_chain_row"
2494 LANGUAGE 'plpgsql' STABLE AS $$
2495 DECLARE
2496 "scope_v" "delegation_scope";
2497 "unit_id_v" "unit"."id"%TYPE;
2498 "area_id_v" "area"."id"%TYPE;
2499 "issue_row" "issue"%ROWTYPE;
2500 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2501 "loop_member_id_v" "member"."id"%TYPE;
2502 "output_row" "delegation_chain_row";
2503 "output_rows" "delegation_chain_row"[];
2504 "simulate_v" BOOLEAN;
2505 "simulate_here_v" BOOLEAN;
2506 "delegation_row" "delegation"%ROWTYPE;
2507 "row_count" INT4;
2508 "i" INT4;
2509 "loop_v" BOOLEAN;
2510 BEGIN
2511 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2512 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2513 END IF;
2514 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2515 "simulate_v" := TRUE;
2516 ELSE
2517 "simulate_v" := FALSE;
2518 END IF;
2519 IF
2520 "unit_id_p" NOTNULL AND
2521 "area_id_p" ISNULL AND
2522 "issue_id_p" ISNULL
2523 THEN
2524 "scope_v" := 'unit';
2525 "unit_id_v" := "unit_id_p";
2526 ELSIF
2527 "unit_id_p" ISNULL AND
2528 "area_id_p" NOTNULL AND
2529 "issue_id_p" ISNULL
2530 THEN
2531 "scope_v" := 'area';
2532 "area_id_v" := "area_id_p";
2533 SELECT "unit_id" INTO "unit_id_v"
2534 FROM "area" WHERE "id" = "area_id_v";
2535 ELSIF
2536 "unit_id_p" ISNULL AND
2537 "area_id_p" ISNULL AND
2538 "issue_id_p" NOTNULL
2539 THEN
2540 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2541 IF "issue_row"."id" ISNULL THEN
2542 RETURN;
2543 END IF;
2544 IF "issue_row"."closed" NOTNULL THEN
2545 IF "simulate_v" THEN
2546 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2547 END IF;
2548 FOR "output_row" IN
2549 SELECT * FROM
2550 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2551 LOOP
2552 RETURN NEXT "output_row";
2553 END LOOP;
2554 RETURN;
2555 END IF;
2556 "scope_v" := 'issue';
2557 SELECT "area_id" INTO "area_id_v"
2558 FROM "issue" WHERE "id" = "issue_id_p";
2559 SELECT "unit_id" INTO "unit_id_v"
2560 FROM "area" WHERE "id" = "area_id_v";
2561 ELSE
2562 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2563 END IF;
2564 "visited_member_ids" := '{}';
2565 "loop_member_id_v" := NULL;
2566 "output_rows" := '{}';
2567 "output_row"."index" := 0;
2568 "output_row"."member_id" := "member_id_p";
2569 "output_row"."member_valid" := TRUE;
2570 "output_row"."participation" := FALSE;
2571 "output_row"."overridden" := FALSE;
2572 "output_row"."disabled_out" := FALSE;
2573 "output_row"."scope_out" := NULL;
2574 LOOP
2575 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2576 "loop_member_id_v" := "output_row"."member_id";
2577 ELSE
2578 "visited_member_ids" :=
2579 "visited_member_ids" || "output_row"."member_id";
2580 END IF;
2581 IF "output_row"."participation" ISNULL THEN
2582 "output_row"."overridden" := NULL;
2583 ELSIF "output_row"."participation" THEN
2584 "output_row"."overridden" := TRUE;
2585 END IF;
2586 "output_row"."scope_in" := "output_row"."scope_out";
2587 "output_row"."member_valid" := EXISTS (
2588 SELECT NULL FROM "member" JOIN "privilege"
2589 ON "privilege"."member_id" = "member"."id"
2590 AND "privilege"."unit_id" = "unit_id_v"
2591 WHERE "id" = "output_row"."member_id"
2592 AND "member"."active" AND "privilege"."voting_right"
2593 );
2594 "simulate_here_v" := (
2595 "simulate_v" AND
2596 "output_row"."member_id" = "member_id_p"
2597 );
2598 "delegation_row" := ROW(NULL);
2599 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2600 IF "scope_v" = 'unit' THEN
2601 IF NOT "simulate_here_v" THEN
2602 SELECT * INTO "delegation_row" FROM "delegation"
2603 WHERE "truster_id" = "output_row"."member_id"
2604 AND "unit_id" = "unit_id_v";
2605 END IF;
2606 ELSIF "scope_v" = 'area' THEN
2607 "output_row"."participation" := EXISTS (
2608 SELECT NULL FROM "membership"
2609 WHERE "area_id" = "area_id_p"
2610 AND "member_id" = "output_row"."member_id"
2611 );
2612 IF "simulate_here_v" THEN
2613 IF "simulate_trustee_id_p" ISNULL THEN
2614 SELECT * INTO "delegation_row" FROM "delegation"
2615 WHERE "truster_id" = "output_row"."member_id"
2616 AND "unit_id" = "unit_id_v";
2617 END IF;
2618 ELSE
2619 SELECT * INTO "delegation_row" FROM "delegation"
2620 WHERE "truster_id" = "output_row"."member_id"
2621 AND (
2622 "unit_id" = "unit_id_v" OR
2623 "area_id" = "area_id_v"
2625 ORDER BY "scope" DESC;
2626 END IF;
2627 ELSIF "scope_v" = 'issue' THEN
2628 IF "issue_row"."fully_frozen" ISNULL THEN
2629 "output_row"."participation" := EXISTS (
2630 SELECT NULL FROM "interest"
2631 WHERE "issue_id" = "issue_id_p"
2632 AND "member_id" = "output_row"."member_id"
2633 );
2634 ELSE
2635 IF "output_row"."member_id" = "member_id_p" THEN
2636 "output_row"."participation" := EXISTS (
2637 SELECT NULL FROM "direct_voter"
2638 WHERE "issue_id" = "issue_id_p"
2639 AND "member_id" = "output_row"."member_id"
2640 );
2641 ELSE
2642 "output_row"."participation" := NULL;
2643 END IF;
2644 END IF;
2645 IF "simulate_here_v" THEN
2646 IF "simulate_trustee_id_p" ISNULL THEN
2647 SELECT * INTO "delegation_row" FROM "delegation"
2648 WHERE "truster_id" = "output_row"."member_id"
2649 AND (
2650 "unit_id" = "unit_id_v" OR
2651 "area_id" = "area_id_v"
2653 ORDER BY "scope" DESC;
2654 END IF;
2655 ELSE
2656 SELECT * INTO "delegation_row" FROM "delegation"
2657 WHERE "truster_id" = "output_row"."member_id"
2658 AND (
2659 "unit_id" = "unit_id_v" OR
2660 "area_id" = "area_id_v" OR
2661 "issue_id" = "issue_id_p"
2663 ORDER BY "scope" DESC;
2664 END IF;
2665 END IF;
2666 ELSE
2667 "output_row"."participation" := FALSE;
2668 END IF;
2669 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2670 "output_row"."scope_out" := "scope_v";
2671 "output_rows" := "output_rows" || "output_row";
2672 "output_row"."member_id" := "simulate_trustee_id_p";
2673 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2674 "output_row"."scope_out" := "delegation_row"."scope";
2675 "output_rows" := "output_rows" || "output_row";
2676 "output_row"."member_id" := "delegation_row"."trustee_id";
2677 ELSIF "delegation_row"."scope" NOTNULL THEN
2678 "output_row"."scope_out" := "delegation_row"."scope";
2679 "output_row"."disabled_out" := TRUE;
2680 "output_rows" := "output_rows" || "output_row";
2681 EXIT;
2682 ELSE
2683 "output_row"."scope_out" := NULL;
2684 "output_rows" := "output_rows" || "output_row";
2685 EXIT;
2686 END IF;
2687 EXIT WHEN "loop_member_id_v" NOTNULL;
2688 "output_row"."index" := "output_row"."index" + 1;
2689 END LOOP;
2690 "row_count" := array_upper("output_rows", 1);
2691 "i" := 1;
2692 "loop_v" := FALSE;
2693 LOOP
2694 "output_row" := "output_rows"["i"];
2695 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2696 IF "loop_v" THEN
2697 IF "i" + 1 = "row_count" THEN
2698 "output_row"."loop" := 'last';
2699 ELSIF "i" = "row_count" THEN
2700 "output_row"."loop" := 'repetition';
2701 ELSE
2702 "output_row"."loop" := 'intermediate';
2703 END IF;
2704 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2705 "output_row"."loop" := 'first';
2706 "loop_v" := TRUE;
2707 END IF;
2708 IF "scope_v" = 'unit' THEN
2709 "output_row"."participation" := NULL;
2710 END IF;
2711 RETURN NEXT "output_row";
2712 "i" := "i" + 1;
2713 END LOOP;
2714 RETURN;
2715 END;
2716 $$;
2718 COMMENT ON FUNCTION "delegation_chain"
2719 ( "member"."id"%TYPE,
2720 "unit"."id"%TYPE,
2721 "area"."id"%TYPE,
2722 "issue"."id"%TYPE,
2723 "member"."id"%TYPE,
2724 BOOLEAN )
2725 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2729 ---------------------------------------------------------
2730 -- Single row returning function for delegation chains --
2731 ---------------------------------------------------------
2734 CREATE TYPE "delegation_info_loop_type" AS ENUM
2735 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2737 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''';
2740 CREATE TYPE "delegation_info_type" AS (
2741 "own_participation" BOOLEAN,
2742 "own_delegation_scope" "delegation_scope",
2743 "first_trustee_id" INT4,
2744 "first_trustee_participation" BOOLEAN,
2745 "first_trustee_ellipsis" BOOLEAN,
2746 "other_trustee_id" INT4,
2747 "other_trustee_participation" BOOLEAN,
2748 "other_trustee_ellipsis" BOOLEAN,
2749 "delegation_loop" "delegation_info_loop_type",
2750 "participating_member_id" INT4 );
2752 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';
2754 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2755 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2756 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2757 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2758 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2759 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2760 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)';
2761 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2762 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';
2763 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2766 CREATE FUNCTION "delegation_info"
2767 ( "member_id_p" "member"."id"%TYPE,
2768 "unit_id_p" "unit"."id"%TYPE,
2769 "area_id_p" "area"."id"%TYPE,
2770 "issue_id_p" "issue"."id"%TYPE,
2771 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2772 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2773 RETURNS "delegation_info_type"
2774 LANGUAGE 'plpgsql' STABLE AS $$
2775 DECLARE
2776 "current_row" "delegation_chain_row";
2777 "result" "delegation_info_type";
2778 BEGIN
2779 "result"."own_participation" := FALSE;
2780 FOR "current_row" IN
2781 SELECT * FROM "delegation_chain"(
2782 "member_id_p",
2783 "unit_id_p", "area_id_p", "issue_id_p",
2784 "simulate_trustee_id_p", "simulate_default_p")
2785 LOOP
2786 IF
2787 "result"."participating_member_id" ISNULL AND
2788 "current_row"."participation"
2789 THEN
2790 "result"."participating_member_id" := "current_row"."member_id";
2791 END IF;
2792 IF "current_row"."member_id" = "member_id_p" THEN
2793 "result"."own_participation" := "current_row"."participation";
2794 "result"."own_delegation_scope" := "current_row"."scope_out";
2795 IF "current_row"."loop" = 'first' THEN
2796 "result"."delegation_loop" := 'own';
2797 END IF;
2798 ELSIF
2799 "current_row"."member_valid" AND
2800 ( "current_row"."loop" ISNULL OR
2801 "current_row"."loop" != 'repetition' )
2802 THEN
2803 IF "result"."first_trustee_id" ISNULL THEN
2804 "result"."first_trustee_id" := "current_row"."member_id";
2805 "result"."first_trustee_participation" := "current_row"."participation";
2806 "result"."first_trustee_ellipsis" := FALSE;
2807 IF "current_row"."loop" = 'first' THEN
2808 "result"."delegation_loop" := 'first';
2809 END IF;
2810 ELSIF "result"."other_trustee_id" ISNULL THEN
2811 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2812 "result"."other_trustee_id" := "current_row"."member_id";
2813 "result"."other_trustee_participation" := TRUE;
2814 "result"."other_trustee_ellipsis" := FALSE;
2815 IF "current_row"."loop" = 'first' THEN
2816 "result"."delegation_loop" := 'other';
2817 END IF;
2818 ELSE
2819 "result"."first_trustee_ellipsis" := TRUE;
2820 IF "current_row"."loop" = 'first' THEN
2821 "result"."delegation_loop" := 'first_ellipsis';
2822 END IF;
2823 END IF;
2824 ELSE
2825 "result"."other_trustee_ellipsis" := TRUE;
2826 IF "current_row"."loop" = 'first' THEN
2827 "result"."delegation_loop" := 'other_ellipsis';
2828 END IF;
2829 END IF;
2830 END IF;
2831 END LOOP;
2832 RETURN "result";
2833 END;
2834 $$;
2836 COMMENT ON FUNCTION "delegation_info"
2837 ( "member"."id"%TYPE,
2838 "unit"."id"%TYPE,
2839 "area"."id"%TYPE,
2840 "issue"."id"%TYPE,
2841 "member"."id"%TYPE,
2842 BOOLEAN )
2843 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2847 ------------------------------
2848 -- Comparison by vote count --
2849 ------------------------------
2851 CREATE FUNCTION "vote_ratio"
2852 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2853 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2854 RETURNS FLOAT8
2855 LANGUAGE 'plpgsql' STABLE AS $$
2856 BEGIN
2857 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2858 RETURN
2859 "positive_votes_p"::FLOAT8 /
2860 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2861 ELSIF "positive_votes_p" > 0 THEN
2862 RETURN "positive_votes_p";
2863 ELSIF "negative_votes_p" > 0 THEN
2864 RETURN 1 - "negative_votes_p";
2865 ELSE
2866 RETURN 0.5;
2867 END IF;
2868 END;
2869 $$;
2871 COMMENT ON FUNCTION "vote_ratio"
2872 ( "initiative"."positive_votes"%TYPE,
2873 "initiative"."negative_votes"%TYPE )
2874 IS 'Returns a number, which can be used for comparison of initiatives based on count of approvals and disapprovals. Greater numbers indicate a better result. This function is NOT injective.';
2878 ------------------------------------------------
2879 -- Locking for snapshots and voting procedure --
2880 ------------------------------------------------
2883 CREATE FUNCTION "share_row_lock_issue_trigger"()
2884 RETURNS TRIGGER
2885 LANGUAGE 'plpgsql' VOLATILE AS $$
2886 BEGIN
2887 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2888 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2889 END IF;
2890 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2891 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2892 RETURN NEW;
2893 ELSE
2894 RETURN OLD;
2895 END IF;
2896 END;
2897 $$;
2899 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2902 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2903 RETURNS TRIGGER
2904 LANGUAGE 'plpgsql' VOLATILE AS $$
2905 BEGIN
2906 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2907 PERFORM NULL FROM "issue"
2908 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2909 WHERE "initiative"."id" = OLD."initiative_id"
2910 FOR SHARE OF "issue";
2911 END IF;
2912 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2913 PERFORM NULL FROM "issue"
2914 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2915 WHERE "initiative"."id" = NEW."initiative_id"
2916 FOR SHARE OF "issue";
2917 RETURN NEW;
2918 ELSE
2919 RETURN OLD;
2920 END IF;
2921 END;
2922 $$;
2924 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2927 CREATE TRIGGER "share_row_lock_issue"
2928 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2929 FOR EACH ROW EXECUTE PROCEDURE
2930 "share_row_lock_issue_trigger"();
2932 CREATE TRIGGER "share_row_lock_issue"
2933 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2934 FOR EACH ROW EXECUTE PROCEDURE
2935 "share_row_lock_issue_trigger"();
2937 CREATE TRIGGER "share_row_lock_issue"
2938 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2939 FOR EACH ROW EXECUTE PROCEDURE
2940 "share_row_lock_issue_trigger"();
2942 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2943 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2944 FOR EACH ROW EXECUTE PROCEDURE
2945 "share_row_lock_issue_via_initiative_trigger"();
2947 CREATE TRIGGER "share_row_lock_issue"
2948 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2949 FOR EACH ROW EXECUTE PROCEDURE
2950 "share_row_lock_issue_trigger"();
2952 CREATE TRIGGER "share_row_lock_issue"
2953 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2954 FOR EACH ROW EXECUTE PROCEDURE
2955 "share_row_lock_issue_trigger"();
2957 CREATE TRIGGER "share_row_lock_issue"
2958 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2959 FOR EACH ROW EXECUTE PROCEDURE
2960 "share_row_lock_issue_trigger"();
2962 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2963 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2964 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2965 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2966 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2967 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2968 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2971 CREATE FUNCTION "lock_issue"
2972 ( "issue_id_p" "issue"."id"%TYPE )
2973 RETURNS VOID
2974 LANGUAGE 'plpgsql' VOLATILE AS $$
2975 BEGIN
2976 LOCK TABLE "member" IN SHARE MODE;
2977 LOCK TABLE "privilege" IN SHARE MODE;
2978 LOCK TABLE "membership" IN SHARE MODE;
2979 LOCK TABLE "policy" IN SHARE MODE;
2980 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2981 -- NOTE: The row-level exclusive lock in combination with the
2982 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2983 -- acquire a row-level share lock on the issue) ensure that no data
2984 -- is changed, which could affect calculation of snapshots or
2985 -- counting of votes. Table "delegation" must be table-level-locked,
2986 -- as it also contains issue- and global-scope delegations.
2987 LOCK TABLE "delegation" IN SHARE MODE;
2988 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2989 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2990 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2991 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2992 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2993 RETURN;
2994 END;
2995 $$;
2997 COMMENT ON FUNCTION "lock_issue"
2998 ( "issue"."id"%TYPE )
2999 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
3003 ------------------------------------------------------------------------
3004 -- Regular tasks, except calculcation of snapshots and voting results --
3005 ------------------------------------------------------------------------
3007 CREATE FUNCTION "check_activity"()
3008 RETURNS VOID
3009 LANGUAGE 'plpgsql' VOLATILE AS $$
3010 DECLARE
3011 "system_setting_row" "system_setting"%ROWTYPE;
3012 BEGIN
3013 SELECT * INTO "system_setting_row" FROM "system_setting";
3014 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
3015 IF "system_setting_row"."member_ttl" NOTNULL THEN
3016 UPDATE "member" SET "active" = FALSE
3017 WHERE "active" = TRUE
3018 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
3019 END IF;
3020 RETURN;
3021 END;
3022 $$;
3024 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
3027 CREATE FUNCTION "calculate_member_counts"()
3028 RETURNS VOID
3029 LANGUAGE 'plpgsql' VOLATILE AS $$
3030 BEGIN
3031 LOCK TABLE "member" IN SHARE MODE;
3032 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
3033 LOCK TABLE "unit" IN EXCLUSIVE MODE;
3034 LOCK TABLE "area" IN EXCLUSIVE MODE;
3035 LOCK TABLE "privilege" IN SHARE MODE;
3036 LOCK TABLE "membership" IN SHARE MODE;
3037 DELETE FROM "member_count";
3038 INSERT INTO "member_count" ("total_count")
3039 SELECT "total_count" FROM "member_count_view";
3040 UPDATE "unit" SET "member_count" = "view"."member_count"
3041 FROM "unit_member_count" AS "view"
3042 WHERE "view"."unit_id" = "unit"."id";
3043 UPDATE "area" SET
3044 "direct_member_count" = "view"."direct_member_count",
3045 "member_weight" = "view"."member_weight"
3046 FROM "area_member_count" AS "view"
3047 WHERE "view"."area_id" = "area"."id";
3048 RETURN;
3049 END;
3050 $$;
3052 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"';
3056 ------------------------------
3057 -- Calculation of snapshots --
3058 ------------------------------
3060 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3061 ( "issue_id_p" "issue"."id"%TYPE,
3062 "member_id_p" "member"."id"%TYPE,
3063 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3064 RETURNS "direct_population_snapshot"."weight"%TYPE
3065 LANGUAGE 'plpgsql' VOLATILE AS $$
3066 DECLARE
3067 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3068 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3069 "weight_v" INT4;
3070 "sub_weight_v" INT4;
3071 BEGIN
3072 "weight_v" := 0;
3073 FOR "issue_delegation_row" IN
3074 SELECT * FROM "issue_delegation"
3075 WHERE "trustee_id" = "member_id_p"
3076 AND "issue_id" = "issue_id_p"
3077 LOOP
3078 IF NOT EXISTS (
3079 SELECT NULL FROM "direct_population_snapshot"
3080 WHERE "issue_id" = "issue_id_p"
3081 AND "event" = 'periodic'
3082 AND "member_id" = "issue_delegation_row"."truster_id"
3083 ) AND NOT EXISTS (
3084 SELECT NULL FROM "delegating_population_snapshot"
3085 WHERE "issue_id" = "issue_id_p"
3086 AND "event" = 'periodic'
3087 AND "member_id" = "issue_delegation_row"."truster_id"
3088 ) THEN
3089 "delegate_member_ids_v" :=
3090 "member_id_p" || "delegate_member_ids_p";
3091 INSERT INTO "delegating_population_snapshot" (
3092 "issue_id",
3093 "event",
3094 "member_id",
3095 "scope",
3096 "delegate_member_ids"
3097 ) VALUES (
3098 "issue_id_p",
3099 'periodic',
3100 "issue_delegation_row"."truster_id",
3101 "issue_delegation_row"."scope",
3102 "delegate_member_ids_v"
3103 );
3104 "sub_weight_v" := 1 +
3105 "weight_of_added_delegations_for_population_snapshot"(
3106 "issue_id_p",
3107 "issue_delegation_row"."truster_id",
3108 "delegate_member_ids_v"
3109 );
3110 UPDATE "delegating_population_snapshot"
3111 SET "weight" = "sub_weight_v"
3112 WHERE "issue_id" = "issue_id_p"
3113 AND "event" = 'periodic'
3114 AND "member_id" = "issue_delegation_row"."truster_id";
3115 "weight_v" := "weight_v" + "sub_weight_v";
3116 END IF;
3117 END LOOP;
3118 RETURN "weight_v";
3119 END;
3120 $$;
3122 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3123 ( "issue"."id"%TYPE,
3124 "member"."id"%TYPE,
3125 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3126 IS 'Helper function for "create_population_snapshot" function';
3129 CREATE FUNCTION "create_population_snapshot"
3130 ( "issue_id_p" "issue"."id"%TYPE )
3131 RETURNS VOID
3132 LANGUAGE 'plpgsql' VOLATILE AS $$
3133 DECLARE
3134 "member_id_v" "member"."id"%TYPE;
3135 BEGIN
3136 DELETE FROM "direct_population_snapshot"
3137 WHERE "issue_id" = "issue_id_p"
3138 AND "event" = 'periodic';
3139 DELETE FROM "delegating_population_snapshot"
3140 WHERE "issue_id" = "issue_id_p"
3141 AND "event" = 'periodic';
3142 INSERT INTO "direct_population_snapshot"
3143 ("issue_id", "event", "member_id")
3144 SELECT
3145 "issue_id_p" AS "issue_id",
3146 'periodic'::"snapshot_event" AS "event",
3147 "member"."id" AS "member_id"
3148 FROM "issue"
3149 JOIN "area" ON "issue"."area_id" = "area"."id"
3150 JOIN "membership" ON "area"."id" = "membership"."area_id"
3151 JOIN "member" ON "membership"."member_id" = "member"."id"
3152 JOIN "privilege"
3153 ON "privilege"."unit_id" = "area"."unit_id"
3154 AND "privilege"."member_id" = "member"."id"
3155 WHERE "issue"."id" = "issue_id_p"
3156 AND "member"."active" AND "privilege"."voting_right"
3157 UNION
3158 SELECT
3159 "issue_id_p" AS "issue_id",
3160 'periodic'::"snapshot_event" AS "event",
3161 "member"."id" AS "member_id"
3162 FROM "issue"
3163 JOIN "area" ON "issue"."area_id" = "area"."id"
3164 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3165 JOIN "member" ON "interest"."member_id" = "member"."id"
3166 JOIN "privilege"
3167 ON "privilege"."unit_id" = "area"."unit_id"
3168 AND "privilege"."member_id" = "member"."id"
3169 WHERE "issue"."id" = "issue_id_p"
3170 AND "member"."active" AND "privilege"."voting_right";
3171 FOR "member_id_v" IN
3172 SELECT "member_id" FROM "direct_population_snapshot"
3173 WHERE "issue_id" = "issue_id_p"
3174 AND "event" = 'periodic'
3175 LOOP
3176 UPDATE "direct_population_snapshot" SET
3177 "weight" = 1 +
3178 "weight_of_added_delegations_for_population_snapshot"(
3179 "issue_id_p",
3180 "member_id_v",
3181 '{}'
3183 WHERE "issue_id" = "issue_id_p"
3184 AND "event" = 'periodic'
3185 AND "member_id" = "member_id_v";
3186 END LOOP;
3187 RETURN;
3188 END;
3189 $$;
3191 COMMENT ON FUNCTION "create_population_snapshot"
3192 ( "issue"."id"%TYPE )
3193 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.';
3196 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3197 ( "issue_id_p" "issue"."id"%TYPE,
3198 "member_id_p" "member"."id"%TYPE,
3199 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3200 RETURNS "direct_interest_snapshot"."weight"%TYPE
3201 LANGUAGE 'plpgsql' VOLATILE AS $$
3202 DECLARE
3203 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3204 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3205 "weight_v" INT4;
3206 "sub_weight_v" INT4;
3207 BEGIN
3208 "weight_v" := 0;
3209 FOR "issue_delegation_row" IN
3210 SELECT * FROM "issue_delegation"
3211 WHERE "trustee_id" = "member_id_p"
3212 AND "issue_id" = "issue_id_p"
3213 LOOP
3214 IF NOT EXISTS (
3215 SELECT NULL FROM "direct_interest_snapshot"
3216 WHERE "issue_id" = "issue_id_p"
3217 AND "event" = 'periodic'
3218 AND "member_id" = "issue_delegation_row"."truster_id"
3219 ) AND NOT EXISTS (
3220 SELECT NULL FROM "delegating_interest_snapshot"
3221 WHERE "issue_id" = "issue_id_p"
3222 AND "event" = 'periodic'
3223 AND "member_id" = "issue_delegation_row"."truster_id"
3224 ) THEN
3225 "delegate_member_ids_v" :=
3226 "member_id_p" || "delegate_member_ids_p";
3227 INSERT INTO "delegating_interest_snapshot" (
3228 "issue_id",
3229 "event",
3230 "member_id",
3231 "scope",
3232 "delegate_member_ids"
3233 ) VALUES (
3234 "issue_id_p",
3235 'periodic',
3236 "issue_delegation_row"."truster_id",
3237 "issue_delegation_row"."scope",
3238 "delegate_member_ids_v"
3239 );
3240 "sub_weight_v" := 1 +
3241 "weight_of_added_delegations_for_interest_snapshot"(
3242 "issue_id_p",
3243 "issue_delegation_row"."truster_id",
3244 "delegate_member_ids_v"
3245 );
3246 UPDATE "delegating_interest_snapshot"
3247 SET "weight" = "sub_weight_v"
3248 WHERE "issue_id" = "issue_id_p"
3249 AND "event" = 'periodic'
3250 AND "member_id" = "issue_delegation_row"."truster_id";
3251 "weight_v" := "weight_v" + "sub_weight_v";
3252 END IF;
3253 END LOOP;
3254 RETURN "weight_v";
3255 END;
3256 $$;
3258 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3259 ( "issue"."id"%TYPE,
3260 "member"."id"%TYPE,
3261 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3262 IS 'Helper function for "create_interest_snapshot" function';
3265 CREATE FUNCTION "create_interest_snapshot"
3266 ( "issue_id_p" "issue"."id"%TYPE )
3267 RETURNS VOID
3268 LANGUAGE 'plpgsql' VOLATILE AS $$
3269 DECLARE
3270 "member_id_v" "member"."id"%TYPE;
3271 BEGIN
3272 DELETE FROM "direct_interest_snapshot"
3273 WHERE "issue_id" = "issue_id_p"
3274 AND "event" = 'periodic';
3275 DELETE FROM "delegating_interest_snapshot"
3276 WHERE "issue_id" = "issue_id_p"
3277 AND "event" = 'periodic';
3278 DELETE FROM "direct_supporter_snapshot"
3279 WHERE "issue_id" = "issue_id_p"
3280 AND "event" = 'periodic';
3281 INSERT INTO "direct_interest_snapshot"
3282 ("issue_id", "event", "member_id")
3283 SELECT
3284 "issue_id_p" AS "issue_id",
3285 'periodic' AS "event",
3286 "member"."id" AS "member_id"
3287 FROM "issue"
3288 JOIN "area" ON "issue"."area_id" = "area"."id"
3289 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3290 JOIN "member" ON "interest"."member_id" = "member"."id"
3291 JOIN "privilege"
3292 ON "privilege"."unit_id" = "area"."unit_id"
3293 AND "privilege"."member_id" = "member"."id"
3294 WHERE "issue"."id" = "issue_id_p"
3295 AND "member"."active" AND "privilege"."voting_right";
3296 FOR "member_id_v" IN
3297 SELECT "member_id" FROM "direct_interest_snapshot"
3298 WHERE "issue_id" = "issue_id_p"
3299 AND "event" = 'periodic'
3300 LOOP
3301 UPDATE "direct_interest_snapshot" SET
3302 "weight" = 1 +
3303 "weight_of_added_delegations_for_interest_snapshot"(
3304 "issue_id_p",
3305 "member_id_v",
3306 '{}'
3308 WHERE "issue_id" = "issue_id_p"
3309 AND "event" = 'periodic'
3310 AND "member_id" = "member_id_v";
3311 END LOOP;
3312 INSERT INTO "direct_supporter_snapshot"
3313 ( "issue_id", "initiative_id", "event", "member_id",
3314 "draft_id", "informed", "satisfied" )
3315 SELECT
3316 "issue_id_p" AS "issue_id",
3317 "initiative"."id" AS "initiative_id",
3318 'periodic' AS "event",
3319 "supporter"."member_id" AS "member_id",
3320 "supporter"."draft_id" AS "draft_id",
3321 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3322 NOT EXISTS (
3323 SELECT NULL FROM "critical_opinion"
3324 WHERE "initiative_id" = "initiative"."id"
3325 AND "member_id" = "supporter"."member_id"
3326 ) AS "satisfied"
3327 FROM "initiative"
3328 JOIN "supporter"
3329 ON "supporter"."initiative_id" = "initiative"."id"
3330 JOIN "current_draft"
3331 ON "initiative"."id" = "current_draft"."initiative_id"
3332 JOIN "direct_interest_snapshot"
3333 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3334 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3335 AND "event" = 'periodic'
3336 WHERE "initiative"."issue_id" = "issue_id_p";
3337 RETURN;
3338 END;
3339 $$;
3341 COMMENT ON FUNCTION "create_interest_snapshot"
3342 ( "issue"."id"%TYPE )
3343 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.';
3346 CREATE FUNCTION "create_snapshot"
3347 ( "issue_id_p" "issue"."id"%TYPE )
3348 RETURNS VOID
3349 LANGUAGE 'plpgsql' VOLATILE AS $$
3350 DECLARE
3351 "initiative_id_v" "initiative"."id"%TYPE;
3352 "suggestion_id_v" "suggestion"."id"%TYPE;
3353 BEGIN
3354 PERFORM "lock_issue"("issue_id_p");
3355 PERFORM "create_population_snapshot"("issue_id_p");
3356 PERFORM "create_interest_snapshot"("issue_id_p");
3357 UPDATE "issue" SET
3358 "snapshot" = 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 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3551 RETURN;
3552 END;
3553 $$;
3555 COMMENT ON FUNCTION "set_snapshot_event"
3556 ( "issue"."id"%TYPE,
3557 "snapshot_event" )
3558 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3562 ---------------------
3563 -- Freezing issues --
3564 ---------------------
3566 CREATE FUNCTION "freeze_after_snapshot"
3567 ( "issue_id_p" "issue"."id"%TYPE )
3568 RETURNS VOID
3569 LANGUAGE 'plpgsql' VOLATILE AS $$
3570 DECLARE
3571 "issue_row" "issue"%ROWTYPE;
3572 "policy_row" "policy"%ROWTYPE;
3573 "initiative_row" "initiative"%ROWTYPE;
3574 BEGIN
3575 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3576 SELECT * INTO "policy_row"
3577 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3578 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3579 FOR "initiative_row" IN
3580 SELECT * FROM "initiative"
3581 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3582 LOOP
3583 IF
3584 "initiative_row"."polling" OR (
3585 "initiative_row"."satisfied_supporter_count" > 0 AND
3586 "initiative_row"."satisfied_supporter_count" *
3587 "policy_row"."initiative_quorum_den" >=
3588 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3590 THEN
3591 UPDATE "initiative" SET "admitted" = TRUE
3592 WHERE "id" = "initiative_row"."id";
3593 ELSE
3594 UPDATE "initiative" SET "admitted" = FALSE
3595 WHERE "id" = "initiative_row"."id";
3596 END IF;
3597 END LOOP;
3598 IF EXISTS (
3599 SELECT NULL FROM "initiative"
3600 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3601 ) THEN
3602 UPDATE "issue" SET
3603 "state" = 'voting',
3604 "accepted" = coalesce("accepted", now()),
3605 "half_frozen" = coalesce("half_frozen", now()),
3606 "fully_frozen" = now()
3607 WHERE "id" = "issue_id_p";
3608 ELSE
3609 UPDATE "issue" SET
3610 "state" = 'canceled_no_initiative_admitted',
3611 "accepted" = coalesce("accepted", now()),
3612 "half_frozen" = coalesce("half_frozen", now()),
3613 "fully_frozen" = now(),
3614 "closed" = now(),
3615 "ranks_available" = TRUE
3616 WHERE "id" = "issue_id_p";
3617 -- NOTE: The following DELETE statements have effect only when
3618 -- issue state has been manipulated
3619 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3620 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3621 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3622 END IF;
3623 RETURN;
3624 END;
3625 $$;
3627 COMMENT ON FUNCTION "freeze_after_snapshot"
3628 ( "issue"."id"%TYPE )
3629 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3632 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3633 RETURNS VOID
3634 LANGUAGE 'plpgsql' VOLATILE AS $$
3635 DECLARE
3636 "issue_row" "issue"%ROWTYPE;
3637 BEGIN
3638 PERFORM "create_snapshot"("issue_id_p");
3639 PERFORM "freeze_after_snapshot"("issue_id_p");
3640 RETURN;
3641 END;
3642 $$;
3644 COMMENT ON FUNCTION "manual_freeze"
3645 ( "issue"."id"%TYPE )
3646 IS 'Freeze an issue manually (fully) and start voting';
3650 -----------------------
3651 -- Counting of votes --
3652 -----------------------
3655 CREATE FUNCTION "weight_of_added_vote_delegations"
3656 ( "issue_id_p" "issue"."id"%TYPE,
3657 "member_id_p" "member"."id"%TYPE,
3658 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3659 RETURNS "direct_voter"."weight"%TYPE
3660 LANGUAGE 'plpgsql' VOLATILE AS $$
3661 DECLARE
3662 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3663 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3664 "weight_v" INT4;
3665 "sub_weight_v" INT4;
3666 BEGIN
3667 "weight_v" := 0;
3668 FOR "issue_delegation_row" IN
3669 SELECT * FROM "issue_delegation"
3670 WHERE "trustee_id" = "member_id_p"
3671 AND "issue_id" = "issue_id_p"
3672 LOOP
3673 IF NOT EXISTS (
3674 SELECT NULL FROM "direct_voter"
3675 WHERE "member_id" = "issue_delegation_row"."truster_id"
3676 AND "issue_id" = "issue_id_p"
3677 ) AND NOT EXISTS (
3678 SELECT NULL FROM "delegating_voter"
3679 WHERE "member_id" = "issue_delegation_row"."truster_id"
3680 AND "issue_id" = "issue_id_p"
3681 ) THEN
3682 "delegate_member_ids_v" :=
3683 "member_id_p" || "delegate_member_ids_p";
3684 INSERT INTO "delegating_voter" (
3685 "issue_id",
3686 "member_id",
3687 "scope",
3688 "delegate_member_ids"
3689 ) VALUES (
3690 "issue_id_p",
3691 "issue_delegation_row"."truster_id",
3692 "issue_delegation_row"."scope",
3693 "delegate_member_ids_v"
3694 );
3695 "sub_weight_v" := 1 +
3696 "weight_of_added_vote_delegations"(
3697 "issue_id_p",
3698 "issue_delegation_row"."truster_id",
3699 "delegate_member_ids_v"
3700 );
3701 UPDATE "delegating_voter"
3702 SET "weight" = "sub_weight_v"
3703 WHERE "issue_id" = "issue_id_p"
3704 AND "member_id" = "issue_delegation_row"."truster_id";
3705 "weight_v" := "weight_v" + "sub_weight_v";
3706 END IF;
3707 END LOOP;
3708 RETURN "weight_v";
3709 END;
3710 $$;
3712 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3713 ( "issue"."id"%TYPE,
3714 "member"."id"%TYPE,
3715 "delegating_voter"."delegate_member_ids"%TYPE )
3716 IS 'Helper function for "add_vote_delegations" function';
3719 CREATE FUNCTION "add_vote_delegations"
3720 ( "issue_id_p" "issue"."id"%TYPE )
3721 RETURNS VOID
3722 LANGUAGE 'plpgsql' VOLATILE AS $$
3723 DECLARE
3724 "member_id_v" "member"."id"%TYPE;
3725 BEGIN
3726 FOR "member_id_v" IN
3727 SELECT "member_id" FROM "direct_voter"
3728 WHERE "issue_id" = "issue_id_p"
3729 LOOP
3730 UPDATE "direct_voter" SET
3731 "weight" = "weight" + "weight_of_added_vote_delegations"(
3732 "issue_id_p",
3733 "member_id_v",
3734 '{}'
3736 WHERE "member_id" = "member_id_v"
3737 AND "issue_id" = "issue_id_p";
3738 END LOOP;
3739 RETURN;
3740 END;
3741 $$;
3743 COMMENT ON FUNCTION "add_vote_delegations"
3744 ( "issue_id_p" "issue"."id"%TYPE )
3745 IS 'Helper function for "close_voting" function';
3748 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3749 RETURNS VOID
3750 LANGUAGE 'plpgsql' VOLATILE AS $$
3751 DECLARE
3752 "area_id_v" "area"."id"%TYPE;
3753 "unit_id_v" "unit"."id"%TYPE;
3754 "member_id_v" "member"."id"%TYPE;
3755 BEGIN
3756 PERFORM "lock_issue"("issue_id_p");
3757 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3758 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3759 -- delete timestamp of voting comment:
3760 UPDATE "direct_voter" SET "comment_changed" = NULL
3761 WHERE "issue_id" = "issue_id_p";
3762 -- delete delegating votes (in cases of manual reset of issue state):
3763 DELETE FROM "delegating_voter"
3764 WHERE "issue_id" = "issue_id_p";
3765 -- delete votes from non-privileged voters:
3766 DELETE FROM "direct_voter"
3767 USING (
3768 SELECT
3769 "direct_voter"."member_id"
3770 FROM "direct_voter"
3771 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3772 LEFT JOIN "privilege"
3773 ON "privilege"."unit_id" = "unit_id_v"
3774 AND "privilege"."member_id" = "direct_voter"."member_id"
3775 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3776 "member"."active" = FALSE OR
3777 "privilege"."voting_right" ISNULL OR
3778 "privilege"."voting_right" = FALSE
3780 ) AS "subquery"
3781 WHERE "direct_voter"."issue_id" = "issue_id_p"
3782 AND "direct_voter"."member_id" = "subquery"."member_id";
3783 -- consider delegations:
3784 UPDATE "direct_voter" SET "weight" = 1
3785 WHERE "issue_id" = "issue_id_p";
3786 PERFORM "add_vote_delegations"("issue_id_p");
3787 -- set voter count and mark issue as being calculated:
3788 UPDATE "issue" SET
3789 "state" = 'calculation',
3790 "closed" = now(),
3791 "voter_count" = (
3792 SELECT coalesce(sum("weight"), 0)
3793 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3795 WHERE "id" = "issue_id_p";
3796 -- materialize battle_view:
3797 -- NOTE: "closed" column of issue must be set at this point
3798 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3799 INSERT INTO "battle" (
3800 "issue_id",
3801 "winning_initiative_id", "losing_initiative_id",
3802 "count"
3803 ) SELECT
3804 "issue_id",
3805 "winning_initiative_id", "losing_initiative_id",
3806 "count"
3807 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3808 -- copy "positive_votes" and "negative_votes" from "battle" table:
3809 UPDATE "initiative" SET
3810 "positive_votes" = "battle_win"."count",
3811 "negative_votes" = "battle_lose"."count"
3812 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3813 WHERE
3814 "battle_win"."issue_id" = "issue_id_p" AND
3815 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3816 "battle_win"."losing_initiative_id" ISNULL AND
3817 "battle_lose"."issue_id" = "issue_id_p" AND
3818 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3819 "battle_lose"."winning_initiative_id" ISNULL;
3820 END;
3821 $$;
3823 COMMENT ON FUNCTION "close_voting"
3824 ( "issue"."id"%TYPE )
3825 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.';
3828 CREATE FUNCTION "defeat_strength"
3829 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3830 RETURNS INT8
3831 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3832 BEGIN
3833 IF "positive_votes_p" > "negative_votes_p" THEN
3834 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3835 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3836 RETURN 0;
3837 ELSE
3838 RETURN -1;
3839 END IF;
3840 END;
3841 $$;
3843 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';
3846 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3847 RETURNS VOID
3848 LANGUAGE 'plpgsql' VOLATILE AS $$
3849 DECLARE
3850 "issue_row" "issue"%ROWTYPE;
3851 "policy_row" "policy"%ROWTYPE;
3852 "dimension_v" INTEGER;
3853 "vote_matrix" INT4[][]; -- absolute votes
3854 "matrix" INT8[][]; -- defeat strength / best paths
3855 "i" INTEGER;
3856 "j" INTEGER;
3857 "k" INTEGER;
3858 "battle_row" "battle"%ROWTYPE;
3859 "rank_ary" INT4[];
3860 "rank_v" INT4;
3861 "done_v" INTEGER;
3862 "winners_ary" INTEGER[];
3863 "initiative_id_v" "initiative"."id"%TYPE;
3864 BEGIN
3865 SELECT * INTO "issue_row"
3866 FROM "issue" WHERE "id" = "issue_id_p"
3867 FOR UPDATE;
3868 SELECT * INTO "policy_row"
3869 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3870 SELECT count(1) INTO "dimension_v"
3871 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3872 -- Create "vote_matrix" with absolute number of votes in pairwise
3873 -- comparison:
3874 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3875 "i" := 1;
3876 "j" := 2;
3877 FOR "battle_row" IN
3878 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3879 ORDER BY
3880 "winning_initiative_id" NULLS LAST,
3881 "losing_initiative_id" NULLS LAST
3882 LOOP
3883 "vote_matrix"["i"]["j"] := "battle_row"."count";
3884 IF "j" = "dimension_v" THEN
3885 "i" := "i" + 1;
3886 "j" := 1;
3887 ELSE
3888 "j" := "j" + 1;
3889 IF "j" = "i" THEN
3890 "j" := "j" + 1;
3891 END IF;
3892 END IF;
3893 END LOOP;
3894 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3895 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3896 END IF;
3897 -- Store defeat strengths in "matrix" using "defeat_strength"
3898 -- function:
3899 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3900 "i" := 1;
3901 LOOP
3902 "j" := 1;
3903 LOOP
3904 IF "i" != "j" THEN
3905 "matrix"["i"]["j"] := "defeat_strength"(
3906 "vote_matrix"["i"]["j"],
3907 "vote_matrix"["j"]["i"]
3908 );
3909 END IF;
3910 EXIT WHEN "j" = "dimension_v";
3911 "j" := "j" + 1;
3912 END LOOP;
3913 EXIT WHEN "i" = "dimension_v";
3914 "i" := "i" + 1;
3915 END LOOP;
3916 -- Find best paths:
3917 "i" := 1;
3918 LOOP
3919 "j" := 1;
3920 LOOP
3921 IF "i" != "j" THEN
3922 "k" := 1;
3923 LOOP
3924 IF "i" != "k" AND "j" != "k" THEN
3925 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3926 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3927 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3928 END IF;
3929 ELSE
3930 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3931 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3932 END IF;
3933 END IF;
3934 END IF;
3935 EXIT WHEN "k" = "dimension_v";
3936 "k" := "k" + 1;
3937 END LOOP;
3938 END IF;
3939 EXIT WHEN "j" = "dimension_v";
3940 "j" := "j" + 1;
3941 END LOOP;
3942 EXIT WHEN "i" = "dimension_v";
3943 "i" := "i" + 1;
3944 END LOOP;
3945 -- Determine order of winners:
3946 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3947 "rank_v" := 1;
3948 "done_v" := 0;
3949 LOOP
3950 "winners_ary" := '{}';
3951 "i" := 1;
3952 LOOP
3953 IF "rank_ary"["i"] ISNULL THEN
3954 "j" := 1;
3955 LOOP
3956 IF
3957 "i" != "j" AND
3958 "rank_ary"["j"] ISNULL AND
3959 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3960 THEN
3961 -- someone else is better
3962 EXIT;
3963 END IF;
3964 IF "j" = "dimension_v" THEN
3965 -- noone is better
3966 "winners_ary" := "winners_ary" || "i";
3967 EXIT;
3968 END IF;
3969 "j" := "j" + 1;
3970 END LOOP;
3971 END IF;
3972 EXIT WHEN "i" = "dimension_v";
3973 "i" := "i" + 1;
3974 END LOOP;
3975 "i" := 1;
3976 LOOP
3977 "rank_ary"["winners_ary"["i"]] := "rank_v";
3978 "done_v" := "done_v" + 1;
3979 EXIT WHEN "i" = array_upper("winners_ary", 1);
3980 "i" := "i" + 1;
3981 END LOOP;
3982 EXIT WHEN "done_v" = "dimension_v";
3983 "rank_v" := "rank_v" + 1;
3984 END LOOP;
3985 -- write preliminary results:
3986 "i" := 1;
3987 FOR "initiative_id_v" IN
3988 SELECT "id" FROM "initiative"
3989 WHERE "issue_id" = "issue_id_p" AND "admitted"
3990 ORDER BY "id"
3991 LOOP
3992 UPDATE "initiative" SET
3993 "direct_majority" =
3994 CASE WHEN "policy_row"."direct_majority_strict" THEN
3995 "positive_votes" * "policy_row"."direct_majority_den" >
3996 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3997 ELSE
3998 "positive_votes" * "policy_row"."direct_majority_den" >=
3999 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4000 END
4001 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4002 AND "issue_row"."voter_count"-"negative_votes" >=
4003 "policy_row"."direct_majority_non_negative",
4004 "indirect_majority" =
4005 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4006 "positive_votes" * "policy_row"."indirect_majority_den" >
4007 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4008 ELSE
4009 "positive_votes" * "policy_row"."indirect_majority_den" >=
4010 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4011 END
4012 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4013 AND "issue_row"."voter_count"-"negative_votes" >=
4014 "policy_row"."indirect_majority_non_negative",
4015 "schulze_rank" = "rank_ary"["i"],
4016 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
4017 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
4018 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
4019 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
4020 "eligible" = FALSE,
4021 "winner" = FALSE,
4022 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4023 WHERE "id" = "initiative_id_v";
4024 "i" := "i" + 1;
4025 END LOOP;
4026 IF "i" != "dimension_v" THEN
4027 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4028 END IF;
4029 -- take indirect majorities into account:
4030 LOOP
4031 UPDATE "initiative" SET "indirect_majority" = TRUE
4032 FROM (
4033 SELECT "new_initiative"."id" AS "initiative_id"
4034 FROM "initiative" "old_initiative"
4035 JOIN "initiative" "new_initiative"
4036 ON "new_initiative"."issue_id" = "issue_id_p"
4037 AND "new_initiative"."indirect_majority" = FALSE
4038 JOIN "battle" "battle_win"
4039 ON "battle_win"."issue_id" = "issue_id_p"
4040 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4041 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4042 JOIN "battle" "battle_lose"
4043 ON "battle_lose"."issue_id" = "issue_id_p"
4044 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4045 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4046 WHERE "old_initiative"."issue_id" = "issue_id_p"
4047 AND "old_initiative"."indirect_majority" = TRUE
4048 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4049 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4050 "policy_row"."indirect_majority_num" *
4051 ("battle_win"."count"+"battle_lose"."count")
4052 ELSE
4053 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4054 "policy_row"."indirect_majority_num" *
4055 ("battle_win"."count"+"battle_lose"."count")
4056 END
4057 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4058 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4059 "policy_row"."indirect_majority_non_negative"
4060 ) AS "subquery"
4061 WHERE "id" = "subquery"."initiative_id";
4062 EXIT WHEN NOT FOUND;
4063 END LOOP;
4064 -- set "multistage_majority" for remaining matching initiatives:
4065 UPDATE "initiative" SET "multistage_majority" = TRUE
4066 FROM (
4067 SELECT "losing_initiative"."id" AS "initiative_id"
4068 FROM "initiative" "losing_initiative"
4069 JOIN "initiative" "winning_initiative"
4070 ON "winning_initiative"."issue_id" = "issue_id_p"
4071 AND "winning_initiative"."admitted"
4072 JOIN "battle" "battle_win"
4073 ON "battle_win"."issue_id" = "issue_id_p"
4074 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4075 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4076 JOIN "battle" "battle_lose"
4077 ON "battle_lose"."issue_id" = "issue_id_p"
4078 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4079 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4080 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4081 AND "losing_initiative"."admitted"
4082 AND "winning_initiative"."schulze_rank" <
4083 "losing_initiative"."schulze_rank"
4084 AND "battle_win"."count" > "battle_lose"."count"
4085 AND (
4086 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4087 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4088 ) AS "subquery"
4089 WHERE "id" = "subquery"."initiative_id";
4090 -- mark eligible initiatives:
4091 UPDATE "initiative" SET "eligible" = TRUE
4092 WHERE "issue_id" = "issue_id_p"
4093 AND "initiative"."direct_majority"
4094 AND "initiative"."indirect_majority"
4095 AND "initiative"."better_than_status_quo"
4096 AND (
4097 "policy_row"."no_multistage_majority" = FALSE OR
4098 "initiative"."multistage_majority" = FALSE )
4099 AND (
4100 "policy_row"."no_reverse_beat_path" = FALSE OR
4101 "initiative"."reverse_beat_path" = FALSE );
4102 -- mark final winner:
4103 UPDATE "initiative" SET "winner" = TRUE
4104 FROM (
4105 SELECT "id" AS "initiative_id"
4106 FROM "initiative"
4107 WHERE "issue_id" = "issue_id_p" AND "eligible"
4108 ORDER BY
4109 "schulze_rank",
4110 "vote_ratio"("positive_votes", "negative_votes"),
4111 "id"
4112 LIMIT 1
4113 ) AS "subquery"
4114 WHERE "id" = "subquery"."initiative_id";
4115 -- write (final) ranks:
4116 "rank_v" := 1;
4117 FOR "initiative_id_v" IN
4118 SELECT "id"
4119 FROM "initiative"
4120 WHERE "issue_id" = "issue_id_p" AND "admitted"
4121 ORDER BY
4122 "winner" DESC,
4123 "eligible" DESC,
4124 "schulze_rank",
4125 "vote_ratio"("positive_votes", "negative_votes"),
4126 "id"
4127 LOOP
4128 UPDATE "initiative" SET "rank" = "rank_v"
4129 WHERE "id" = "initiative_id_v";
4130 "rank_v" := "rank_v" + 1;
4131 END LOOP;
4132 -- set schulze rank of status quo and mark issue as finished:
4133 UPDATE "issue" SET
4134 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4135 "state" =
4136 CASE WHEN EXISTS (
4137 SELECT NULL FROM "initiative"
4138 WHERE "issue_id" = "issue_id_p" AND "winner"
4139 ) THEN
4140 'finished_with_winner'::"issue_state"
4141 ELSE
4142 'finished_without_winner'::"issue_state"
4143 END,
4144 "ranks_available" = TRUE
4145 WHERE "id" = "issue_id_p";
4146 RETURN;
4147 END;
4148 $$;
4150 COMMENT ON FUNCTION "calculate_ranks"
4151 ( "issue"."id"%TYPE )
4152 IS 'Determine ranking (Votes have to be counted first)';
4156 -----------------------------
4157 -- Automatic state changes --
4158 -----------------------------
4161 CREATE FUNCTION "check_issue"
4162 ( "issue_id_p" "issue"."id"%TYPE )
4163 RETURNS VOID
4164 LANGUAGE 'plpgsql' VOLATILE AS $$
4165 DECLARE
4166 "issue_row" "issue"%ROWTYPE;
4167 "policy_row" "policy"%ROWTYPE;
4168 BEGIN
4169 PERFORM "lock_issue"("issue_id_p");
4170 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4171 -- only process open issues:
4172 IF "issue_row"."closed" ISNULL THEN
4173 SELECT * INTO "policy_row" FROM "policy"
4174 WHERE "id" = "issue_row"."policy_id";
4175 -- create a snapshot, unless issue is already fully frozen:
4176 IF "issue_row"."fully_frozen" ISNULL THEN
4177 PERFORM "create_snapshot"("issue_id_p");
4178 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4179 END IF;
4180 -- eventually close or accept issues, which have not been accepted:
4181 IF "issue_row"."accepted" ISNULL THEN
4182 IF EXISTS (
4183 SELECT NULL FROM "initiative"
4184 WHERE "issue_id" = "issue_id_p"
4185 AND "supporter_count" > 0
4186 AND "supporter_count" * "policy_row"."issue_quorum_den"
4187 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4188 ) THEN
4189 -- accept issues, if supporter count is high enough
4190 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4191 -- NOTE: "issue_row" used later
4192 "issue_row"."state" := 'discussion';
4193 "issue_row"."accepted" := now();
4194 UPDATE "issue" SET
4195 "state" = "issue_row"."state",
4196 "accepted" = "issue_row"."accepted"
4197 WHERE "id" = "issue_row"."id";
4198 ELSIF
4199 now() >= "issue_row"."created" + "issue_row"."admission_time"
4200 THEN
4201 -- close issues, if admission time has expired
4202 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4203 UPDATE "issue" SET
4204 "state" = 'canceled_issue_not_accepted',
4205 "closed" = now()
4206 WHERE "id" = "issue_row"."id";
4207 END IF;
4208 END IF;
4209 -- eventually half freeze issues:
4210 IF
4211 -- NOTE: issue can't be closed at this point, if it has been accepted
4212 "issue_row"."accepted" NOTNULL AND
4213 "issue_row"."half_frozen" ISNULL
4214 THEN
4215 IF
4216 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4217 THEN
4218 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4219 -- NOTE: "issue_row" used later
4220 "issue_row"."state" := 'verification';
4221 "issue_row"."half_frozen" := now();
4222 UPDATE "issue" SET
4223 "state" = "issue_row"."state",
4224 "half_frozen" = "issue_row"."half_frozen"
4225 WHERE "id" = "issue_row"."id";
4226 END IF;
4227 END IF;
4228 -- close issues after some time, if all initiatives have been revoked:
4229 IF
4230 "issue_row"."closed" ISNULL AND
4231 NOT EXISTS (
4232 -- all initiatives are revoked
4233 SELECT NULL FROM "initiative"
4234 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4235 ) AND (
4236 -- and issue has not been accepted yet
4237 "issue_row"."accepted" ISNULL OR
4238 NOT EXISTS (
4239 -- or no initiatives have been revoked lately
4240 SELECT NULL FROM "initiative"
4241 WHERE "issue_id" = "issue_id_p"
4242 AND now() < "revoked" + "issue_row"."verification_time"
4243 ) OR (
4244 -- or verification time has elapsed
4245 "issue_row"."half_frozen" NOTNULL AND
4246 "issue_row"."fully_frozen" ISNULL AND
4247 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4250 THEN
4251 -- NOTE: "issue_row" used later
4252 IF "issue_row"."accepted" ISNULL THEN
4253 "issue_row"."state" := 'canceled_revoked_before_accepted';
4254 ELSIF "issue_row"."half_frozen" ISNULL THEN
4255 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4256 ELSE
4257 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4258 END IF;
4259 "issue_row"."closed" := now();
4260 UPDATE "issue" SET
4261 "state" = "issue_row"."state",
4262 "closed" = "issue_row"."closed"
4263 WHERE "id" = "issue_row"."id";
4264 END IF;
4265 -- fully freeze issue after verification time:
4266 IF
4267 "issue_row"."half_frozen" NOTNULL AND
4268 "issue_row"."fully_frozen" ISNULL AND
4269 "issue_row"."closed" ISNULL AND
4270 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4271 THEN
4272 PERFORM "freeze_after_snapshot"("issue_id_p");
4273 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4274 END IF;
4275 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4276 -- close issue by calling close_voting(...) after voting time:
4277 IF
4278 "issue_row"."closed" ISNULL AND
4279 "issue_row"."fully_frozen" NOTNULL AND
4280 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4281 THEN
4282 PERFORM "close_voting"("issue_id_p");
4283 -- calculate ranks will not consume much time and can be done now
4284 PERFORM "calculate_ranks"("issue_id_p");
4285 END IF;
4286 END IF;
4287 RETURN;
4288 END;
4289 $$;
4291 COMMENT ON FUNCTION "check_issue"
4292 ( "issue"."id"%TYPE )
4293 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.';
4296 CREATE FUNCTION "check_everything"()
4297 RETURNS VOID
4298 LANGUAGE 'plpgsql' VOLATILE AS $$
4299 DECLARE
4300 "issue_id_v" "issue"."id"%TYPE;
4301 BEGIN
4302 DELETE FROM "expired_session";
4303 PERFORM "check_activity"();
4304 PERFORM "calculate_member_counts"();
4305 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4306 PERFORM "check_issue"("issue_id_v");
4307 END LOOP;
4308 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4309 PERFORM "calculate_ranks"("issue_id_v");
4310 END LOOP;
4311 RETURN;
4312 END;
4313 $$;
4315 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.';
4319 ----------------------
4320 -- Deletion of data --
4321 ----------------------
4324 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4325 RETURNS VOID
4326 LANGUAGE 'plpgsql' VOLATILE AS $$
4327 DECLARE
4328 "issue_row" "issue"%ROWTYPE;
4329 BEGIN
4330 SELECT * INTO "issue_row"
4331 FROM "issue" WHERE "id" = "issue_id_p"
4332 FOR UPDATE;
4333 IF "issue_row"."cleaned" ISNULL THEN
4334 UPDATE "issue" SET
4335 "state" = 'voting',
4336 "closed" = NULL,
4337 "ranks_available" = FALSE
4338 WHERE "id" = "issue_id_p";
4339 DELETE FROM "delegating_voter"
4340 WHERE "issue_id" = "issue_id_p";
4341 DELETE FROM "direct_voter"
4342 WHERE "issue_id" = "issue_id_p";
4343 DELETE FROM "delegating_interest_snapshot"
4344 WHERE "issue_id" = "issue_id_p";
4345 DELETE FROM "direct_interest_snapshot"
4346 WHERE "issue_id" = "issue_id_p";
4347 DELETE FROM "delegating_population_snapshot"
4348 WHERE "issue_id" = "issue_id_p";
4349 DELETE FROM "direct_population_snapshot"
4350 WHERE "issue_id" = "issue_id_p";
4351 DELETE FROM "non_voter"
4352 WHERE "issue_id" = "issue_id_p";
4353 DELETE FROM "delegation"
4354 WHERE "issue_id" = "issue_id_p";
4355 DELETE FROM "supporter"
4356 WHERE "issue_id" = "issue_id_p";
4357 UPDATE "issue" SET
4358 "state" = "issue_row"."state",
4359 "closed" = "issue_row"."closed",
4360 "ranks_available" = "issue_row"."ranks_available",
4361 "cleaned" = now()
4362 WHERE "id" = "issue_id_p";
4363 END IF;
4364 RETURN;
4365 END;
4366 $$;
4368 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4371 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4372 RETURNS VOID
4373 LANGUAGE 'plpgsql' VOLATILE AS $$
4374 BEGIN
4375 UPDATE "member" SET
4376 "last_login" = NULL,
4377 "login" = NULL,
4378 "password" = NULL,
4379 "locked" = TRUE,
4380 "active" = FALSE,
4381 "notify_email" = NULL,
4382 "notify_email_unconfirmed" = NULL,
4383 "notify_email_secret" = NULL,
4384 "notify_email_secret_expiry" = NULL,
4385 "notify_email_lock_expiry" = NULL,
4386 "password_reset_secret" = NULL,
4387 "password_reset_secret_expiry" = NULL,
4388 "organizational_unit" = NULL,
4389 "internal_posts" = NULL,
4390 "realname" = NULL,
4391 "birthday" = NULL,
4392 "address" = NULL,
4393 "email" = NULL,
4394 "xmpp_address" = NULL,
4395 "website" = NULL,
4396 "phone" = NULL,
4397 "mobile_phone" = NULL,
4398 "profession" = NULL,
4399 "external_memberships" = NULL,
4400 "external_posts" = NULL,
4401 "statement" = NULL
4402 WHERE "id" = "member_id_p";
4403 -- "text_search_data" is updated by triggers
4404 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4405 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4406 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4407 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4408 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4409 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4410 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4411 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4412 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4413 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4414 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4415 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4416 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4417 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4418 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4419 DELETE FROM "direct_voter" USING "issue"
4420 WHERE "direct_voter"."issue_id" = "issue"."id"
4421 AND "issue"."closed" ISNULL
4422 AND "member_id" = "member_id_p";
4423 RETURN;
4424 END;
4425 $$;
4427 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)';
4430 CREATE FUNCTION "delete_private_data"()
4431 RETURNS VOID
4432 LANGUAGE 'plpgsql' VOLATILE AS $$
4433 BEGIN
4434 DELETE FROM "member" WHERE "activated" ISNULL;
4435 UPDATE "member" SET
4436 "invite_code" = NULL,
4437 "invite_code_expiry" = NULL,
4438 "admin_comment" = NULL,
4439 "last_login" = NULL,
4440 "login" = NULL,
4441 "password" = NULL,
4442 "lang" = NULL,
4443 "notify_email" = NULL,
4444 "notify_email_unconfirmed" = NULL,
4445 "notify_email_secret" = NULL,
4446 "notify_email_secret_expiry" = NULL,
4447 "notify_email_lock_expiry" = NULL,
4448 "notify_level" = NULL,
4449 "password_reset_secret" = NULL,
4450 "password_reset_secret_expiry" = NULL,
4451 "organizational_unit" = NULL,
4452 "internal_posts" = NULL,
4453 "realname" = NULL,
4454 "birthday" = NULL,
4455 "address" = NULL,
4456 "email" = NULL,
4457 "xmpp_address" = NULL,
4458 "website" = NULL,
4459 "phone" = NULL,
4460 "mobile_phone" = NULL,
4461 "profession" = NULL,
4462 "external_memberships" = NULL,
4463 "external_posts" = NULL,
4464 "formatting_engine" = NULL,
4465 "statement" = NULL;
4466 -- "text_search_data" is updated by triggers
4467 DELETE FROM "setting";
4468 DELETE FROM "setting_map";
4469 DELETE FROM "member_relation_setting";
4470 DELETE FROM "member_image";
4471 DELETE FROM "contact";
4472 DELETE FROM "ignored_member";
4473 DELETE FROM "session";
4474 DELETE FROM "area_setting";
4475 DELETE FROM "issue_setting";
4476 DELETE FROM "ignored_initiative";
4477 DELETE FROM "initiative_setting";
4478 DELETE FROM "suggestion_setting";
4479 DELETE FROM "non_voter";
4480 DELETE FROM "direct_voter" USING "issue"
4481 WHERE "direct_voter"."issue_id" = "issue"."id"
4482 AND "issue"."closed" ISNULL;
4483 RETURN;
4484 END;
4485 $$;
4487 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.';
4491 COMMIT;

Impressum / About Us