liquid_feedback_core

view core.sql @ 311:4dd3339453b8

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

Impressum / About Us