liquid_feedback_core

view core.sql @ 303:585c1cf4a3c9

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

Impressum / About Us