liquid_feedback_core

view core.sql @ 328:16803f8dfcf0

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

Impressum / About Us