liquid_feedback_core

view core.sql @ 337:c8289a674ef2

Removed deprecated timeline views
author jbe
date Wed Feb 20 23:58:09 2013 +0100 (2013-02-20)
parents a7537038640d
children 705c29b0ed44
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 closed --
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_OP = 'DELETE' THEN
1585 "issue_id_v" := OLD."issue_id";
1586 ELSE
1587 "issue_id_v" := NEW."issue_id";
1588 END IF;
1589 SELECT INTO "issue_row" * FROM "issue"
1590 WHERE "id" = "issue_id_v" FOR SHARE;
1591 IF "issue_row"."closed" NOTNULL THEN
1592 IF
1593 TG_RELID = 'direct_voter'::regclass AND
1594 TG_OP = 'UPDATE'
1595 THEN
1596 IF
1597 OLD."issue_id" = NEW."issue_id" AND
1598 OLD."member_id" = NEW."member_id" AND
1599 OLD."weight" = NEW."weight"
1600 THEN
1601 RETURN NULL; -- allows changing of voter comment
1602 END IF;
1603 END IF;
1604 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1605 ELSIF
1606 "issue_row"."state" = 'voting' AND
1607 "issue_row"."phase_finished" NOTNULL
1608 THEN
1609 IF TG_RELID = 'vote'::regclass THEN
1610 RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
1611 END IF;
1612 END IF;
1613 RETURN NULL;
1614 END;
1615 $$;
1617 CREATE TRIGGER "forbid_changes_on_closed_issue"
1618 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1619 FOR EACH ROW EXECUTE PROCEDURE
1620 "forbid_changes_on_closed_issue_trigger"();
1622 CREATE TRIGGER "forbid_changes_on_closed_issue"
1623 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1624 FOR EACH ROW EXECUTE PROCEDURE
1625 "forbid_changes_on_closed_issue_trigger"();
1627 CREATE TRIGGER "forbid_changes_on_closed_issue"
1628 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1629 FOR EACH ROW EXECUTE PROCEDURE
1630 "forbid_changes_on_closed_issue_trigger"();
1632 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"';
1633 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';
1634 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';
1635 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';
1639 --------------------------------------------------------------------
1640 -- Auto-retrieval of fields only needed for referential integrity --
1641 --------------------------------------------------------------------
1644 CREATE FUNCTION "autofill_issue_id_trigger"()
1645 RETURNS TRIGGER
1646 LANGUAGE 'plpgsql' VOLATILE AS $$
1647 BEGIN
1648 IF NEW."issue_id" ISNULL THEN
1649 SELECT "issue_id" INTO NEW."issue_id"
1650 FROM "initiative" WHERE "id" = NEW."initiative_id";
1651 END IF;
1652 RETURN NEW;
1653 END;
1654 $$;
1656 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1657 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1659 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1660 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1662 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1663 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1664 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1667 CREATE FUNCTION "autofill_initiative_id_trigger"()
1668 RETURNS TRIGGER
1669 LANGUAGE 'plpgsql' VOLATILE AS $$
1670 BEGIN
1671 IF NEW."initiative_id" ISNULL THEN
1672 SELECT "initiative_id" INTO NEW."initiative_id"
1673 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1674 END IF;
1675 RETURN NEW;
1676 END;
1677 $$;
1679 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1680 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1682 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1683 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1687 -----------------------------------------------------
1688 -- Automatic calculation of certain default values --
1689 -----------------------------------------------------
1692 CREATE FUNCTION "copy_timings_trigger"()
1693 RETURNS TRIGGER
1694 LANGUAGE 'plpgsql' VOLATILE AS $$
1695 DECLARE
1696 "policy_row" "policy"%ROWTYPE;
1697 BEGIN
1698 SELECT * INTO "policy_row" FROM "policy"
1699 WHERE "id" = NEW."policy_id";
1700 IF NEW."admission_time" ISNULL THEN
1701 NEW."admission_time" := "policy_row"."admission_time";
1702 END IF;
1703 IF NEW."discussion_time" ISNULL THEN
1704 NEW."discussion_time" := "policy_row"."discussion_time";
1705 END IF;
1706 IF NEW."verification_time" ISNULL THEN
1707 NEW."verification_time" := "policy_row"."verification_time";
1708 END IF;
1709 IF NEW."voting_time" ISNULL THEN
1710 NEW."voting_time" := "policy_row"."voting_time";
1711 END IF;
1712 RETURN NEW;
1713 END;
1714 $$;
1716 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1717 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1719 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1720 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1723 CREATE FUNCTION "default_for_draft_id_trigger"()
1724 RETURNS TRIGGER
1725 LANGUAGE 'plpgsql' VOLATILE AS $$
1726 BEGIN
1727 IF NEW."draft_id" ISNULL THEN
1728 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1729 WHERE "initiative_id" = NEW."initiative_id";
1730 END IF;
1731 RETURN NEW;
1732 END;
1733 $$;
1735 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1736 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1737 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1738 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1740 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1741 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';
1742 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';
1746 ----------------------------------------
1747 -- Automatic creation of dependencies --
1748 ----------------------------------------
1751 CREATE FUNCTION "autocreate_interest_trigger"()
1752 RETURNS TRIGGER
1753 LANGUAGE 'plpgsql' VOLATILE AS $$
1754 BEGIN
1755 IF NOT EXISTS (
1756 SELECT NULL FROM "initiative" JOIN "interest"
1757 ON "initiative"."issue_id" = "interest"."issue_id"
1758 WHERE "initiative"."id" = NEW."initiative_id"
1759 AND "interest"."member_id" = NEW."member_id"
1760 ) THEN
1761 BEGIN
1762 INSERT INTO "interest" ("issue_id", "member_id")
1763 SELECT "issue_id", NEW."member_id"
1764 FROM "initiative" WHERE "id" = NEW."initiative_id";
1765 EXCEPTION WHEN unique_violation THEN END;
1766 END IF;
1767 RETURN NEW;
1768 END;
1769 $$;
1771 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1772 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1774 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1775 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';
1778 CREATE FUNCTION "autocreate_supporter_trigger"()
1779 RETURNS TRIGGER
1780 LANGUAGE 'plpgsql' VOLATILE AS $$
1781 BEGIN
1782 IF NOT EXISTS (
1783 SELECT NULL FROM "suggestion" JOIN "supporter"
1784 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1785 WHERE "suggestion"."id" = NEW."suggestion_id"
1786 AND "supporter"."member_id" = NEW."member_id"
1787 ) THEN
1788 BEGIN
1789 INSERT INTO "supporter" ("initiative_id", "member_id")
1790 SELECT "initiative_id", NEW."member_id"
1791 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1792 EXCEPTION WHEN unique_violation THEN END;
1793 END IF;
1794 RETURN NEW;
1795 END;
1796 $$;
1798 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1799 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1801 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1802 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.';
1806 ------------------------------------------
1807 -- Views and helper functions for views --
1808 ------------------------------------------
1811 CREATE VIEW "unit_delegation" AS
1812 SELECT
1813 "unit"."id" AS "unit_id",
1814 "delegation"."id",
1815 "delegation"."truster_id",
1816 "delegation"."trustee_id",
1817 "delegation"."scope"
1818 FROM "unit"
1819 JOIN "delegation"
1820 ON "delegation"."unit_id" = "unit"."id"
1821 JOIN "member"
1822 ON "delegation"."truster_id" = "member"."id"
1823 JOIN "privilege"
1824 ON "delegation"."unit_id" = "privilege"."unit_id"
1825 AND "delegation"."truster_id" = "privilege"."member_id"
1826 WHERE "member"."active" AND "privilege"."voting_right";
1828 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1831 CREATE VIEW "area_delegation" AS
1832 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1833 "area"."id" AS "area_id",
1834 "delegation"."id",
1835 "delegation"."truster_id",
1836 "delegation"."trustee_id",
1837 "delegation"."scope"
1838 FROM "area"
1839 JOIN "delegation"
1840 ON "delegation"."unit_id" = "area"."unit_id"
1841 OR "delegation"."area_id" = "area"."id"
1842 JOIN "member"
1843 ON "delegation"."truster_id" = "member"."id"
1844 JOIN "privilege"
1845 ON "area"."unit_id" = "privilege"."unit_id"
1846 AND "delegation"."truster_id" = "privilege"."member_id"
1847 WHERE "member"."active" AND "privilege"."voting_right"
1848 ORDER BY
1849 "area"."id",
1850 "delegation"."truster_id",
1851 "delegation"."scope" DESC;
1853 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1856 CREATE VIEW "issue_delegation" AS
1857 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1858 "issue"."id" AS "issue_id",
1859 "delegation"."id",
1860 "delegation"."truster_id",
1861 "delegation"."trustee_id",
1862 "delegation"."scope"
1863 FROM "issue"
1864 JOIN "area"
1865 ON "area"."id" = "issue"."area_id"
1866 JOIN "delegation"
1867 ON "delegation"."unit_id" = "area"."unit_id"
1868 OR "delegation"."area_id" = "area"."id"
1869 OR "delegation"."issue_id" = "issue"."id"
1870 JOIN "member"
1871 ON "delegation"."truster_id" = "member"."id"
1872 JOIN "privilege"
1873 ON "area"."unit_id" = "privilege"."unit_id"
1874 AND "delegation"."truster_id" = "privilege"."member_id"
1875 WHERE "member"."active" AND "privilege"."voting_right"
1876 ORDER BY
1877 "issue"."id",
1878 "delegation"."truster_id",
1879 "delegation"."scope" DESC;
1881 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1884 CREATE FUNCTION "membership_weight_with_skipping"
1885 ( "area_id_p" "area"."id"%TYPE,
1886 "member_id_p" "member"."id"%TYPE,
1887 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1888 RETURNS INT4
1889 LANGUAGE 'plpgsql' STABLE AS $$
1890 DECLARE
1891 "sum_v" INT4;
1892 "delegation_row" "area_delegation"%ROWTYPE;
1893 BEGIN
1894 "sum_v" := 1;
1895 FOR "delegation_row" IN
1896 SELECT "area_delegation".*
1897 FROM "area_delegation" LEFT JOIN "membership"
1898 ON "membership"."area_id" = "area_id_p"
1899 AND "membership"."member_id" = "area_delegation"."truster_id"
1900 WHERE "area_delegation"."area_id" = "area_id_p"
1901 AND "area_delegation"."trustee_id" = "member_id_p"
1902 AND "membership"."member_id" ISNULL
1903 LOOP
1904 IF NOT
1905 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1906 THEN
1907 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1908 "area_id_p",
1909 "delegation_row"."truster_id",
1910 "skip_member_ids_p" || "delegation_row"."truster_id"
1911 );
1912 END IF;
1913 END LOOP;
1914 RETURN "sum_v";
1915 END;
1916 $$;
1918 COMMENT ON FUNCTION "membership_weight_with_skipping"
1919 ( "area"."id"%TYPE,
1920 "member"."id"%TYPE,
1921 INT4[] )
1922 IS 'Helper function for "membership_weight" function';
1925 CREATE FUNCTION "membership_weight"
1926 ( "area_id_p" "area"."id"%TYPE,
1927 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1928 RETURNS INT4
1929 LANGUAGE 'plpgsql' STABLE AS $$
1930 BEGIN
1931 RETURN "membership_weight_with_skipping"(
1932 "area_id_p",
1933 "member_id_p",
1934 ARRAY["member_id_p"]
1935 );
1936 END;
1937 $$;
1939 COMMENT ON FUNCTION "membership_weight"
1940 ( "area"."id"%TYPE,
1941 "member"."id"%TYPE )
1942 IS 'Calculates the potential voting weight of a member in a given area';
1945 CREATE VIEW "member_count_view" AS
1946 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1948 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1951 CREATE VIEW "unit_member_count" AS
1952 SELECT
1953 "unit"."id" AS "unit_id",
1954 count("member"."id") AS "member_count"
1955 FROM "unit"
1956 LEFT JOIN "privilege"
1957 ON "privilege"."unit_id" = "unit"."id"
1958 AND "privilege"."voting_right"
1959 LEFT JOIN "member"
1960 ON "member"."id" = "privilege"."member_id"
1961 AND "member"."active"
1962 GROUP BY "unit"."id";
1964 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1967 CREATE VIEW "area_member_count" AS
1968 SELECT
1969 "area"."id" AS "area_id",
1970 count("member"."id") AS "direct_member_count",
1971 coalesce(
1972 sum(
1973 CASE WHEN "member"."id" NOTNULL THEN
1974 "membership_weight"("area"."id", "member"."id")
1975 ELSE 0 END
1977 ) AS "member_weight"
1978 FROM "area"
1979 LEFT JOIN "membership"
1980 ON "area"."id" = "membership"."area_id"
1981 LEFT JOIN "privilege"
1982 ON "privilege"."unit_id" = "area"."unit_id"
1983 AND "privilege"."member_id" = "membership"."member_id"
1984 AND "privilege"."voting_right"
1985 LEFT JOIN "member"
1986 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1987 AND "member"."active"
1988 GROUP BY "area"."id";
1990 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1993 CREATE VIEW "opening_draft" AS
1994 SELECT "draft".* FROM (
1995 SELECT
1996 "initiative"."id" AS "initiative_id",
1997 min("draft"."id") AS "draft_id"
1998 FROM "initiative" JOIN "draft"
1999 ON "initiative"."id" = "draft"."initiative_id"
2000 GROUP BY "initiative"."id"
2001 ) AS "subquery"
2002 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2004 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2007 CREATE VIEW "current_draft" AS
2008 SELECT "draft".* FROM (
2009 SELECT
2010 "initiative"."id" AS "initiative_id",
2011 max("draft"."id") AS "draft_id"
2012 FROM "initiative" JOIN "draft"
2013 ON "initiative"."id" = "draft"."initiative_id"
2014 GROUP BY "initiative"."id"
2015 ) AS "subquery"
2016 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2018 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2021 CREATE VIEW "critical_opinion" AS
2022 SELECT * FROM "opinion"
2023 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2024 OR ("degree" = -2 AND "fulfilled" = TRUE);
2026 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2029 CREATE VIEW "battle_participant" AS
2030 SELECT "initiative"."id", "initiative"."issue_id"
2031 FROM "issue" JOIN "initiative"
2032 ON "issue"."id" = "initiative"."issue_id"
2033 WHERE "initiative"."admitted"
2034 UNION ALL
2035 SELECT NULL, "id" AS "issue_id"
2036 FROM "issue";
2038 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2041 CREATE VIEW "battle_view" AS
2042 SELECT
2043 "issue"."id" AS "issue_id",
2044 "winning_initiative"."id" AS "winning_initiative_id",
2045 "losing_initiative"."id" AS "losing_initiative_id",
2046 sum(
2047 CASE WHEN
2048 coalesce("better_vote"."grade", 0) >
2049 coalesce("worse_vote"."grade", 0)
2050 THEN "direct_voter"."weight" ELSE 0 END
2051 ) AS "count"
2052 FROM "issue"
2053 LEFT JOIN "direct_voter"
2054 ON "issue"."id" = "direct_voter"."issue_id"
2055 JOIN "battle_participant" AS "winning_initiative"
2056 ON "issue"."id" = "winning_initiative"."issue_id"
2057 JOIN "battle_participant" AS "losing_initiative"
2058 ON "issue"."id" = "losing_initiative"."issue_id"
2059 LEFT JOIN "vote" AS "better_vote"
2060 ON "direct_voter"."member_id" = "better_vote"."member_id"
2061 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2062 LEFT JOIN "vote" AS "worse_vote"
2063 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2064 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2065 WHERE "issue"."state" = 'voting'
2066 AND "issue"."phase_finished" NOTNULL
2067 AND (
2068 "winning_initiative"."id" != "losing_initiative"."id" OR
2069 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2070 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2071 GROUP BY
2072 "issue"."id",
2073 "winning_initiative"."id",
2074 "losing_initiative"."id";
2076 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';
2079 CREATE VIEW "expired_session" AS
2080 SELECT * FROM "session" WHERE now() > "expiry";
2082 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2083 DELETE FROM "session" WHERE "ident" = OLD."ident";
2085 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2086 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2089 CREATE VIEW "open_issue" AS
2090 SELECT * FROM "issue" WHERE "closed" ISNULL;
2092 COMMENT ON VIEW "open_issue" IS 'All open issues';
2095 CREATE VIEW "member_contingent" AS
2096 SELECT
2097 "member"."id" AS "member_id",
2098 "contingent"."polling",
2099 "contingent"."time_frame",
2100 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2102 SELECT count(1) FROM "draft"
2103 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2104 WHERE "draft"."author_id" = "member"."id"
2105 AND "initiative"."polling" = "contingent"."polling"
2106 AND "draft"."created" > now() - "contingent"."time_frame"
2107 ) + (
2108 SELECT count(1) FROM "suggestion"
2109 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2110 WHERE "suggestion"."author_id" = "member"."id"
2111 AND "contingent"."polling" = FALSE
2112 AND "suggestion"."created" > now() - "contingent"."time_frame"
2114 ELSE NULL END AS "text_entry_count",
2115 "contingent"."text_entry_limit",
2116 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2117 SELECT count(1) FROM "opening_draft" AS "draft"
2118 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2119 WHERE "draft"."author_id" = "member"."id"
2120 AND "initiative"."polling" = "contingent"."polling"
2121 AND "draft"."created" > now() - "contingent"."time_frame"
2122 ) ELSE NULL END AS "initiative_count",
2123 "contingent"."initiative_limit"
2124 FROM "member" CROSS JOIN "contingent";
2126 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2128 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2129 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2132 CREATE VIEW "member_contingent_left" AS
2133 SELECT
2134 "member_id",
2135 "polling",
2136 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2137 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2138 FROM "member_contingent" GROUP BY "member_id", "polling";
2140 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.';
2143 CREATE VIEW "event_seen_by_member" AS
2144 SELECT
2145 "member"."id" AS "seen_by_member_id",
2146 CASE WHEN "event"."state" IN (
2147 'voting',
2148 'finished_without_winner',
2149 'finished_with_winner'
2150 ) THEN
2151 'voting'::"notify_level"
2152 ELSE
2153 CASE WHEN "event"."state" IN (
2154 'verification',
2155 'canceled_after_revocation_during_verification',
2156 'canceled_no_initiative_admitted'
2157 ) THEN
2158 'verification'::"notify_level"
2159 ELSE
2160 CASE WHEN "event"."state" IN (
2161 'discussion',
2162 'canceled_after_revocation_during_discussion'
2163 ) THEN
2164 'discussion'::"notify_level"
2165 ELSE
2166 'all'::"notify_level"
2167 END
2168 END
2169 END AS "notify_level",
2170 "event".*
2171 FROM "member" CROSS JOIN "event"
2172 LEFT JOIN "issue"
2173 ON "event"."issue_id" = "issue"."id"
2174 LEFT JOIN "membership"
2175 ON "member"."id" = "membership"."member_id"
2176 AND "issue"."area_id" = "membership"."area_id"
2177 LEFT JOIN "interest"
2178 ON "member"."id" = "interest"."member_id"
2179 AND "event"."issue_id" = "interest"."issue_id"
2180 LEFT JOIN "supporter"
2181 ON "member"."id" = "supporter"."member_id"
2182 AND "event"."initiative_id" = "supporter"."initiative_id"
2183 LEFT JOIN "ignored_member"
2184 ON "member"."id" = "ignored_member"."member_id"
2185 AND "event"."member_id" = "ignored_member"."other_member_id"
2186 LEFT JOIN "ignored_initiative"
2187 ON "member"."id" = "ignored_initiative"."member_id"
2188 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2189 WHERE (
2190 "supporter"."member_id" NOTNULL OR
2191 "interest"."member_id" NOTNULL OR
2192 ( "membership"."member_id" NOTNULL AND
2193 "event"."event" IN (
2194 'issue_state_changed',
2195 'initiative_created_in_new_issue',
2196 'initiative_created_in_existing_issue',
2197 'initiative_revoked' ) ) )
2198 AND "ignored_member"."member_id" ISNULL
2199 AND "ignored_initiative"."member_id" ISNULL;
2201 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"';
2204 CREATE VIEW "selected_event_seen_by_member" AS
2205 SELECT
2206 "member"."id" AS "seen_by_member_id",
2207 CASE WHEN "event"."state" IN (
2208 'voting',
2209 'finished_without_winner',
2210 'finished_with_winner'
2211 ) THEN
2212 'voting'::"notify_level"
2213 ELSE
2214 CASE WHEN "event"."state" IN (
2215 'verification',
2216 'canceled_after_revocation_during_verification',
2217 'canceled_no_initiative_admitted'
2218 ) THEN
2219 'verification'::"notify_level"
2220 ELSE
2221 CASE WHEN "event"."state" IN (
2222 'discussion',
2223 'canceled_after_revocation_during_discussion'
2224 ) THEN
2225 'discussion'::"notify_level"
2226 ELSE
2227 'all'::"notify_level"
2228 END
2229 END
2230 END AS "notify_level",
2231 "event".*
2232 FROM "member" CROSS JOIN "event"
2233 LEFT JOIN "issue"
2234 ON "event"."issue_id" = "issue"."id"
2235 LEFT JOIN "membership"
2236 ON "member"."id" = "membership"."member_id"
2237 AND "issue"."area_id" = "membership"."area_id"
2238 LEFT JOIN "interest"
2239 ON "member"."id" = "interest"."member_id"
2240 AND "event"."issue_id" = "interest"."issue_id"
2241 LEFT JOIN "supporter"
2242 ON "member"."id" = "supporter"."member_id"
2243 AND "event"."initiative_id" = "supporter"."initiative_id"
2244 LEFT JOIN "ignored_member"
2245 ON "member"."id" = "ignored_member"."member_id"
2246 AND "event"."member_id" = "ignored_member"."other_member_id"
2247 LEFT JOIN "ignored_initiative"
2248 ON "member"."id" = "ignored_initiative"."member_id"
2249 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2250 WHERE (
2251 ( "member"."notify_level" >= 'all' ) OR
2252 ( "member"."notify_level" >= 'voting' AND
2253 "event"."state" IN (
2254 'voting',
2255 'finished_without_winner',
2256 'finished_with_winner' ) ) OR
2257 ( "member"."notify_level" >= 'verification' AND
2258 "event"."state" IN (
2259 'verification',
2260 'canceled_after_revocation_during_verification',
2261 'canceled_no_initiative_admitted' ) ) OR
2262 ( "member"."notify_level" >= 'discussion' AND
2263 "event"."state" IN (
2264 'discussion',
2265 'canceled_after_revocation_during_discussion' ) ) )
2266 AND (
2267 "supporter"."member_id" NOTNULL OR
2268 "interest"."member_id" NOTNULL OR
2269 ( "membership"."member_id" NOTNULL AND
2270 "event"."event" IN (
2271 'issue_state_changed',
2272 'initiative_created_in_new_issue',
2273 'initiative_created_in_existing_issue',
2274 'initiative_revoked' ) ) )
2275 AND "ignored_member"."member_id" ISNULL
2276 AND "ignored_initiative"."member_id" ISNULL;
2278 COMMENT ON VIEW "selected_event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests, support and members "notify_level"';
2282 ------------------------------------------------------
2283 -- Row set returning function for delegation chains --
2284 ------------------------------------------------------
2287 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2288 ('first', 'intermediate', 'last', 'repetition');
2290 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2293 CREATE TYPE "delegation_chain_row" AS (
2294 "index" INT4,
2295 "member_id" INT4,
2296 "member_valid" BOOLEAN,
2297 "participation" BOOLEAN,
2298 "overridden" BOOLEAN,
2299 "scope_in" "delegation_scope",
2300 "scope_out" "delegation_scope",
2301 "disabled_out" BOOLEAN,
2302 "loop" "delegation_chain_loop_tag" );
2304 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2306 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2307 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';
2308 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2309 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2310 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2311 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2312 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2315 CREATE FUNCTION "delegation_chain_for_closed_issue"
2316 ( "member_id_p" "member"."id"%TYPE,
2317 "issue_id_p" "issue"."id"%TYPE )
2318 RETURNS SETOF "delegation_chain_row"
2319 LANGUAGE 'plpgsql' STABLE AS $$
2320 DECLARE
2321 "output_row" "delegation_chain_row";
2322 "direct_voter_row" "direct_voter"%ROWTYPE;
2323 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2324 BEGIN
2325 "output_row"."index" := 0;
2326 "output_row"."member_id" := "member_id_p";
2327 "output_row"."member_valid" := TRUE;
2328 "output_row"."participation" := FALSE;
2329 "output_row"."overridden" := FALSE;
2330 "output_row"."disabled_out" := FALSE;
2331 LOOP
2332 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2333 WHERE "issue_id" = "issue_id_p"
2334 AND "member_id" = "output_row"."member_id";
2335 IF "direct_voter_row"."member_id" NOTNULL THEN
2336 "output_row"."participation" := TRUE;
2337 "output_row"."scope_out" := NULL;
2338 "output_row"."disabled_out" := NULL;
2339 RETURN NEXT "output_row";
2340 RETURN;
2341 END IF;
2342 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2343 WHERE "issue_id" = "issue_id_p"
2344 AND "member_id" = "output_row"."member_id";
2345 IF "delegating_voter_row"."member_id" ISNULL THEN
2346 RETURN;
2347 END IF;
2348 "output_row"."scope_out" := "delegating_voter_row"."scope";
2349 RETURN NEXT "output_row";
2350 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2351 "output_row"."scope_in" := "output_row"."scope_out";
2352 END LOOP;
2353 END;
2354 $$;
2356 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2357 ( "member"."id"%TYPE,
2358 "member"."id"%TYPE )
2359 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2362 CREATE FUNCTION "delegation_chain"
2363 ( "member_id_p" "member"."id"%TYPE,
2364 "unit_id_p" "unit"."id"%TYPE,
2365 "area_id_p" "area"."id"%TYPE,
2366 "issue_id_p" "issue"."id"%TYPE,
2367 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2368 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2369 RETURNS SETOF "delegation_chain_row"
2370 LANGUAGE 'plpgsql' STABLE AS $$
2371 DECLARE
2372 "scope_v" "delegation_scope";
2373 "unit_id_v" "unit"."id"%TYPE;
2374 "area_id_v" "area"."id"%TYPE;
2375 "issue_row" "issue"%ROWTYPE;
2376 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2377 "loop_member_id_v" "member"."id"%TYPE;
2378 "output_row" "delegation_chain_row";
2379 "output_rows" "delegation_chain_row"[];
2380 "simulate_v" BOOLEAN;
2381 "simulate_here_v" BOOLEAN;
2382 "delegation_row" "delegation"%ROWTYPE;
2383 "row_count" INT4;
2384 "i" INT4;
2385 "loop_v" BOOLEAN;
2386 BEGIN
2387 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2388 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2389 END IF;
2390 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2391 "simulate_v" := TRUE;
2392 ELSE
2393 "simulate_v" := FALSE;
2394 END IF;
2395 IF
2396 "unit_id_p" NOTNULL AND
2397 "area_id_p" ISNULL AND
2398 "issue_id_p" ISNULL
2399 THEN
2400 "scope_v" := 'unit';
2401 "unit_id_v" := "unit_id_p";
2402 ELSIF
2403 "unit_id_p" ISNULL AND
2404 "area_id_p" NOTNULL AND
2405 "issue_id_p" ISNULL
2406 THEN
2407 "scope_v" := 'area';
2408 "area_id_v" := "area_id_p";
2409 SELECT "unit_id" INTO "unit_id_v"
2410 FROM "area" WHERE "id" = "area_id_v";
2411 ELSIF
2412 "unit_id_p" ISNULL AND
2413 "area_id_p" ISNULL AND
2414 "issue_id_p" NOTNULL
2415 THEN
2416 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2417 IF "issue_row"."id" ISNULL THEN
2418 RETURN;
2419 END IF;
2420 IF "issue_row"."closed" NOTNULL THEN
2421 IF "simulate_v" THEN
2422 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2423 END IF;
2424 FOR "output_row" IN
2425 SELECT * FROM
2426 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2427 LOOP
2428 RETURN NEXT "output_row";
2429 END LOOP;
2430 RETURN;
2431 END IF;
2432 "scope_v" := 'issue';
2433 SELECT "area_id" INTO "area_id_v"
2434 FROM "issue" WHERE "id" = "issue_id_p";
2435 SELECT "unit_id" INTO "unit_id_v"
2436 FROM "area" WHERE "id" = "area_id_v";
2437 ELSE
2438 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2439 END IF;
2440 "visited_member_ids" := '{}';
2441 "loop_member_id_v" := NULL;
2442 "output_rows" := '{}';
2443 "output_row"."index" := 0;
2444 "output_row"."member_id" := "member_id_p";
2445 "output_row"."member_valid" := TRUE;
2446 "output_row"."participation" := FALSE;
2447 "output_row"."overridden" := FALSE;
2448 "output_row"."disabled_out" := FALSE;
2449 "output_row"."scope_out" := NULL;
2450 LOOP
2451 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2452 "loop_member_id_v" := "output_row"."member_id";
2453 ELSE
2454 "visited_member_ids" :=
2455 "visited_member_ids" || "output_row"."member_id";
2456 END IF;
2457 IF "output_row"."participation" ISNULL THEN
2458 "output_row"."overridden" := NULL;
2459 ELSIF "output_row"."participation" THEN
2460 "output_row"."overridden" := TRUE;
2461 END IF;
2462 "output_row"."scope_in" := "output_row"."scope_out";
2463 "output_row"."member_valid" := EXISTS (
2464 SELECT NULL FROM "member" JOIN "privilege"
2465 ON "privilege"."member_id" = "member"."id"
2466 AND "privilege"."unit_id" = "unit_id_v"
2467 WHERE "id" = "output_row"."member_id"
2468 AND "member"."active" AND "privilege"."voting_right"
2469 );
2470 "simulate_here_v" := (
2471 "simulate_v" AND
2472 "output_row"."member_id" = "member_id_p"
2473 );
2474 "delegation_row" := ROW(NULL);
2475 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2476 IF "scope_v" = 'unit' THEN
2477 IF NOT "simulate_here_v" THEN
2478 SELECT * INTO "delegation_row" FROM "delegation"
2479 WHERE "truster_id" = "output_row"."member_id"
2480 AND "unit_id" = "unit_id_v";
2481 END IF;
2482 ELSIF "scope_v" = 'area' THEN
2483 "output_row"."participation" := EXISTS (
2484 SELECT NULL FROM "membership"
2485 WHERE "area_id" = "area_id_p"
2486 AND "member_id" = "output_row"."member_id"
2487 );
2488 IF "simulate_here_v" THEN
2489 IF "simulate_trustee_id_p" ISNULL THEN
2490 SELECT * INTO "delegation_row" FROM "delegation"
2491 WHERE "truster_id" = "output_row"."member_id"
2492 AND "unit_id" = "unit_id_v";
2493 END IF;
2494 ELSE
2495 SELECT * INTO "delegation_row" FROM "delegation"
2496 WHERE "truster_id" = "output_row"."member_id"
2497 AND (
2498 "unit_id" = "unit_id_v" OR
2499 "area_id" = "area_id_v"
2501 ORDER BY "scope" DESC;
2502 END IF;
2503 ELSIF "scope_v" = 'issue' THEN
2504 IF "issue_row"."fully_frozen" ISNULL THEN
2505 "output_row"."participation" := EXISTS (
2506 SELECT NULL FROM "interest"
2507 WHERE "issue_id" = "issue_id_p"
2508 AND "member_id" = "output_row"."member_id"
2509 );
2510 ELSE
2511 IF "output_row"."member_id" = "member_id_p" THEN
2512 "output_row"."participation" := EXISTS (
2513 SELECT NULL FROM "direct_voter"
2514 WHERE "issue_id" = "issue_id_p"
2515 AND "member_id" = "output_row"."member_id"
2516 );
2517 ELSE
2518 "output_row"."participation" := NULL;
2519 END IF;
2520 END IF;
2521 IF "simulate_here_v" THEN
2522 IF "simulate_trustee_id_p" ISNULL THEN
2523 SELECT * INTO "delegation_row" FROM "delegation"
2524 WHERE "truster_id" = "output_row"."member_id"
2525 AND (
2526 "unit_id" = "unit_id_v" OR
2527 "area_id" = "area_id_v"
2529 ORDER BY "scope" DESC;
2530 END IF;
2531 ELSE
2532 SELECT * INTO "delegation_row" FROM "delegation"
2533 WHERE "truster_id" = "output_row"."member_id"
2534 AND (
2535 "unit_id" = "unit_id_v" OR
2536 "area_id" = "area_id_v" OR
2537 "issue_id" = "issue_id_p"
2539 ORDER BY "scope" DESC;
2540 END IF;
2541 END IF;
2542 ELSE
2543 "output_row"."participation" := FALSE;
2544 END IF;
2545 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2546 "output_row"."scope_out" := "scope_v";
2547 "output_rows" := "output_rows" || "output_row";
2548 "output_row"."member_id" := "simulate_trustee_id_p";
2549 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2550 "output_row"."scope_out" := "delegation_row"."scope";
2551 "output_rows" := "output_rows" || "output_row";
2552 "output_row"."member_id" := "delegation_row"."trustee_id";
2553 ELSIF "delegation_row"."scope" NOTNULL THEN
2554 "output_row"."scope_out" := "delegation_row"."scope";
2555 "output_row"."disabled_out" := TRUE;
2556 "output_rows" := "output_rows" || "output_row";
2557 EXIT;
2558 ELSE
2559 "output_row"."scope_out" := NULL;
2560 "output_rows" := "output_rows" || "output_row";
2561 EXIT;
2562 END IF;
2563 EXIT WHEN "loop_member_id_v" NOTNULL;
2564 "output_row"."index" := "output_row"."index" + 1;
2565 END LOOP;
2566 "row_count" := array_upper("output_rows", 1);
2567 "i" := 1;
2568 "loop_v" := FALSE;
2569 LOOP
2570 "output_row" := "output_rows"["i"];
2571 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2572 IF "loop_v" THEN
2573 IF "i" + 1 = "row_count" THEN
2574 "output_row"."loop" := 'last';
2575 ELSIF "i" = "row_count" THEN
2576 "output_row"."loop" := 'repetition';
2577 ELSE
2578 "output_row"."loop" := 'intermediate';
2579 END IF;
2580 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2581 "output_row"."loop" := 'first';
2582 "loop_v" := TRUE;
2583 END IF;
2584 IF "scope_v" = 'unit' THEN
2585 "output_row"."participation" := NULL;
2586 END IF;
2587 RETURN NEXT "output_row";
2588 "i" := "i" + 1;
2589 END LOOP;
2590 RETURN;
2591 END;
2592 $$;
2594 COMMENT ON FUNCTION "delegation_chain"
2595 ( "member"."id"%TYPE,
2596 "unit"."id"%TYPE,
2597 "area"."id"%TYPE,
2598 "issue"."id"%TYPE,
2599 "member"."id"%TYPE,
2600 BOOLEAN )
2601 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2605 ---------------------------------------------------------
2606 -- Single row returning function for delegation chains --
2607 ---------------------------------------------------------
2610 CREATE TYPE "delegation_info_loop_type" AS ENUM
2611 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2613 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''';
2616 CREATE TYPE "delegation_info_type" AS (
2617 "own_participation" BOOLEAN,
2618 "own_delegation_scope" "delegation_scope",
2619 "first_trustee_id" INT4,
2620 "first_trustee_participation" BOOLEAN,
2621 "first_trustee_ellipsis" BOOLEAN,
2622 "other_trustee_id" INT4,
2623 "other_trustee_participation" BOOLEAN,
2624 "other_trustee_ellipsis" BOOLEAN,
2625 "delegation_loop" "delegation_info_loop_type",
2626 "participating_member_id" INT4 );
2628 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';
2630 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2631 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2632 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2633 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2634 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2635 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2636 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)';
2637 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2638 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';
2639 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2642 CREATE FUNCTION "delegation_info"
2643 ( "member_id_p" "member"."id"%TYPE,
2644 "unit_id_p" "unit"."id"%TYPE,
2645 "area_id_p" "area"."id"%TYPE,
2646 "issue_id_p" "issue"."id"%TYPE,
2647 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2648 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2649 RETURNS "delegation_info_type"
2650 LANGUAGE 'plpgsql' STABLE AS $$
2651 DECLARE
2652 "current_row" "delegation_chain_row";
2653 "result" "delegation_info_type";
2654 BEGIN
2655 "result"."own_participation" := FALSE;
2656 FOR "current_row" IN
2657 SELECT * FROM "delegation_chain"(
2658 "member_id_p",
2659 "unit_id_p", "area_id_p", "issue_id_p",
2660 "simulate_trustee_id_p", "simulate_default_p")
2661 LOOP
2662 IF
2663 "result"."participating_member_id" ISNULL AND
2664 "current_row"."participation"
2665 THEN
2666 "result"."participating_member_id" := "current_row"."member_id";
2667 END IF;
2668 IF "current_row"."member_id" = "member_id_p" THEN
2669 "result"."own_participation" := "current_row"."participation";
2670 "result"."own_delegation_scope" := "current_row"."scope_out";
2671 IF "current_row"."loop" = 'first' THEN
2672 "result"."delegation_loop" := 'own';
2673 END IF;
2674 ELSIF
2675 "current_row"."member_valid" AND
2676 ( "current_row"."loop" ISNULL OR
2677 "current_row"."loop" != 'repetition' )
2678 THEN
2679 IF "result"."first_trustee_id" ISNULL THEN
2680 "result"."first_trustee_id" := "current_row"."member_id";
2681 "result"."first_trustee_participation" := "current_row"."participation";
2682 "result"."first_trustee_ellipsis" := FALSE;
2683 IF "current_row"."loop" = 'first' THEN
2684 "result"."delegation_loop" := 'first';
2685 END IF;
2686 ELSIF "result"."other_trustee_id" ISNULL THEN
2687 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2688 "result"."other_trustee_id" := "current_row"."member_id";
2689 "result"."other_trustee_participation" := TRUE;
2690 "result"."other_trustee_ellipsis" := FALSE;
2691 IF "current_row"."loop" = 'first' THEN
2692 "result"."delegation_loop" := 'other';
2693 END IF;
2694 ELSE
2695 "result"."first_trustee_ellipsis" := TRUE;
2696 IF "current_row"."loop" = 'first' THEN
2697 "result"."delegation_loop" := 'first_ellipsis';
2698 END IF;
2699 END IF;
2700 ELSE
2701 "result"."other_trustee_ellipsis" := TRUE;
2702 IF "current_row"."loop" = 'first' THEN
2703 "result"."delegation_loop" := 'other_ellipsis';
2704 END IF;
2705 END IF;
2706 END IF;
2707 END LOOP;
2708 RETURN "result";
2709 END;
2710 $$;
2712 COMMENT ON FUNCTION "delegation_info"
2713 ( "member"."id"%TYPE,
2714 "unit"."id"%TYPE,
2715 "area"."id"%TYPE,
2716 "issue"."id"%TYPE,
2717 "member"."id"%TYPE,
2718 BOOLEAN )
2719 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2723 ---------------------------
2724 -- Transaction isolation --
2725 ---------------------------
2727 CREATE FUNCTION "require_transaction_isolation"()
2728 RETURNS VOID
2729 LANGUAGE 'plpgsql' VOLATILE AS $$
2730 BEGIN
2731 IF
2732 current_setting('transaction_isolation') NOT IN
2733 ('repeatable read', 'serializable')
2734 THEN
2735 RAISE EXCEPTION 'Insufficient transaction isolation level';
2736 END IF;
2737 RETURN;
2738 END;
2739 $$;
2742 CREATE FUNCTION "dont_require_transaction_isolation"()
2743 RETURNS VOID
2744 LANGUAGE 'plpgsql' VOLATILE AS $$
2745 BEGIN
2746 IF
2747 current_setting('transaction_isolation') IN
2748 ('repeatable read', 'serializable')
2749 THEN
2750 RAISE WARNING 'Unneccessary transaction isolation level: %',
2751 current_setting('transaction_isolation');
2752 END IF;
2753 RETURN;
2754 END;
2755 $$;
2759 ------------------------------------------------------------------------
2760 -- Regular tasks, except calculcation of snapshots and voting results --
2761 ------------------------------------------------------------------------
2764 CREATE FUNCTION "check_activity"()
2765 RETURNS VOID
2766 LANGUAGE 'plpgsql' VOLATILE AS $$
2767 DECLARE
2768 "system_setting_row" "system_setting"%ROWTYPE;
2769 BEGIN
2770 PERFORM "dont_require_transaction_isolation"();
2771 SELECT * INTO "system_setting_row" FROM "system_setting";
2772 IF "system_setting_row"."member_ttl" NOTNULL THEN
2773 UPDATE "member" SET "active" = FALSE
2774 WHERE "active" = TRUE
2775 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2776 END IF;
2777 RETURN;
2778 END;
2779 $$;
2781 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2784 CREATE FUNCTION "calculate_member_counts"()
2785 RETURNS VOID
2786 LANGUAGE 'plpgsql' VOLATILE AS $$
2787 BEGIN
2788 PERFORM "require_transaction_isolation"();
2789 DELETE FROM "member_count";
2790 INSERT INTO "member_count" ("total_count")
2791 SELECT "total_count" FROM "member_count_view";
2792 UPDATE "unit" SET "member_count" = "view"."member_count"
2793 FROM "unit_member_count" AS "view"
2794 WHERE "view"."unit_id" = "unit"."id";
2795 UPDATE "area" SET
2796 "direct_member_count" = "view"."direct_member_count",
2797 "member_weight" = "view"."member_weight"
2798 FROM "area_member_count" AS "view"
2799 WHERE "view"."area_id" = "area"."id";
2800 RETURN;
2801 END;
2802 $$;
2804 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"';
2808 ------------------------------------
2809 -- Calculation of harmonic weight --
2810 ------------------------------------
2813 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2814 SELECT
2815 "direct_interest_snapshot"."issue_id",
2816 "direct_interest_snapshot"."event",
2817 "direct_interest_snapshot"."member_id",
2818 "direct_interest_snapshot"."weight" AS "weight_num",
2819 count("initiative"."id") AS "weight_den"
2820 FROM "issue"
2821 JOIN "direct_interest_snapshot"
2822 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
2823 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
2824 JOIN "initiative"
2825 ON "issue"."id" = "initiative"."issue_id"
2826 AND "initiative"."harmonic_weight" ISNULL
2827 JOIN "direct_supporter_snapshot"
2828 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2829 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
2830 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
2831 AND (
2832 "direct_supporter_snapshot"."satisfied" = TRUE OR
2833 coalesce("initiative"."admitted", FALSE) = FALSE
2835 GROUP BY
2836 "direct_interest_snapshot"."issue_id",
2837 "direct_interest_snapshot"."event",
2838 "direct_interest_snapshot"."member_id",
2839 "direct_interest_snapshot"."weight";
2841 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
2844 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
2845 SELECT
2846 "initiative"."issue_id",
2847 "initiative"."id" AS "initiative_id",
2848 "initiative"."admitted",
2849 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
2850 "remaining_harmonic_supporter_weight"."weight_den"
2851 FROM "remaining_harmonic_supporter_weight"
2852 JOIN "initiative"
2853 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
2854 AND "initiative"."harmonic_weight" ISNULL
2855 JOIN "direct_supporter_snapshot"
2856 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
2857 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
2858 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
2859 AND (
2860 "direct_supporter_snapshot"."satisfied" = TRUE OR
2861 coalesce("initiative"."admitted", FALSE) = FALSE
2863 GROUP BY
2864 "initiative"."issue_id",
2865 "initiative"."id",
2866 "initiative"."admitted",
2867 "remaining_harmonic_supporter_weight"."weight_den";
2869 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
2872 CREATE FUNCTION "set_harmonic_initiative_weights"
2873 ( "issue_id_p" "issue"."id"%TYPE )
2874 RETURNS VOID
2875 LANGUAGE 'plpgsql' VOLATILE AS $$
2876 DECLARE
2877 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
2878 "i" INT4;
2879 "count_v" INT4;
2880 "summand_v" FLOAT;
2881 "id_ary" INT4[];
2882 "weight_ary" FLOAT[];
2883 "min_weight_v" FLOAT;
2884 BEGIN
2885 PERFORM "require_transaction_isolation"();
2886 UPDATE "initiative" SET "harmonic_weight" = NULL
2887 WHERE "issue_id" = "issue_id_p";
2888 LOOP
2889 "min_weight_v" := NULL;
2890 "i" := 0;
2891 "count_v" := 0;
2892 FOR "weight_row" IN
2893 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
2894 WHERE "issue_id" = "issue_id_p"
2895 AND (
2896 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
2897 SELECT NULL FROM "initiative"
2898 WHERE "issue_id" = "issue_id_p"
2899 AND "harmonic_weight" ISNULL
2900 AND coalesce("admitted", FALSE) = FALSE
2903 ORDER BY "initiative_id" DESC, "weight_den" DESC
2904 -- NOTE: non-admitted initiatives placed first (at last positions),
2905 -- latest initiatives treated worse in case of tie
2906 LOOP
2907 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
2908 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
2909 "i" := "i" + 1;
2910 "count_v" := "i";
2911 "id_ary"["i"] := "weight_row"."initiative_id";
2912 "weight_ary"["i"] := "summand_v";
2913 ELSE
2914 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
2915 END IF;
2916 END LOOP;
2917 EXIT WHEN "count_v" = 0;
2918 "i" := 1;
2919 LOOP
2920 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
2921 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
2922 "min_weight_v" := "weight_ary"["i"];
2923 END IF;
2924 "i" := "i" + 1;
2925 EXIT WHEN "i" > "count_v";
2926 END LOOP;
2927 "i" := 1;
2928 LOOP
2929 IF "weight_ary"["i"] = "min_weight_v" THEN
2930 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
2931 WHERE "id" = "id_ary"["i"];
2932 EXIT;
2933 END IF;
2934 "i" := "i" + 1;
2935 END LOOP;
2936 END LOOP;
2937 UPDATE "initiative" SET "harmonic_weight" = 0
2938 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
2939 END;
2940 $$;
2942 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
2943 ( "issue"."id"%TYPE )
2944 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
2948 ------------------------------
2949 -- Calculation of snapshots --
2950 ------------------------------
2953 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2954 ( "issue_id_p" "issue"."id"%TYPE,
2955 "member_id_p" "member"."id"%TYPE,
2956 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2957 RETURNS "direct_population_snapshot"."weight"%TYPE
2958 LANGUAGE 'plpgsql' VOLATILE AS $$
2959 DECLARE
2960 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2961 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2962 "weight_v" INT4;
2963 "sub_weight_v" INT4;
2964 BEGIN
2965 PERFORM "require_transaction_isolation"();
2966 "weight_v" := 0;
2967 FOR "issue_delegation_row" IN
2968 SELECT * FROM "issue_delegation"
2969 WHERE "trustee_id" = "member_id_p"
2970 AND "issue_id" = "issue_id_p"
2971 LOOP
2972 IF NOT EXISTS (
2973 SELECT NULL FROM "direct_population_snapshot"
2974 WHERE "issue_id" = "issue_id_p"
2975 AND "event" = 'periodic'
2976 AND "member_id" = "issue_delegation_row"."truster_id"
2977 ) AND NOT EXISTS (
2978 SELECT NULL FROM "delegating_population_snapshot"
2979 WHERE "issue_id" = "issue_id_p"
2980 AND "event" = 'periodic'
2981 AND "member_id" = "issue_delegation_row"."truster_id"
2982 ) THEN
2983 "delegate_member_ids_v" :=
2984 "member_id_p" || "delegate_member_ids_p";
2985 INSERT INTO "delegating_population_snapshot" (
2986 "issue_id",
2987 "event",
2988 "member_id",
2989 "scope",
2990 "delegate_member_ids"
2991 ) VALUES (
2992 "issue_id_p",
2993 'periodic',
2994 "issue_delegation_row"."truster_id",
2995 "issue_delegation_row"."scope",
2996 "delegate_member_ids_v"
2997 );
2998 "sub_weight_v" := 1 +
2999 "weight_of_added_delegations_for_population_snapshot"(
3000 "issue_id_p",
3001 "issue_delegation_row"."truster_id",
3002 "delegate_member_ids_v"
3003 );
3004 UPDATE "delegating_population_snapshot"
3005 SET "weight" = "sub_weight_v"
3006 WHERE "issue_id" = "issue_id_p"
3007 AND "event" = 'periodic'
3008 AND "member_id" = "issue_delegation_row"."truster_id";
3009 "weight_v" := "weight_v" + "sub_weight_v";
3010 END IF;
3011 END LOOP;
3012 RETURN "weight_v";
3013 END;
3014 $$;
3016 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3017 ( "issue"."id"%TYPE,
3018 "member"."id"%TYPE,
3019 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3020 IS 'Helper function for "create_population_snapshot" function';
3023 CREATE FUNCTION "create_population_snapshot"
3024 ( "issue_id_p" "issue"."id"%TYPE )
3025 RETURNS VOID
3026 LANGUAGE 'plpgsql' VOLATILE AS $$
3027 DECLARE
3028 "member_id_v" "member"."id"%TYPE;
3029 BEGIN
3030 PERFORM "require_transaction_isolation"();
3031 DELETE FROM "direct_population_snapshot"
3032 WHERE "issue_id" = "issue_id_p"
3033 AND "event" = 'periodic';
3034 DELETE FROM "delegating_population_snapshot"
3035 WHERE "issue_id" = "issue_id_p"
3036 AND "event" = 'periodic';
3037 INSERT INTO "direct_population_snapshot"
3038 ("issue_id", "event", "member_id")
3039 SELECT
3040 "issue_id_p" AS "issue_id",
3041 'periodic'::"snapshot_event" AS "event",
3042 "member"."id" AS "member_id"
3043 FROM "issue"
3044 JOIN "area" ON "issue"."area_id" = "area"."id"
3045 JOIN "membership" ON "area"."id" = "membership"."area_id"
3046 JOIN "member" ON "membership"."member_id" = "member"."id"
3047 JOIN "privilege"
3048 ON "privilege"."unit_id" = "area"."unit_id"
3049 AND "privilege"."member_id" = "member"."id"
3050 WHERE "issue"."id" = "issue_id_p"
3051 AND "member"."active" AND "privilege"."voting_right"
3052 UNION
3053 SELECT
3054 "issue_id_p" AS "issue_id",
3055 'periodic'::"snapshot_event" AS "event",
3056 "member"."id" AS "member_id"
3057 FROM "issue"
3058 JOIN "area" ON "issue"."area_id" = "area"."id"
3059 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3060 JOIN "member" ON "interest"."member_id" = "member"."id"
3061 JOIN "privilege"
3062 ON "privilege"."unit_id" = "area"."unit_id"
3063 AND "privilege"."member_id" = "member"."id"
3064 WHERE "issue"."id" = "issue_id_p"
3065 AND "member"."active" AND "privilege"."voting_right";
3066 FOR "member_id_v" IN
3067 SELECT "member_id" FROM "direct_population_snapshot"
3068 WHERE "issue_id" = "issue_id_p"
3069 AND "event" = 'periodic'
3070 LOOP
3071 UPDATE "direct_population_snapshot" SET
3072 "weight" = 1 +
3073 "weight_of_added_delegations_for_population_snapshot"(
3074 "issue_id_p",
3075 "member_id_v",
3076 '{}'
3078 WHERE "issue_id" = "issue_id_p"
3079 AND "event" = 'periodic'
3080 AND "member_id" = "member_id_v";
3081 END LOOP;
3082 RETURN;
3083 END;
3084 $$;
3086 COMMENT ON FUNCTION "create_population_snapshot"
3087 ( "issue"."id"%TYPE )
3088 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.';
3091 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3092 ( "issue_id_p" "issue"."id"%TYPE,
3093 "member_id_p" "member"."id"%TYPE,
3094 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3095 RETURNS "direct_interest_snapshot"."weight"%TYPE
3096 LANGUAGE 'plpgsql' VOLATILE AS $$
3097 DECLARE
3098 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3099 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3100 "weight_v" INT4;
3101 "sub_weight_v" INT4;
3102 BEGIN
3103 PERFORM "require_transaction_isolation"();
3104 "weight_v" := 0;
3105 FOR "issue_delegation_row" IN
3106 SELECT * FROM "issue_delegation"
3107 WHERE "trustee_id" = "member_id_p"
3108 AND "issue_id" = "issue_id_p"
3109 LOOP
3110 IF NOT EXISTS (
3111 SELECT NULL FROM "direct_interest_snapshot"
3112 WHERE "issue_id" = "issue_id_p"
3113 AND "event" = 'periodic'
3114 AND "member_id" = "issue_delegation_row"."truster_id"
3115 ) AND NOT EXISTS (
3116 SELECT NULL FROM "delegating_interest_snapshot"
3117 WHERE "issue_id" = "issue_id_p"
3118 AND "event" = 'periodic'
3119 AND "member_id" = "issue_delegation_row"."truster_id"
3120 ) THEN
3121 "delegate_member_ids_v" :=
3122 "member_id_p" || "delegate_member_ids_p";
3123 INSERT INTO "delegating_interest_snapshot" (
3124 "issue_id",
3125 "event",
3126 "member_id",
3127 "scope",
3128 "delegate_member_ids"
3129 ) VALUES (
3130 "issue_id_p",
3131 'periodic',
3132 "issue_delegation_row"."truster_id",
3133 "issue_delegation_row"."scope",
3134 "delegate_member_ids_v"
3135 );
3136 "sub_weight_v" := 1 +
3137 "weight_of_added_delegations_for_interest_snapshot"(
3138 "issue_id_p",
3139 "issue_delegation_row"."truster_id",
3140 "delegate_member_ids_v"
3141 );
3142 UPDATE "delegating_interest_snapshot"
3143 SET "weight" = "sub_weight_v"
3144 WHERE "issue_id" = "issue_id_p"
3145 AND "event" = 'periodic'
3146 AND "member_id" = "issue_delegation_row"."truster_id";
3147 "weight_v" := "weight_v" + "sub_weight_v";
3148 END IF;
3149 END LOOP;
3150 RETURN "weight_v";
3151 END;
3152 $$;
3154 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3155 ( "issue"."id"%TYPE,
3156 "member"."id"%TYPE,
3157 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3158 IS 'Helper function for "create_interest_snapshot" function';
3161 CREATE FUNCTION "create_interest_snapshot"
3162 ( "issue_id_p" "issue"."id"%TYPE )
3163 RETURNS VOID
3164 LANGUAGE 'plpgsql' VOLATILE AS $$
3165 DECLARE
3166 "member_id_v" "member"."id"%TYPE;
3167 BEGIN
3168 PERFORM "require_transaction_isolation"();
3169 DELETE FROM "direct_interest_snapshot"
3170 WHERE "issue_id" = "issue_id_p"
3171 AND "event" = 'periodic';
3172 DELETE FROM "delegating_interest_snapshot"
3173 WHERE "issue_id" = "issue_id_p"
3174 AND "event" = 'periodic';
3175 DELETE FROM "direct_supporter_snapshot"
3176 USING "initiative" -- NOTE: due to missing index on issue_id
3177 WHERE "initiative"."issue_id" = "issue_id_p"
3178 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3179 AND "direct_supporter_snapshot"."event" = 'periodic';
3180 INSERT INTO "direct_interest_snapshot"
3181 ("issue_id", "event", "member_id")
3182 SELECT
3183 "issue_id_p" AS "issue_id",
3184 'periodic' AS "event",
3185 "member"."id" AS "member_id"
3186 FROM "issue"
3187 JOIN "area" ON "issue"."area_id" = "area"."id"
3188 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3189 JOIN "member" ON "interest"."member_id" = "member"."id"
3190 JOIN "privilege"
3191 ON "privilege"."unit_id" = "area"."unit_id"
3192 AND "privilege"."member_id" = "member"."id"
3193 WHERE "issue"."id" = "issue_id_p"
3194 AND "member"."active" AND "privilege"."voting_right";
3195 FOR "member_id_v" IN
3196 SELECT "member_id" FROM "direct_interest_snapshot"
3197 WHERE "issue_id" = "issue_id_p"
3198 AND "event" = 'periodic'
3199 LOOP
3200 UPDATE "direct_interest_snapshot" SET
3201 "weight" = 1 +
3202 "weight_of_added_delegations_for_interest_snapshot"(
3203 "issue_id_p",
3204 "member_id_v",
3205 '{}'
3207 WHERE "issue_id" = "issue_id_p"
3208 AND "event" = 'periodic'
3209 AND "member_id" = "member_id_v";
3210 END LOOP;
3211 INSERT INTO "direct_supporter_snapshot"
3212 ( "issue_id", "initiative_id", "event", "member_id",
3213 "draft_id", "informed", "satisfied" )
3214 SELECT
3215 "issue_id_p" AS "issue_id",
3216 "initiative"."id" AS "initiative_id",
3217 'periodic' AS "event",
3218 "supporter"."member_id" AS "member_id",
3219 "supporter"."draft_id" AS "draft_id",
3220 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3221 NOT EXISTS (
3222 SELECT NULL FROM "critical_opinion"
3223 WHERE "initiative_id" = "initiative"."id"
3224 AND "member_id" = "supporter"."member_id"
3225 ) AS "satisfied"
3226 FROM "initiative"
3227 JOIN "supporter"
3228 ON "supporter"."initiative_id" = "initiative"."id"
3229 JOIN "current_draft"
3230 ON "initiative"."id" = "current_draft"."initiative_id"
3231 JOIN "direct_interest_snapshot"
3232 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3233 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3234 AND "event" = 'periodic'
3235 WHERE "initiative"."issue_id" = "issue_id_p";
3236 RETURN;
3237 END;
3238 $$;
3240 COMMENT ON FUNCTION "create_interest_snapshot"
3241 ( "issue"."id"%TYPE )
3242 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.';
3245 CREATE FUNCTION "create_snapshot"
3246 ( "issue_id_p" "issue"."id"%TYPE )
3247 RETURNS VOID
3248 LANGUAGE 'plpgsql' VOLATILE AS $$
3249 DECLARE
3250 "initiative_id_v" "initiative"."id"%TYPE;
3251 "suggestion_id_v" "suggestion"."id"%TYPE;
3252 BEGIN
3253 PERFORM "require_transaction_isolation"();
3254 PERFORM "create_population_snapshot"("issue_id_p");
3255 PERFORM "create_interest_snapshot"("issue_id_p");
3256 UPDATE "issue" SET
3257 "snapshot" = coalesce("phase_finished", now()),
3258 "latest_snapshot_event" = 'periodic',
3259 "population" = (
3260 SELECT coalesce(sum("weight"), 0)
3261 FROM "direct_population_snapshot"
3262 WHERE "issue_id" = "issue_id_p"
3263 AND "event" = 'periodic'
3265 WHERE "id" = "issue_id_p";
3266 FOR "initiative_id_v" IN
3267 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3268 LOOP
3269 UPDATE "initiative" SET
3270 "supporter_count" = (
3271 SELECT coalesce(sum("di"."weight"), 0)
3272 FROM "direct_interest_snapshot" AS "di"
3273 JOIN "direct_supporter_snapshot" AS "ds"
3274 ON "di"."member_id" = "ds"."member_id"
3275 WHERE "di"."issue_id" = "issue_id_p"
3276 AND "di"."event" = 'periodic'
3277 AND "ds"."initiative_id" = "initiative_id_v"
3278 AND "ds"."event" = 'periodic'
3279 ),
3280 "informed_supporter_count" = (
3281 SELECT coalesce(sum("di"."weight"), 0)
3282 FROM "direct_interest_snapshot" AS "di"
3283 JOIN "direct_supporter_snapshot" AS "ds"
3284 ON "di"."member_id" = "ds"."member_id"
3285 WHERE "di"."issue_id" = "issue_id_p"
3286 AND "di"."event" = 'periodic'
3287 AND "ds"."initiative_id" = "initiative_id_v"
3288 AND "ds"."event" = 'periodic'
3289 AND "ds"."informed"
3290 ),
3291 "satisfied_supporter_count" = (
3292 SELECT coalesce(sum("di"."weight"), 0)
3293 FROM "direct_interest_snapshot" AS "di"
3294 JOIN "direct_supporter_snapshot" AS "ds"
3295 ON "di"."member_id" = "ds"."member_id"
3296 WHERE "di"."issue_id" = "issue_id_p"
3297 AND "di"."event" = 'periodic'
3298 AND "ds"."initiative_id" = "initiative_id_v"
3299 AND "ds"."event" = 'periodic'
3300 AND "ds"."satisfied"
3301 ),
3302 "satisfied_informed_supporter_count" = (
3303 SELECT coalesce(sum("di"."weight"), 0)
3304 FROM "direct_interest_snapshot" AS "di"
3305 JOIN "direct_supporter_snapshot" AS "ds"
3306 ON "di"."member_id" = "ds"."member_id"
3307 WHERE "di"."issue_id" = "issue_id_p"
3308 AND "di"."event" = 'periodic'
3309 AND "ds"."initiative_id" = "initiative_id_v"
3310 AND "ds"."event" = 'periodic'
3311 AND "ds"."informed"
3312 AND "ds"."satisfied"
3314 WHERE "id" = "initiative_id_v";
3315 FOR "suggestion_id_v" IN
3316 SELECT "id" FROM "suggestion"
3317 WHERE "initiative_id" = "initiative_id_v"
3318 LOOP
3319 UPDATE "suggestion" SET
3320 "minus2_unfulfilled_count" = (
3321 SELECT coalesce(sum("snapshot"."weight"), 0)
3322 FROM "issue" CROSS JOIN "opinion"
3323 JOIN "direct_interest_snapshot" AS "snapshot"
3324 ON "snapshot"."issue_id" = "issue"."id"
3325 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3326 AND "snapshot"."member_id" = "opinion"."member_id"
3327 WHERE "issue"."id" = "issue_id_p"
3328 AND "opinion"."suggestion_id" = "suggestion_id_v"
3329 AND "opinion"."degree" = -2
3330 AND "opinion"."fulfilled" = FALSE
3331 ),
3332 "minus2_fulfilled_count" = (
3333 SELECT coalesce(sum("snapshot"."weight"), 0)
3334 FROM "issue" CROSS JOIN "opinion"
3335 JOIN "direct_interest_snapshot" AS "snapshot"
3336 ON "snapshot"."issue_id" = "issue"."id"
3337 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3338 AND "snapshot"."member_id" = "opinion"."member_id"
3339 WHERE "issue"."id" = "issue_id_p"
3340 AND "opinion"."suggestion_id" = "suggestion_id_v"
3341 AND "opinion"."degree" = -2
3342 AND "opinion"."fulfilled" = TRUE
3343 ),
3344 "minus1_unfulfilled_count" = (
3345 SELECT coalesce(sum("snapshot"."weight"), 0)
3346 FROM "issue" CROSS JOIN "opinion"
3347 JOIN "direct_interest_snapshot" AS "snapshot"
3348 ON "snapshot"."issue_id" = "issue"."id"
3349 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3350 AND "snapshot"."member_id" = "opinion"."member_id"
3351 WHERE "issue"."id" = "issue_id_p"
3352 AND "opinion"."suggestion_id" = "suggestion_id_v"
3353 AND "opinion"."degree" = -1
3354 AND "opinion"."fulfilled" = FALSE
3355 ),
3356 "minus1_fulfilled_count" = (
3357 SELECT coalesce(sum("snapshot"."weight"), 0)
3358 FROM "issue" CROSS JOIN "opinion"
3359 JOIN "direct_interest_snapshot" AS "snapshot"
3360 ON "snapshot"."issue_id" = "issue"."id"
3361 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3362 AND "snapshot"."member_id" = "opinion"."member_id"
3363 WHERE "issue"."id" = "issue_id_p"
3364 AND "opinion"."suggestion_id" = "suggestion_id_v"
3365 AND "opinion"."degree" = -1
3366 AND "opinion"."fulfilled" = TRUE
3367 ),
3368 "plus1_unfulfilled_count" = (
3369 SELECT coalesce(sum("snapshot"."weight"), 0)
3370 FROM "issue" CROSS JOIN "opinion"
3371 JOIN "direct_interest_snapshot" AS "snapshot"
3372 ON "snapshot"."issue_id" = "issue"."id"
3373 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3374 AND "snapshot"."member_id" = "opinion"."member_id"
3375 WHERE "issue"."id" = "issue_id_p"
3376 AND "opinion"."suggestion_id" = "suggestion_id_v"
3377 AND "opinion"."degree" = 1
3378 AND "opinion"."fulfilled" = FALSE
3379 ),
3380 "plus1_fulfilled_count" = (
3381 SELECT coalesce(sum("snapshot"."weight"), 0)
3382 FROM "issue" CROSS JOIN "opinion"
3383 JOIN "direct_interest_snapshot" AS "snapshot"
3384 ON "snapshot"."issue_id" = "issue"."id"
3385 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3386 AND "snapshot"."member_id" = "opinion"."member_id"
3387 WHERE "issue"."id" = "issue_id_p"
3388 AND "opinion"."suggestion_id" = "suggestion_id_v"
3389 AND "opinion"."degree" = 1
3390 AND "opinion"."fulfilled" = TRUE
3391 ),
3392 "plus2_unfulfilled_count" = (
3393 SELECT coalesce(sum("snapshot"."weight"), 0)
3394 FROM "issue" CROSS JOIN "opinion"
3395 JOIN "direct_interest_snapshot" AS "snapshot"
3396 ON "snapshot"."issue_id" = "issue"."id"
3397 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3398 AND "snapshot"."member_id" = "opinion"."member_id"
3399 WHERE "issue"."id" = "issue_id_p"
3400 AND "opinion"."suggestion_id" = "suggestion_id_v"
3401 AND "opinion"."degree" = 2
3402 AND "opinion"."fulfilled" = FALSE
3403 ),
3404 "plus2_fulfilled_count" = (
3405 SELECT coalesce(sum("snapshot"."weight"), 0)
3406 FROM "issue" CROSS JOIN "opinion"
3407 JOIN "direct_interest_snapshot" AS "snapshot"
3408 ON "snapshot"."issue_id" = "issue"."id"
3409 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3410 AND "snapshot"."member_id" = "opinion"."member_id"
3411 WHERE "issue"."id" = "issue_id_p"
3412 AND "opinion"."suggestion_id" = "suggestion_id_v"
3413 AND "opinion"."degree" = 2
3414 AND "opinion"."fulfilled" = TRUE
3416 WHERE "suggestion"."id" = "suggestion_id_v";
3417 END LOOP;
3418 END LOOP;
3419 RETURN;
3420 END;
3421 $$;
3423 COMMENT ON FUNCTION "create_snapshot"
3424 ( "issue"."id"%TYPE )
3425 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.';
3428 CREATE FUNCTION "set_snapshot_event"
3429 ( "issue_id_p" "issue"."id"%TYPE,
3430 "event_p" "snapshot_event" )
3431 RETURNS VOID
3432 LANGUAGE 'plpgsql' VOLATILE AS $$
3433 DECLARE
3434 "event_v" "issue"."latest_snapshot_event"%TYPE;
3435 BEGIN
3436 PERFORM "require_transaction_isolation"();
3437 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3438 WHERE "id" = "issue_id_p" FOR UPDATE;
3439 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3440 WHERE "id" = "issue_id_p";
3441 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3442 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3443 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3444 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3445 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3446 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3447 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3448 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3449 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3450 FROM "initiative" -- NOTE: due to missing index on issue_id
3451 WHERE "initiative"."issue_id" = "issue_id_p"
3452 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3453 AND "direct_supporter_snapshot"."event" = "event_v";
3454 RETURN;
3455 END;
3456 $$;
3458 COMMENT ON FUNCTION "set_snapshot_event"
3459 ( "issue"."id"%TYPE,
3460 "snapshot_event" )
3461 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3465 -----------------------
3466 -- Counting of votes --
3467 -----------------------
3470 CREATE FUNCTION "weight_of_added_vote_delegations"
3471 ( "issue_id_p" "issue"."id"%TYPE,
3472 "member_id_p" "member"."id"%TYPE,
3473 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3474 RETURNS "direct_voter"."weight"%TYPE
3475 LANGUAGE 'plpgsql' VOLATILE AS $$
3476 DECLARE
3477 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3478 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3479 "weight_v" INT4;
3480 "sub_weight_v" INT4;
3481 BEGIN
3482 PERFORM "require_transaction_isolation"();
3483 "weight_v" := 0;
3484 FOR "issue_delegation_row" IN
3485 SELECT * FROM "issue_delegation"
3486 WHERE "trustee_id" = "member_id_p"
3487 AND "issue_id" = "issue_id_p"
3488 LOOP
3489 IF NOT EXISTS (
3490 SELECT NULL FROM "direct_voter"
3491 WHERE "member_id" = "issue_delegation_row"."truster_id"
3492 AND "issue_id" = "issue_id_p"
3493 ) AND NOT EXISTS (
3494 SELECT NULL FROM "delegating_voter"
3495 WHERE "member_id" = "issue_delegation_row"."truster_id"
3496 AND "issue_id" = "issue_id_p"
3497 ) THEN
3498 "delegate_member_ids_v" :=
3499 "member_id_p" || "delegate_member_ids_p";
3500 INSERT INTO "delegating_voter" (
3501 "issue_id",
3502 "member_id",
3503 "scope",
3504 "delegate_member_ids"
3505 ) VALUES (
3506 "issue_id_p",
3507 "issue_delegation_row"."truster_id",
3508 "issue_delegation_row"."scope",
3509 "delegate_member_ids_v"
3510 );
3511 "sub_weight_v" := 1 +
3512 "weight_of_added_vote_delegations"(
3513 "issue_id_p",
3514 "issue_delegation_row"."truster_id",
3515 "delegate_member_ids_v"
3516 );
3517 UPDATE "delegating_voter"
3518 SET "weight" = "sub_weight_v"
3519 WHERE "issue_id" = "issue_id_p"
3520 AND "member_id" = "issue_delegation_row"."truster_id";
3521 "weight_v" := "weight_v" + "sub_weight_v";
3522 END IF;
3523 END LOOP;
3524 RETURN "weight_v";
3525 END;
3526 $$;
3528 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3529 ( "issue"."id"%TYPE,
3530 "member"."id"%TYPE,
3531 "delegating_voter"."delegate_member_ids"%TYPE )
3532 IS 'Helper function for "add_vote_delegations" function';
3535 CREATE FUNCTION "add_vote_delegations"
3536 ( "issue_id_p" "issue"."id"%TYPE )
3537 RETURNS VOID
3538 LANGUAGE 'plpgsql' VOLATILE AS $$
3539 DECLARE
3540 "member_id_v" "member"."id"%TYPE;
3541 BEGIN
3542 PERFORM "require_transaction_isolation"();
3543 FOR "member_id_v" IN
3544 SELECT "member_id" FROM "direct_voter"
3545 WHERE "issue_id" = "issue_id_p"
3546 LOOP
3547 UPDATE "direct_voter" SET
3548 "weight" = "weight" + "weight_of_added_vote_delegations"(
3549 "issue_id_p",
3550 "member_id_v",
3551 '{}'
3553 WHERE "member_id" = "member_id_v"
3554 AND "issue_id" = "issue_id_p";
3555 END LOOP;
3556 RETURN;
3557 END;
3558 $$;
3560 COMMENT ON FUNCTION "add_vote_delegations"
3561 ( "issue_id_p" "issue"."id"%TYPE )
3562 IS 'Helper function for "close_voting" function';
3565 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3566 RETURNS VOID
3567 LANGUAGE 'plpgsql' VOLATILE AS $$
3568 DECLARE
3569 "area_id_v" "area"."id"%TYPE;
3570 "unit_id_v" "unit"."id"%TYPE;
3571 "member_id_v" "member"."id"%TYPE;
3572 BEGIN
3573 PERFORM "require_transaction_isolation"();
3574 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3575 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3576 -- delete timestamp of voting comment:
3577 UPDATE "direct_voter" SET "comment_changed" = NULL
3578 WHERE "issue_id" = "issue_id_p";
3579 -- delete delegating votes (in cases of manual reset of issue state):
3580 DELETE FROM "delegating_voter"
3581 WHERE "issue_id" = "issue_id_p";
3582 -- delete votes from non-privileged voters:
3583 DELETE FROM "direct_voter"
3584 USING (
3585 SELECT
3586 "direct_voter"."member_id"
3587 FROM "direct_voter"
3588 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3589 LEFT JOIN "privilege"
3590 ON "privilege"."unit_id" = "unit_id_v"
3591 AND "privilege"."member_id" = "direct_voter"."member_id"
3592 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3593 "member"."active" = FALSE OR
3594 "privilege"."voting_right" ISNULL OR
3595 "privilege"."voting_right" = FALSE
3597 ) AS "subquery"
3598 WHERE "direct_voter"."issue_id" = "issue_id_p"
3599 AND "direct_voter"."member_id" = "subquery"."member_id";
3600 -- consider delegations:
3601 UPDATE "direct_voter" SET "weight" = 1
3602 WHERE "issue_id" = "issue_id_p";
3603 PERFORM "add_vote_delegations"("issue_id_p");
3604 -- materialize battle_view:
3605 -- NOTE: "closed" column of issue must be set at this point
3606 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3607 INSERT INTO "battle" (
3608 "issue_id",
3609 "winning_initiative_id", "losing_initiative_id",
3610 "count"
3611 ) SELECT
3612 "issue_id",
3613 "winning_initiative_id", "losing_initiative_id",
3614 "count"
3615 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3616 -- set voter count:
3617 UPDATE "issue" SET
3618 "voter_count" = (
3619 SELECT coalesce(sum("weight"), 0)
3620 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3622 WHERE "id" = "issue_id_p";
3623 -- copy "positive_votes" and "negative_votes" from "battle" table:
3624 UPDATE "initiative" SET
3625 "positive_votes" = "battle_win"."count",
3626 "negative_votes" = "battle_lose"."count"
3627 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3628 WHERE
3629 "battle_win"."issue_id" = "issue_id_p" AND
3630 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3631 "battle_win"."losing_initiative_id" ISNULL AND
3632 "battle_lose"."issue_id" = "issue_id_p" AND
3633 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3634 "battle_lose"."winning_initiative_id" ISNULL;
3635 END;
3636 $$;
3638 COMMENT ON FUNCTION "close_voting"
3639 ( "issue"."id"%TYPE )
3640 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.';
3643 CREATE FUNCTION "defeat_strength"
3644 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3645 RETURNS INT8
3646 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3647 BEGIN
3648 IF "positive_votes_p" > "negative_votes_p" THEN
3649 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3650 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3651 RETURN 0;
3652 ELSE
3653 RETURN -1;
3654 END IF;
3655 END;
3656 $$;
3658 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';
3661 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3662 RETURNS VOID
3663 LANGUAGE 'plpgsql' VOLATILE AS $$
3664 DECLARE
3665 "issue_row" "issue"%ROWTYPE;
3666 "policy_row" "policy"%ROWTYPE;
3667 "dimension_v" INTEGER;
3668 "vote_matrix" INT4[][]; -- absolute votes
3669 "matrix" INT8[][]; -- defeat strength / best paths
3670 "i" INTEGER;
3671 "j" INTEGER;
3672 "k" INTEGER;
3673 "battle_row" "battle"%ROWTYPE;
3674 "rank_ary" INT4[];
3675 "rank_v" INT4;
3676 "done_v" INTEGER;
3677 "winners_ary" INTEGER[];
3678 "initiative_id_v" "initiative"."id"%TYPE;
3679 BEGIN
3680 PERFORM "require_transaction_isolation"();
3681 SELECT * INTO "issue_row"
3682 FROM "issue" WHERE "id" = "issue_id_p";
3683 SELECT * INTO "policy_row"
3684 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3685 SELECT count(1) INTO "dimension_v"
3686 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3687 -- Create "vote_matrix" with absolute number of votes in pairwise
3688 -- comparison:
3689 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3690 "i" := 1;
3691 "j" := 2;
3692 FOR "battle_row" IN
3693 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3694 ORDER BY
3695 "winning_initiative_id" NULLS LAST,
3696 "losing_initiative_id" NULLS LAST
3697 LOOP
3698 "vote_matrix"["i"]["j"] := "battle_row"."count";
3699 IF "j" = "dimension_v" THEN
3700 "i" := "i" + 1;
3701 "j" := 1;
3702 ELSE
3703 "j" := "j" + 1;
3704 IF "j" = "i" THEN
3705 "j" := "j" + 1;
3706 END IF;
3707 END IF;
3708 END LOOP;
3709 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3710 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3711 END IF;
3712 -- Store defeat strengths in "matrix" using "defeat_strength"
3713 -- function:
3714 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3715 "i" := 1;
3716 LOOP
3717 "j" := 1;
3718 LOOP
3719 IF "i" != "j" THEN
3720 "matrix"["i"]["j"] := "defeat_strength"(
3721 "vote_matrix"["i"]["j"],
3722 "vote_matrix"["j"]["i"]
3723 );
3724 END IF;
3725 EXIT WHEN "j" = "dimension_v";
3726 "j" := "j" + 1;
3727 END LOOP;
3728 EXIT WHEN "i" = "dimension_v";
3729 "i" := "i" + 1;
3730 END LOOP;
3731 -- Find best paths:
3732 "i" := 1;
3733 LOOP
3734 "j" := 1;
3735 LOOP
3736 IF "i" != "j" THEN
3737 "k" := 1;
3738 LOOP
3739 IF "i" != "k" AND "j" != "k" THEN
3740 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3741 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3742 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3743 END IF;
3744 ELSE
3745 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3746 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3747 END IF;
3748 END IF;
3749 END IF;
3750 EXIT WHEN "k" = "dimension_v";
3751 "k" := "k" + 1;
3752 END LOOP;
3753 END IF;
3754 EXIT WHEN "j" = "dimension_v";
3755 "j" := "j" + 1;
3756 END LOOP;
3757 EXIT WHEN "i" = "dimension_v";
3758 "i" := "i" + 1;
3759 END LOOP;
3760 -- Determine order of winners:
3761 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3762 "rank_v" := 1;
3763 "done_v" := 0;
3764 LOOP
3765 "winners_ary" := '{}';
3766 "i" := 1;
3767 LOOP
3768 IF "rank_ary"["i"] ISNULL THEN
3769 "j" := 1;
3770 LOOP
3771 IF
3772 "i" != "j" AND
3773 "rank_ary"["j"] ISNULL AND
3774 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3775 THEN
3776 -- someone else is better
3777 EXIT;
3778 END IF;
3779 IF "j" = "dimension_v" THEN
3780 -- noone is better
3781 "winners_ary" := "winners_ary" || "i";
3782 EXIT;
3783 END IF;
3784 "j" := "j" + 1;
3785 END LOOP;
3786 END IF;
3787 EXIT WHEN "i" = "dimension_v";
3788 "i" := "i" + 1;
3789 END LOOP;
3790 "i" := 1;
3791 LOOP
3792 "rank_ary"["winners_ary"["i"]] := "rank_v";
3793 "done_v" := "done_v" + 1;
3794 EXIT WHEN "i" = array_upper("winners_ary", 1);
3795 "i" := "i" + 1;
3796 END LOOP;
3797 EXIT WHEN "done_v" = "dimension_v";
3798 "rank_v" := "rank_v" + 1;
3799 END LOOP;
3800 -- write preliminary results:
3801 "i" := 1;
3802 FOR "initiative_id_v" IN
3803 SELECT "id" FROM "initiative"
3804 WHERE "issue_id" = "issue_id_p" AND "admitted"
3805 ORDER BY "id"
3806 LOOP
3807 UPDATE "initiative" SET
3808 "direct_majority" =
3809 CASE WHEN "policy_row"."direct_majority_strict" THEN
3810 "positive_votes" * "policy_row"."direct_majority_den" >
3811 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3812 ELSE
3813 "positive_votes" * "policy_row"."direct_majority_den" >=
3814 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3815 END
3816 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3817 AND "issue_row"."voter_count"-"negative_votes" >=
3818 "policy_row"."direct_majority_non_negative",
3819 "indirect_majority" =
3820 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3821 "positive_votes" * "policy_row"."indirect_majority_den" >
3822 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3823 ELSE
3824 "positive_votes" * "policy_row"."indirect_majority_den" >=
3825 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3826 END
3827 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3828 AND "issue_row"."voter_count"-"negative_votes" >=
3829 "policy_row"."indirect_majority_non_negative",
3830 "schulze_rank" = "rank_ary"["i"],
3831 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3832 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3833 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3834 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3835 "eligible" = FALSE,
3836 "winner" = FALSE,
3837 "rank" = NULL -- NOTE: in cases of manual reset of issue state
3838 WHERE "id" = "initiative_id_v";
3839 "i" := "i" + 1;
3840 END LOOP;
3841 IF "i" != "dimension_v" THEN
3842 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3843 END IF;
3844 -- take indirect majorities into account:
3845 LOOP
3846 UPDATE "initiative" SET "indirect_majority" = TRUE
3847 FROM (
3848 SELECT "new_initiative"."id" AS "initiative_id"
3849 FROM "initiative" "old_initiative"
3850 JOIN "initiative" "new_initiative"
3851 ON "new_initiative"."issue_id" = "issue_id_p"
3852 AND "new_initiative"."indirect_majority" = FALSE
3853 JOIN "battle" "battle_win"
3854 ON "battle_win"."issue_id" = "issue_id_p"
3855 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3856 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3857 JOIN "battle" "battle_lose"
3858 ON "battle_lose"."issue_id" = "issue_id_p"
3859 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3860 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3861 WHERE "old_initiative"."issue_id" = "issue_id_p"
3862 AND "old_initiative"."indirect_majority" = TRUE
3863 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3864 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3865 "policy_row"."indirect_majority_num" *
3866 ("battle_win"."count"+"battle_lose"."count")
3867 ELSE
3868 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3869 "policy_row"."indirect_majority_num" *
3870 ("battle_win"."count"+"battle_lose"."count")
3871 END
3872 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3873 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3874 "policy_row"."indirect_majority_non_negative"
3875 ) AS "subquery"
3876 WHERE "id" = "subquery"."initiative_id";
3877 EXIT WHEN NOT FOUND;
3878 END LOOP;
3879 -- set "multistage_majority" for remaining matching initiatives:
3880 UPDATE "initiative" SET "multistage_majority" = TRUE
3881 FROM (
3882 SELECT "losing_initiative"."id" AS "initiative_id"
3883 FROM "initiative" "losing_initiative"
3884 JOIN "initiative" "winning_initiative"
3885 ON "winning_initiative"."issue_id" = "issue_id_p"
3886 AND "winning_initiative"."admitted"
3887 JOIN "battle" "battle_win"
3888 ON "battle_win"."issue_id" = "issue_id_p"
3889 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3890 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3891 JOIN "battle" "battle_lose"
3892 ON "battle_lose"."issue_id" = "issue_id_p"
3893 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3894 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3895 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3896 AND "losing_initiative"."admitted"
3897 AND "winning_initiative"."schulze_rank" <
3898 "losing_initiative"."schulze_rank"
3899 AND "battle_win"."count" > "battle_lose"."count"
3900 AND (
3901 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3902 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3903 ) AS "subquery"
3904 WHERE "id" = "subquery"."initiative_id";
3905 -- mark eligible initiatives:
3906 UPDATE "initiative" SET "eligible" = TRUE
3907 WHERE "issue_id" = "issue_id_p"
3908 AND "initiative"."direct_majority"
3909 AND "initiative"."indirect_majority"
3910 AND "initiative"."better_than_status_quo"
3911 AND (
3912 "policy_row"."no_multistage_majority" = FALSE OR
3913 "initiative"."multistage_majority" = FALSE )
3914 AND (
3915 "policy_row"."no_reverse_beat_path" = FALSE OR
3916 "initiative"."reverse_beat_path" = FALSE );
3917 -- mark final winner:
3918 UPDATE "initiative" SET "winner" = TRUE
3919 FROM (
3920 SELECT "id" AS "initiative_id"
3921 FROM "initiative"
3922 WHERE "issue_id" = "issue_id_p" AND "eligible"
3923 ORDER BY
3924 "schulze_rank",
3925 "id"
3926 LIMIT 1
3927 ) AS "subquery"
3928 WHERE "id" = "subquery"."initiative_id";
3929 -- write (final) ranks:
3930 "rank_v" := 1;
3931 FOR "initiative_id_v" IN
3932 SELECT "id"
3933 FROM "initiative"
3934 WHERE "issue_id" = "issue_id_p" AND "admitted"
3935 ORDER BY
3936 "winner" DESC,
3937 "eligible" DESC,
3938 "schulze_rank",
3939 "id"
3940 LOOP
3941 UPDATE "initiative" SET "rank" = "rank_v"
3942 WHERE "id" = "initiative_id_v";
3943 "rank_v" := "rank_v" + 1;
3944 END LOOP;
3945 -- set schulze rank of status quo and mark issue as finished:
3946 UPDATE "issue" SET
3947 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
3948 "state" =
3949 CASE WHEN EXISTS (
3950 SELECT NULL FROM "initiative"
3951 WHERE "issue_id" = "issue_id_p" AND "winner"
3952 ) THEN
3953 'finished_with_winner'::"issue_state"
3954 ELSE
3955 'finished_without_winner'::"issue_state"
3956 END,
3957 "closed" = "phase_finished",
3958 "phase_finished" = NULL
3959 WHERE "id" = "issue_id_p";
3960 RETURN;
3961 END;
3962 $$;
3964 COMMENT ON FUNCTION "calculate_ranks"
3965 ( "issue"."id"%TYPE )
3966 IS 'Determine ranking (Votes have to be counted first)';
3970 -----------------------------
3971 -- Automatic state changes --
3972 -----------------------------
3975 CREATE TYPE "check_issue_persistence" AS (
3976 "state" "issue_state",
3977 "phase_finished" BOOLEAN,
3978 "issue_revoked" BOOLEAN,
3979 "snapshot_created" BOOLEAN,
3980 "harmonic_weights_set" BOOLEAN,
3981 "closed_voting" BOOLEAN );
3983 COMMENT ON TYPE "check_issue_persistence" IS 'Type of data returned by "check_issue" function, to be passed to subsequent calls of the same function';
3986 CREATE FUNCTION "check_issue"
3987 ( "issue_id_p" "issue"."id"%TYPE,
3988 "persist" "check_issue_persistence" )
3989 RETURNS "check_issue_persistence"
3990 LANGUAGE 'plpgsql' VOLATILE AS $$
3991 DECLARE
3992 "issue_row" "issue"%ROWTYPE;
3993 "policy_row" "policy"%ROWTYPE;
3994 "initiative_row" "initiative"%ROWTYPE;
3995 "state_v" "issue_state";
3996 BEGIN
3997 PERFORM "require_transaction_isolation"();
3998 IF "persist" ISNULL THEN
3999 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4000 FOR UPDATE;
4001 IF "issue_row"."closed" NOTNULL THEN
4002 RETURN NULL;
4003 END IF;
4004 "persist"."state" := "issue_row"."state";
4005 IF
4006 ( "issue_row"."state" = 'admission' AND now() >=
4007 "issue_row"."created" + "issue_row"."admission_time" ) OR
4008 ( "issue_row"."state" = 'discussion' AND now() >=
4009 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4010 ( "issue_row"."state" = 'verification' AND now() >=
4011 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4012 ( "issue_row"."state" = 'voting' AND now() >=
4013 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4014 THEN
4015 "persist"."phase_finished" := TRUE;
4016 ELSE
4017 "persist"."phase_finished" := FALSE;
4018 END IF;
4019 IF
4020 NOT EXISTS (
4021 -- all initiatives are revoked
4022 SELECT NULL FROM "initiative"
4023 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4024 ) AND (
4025 -- and issue has not been accepted yet
4026 "persist"."state" = 'admission' OR
4027 -- or verification time has elapsed
4028 ( "persist"."state" = 'verification' AND
4029 "persist"."phase_finished" ) OR
4030 -- or no initiatives have been revoked lately
4031 NOT EXISTS (
4032 SELECT NULL FROM "initiative"
4033 WHERE "issue_id" = "issue_id_p"
4034 AND now() < "revoked" + "issue_row"."verification_time"
4037 THEN
4038 "persist"."issue_revoked" := TRUE;
4039 ELSE
4040 "persist"."issue_revoked" := FALSE;
4041 END IF;
4042 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4043 UPDATE "issue" SET "phase_finished" = now()
4044 WHERE "id" = "issue_row"."id";
4045 RETURN "persist";
4046 ELSIF
4047 "persist"."state" IN ('admission', 'discussion', 'verification')
4048 THEN
4049 RETURN "persist";
4050 ELSE
4051 RETURN NULL;
4052 END IF;
4053 END IF;
4054 IF
4055 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4056 coalesce("persist"."snapshot_created", FALSE) = FALSE
4057 THEN
4058 PERFORM "create_snapshot"("issue_id_p");
4059 "persist"."snapshot_created" = TRUE;
4060 IF "persist"."phase_finished" THEN
4061 IF "persist"."state" = 'admission' THEN
4062 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4063 ELSIF "persist"."state" = 'discussion' THEN
4064 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4065 ELSIF "persist"."state" = 'verification' THEN
4066 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4067 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4068 SELECT * INTO "policy_row" FROM "policy"
4069 WHERE "id" = "issue_row"."policy_id";
4070 FOR "initiative_row" IN
4071 SELECT * FROM "initiative"
4072 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4073 FOR UPDATE
4074 LOOP
4075 IF
4076 "initiative_row"."polling" OR (
4077 "initiative_row"."satisfied_supporter_count" > 0 AND
4078 "initiative_row"."satisfied_supporter_count" *
4079 "policy_row"."initiative_quorum_den" >=
4080 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4082 THEN
4083 UPDATE "initiative" SET "admitted" = TRUE
4084 WHERE "id" = "initiative_row"."id";
4085 ELSE
4086 UPDATE "initiative" SET "admitted" = FALSE
4087 WHERE "id" = "initiative_row"."id";
4088 END IF;
4089 END LOOP;
4090 END IF;
4091 END IF;
4092 RETURN "persist";
4093 END IF;
4094 IF
4095 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4096 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4097 THEN
4098 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4099 "persist"."harmonic_weights_set" = TRUE;
4100 IF
4101 "persist"."phase_finished" OR
4102 "persist"."issue_revoked" OR
4103 "persist"."state" = 'admission'
4104 THEN
4105 RETURN "persist";
4106 ELSE
4107 RETURN NULL;
4108 END IF;
4109 END IF;
4110 IF "persist"."issue_revoked" THEN
4111 IF "persist"."state" = 'admission' THEN
4112 "state_v" := 'canceled_revoked_before_accepted';
4113 ELSIF "persist"."state" = 'discussion' THEN
4114 "state_v" := 'canceled_after_revocation_during_discussion';
4115 ELSIF "persist"."state" = 'verification' THEN
4116 "state_v" := 'canceled_after_revocation_during_verification';
4117 END IF;
4118 UPDATE "issue" SET
4119 "state" = "state_v",
4120 "closed" = "phase_finished",
4121 "phase_finished" = NULL
4122 WHERE "id" = "issue_id_p";
4123 RETURN NULL;
4124 END IF;
4125 IF "persist"."state" = 'admission' THEN
4126 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4127 FOR UPDATE;
4128 SELECT * INTO "policy_row"
4129 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4130 IF EXISTS (
4131 SELECT NULL FROM "initiative"
4132 WHERE "issue_id" = "issue_id_p"
4133 AND "supporter_count" > 0
4134 AND "supporter_count" * "policy_row"."issue_quorum_den"
4135 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4136 ) THEN
4137 UPDATE "issue" SET
4138 "state" = 'discussion',
4139 "accepted" = coalesce("phase_finished", now()),
4140 "phase_finished" = NULL
4141 WHERE "id" = "issue_id_p";
4142 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4143 UPDATE "issue" SET
4144 "state" = 'canceled_issue_not_accepted',
4145 "closed" = "phase_finished",
4146 "phase_finished" = NULL
4147 WHERE "id" = "issue_id_p";
4148 END IF;
4149 RETURN NULL;
4150 END IF;
4151 IF "persist"."phase_finished" THEN
4152 if "persist"."state" = 'discussion' THEN
4153 UPDATE "issue" SET
4154 "state" = 'verification',
4155 "half_frozen" = "phase_finished",
4156 "phase_finished" = NULL
4157 WHERE "id" = "issue_id_p";
4158 RETURN NULL;
4159 END IF;
4160 IF "persist"."state" = 'verification' THEN
4161 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4162 FOR UPDATE;
4163 SELECT * INTO "policy_row" FROM "policy"
4164 WHERE "id" = "issue_row"."policy_id";
4165 IF EXISTS (
4166 SELECT NULL FROM "initiative"
4167 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4168 ) THEN
4169 UPDATE "issue" SET
4170 "state" = 'voting',
4171 "accepted" = coalesce("accepted", "phase_finished"),
4172 "half_frozen" = coalesce("half_frozen", "phase_finished"),
4173 "fully_frozen" = "phase_finished",
4174 "phase_finished" = NULL
4175 WHERE "id" = "issue_id_p";
4176 ELSE
4177 UPDATE "issue" SET
4178 "state" = 'canceled_no_initiative_admitted',
4179 "accepted" = coalesce("accepted", "phase_finished"),
4180 "half_frozen" = coalesce("half_frozen", "phase_finished"),
4181 "fully_frozen" = "phase_finished",
4182 "closed" = "phase_finished",
4183 "phase_finished" = NULL
4184 WHERE "id" = "issue_id_p";
4185 -- NOTE: The following DELETE statements have effect only when
4186 -- issue state has been manipulated
4187 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4188 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4189 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4190 END IF;
4191 RETURN NULL;
4192 END IF;
4193 IF "persist"."state" = 'voting' THEN
4194 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4195 PERFORM "close_voting"("issue_id_p");
4196 "persist"."closed_voting" = TRUE;
4197 RETURN "persist";
4198 END IF;
4199 PERFORM "calculate_ranks"("issue_id_p");
4200 RETURN NULL;
4201 END IF;
4202 END IF;
4203 RAISE WARNING 'should not happen';
4204 RETURN NULL;
4205 END;
4206 $$;
4208 COMMENT ON FUNCTION "check_issue"
4209 ( "issue"."id"%TYPE,
4210 "check_issue_persistence" )
4211 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required, and perform the status change when necessary; Function must be called multiple times with the previous result as second parameter, until the result is NULL (see source code of function "check_everything")';
4214 CREATE FUNCTION "check_everything"()
4215 RETURNS VOID
4216 LANGUAGE 'plpgsql' VOLATILE AS $$
4217 DECLARE
4218 "issue_id_v" "issue"."id"%TYPE;
4219 "persist_v" "check_issue_persistence";
4220 BEGIN
4221 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4222 DELETE FROM "expired_session";
4223 PERFORM "check_activity"();
4224 PERFORM "calculate_member_counts"();
4225 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4226 "persist_v" := NULL;
4227 LOOP
4228 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4229 EXIT WHEN "persist_v" ISNULL;
4230 END LOOP;
4231 END LOOP;
4232 RETURN;
4233 END;
4234 $$;
4236 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue. Use this function only for development and debugging purposes, as you may run into locking and/or serialization problems in productive environments.';
4240 ----------------------
4241 -- Deletion of data --
4242 ----------------------
4245 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4246 RETURNS VOID
4247 LANGUAGE 'plpgsql' VOLATILE AS $$
4248 DECLARE
4249 "issue_row" "issue"%ROWTYPE;
4250 BEGIN
4251 SELECT * INTO "issue_row"
4252 FROM "issue" WHERE "id" = "issue_id_p"
4253 FOR UPDATE;
4254 IF "issue_row"."cleaned" ISNULL THEN
4255 UPDATE "issue" SET
4256 "state" = 'voting',
4257 "closed" = NULL,
4258 "ranks_available" = FALSE
4259 WHERE "id" = "issue_id_p";
4260 DELETE FROM "delegating_voter"
4261 WHERE "issue_id" = "issue_id_p";
4262 DELETE FROM "direct_voter"
4263 WHERE "issue_id" = "issue_id_p";
4264 DELETE FROM "delegating_interest_snapshot"
4265 WHERE "issue_id" = "issue_id_p";
4266 DELETE FROM "direct_interest_snapshot"
4267 WHERE "issue_id" = "issue_id_p";
4268 DELETE FROM "delegating_population_snapshot"
4269 WHERE "issue_id" = "issue_id_p";
4270 DELETE FROM "direct_population_snapshot"
4271 WHERE "issue_id" = "issue_id_p";
4272 DELETE FROM "non_voter"
4273 WHERE "issue_id" = "issue_id_p";
4274 DELETE FROM "delegation"
4275 WHERE "issue_id" = "issue_id_p";
4276 DELETE FROM "supporter"
4277 USING "initiative" -- NOTE: due to missing index on issue_id
4278 WHERE "initiative"."issue_id" = "issue_id_p"
4279 AND "supporter"."initiative_id" = "initiative_id";
4280 UPDATE "issue" SET
4281 "state" = "issue_row"."state",
4282 "closed" = "issue_row"."closed",
4283 "ranks_available" = "issue_row"."ranks_available",
4284 "cleaned" = now()
4285 WHERE "id" = "issue_id_p";
4286 END IF;
4287 RETURN;
4288 END;
4289 $$;
4291 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4294 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4295 RETURNS VOID
4296 LANGUAGE 'plpgsql' VOLATILE AS $$
4297 BEGIN
4298 UPDATE "member" SET
4299 "last_login" = NULL,
4300 "login" = NULL,
4301 "password" = NULL,
4302 "locked" = TRUE,
4303 "active" = FALSE,
4304 "notify_email" = NULL,
4305 "notify_email_unconfirmed" = NULL,
4306 "notify_email_secret" = NULL,
4307 "notify_email_secret_expiry" = NULL,
4308 "notify_email_lock_expiry" = NULL,
4309 "password_reset_secret" = NULL,
4310 "password_reset_secret_expiry" = NULL,
4311 "organizational_unit" = NULL,
4312 "internal_posts" = NULL,
4313 "realname" = NULL,
4314 "birthday" = NULL,
4315 "address" = NULL,
4316 "email" = NULL,
4317 "xmpp_address" = NULL,
4318 "website" = NULL,
4319 "phone" = NULL,
4320 "mobile_phone" = NULL,
4321 "profession" = NULL,
4322 "external_memberships" = NULL,
4323 "external_posts" = NULL,
4324 "statement" = NULL
4325 WHERE "id" = "member_id_p";
4326 -- "text_search_data" is updated by triggers
4327 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4328 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4329 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4330 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4331 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4332 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4333 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4334 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4335 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4336 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4337 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4338 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4339 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4340 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4341 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4342 DELETE FROM "direct_voter" USING "issue"
4343 WHERE "direct_voter"."issue_id" = "issue"."id"
4344 AND "issue"."closed" ISNULL
4345 AND "member_id" = "member_id_p";
4346 RETURN;
4347 END;
4348 $$;
4350 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)';
4353 CREATE FUNCTION "delete_private_data"()
4354 RETURNS VOID
4355 LANGUAGE 'plpgsql' VOLATILE AS $$
4356 BEGIN
4357 DELETE FROM "member" WHERE "activated" ISNULL;
4358 UPDATE "member" SET
4359 "invite_code" = NULL,
4360 "invite_code_expiry" = NULL,
4361 "admin_comment" = NULL,
4362 "last_login" = NULL,
4363 "login" = NULL,
4364 "password" = NULL,
4365 "lang" = NULL,
4366 "notify_email" = NULL,
4367 "notify_email_unconfirmed" = NULL,
4368 "notify_email_secret" = NULL,
4369 "notify_email_secret_expiry" = NULL,
4370 "notify_email_lock_expiry" = NULL,
4371 "notify_level" = NULL,
4372 "password_reset_secret" = NULL,
4373 "password_reset_secret_expiry" = NULL,
4374 "organizational_unit" = NULL,
4375 "internal_posts" = NULL,
4376 "realname" = NULL,
4377 "birthday" = NULL,
4378 "address" = NULL,
4379 "email" = NULL,
4380 "xmpp_address" = NULL,
4381 "website" = NULL,
4382 "phone" = NULL,
4383 "mobile_phone" = NULL,
4384 "profession" = NULL,
4385 "external_memberships" = NULL,
4386 "external_posts" = NULL,
4387 "formatting_engine" = NULL,
4388 "statement" = NULL;
4389 -- "text_search_data" is updated by triggers
4390 DELETE FROM "setting";
4391 DELETE FROM "setting_map";
4392 DELETE FROM "member_relation_setting";
4393 DELETE FROM "member_image";
4394 DELETE FROM "contact";
4395 DELETE FROM "ignored_member";
4396 DELETE FROM "session";
4397 DELETE FROM "area_setting";
4398 DELETE FROM "issue_setting";
4399 DELETE FROM "ignored_initiative";
4400 DELETE FROM "initiative_setting";
4401 DELETE FROM "suggestion_setting";
4402 DELETE FROM "non_voter";
4403 DELETE FROM "direct_voter" USING "issue"
4404 WHERE "direct_voter"."issue_id" = "issue"."id"
4405 AND "issue"."closed" ISNULL;
4406 RETURN;
4407 END;
4408 $$;
4410 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.';
4414 COMMIT;

Impressum / About Us