liquid_feedback_core

view core.sql @ 264:c8cd87b87708

Changed Makefile: Placed argument for the linked library after the source file that uses its symbols
author jbe
date Tue Aug 07 12:25:02 2012 +0200 (2012-08-07)
parents 30465830ad9c
children e3c9f737a096
line source
2 -- Execute the following command manually for PostgreSQL prior version 9.0:
3 -- CREATE LANGUAGE plpgsql;
5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
7 BEGIN;
9 CREATE VIEW "liquid_feedback_version" AS
10 SELECT * FROM (VALUES ('2.1.0', 2, 1, 0))
11 AS "subquery"("string", "major", "minor", "revision");
15 ----------------------
16 -- Full text search --
17 ----------------------
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
21 RETURNS TSQUERY
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
23 BEGIN
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
25 END;
26 $$;
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
31 CREATE FUNCTION "highlight"
32 ( "body_p" TEXT,
33 "query_text_p" TEXT )
34 RETURNS TEXT
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
36 BEGIN
37 RETURN ts_headline(
38 'pg_catalog.simple',
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
40 "text_search_query"("query_text_p"),
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
42 END;
43 $$;
45 COMMENT ON FUNCTION "highlight"
46 ( "body_p" TEXT,
47 "query_text_p" TEXT )
48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
52 -------------------------
53 -- Tables and indicies --
54 -------------------------
57 CREATE TABLE "system_setting" (
58 "member_ttl" INTERVAL );
59 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
61 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
62 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
64 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
67 CREATE TABLE "contingent" (
68 "time_frame" INTERVAL PRIMARY KEY,
69 "text_entry_limit" INT4,
70 "initiative_limit" INT4 );
72 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
74 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
75 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
78 CREATE TYPE "notify_level" AS ENUM
79 ('none', 'voting', 'verification', 'discussion', 'all');
81 COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything';
84 CREATE TABLE "member" (
85 "id" SERIAL4 PRIMARY KEY,
86 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
87 "invite_code" TEXT UNIQUE,
88 "invite_code_expiry" TIMESTAMPTZ,
89 "admin_comment" TEXT,
90 "activated" TIMESTAMPTZ,
91 "last_activity" DATE,
92 "last_login" TIMESTAMPTZ,
93 "login" TEXT UNIQUE,
94 "password" TEXT,
95 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
96 "active" BOOLEAN NOT NULL DEFAULT FALSE,
97 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
98 "lang" TEXT,
99 "notify_email" TEXT,
100 "notify_email_unconfirmed" TEXT,
101 "notify_email_secret" TEXT UNIQUE,
102 "notify_email_secret_expiry" TIMESTAMPTZ,
103 "notify_email_lock_expiry" TIMESTAMPTZ,
104 "notify_level" "notify_level",
105 "password_reset_secret" TEXT UNIQUE,
106 "password_reset_secret_expiry" TIMESTAMPTZ,
107 "name" TEXT UNIQUE,
108 "identification" TEXT UNIQUE,
109 "authentication" TEXT,
110 "organizational_unit" TEXT,
111 "internal_posts" TEXT,
112 "realname" TEXT,
113 "birthday" DATE,
114 "address" TEXT,
115 "email" TEXT,
116 "xmpp_address" TEXT,
117 "website" TEXT,
118 "phone" TEXT,
119 "mobile_phone" TEXT,
120 "profession" TEXT,
121 "external_memberships" TEXT,
122 "external_posts" TEXT,
123 "formatting_engine" TEXT,
124 "statement" TEXT,
125 "text_search_data" TSVECTOR,
126 CONSTRAINT "active_requires_activated_and_last_activity"
127 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
128 CONSTRAINT "name_not_null_if_activated"
129 CHECK ("activated" ISNULL OR "name" NOTNULL) );
130 CREATE INDEX "member_active_idx" ON "member" ("active");
131 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
132 CREATE TRIGGER "update_text_search_data"
133 BEFORE INSERT OR UPDATE ON "member"
134 FOR EACH ROW EXECUTE PROCEDURE
135 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
136 "name", "identification", "organizational_unit", "internal_posts",
137 "realname", "external_memberships", "external_posts", "statement" );
139 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
141 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
142 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
143 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
144 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
145 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
146 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
147 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
148 COMMENT ON COLUMN "member"."login" IS 'Login name';
149 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
150 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
151 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
152 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
153 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
154 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
155 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
156 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
157 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
158 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
159 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address, may be NULL if member did not make any selection yet';
160 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
161 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
162 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
163 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
164 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
165 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
166 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
167 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
168 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
169 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
170 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
173 CREATE TYPE "application_access_level" AS ENUM
174 ('member', 'full', 'pseudonymous', 'anonymous');
176 COMMENT ON TYPE "application_access_level" IS 'Access privileges for applications using the API';
179 CREATE TABLE "member_application" (
180 "id" SERIAL8 PRIMARY KEY,
181 UNIQUE ("member_id", "name"),
182 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
183 ON DELETE CASCADE ON UPDATE CASCADE,
184 "name" TEXT NOT NULL,
185 "comment" TEXT,
186 "access_level" "application_access_level" NOT NULL,
187 "key" TEXT NOT NULL UNIQUE,
188 "last_usage" TIMESTAMPTZ );
190 COMMENT ON TABLE "member_application" IS 'Registered application being allowed to use the API';
193 CREATE TABLE "member_history" (
194 "id" SERIAL8 PRIMARY KEY,
195 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
196 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
197 "active" BOOLEAN NOT NULL,
198 "name" TEXT NOT NULL );
199 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
201 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
203 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
204 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
207 CREATE TABLE "rendered_member_statement" (
208 PRIMARY KEY ("member_id", "format"),
209 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
210 "format" TEXT,
211 "content" TEXT NOT NULL );
213 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)';
216 CREATE TABLE "setting" (
217 PRIMARY KEY ("member_id", "key"),
218 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
219 "key" TEXT NOT NULL,
220 "value" TEXT NOT NULL );
221 CREATE INDEX "setting_key_idx" ON "setting" ("key");
223 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
225 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
228 CREATE TABLE "setting_map" (
229 PRIMARY KEY ("member_id", "key", "subkey"),
230 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
231 "key" TEXT NOT NULL,
232 "subkey" TEXT NOT NULL,
233 "value" TEXT NOT NULL );
234 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
236 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
238 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
239 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
240 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
243 CREATE TABLE "member_relation_setting" (
244 PRIMARY KEY ("member_id", "key", "other_member_id"),
245 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
246 "key" TEXT NOT NULL,
247 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
248 "value" TEXT NOT NULL );
250 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
253 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
255 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
258 CREATE TABLE "member_image" (
259 PRIMARY KEY ("member_id", "image_type", "scaled"),
260 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
261 "image_type" "member_image_type",
262 "scaled" BOOLEAN,
263 "content_type" TEXT,
264 "data" BYTEA NOT NULL );
266 COMMENT ON TABLE "member_image" IS 'Images of members';
268 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
271 CREATE TABLE "member_count" (
272 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
273 "total_count" INT4 NOT NULL );
275 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';
277 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
278 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
281 CREATE TABLE "contact" (
282 PRIMARY KEY ("member_id", "other_member_id"),
283 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
284 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
285 "public" BOOLEAN NOT NULL DEFAULT FALSE,
286 CONSTRAINT "cant_save_yourself_as_contact"
287 CHECK ("member_id" != "other_member_id") );
288 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
290 COMMENT ON TABLE "contact" IS 'Contact lists';
292 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
293 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
294 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
297 CREATE TABLE "ignored_member" (
298 PRIMARY KEY ("member_id", "other_member_id"),
299 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
300 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
301 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
303 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
305 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
306 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
309 CREATE TABLE "session" (
310 "ident" TEXT PRIMARY KEY,
311 "additional_secret" TEXT,
312 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
313 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
314 "lang" TEXT );
315 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
317 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
319 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
320 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
321 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
322 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
325 CREATE TABLE "policy" (
326 "id" SERIAL4 PRIMARY KEY,
327 "index" INT4 NOT NULL,
328 "active" BOOLEAN NOT NULL DEFAULT TRUE,
329 "name" TEXT NOT NULL UNIQUE,
330 "description" TEXT NOT NULL DEFAULT '',
331 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
332 "admission_time" INTERVAL,
333 "discussion_time" INTERVAL,
334 "verification_time" INTERVAL,
335 "voting_time" INTERVAL,
336 "issue_quorum_num" INT4 NOT NULL,
337 "issue_quorum_den" INT4 NOT NULL,
338 "initiative_quorum_num" INT4 NOT NULL,
339 "initiative_quorum_den" INT4 NOT NULL,
340 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
341 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
342 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
343 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
344 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
345 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
346 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
347 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
348 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
349 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
350 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
351 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
352 CONSTRAINT "timing" CHECK (
353 ( "polling" = FALSE AND
354 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
355 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
356 ( "polling" = TRUE AND
357 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
358 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
359 ( "polling" = TRUE AND
360 "admission_time" ISNULL AND "discussion_time" ISNULL AND
361 "verification_time" ISNULL AND "voting_time" ISNULL ) ) );
362 CREATE INDEX "policy_active_idx" ON "policy" ("active");
364 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
366 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
367 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
368 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues, i.e. polls ("admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for issues)';
369 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
370 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
371 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"';
372 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'')';
373 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''';
374 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''';
375 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
376 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
377 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
378 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
379 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.';
380 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
381 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';
382 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';
383 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';
384 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.';
385 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';
386 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';
387 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.';
388 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").';
391 CREATE TABLE "unit" (
392 "id" SERIAL4 PRIMARY KEY,
393 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
394 "active" BOOLEAN NOT NULL DEFAULT TRUE,
395 "name" TEXT NOT NULL,
396 "description" TEXT NOT NULL DEFAULT '',
397 "member_count" INT4,
398 "text_search_data" TSVECTOR );
399 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
400 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
401 CREATE INDEX "unit_active_idx" ON "unit" ("active");
402 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
403 CREATE TRIGGER "update_text_search_data"
404 BEFORE INSERT OR UPDATE ON "unit"
405 FOR EACH ROW EXECUTE PROCEDURE
406 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
407 "name", "description" );
409 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
411 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
412 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
413 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
416 CREATE TABLE "unit_setting" (
417 PRIMARY KEY ("member_id", "key", "unit_id"),
418 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
419 "key" TEXT NOT NULL,
420 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
421 "value" TEXT NOT NULL );
423 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
426 CREATE TABLE "area" (
427 "id" SERIAL4 PRIMARY KEY,
428 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
429 "active" BOOLEAN NOT NULL DEFAULT TRUE,
430 "name" TEXT NOT NULL,
431 "description" TEXT NOT NULL DEFAULT '',
432 "direct_member_count" INT4,
433 "member_weight" INT4,
434 "text_search_data" TSVECTOR );
435 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
436 CREATE INDEX "area_active_idx" ON "area" ("active");
437 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
438 CREATE TRIGGER "update_text_search_data"
439 BEFORE INSERT OR UPDATE ON "area"
440 FOR EACH ROW EXECUTE PROCEDURE
441 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
442 "name", "description" );
444 COMMENT ON TABLE "area" IS 'Subject areas';
446 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
447 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"';
448 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
451 CREATE TABLE "area_setting" (
452 PRIMARY KEY ("member_id", "key", "area_id"),
453 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
454 "key" TEXT NOT NULL,
455 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
456 "value" TEXT NOT NULL );
458 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
461 CREATE TABLE "allowed_policy" (
462 PRIMARY KEY ("area_id", "policy_id"),
463 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
464 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
465 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
466 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
468 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
470 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
473 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
475 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';
478 CREATE TYPE "issue_state" AS ENUM (
479 'admission', 'discussion', 'verification', 'voting',
480 'canceled_revoked_before_accepted',
481 'canceled_issue_not_accepted',
482 'canceled_after_revocation_during_discussion',
483 'canceled_after_revocation_during_verification',
484 'calculation',
485 'canceled_no_initiative_admitted',
486 'finished_without_winner', 'finished_with_winner');
488 COMMENT ON TYPE "issue_state" IS 'State of issues';
491 CREATE TABLE "issue" (
492 "id" SERIAL4 PRIMARY KEY,
493 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
494 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
495 "state" "issue_state" NOT NULL DEFAULT 'admission',
496 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
497 "accepted" TIMESTAMPTZ,
498 "half_frozen" TIMESTAMPTZ,
499 "fully_frozen" TIMESTAMPTZ,
500 "closed" TIMESTAMPTZ,
501 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
502 "cleaned" TIMESTAMPTZ,
503 "admission_time" INTERVAL NOT NULL,
504 "discussion_time" INTERVAL NOT NULL,
505 "verification_time" INTERVAL NOT NULL,
506 "voting_time" INTERVAL NOT NULL,
507 "snapshot" TIMESTAMPTZ,
508 "latest_snapshot_event" "snapshot_event",
509 "population" INT4,
510 "voter_count" INT4,
511 "status_quo_schulze_rank" INT4,
512 CONSTRAINT "valid_state" CHECK ((
513 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
514 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
515 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
516 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
517 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
518 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
519 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
520 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
521 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
522 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
523 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
524 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
525 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
526 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
527 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
528 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
529 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
530 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
531 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
532 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
533 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
534 )),
535 CONSTRAINT "state_change_order" CHECK (
536 "created" <= "accepted" AND
537 "accepted" <= "half_frozen" AND
538 "half_frozen" <= "fully_frozen" AND
539 "fully_frozen" <= "closed" ),
540 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
541 "cleaned" ISNULL OR "closed" NOTNULL ),
542 CONSTRAINT "last_snapshot_on_full_freeze"
543 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
544 CONSTRAINT "freeze_requires_snapshot"
545 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
546 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
547 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
548 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
549 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
550 CREATE INDEX "issue_created_idx" ON "issue" ("created");
551 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
552 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
553 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
554 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
555 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
556 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
558 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
560 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
561 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.';
562 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.';
563 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.';
564 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
565 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
566 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
567 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
568 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
569 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
570 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
571 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';
572 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
573 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';
574 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
577 CREATE TABLE "issue_setting" (
578 PRIMARY KEY ("member_id", "key", "issue_id"),
579 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
580 "key" TEXT NOT NULL,
581 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
582 "value" TEXT NOT NULL );
584 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
587 CREATE TABLE "initiative" (
588 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
589 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
590 "id" SERIAL4 PRIMARY KEY,
591 "name" TEXT NOT NULL,
592 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
593 "discussion_url" TEXT,
594 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
595 "revoked" TIMESTAMPTZ,
596 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
597 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
598 "admitted" BOOLEAN,
599 "supporter_count" INT4,
600 "informed_supporter_count" INT4,
601 "satisfied_supporter_count" INT4,
602 "satisfied_informed_supporter_count" INT4,
603 "positive_votes" INT4,
604 "negative_votes" INT4,
605 "direct_majority" BOOLEAN,
606 "indirect_majority" BOOLEAN,
607 "schulze_rank" INT4,
608 "better_than_status_quo" BOOLEAN,
609 "worse_than_status_quo" BOOLEAN,
610 "reverse_beat_path" BOOLEAN,
611 "multistage_majority" BOOLEAN,
612 "eligible" BOOLEAN,
613 "winner" BOOLEAN,
614 "rank" INT4,
615 "text_search_data" TSVECTOR,
616 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
617 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
618 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
619 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
620 CONSTRAINT "revoked_initiatives_cant_be_admitted"
621 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
622 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
623 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
624 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
625 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
626 "schulze_rank" ISNULL AND
627 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
628 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
629 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
630 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
631 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
632 "eligible" = FALSE OR
633 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
634 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
635 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
636 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
637 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
638 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
639 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
640 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
641 CREATE TRIGGER "update_text_search_data"
642 BEFORE INSERT OR UPDATE ON "initiative"
643 FOR EACH ROW EXECUTE PROCEDURE
644 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
645 "name", "discussion_url");
647 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.';
649 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative is an option for a poll (see "policy"."polling"), and does not need to pass the initiative quorum';
650 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
651 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
652 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
653 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
654 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
655 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
656 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
657 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
658 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
659 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
660 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"';
661 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
662 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
663 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
664 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
665 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';
666 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';
667 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"';
668 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
669 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';
672 CREATE TABLE "battle" (
673 "issue_id" INT4 NOT NULL,
674 "winning_initiative_id" INT4,
675 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
676 "losing_initiative_id" INT4,
677 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
678 "count" INT4 NOT NULL,
679 CONSTRAINT "initiative_ids_not_equal" CHECK (
680 "winning_initiative_id" != "losing_initiative_id" OR
681 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
682 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
683 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
684 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
685 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
687 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';
690 CREATE TABLE "ignored_initiative" (
691 PRIMARY KEY ("initiative_id", "member_id"),
692 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
693 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
694 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
696 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
699 CREATE TABLE "initiative_setting" (
700 PRIMARY KEY ("member_id", "key", "initiative_id"),
701 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
702 "key" TEXT NOT NULL,
703 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
704 "value" TEXT NOT NULL );
706 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
709 CREATE TABLE "draft" (
710 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
711 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
712 "id" SERIAL8 PRIMARY KEY,
713 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
714 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
715 "formatting_engine" TEXT,
716 "content" TEXT NOT NULL,
717 "text_search_data" TSVECTOR );
718 CREATE INDEX "draft_created_idx" ON "draft" ("created");
719 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
720 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
721 CREATE TRIGGER "update_text_search_data"
722 BEFORE INSERT OR UPDATE ON "draft"
723 FOR EACH ROW EXECUTE PROCEDURE
724 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
726 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.';
728 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
729 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
732 CREATE TABLE "rendered_draft" (
733 PRIMARY KEY ("draft_id", "format"),
734 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
735 "format" TEXT,
736 "content" TEXT NOT NULL );
738 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)';
741 CREATE TABLE "suggestion" (
742 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
743 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
744 "id" SERIAL8 PRIMARY KEY,
745 "draft_id" INT8 NOT NULL,
746 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
747 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
748 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
749 "name" TEXT NOT NULL,
750 "formatting_engine" TEXT,
751 "content" TEXT NOT NULL DEFAULT '',
752 "text_search_data" TSVECTOR,
753 "minus2_unfulfilled_count" INT4,
754 "minus2_fulfilled_count" INT4,
755 "minus1_unfulfilled_count" INT4,
756 "minus1_fulfilled_count" INT4,
757 "plus1_unfulfilled_count" INT4,
758 "plus1_fulfilled_count" INT4,
759 "plus2_unfulfilled_count" INT4,
760 "plus2_fulfilled_count" INT4 );
761 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
762 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
763 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
764 CREATE TRIGGER "update_text_search_data"
765 BEFORE INSERT OR UPDATE ON "suggestion"
766 FOR EACH ROW EXECUTE PROCEDURE
767 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
768 "name", "content");
770 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';
772 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")';
773 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
774 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
775 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
776 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
777 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
778 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
779 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
780 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
783 CREATE TABLE "rendered_suggestion" (
784 PRIMARY KEY ("suggestion_id", "format"),
785 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
786 "format" TEXT,
787 "content" TEXT NOT NULL );
789 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)';
792 CREATE TABLE "suggestion_setting" (
793 PRIMARY KEY ("member_id", "key", "suggestion_id"),
794 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
795 "key" TEXT NOT NULL,
796 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
797 "value" TEXT NOT NULL );
799 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
802 CREATE TABLE "privilege" (
803 PRIMARY KEY ("unit_id", "member_id"),
804 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
805 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
806 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
807 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
808 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
809 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
810 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
811 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
812 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
814 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
816 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
817 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
818 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
819 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
820 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
821 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
822 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create polls (see "policy"."polling" and "initiative"."polling")';
825 CREATE TABLE "membership" (
826 PRIMARY KEY ("area_id", "member_id"),
827 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
828 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
829 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
831 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
834 CREATE TABLE "interest" (
835 PRIMARY KEY ("issue_id", "member_id"),
836 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
837 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
838 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
840 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.';
843 CREATE TABLE "initiator" (
844 PRIMARY KEY ("initiative_id", "member_id"),
845 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
846 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
847 "accepted" BOOLEAN );
848 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
850 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.';
852 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.';
855 CREATE TABLE "supporter" (
856 "issue_id" INT4 NOT NULL,
857 PRIMARY KEY ("initiative_id", "member_id"),
858 "initiative_id" INT4,
859 "member_id" INT4,
860 "draft_id" INT8 NOT NULL,
861 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
862 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
863 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
865 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.';
867 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
868 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")';
871 CREATE TABLE "opinion" (
872 "initiative_id" INT4 NOT NULL,
873 PRIMARY KEY ("suggestion_id", "member_id"),
874 "suggestion_id" INT8,
875 "member_id" INT4,
876 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
877 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
878 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
879 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
880 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
882 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.';
884 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
887 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
889 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
892 CREATE TABLE "delegation" (
893 "id" SERIAL8 PRIMARY KEY,
894 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
895 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
896 "scope" "delegation_scope" NOT NULL,
897 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
898 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
899 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
900 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
901 CONSTRAINT "no_unit_delegation_to_null"
902 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
903 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
904 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
905 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
906 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
907 UNIQUE ("unit_id", "truster_id"),
908 UNIQUE ("area_id", "truster_id"),
909 UNIQUE ("issue_id", "truster_id") );
910 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
911 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
913 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
915 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
916 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
917 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
920 CREATE TABLE "direct_population_snapshot" (
921 PRIMARY KEY ("issue_id", "event", "member_id"),
922 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
923 "event" "snapshot_event",
924 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
925 "weight" INT4 );
926 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
928 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
930 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
931 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
934 CREATE TABLE "delegating_population_snapshot" (
935 PRIMARY KEY ("issue_id", "event", "member_id"),
936 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
937 "event" "snapshot_event",
938 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
939 "weight" INT4,
940 "scope" "delegation_scope" NOT NULL,
941 "delegate_member_ids" INT4[] NOT NULL );
942 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
944 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
946 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
947 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
948 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
949 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"';
952 CREATE TABLE "direct_interest_snapshot" (
953 PRIMARY KEY ("issue_id", "event", "member_id"),
954 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
955 "event" "snapshot_event",
956 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
957 "weight" INT4 );
958 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
960 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
962 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
963 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
966 CREATE TABLE "delegating_interest_snapshot" (
967 PRIMARY KEY ("issue_id", "event", "member_id"),
968 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
969 "event" "snapshot_event",
970 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
971 "weight" INT4,
972 "scope" "delegation_scope" NOT NULL,
973 "delegate_member_ids" INT4[] NOT NULL );
974 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
976 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
978 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
979 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
980 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
981 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"';
984 CREATE TABLE "direct_supporter_snapshot" (
985 "issue_id" INT4 NOT NULL,
986 PRIMARY KEY ("initiative_id", "event", "member_id"),
987 "initiative_id" INT4,
988 "event" "snapshot_event",
989 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
990 "draft_id" INT8 NOT NULL,
991 "informed" BOOLEAN NOT NULL,
992 "satisfied" BOOLEAN NOT NULL,
993 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
994 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
995 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
996 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
998 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1000 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';
1001 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1002 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1003 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1006 CREATE TABLE "non_voter" (
1007 PRIMARY KEY ("issue_id", "member_id"),
1008 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1009 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1010 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1012 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1015 CREATE TABLE "direct_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 RESTRICT ON UPDATE RESTRICT,
1019 "weight" INT4 );
1020 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1022 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.';
1024 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1027 CREATE TABLE "delegating_voter" (
1028 PRIMARY KEY ("issue_id", "member_id"),
1029 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1030 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1031 "weight" INT4,
1032 "scope" "delegation_scope" NOT NULL,
1033 "delegate_member_ids" INT4[] NOT NULL );
1034 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1036 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1038 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1039 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1040 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"';
1043 CREATE TABLE "vote" (
1044 "issue_id" INT4 NOT NULL,
1045 PRIMARY KEY ("initiative_id", "member_id"),
1046 "initiative_id" INT4,
1047 "member_id" INT4,
1048 "grade" INT4,
1049 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1050 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1051 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1053 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.';
1055 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1056 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.';
1059 CREATE TABLE "voting_comment" (
1060 PRIMARY KEY ("issue_id", "member_id"),
1061 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1062 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1063 "changed" TIMESTAMPTZ,
1064 "formatting_engine" TEXT,
1065 "content" TEXT NOT NULL,
1066 "text_search_data" TSVECTOR );
1067 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1068 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1069 CREATE TRIGGER "update_text_search_data"
1070 BEFORE INSERT OR UPDATE ON "voting_comment"
1071 FOR EACH ROW EXECUTE PROCEDURE
1072 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1074 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1076 COMMENT ON COLUMN "voting_comment"."changed" 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.';
1079 CREATE TABLE "rendered_voting_comment" (
1080 PRIMARY KEY ("issue_id", "member_id", "format"),
1081 FOREIGN KEY ("issue_id", "member_id")
1082 REFERENCES "voting_comment" ("issue_id", "member_id")
1083 ON DELETE CASCADE ON UPDATE CASCADE,
1084 "issue_id" INT4,
1085 "member_id" INT4,
1086 "format" TEXT,
1087 "content" TEXT NOT NULL );
1089 COMMENT ON TABLE "rendered_voting_comment" IS 'This table may be used by frontends to cache "rendered" voting comments (e.g. HTML output generated from wiki text)';
1092 CREATE TYPE "event_type" AS ENUM (
1093 'issue_state_changed',
1094 'initiative_created_in_new_issue',
1095 'initiative_created_in_existing_issue',
1096 'initiative_revoked',
1097 'new_draft_created',
1098 'suggestion_created');
1100 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1103 CREATE TABLE "event" (
1104 "id" SERIAL8 PRIMARY KEY,
1105 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1106 "event" "event_type" NOT NULL,
1107 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1108 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1109 "state" "issue_state" CHECK ("state" != 'calculation'),
1110 "initiative_id" INT4,
1111 "draft_id" INT8,
1112 "suggestion_id" INT8,
1113 FOREIGN KEY ("issue_id", "initiative_id")
1114 REFERENCES "initiative" ("issue_id", "id")
1115 ON DELETE CASCADE ON UPDATE CASCADE,
1116 FOREIGN KEY ("initiative_id", "draft_id")
1117 REFERENCES "draft" ("initiative_id", "id")
1118 ON DELETE CASCADE ON UPDATE CASCADE,
1119 FOREIGN KEY ("initiative_id", "suggestion_id")
1120 REFERENCES "suggestion" ("initiative_id", "id")
1121 ON DELETE CASCADE ON UPDATE CASCADE,
1122 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1123 "event" != 'issue_state_changed' OR (
1124 "member_id" ISNULL AND
1125 "issue_id" NOTNULL AND
1126 "state" NOTNULL AND
1127 "initiative_id" ISNULL AND
1128 "draft_id" ISNULL AND
1129 "suggestion_id" ISNULL )),
1130 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1131 "event" NOT IN (
1132 'initiative_created_in_new_issue',
1133 'initiative_created_in_existing_issue',
1134 'initiative_revoked',
1135 'new_draft_created'
1136 ) OR (
1137 "member_id" NOTNULL AND
1138 "issue_id" NOTNULL AND
1139 "state" NOTNULL AND
1140 "initiative_id" NOTNULL AND
1141 "draft_id" NOTNULL AND
1142 "suggestion_id" ISNULL )),
1143 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1144 "event" != 'suggestion_created' OR (
1145 "member_id" NOTNULL AND
1146 "issue_id" NOTNULL AND
1147 "state" NOTNULL AND
1148 "initiative_id" NOTNULL AND
1149 "draft_id" ISNULL AND
1150 "suggestion_id" NOTNULL )) );
1151 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1153 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1155 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1156 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1157 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1158 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1161 CREATE TABLE "notification_sent" (
1162 "event_id" INT8 NOT NULL );
1163 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1165 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1166 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1170 ----------------------------------------------
1171 -- Writing of history entries and event log --
1172 ----------------------------------------------
1175 CREATE FUNCTION "write_member_history_trigger"()
1176 RETURNS TRIGGER
1177 LANGUAGE 'plpgsql' VOLATILE AS $$
1178 BEGIN
1179 IF
1180 ( NEW."active" != OLD."active" OR
1181 NEW."name" != OLD."name" ) AND
1182 OLD."activated" NOTNULL
1183 THEN
1184 INSERT INTO "member_history"
1185 ("member_id", "active", "name")
1186 VALUES (NEW."id", OLD."active", OLD."name");
1187 END IF;
1188 RETURN NULL;
1189 END;
1190 $$;
1192 CREATE TRIGGER "write_member_history"
1193 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1194 "write_member_history_trigger"();
1196 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1197 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1200 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1201 RETURNS TRIGGER
1202 LANGUAGE 'plpgsql' VOLATILE AS $$
1203 BEGIN
1204 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1205 INSERT INTO "event" ("event", "issue_id", "state")
1206 VALUES ('issue_state_changed', NEW."id", NEW."state");
1207 END IF;
1208 RETURN NULL;
1209 END;
1210 $$;
1212 CREATE TRIGGER "write_event_issue_state_changed"
1213 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1214 "write_event_issue_state_changed_trigger"();
1216 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1217 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1220 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1221 RETURNS TRIGGER
1222 LANGUAGE 'plpgsql' VOLATILE AS $$
1223 DECLARE
1224 "initiative_row" "initiative"%ROWTYPE;
1225 "issue_row" "issue"%ROWTYPE;
1226 "event_v" "event_type";
1227 BEGIN
1228 SELECT * INTO "initiative_row" FROM "initiative"
1229 WHERE "id" = NEW."initiative_id";
1230 SELECT * INTO "issue_row" FROM "issue"
1231 WHERE "id" = "initiative_row"."issue_id";
1232 IF EXISTS (
1233 SELECT NULL FROM "draft"
1234 WHERE "initiative_id" = NEW."initiative_id"
1235 AND "id" != NEW."id"
1236 ) THEN
1237 "event_v" := 'new_draft_created';
1238 ELSE
1239 IF EXISTS (
1240 SELECT NULL FROM "initiative"
1241 WHERE "issue_id" = "initiative_row"."issue_id"
1242 AND "id" != "initiative_row"."id"
1243 ) THEN
1244 "event_v" := 'initiative_created_in_existing_issue';
1245 ELSE
1246 "event_v" := 'initiative_created_in_new_issue';
1247 END IF;
1248 END IF;
1249 INSERT INTO "event" (
1250 "event", "member_id",
1251 "issue_id", "state", "initiative_id", "draft_id"
1252 ) VALUES (
1253 "event_v",
1254 NEW."author_id",
1255 "initiative_row"."issue_id",
1256 "issue_row"."state",
1257 "initiative_row"."id",
1258 NEW."id" );
1259 RETURN NULL;
1260 END;
1261 $$;
1263 CREATE TRIGGER "write_event_initiative_or_draft_created"
1264 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1265 "write_event_initiative_or_draft_created_trigger"();
1267 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1268 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1271 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1272 RETURNS TRIGGER
1273 LANGUAGE 'plpgsql' VOLATILE AS $$
1274 DECLARE
1275 "issue_row" "issue"%ROWTYPE;
1276 "draft_id_v" "draft"."id"%TYPE;
1277 BEGIN
1278 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1279 SELECT * INTO "issue_row" FROM "issue"
1280 WHERE "id" = NEW."issue_id";
1281 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1282 WHERE "initiative_id" = NEW."id";
1283 INSERT INTO "event" (
1284 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1285 ) VALUES (
1286 'initiative_revoked',
1287 NEW."revoked_by_member_id",
1288 NEW."issue_id",
1289 "issue_row"."state",
1290 NEW."id",
1291 "draft_id_v");
1292 END IF;
1293 RETURN NULL;
1294 END;
1295 $$;
1297 CREATE TRIGGER "write_event_initiative_revoked"
1298 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1299 "write_event_initiative_revoked_trigger"();
1301 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1302 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1305 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1306 RETURNS TRIGGER
1307 LANGUAGE 'plpgsql' VOLATILE AS $$
1308 DECLARE
1309 "initiative_row" "initiative"%ROWTYPE;
1310 "issue_row" "issue"%ROWTYPE;
1311 BEGIN
1312 SELECT * INTO "initiative_row" FROM "initiative"
1313 WHERE "id" = NEW."initiative_id";
1314 SELECT * INTO "issue_row" FROM "issue"
1315 WHERE "id" = "initiative_row"."issue_id";
1316 INSERT INTO "event" (
1317 "event", "member_id",
1318 "issue_id", "state", "initiative_id", "suggestion_id"
1319 ) VALUES (
1320 'suggestion_created',
1321 NEW."author_id",
1322 "initiative_row"."issue_id",
1323 "issue_row"."state",
1324 "initiative_row"."id",
1325 NEW."id" );
1326 RETURN NULL;
1327 END;
1328 $$;
1330 CREATE TRIGGER "write_event_suggestion_created"
1331 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1332 "write_event_suggestion_created_trigger"();
1334 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1335 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1339 ----------------------------
1340 -- Additional constraints --
1341 ----------------------------
1344 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1345 RETURNS TRIGGER
1346 LANGUAGE 'plpgsql' VOLATILE AS $$
1347 BEGIN
1348 IF NOT EXISTS (
1349 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1350 ) THEN
1351 --RAISE 'Cannot create issue without an initial initiative.' USING
1352 -- ERRCODE = 'integrity_constraint_violation',
1353 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1354 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1355 END IF;
1356 RETURN NULL;
1357 END;
1358 $$;
1360 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1361 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1362 FOR EACH ROW EXECUTE PROCEDURE
1363 "issue_requires_first_initiative_trigger"();
1365 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1366 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1369 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1370 RETURNS TRIGGER
1371 LANGUAGE 'plpgsql' VOLATILE AS $$
1372 DECLARE
1373 "reference_lost" BOOLEAN;
1374 BEGIN
1375 IF TG_OP = 'DELETE' THEN
1376 "reference_lost" := TRUE;
1377 ELSE
1378 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1379 END IF;
1380 IF
1381 "reference_lost" AND NOT EXISTS (
1382 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1384 THEN
1385 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1386 END IF;
1387 RETURN NULL;
1388 END;
1389 $$;
1391 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1392 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1393 FOR EACH ROW EXECUTE PROCEDURE
1394 "last_initiative_deletes_issue_trigger"();
1396 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1397 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1400 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1401 RETURNS TRIGGER
1402 LANGUAGE 'plpgsql' VOLATILE AS $$
1403 BEGIN
1404 IF NOT EXISTS (
1405 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1406 ) THEN
1407 --RAISE 'Cannot create initiative without an initial draft.' USING
1408 -- ERRCODE = 'integrity_constraint_violation',
1409 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1410 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1411 END IF;
1412 RETURN NULL;
1413 END;
1414 $$;
1416 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1417 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1418 FOR EACH ROW EXECUTE PROCEDURE
1419 "initiative_requires_first_draft_trigger"();
1421 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1422 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1425 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1426 RETURNS TRIGGER
1427 LANGUAGE 'plpgsql' VOLATILE AS $$
1428 DECLARE
1429 "reference_lost" BOOLEAN;
1430 BEGIN
1431 IF TG_OP = 'DELETE' THEN
1432 "reference_lost" := TRUE;
1433 ELSE
1434 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1435 END IF;
1436 IF
1437 "reference_lost" AND NOT EXISTS (
1438 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1440 THEN
1441 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1442 END IF;
1443 RETURN NULL;
1444 END;
1445 $$;
1447 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1448 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1449 FOR EACH ROW EXECUTE PROCEDURE
1450 "last_draft_deletes_initiative_trigger"();
1452 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1453 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1456 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1457 RETURNS TRIGGER
1458 LANGUAGE 'plpgsql' VOLATILE AS $$
1459 BEGIN
1460 IF NOT EXISTS (
1461 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1462 ) THEN
1463 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1464 END IF;
1465 RETURN NULL;
1466 END;
1467 $$;
1469 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1470 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1471 FOR EACH ROW EXECUTE PROCEDURE
1472 "suggestion_requires_first_opinion_trigger"();
1474 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1475 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1478 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1479 RETURNS TRIGGER
1480 LANGUAGE 'plpgsql' VOLATILE AS $$
1481 DECLARE
1482 "reference_lost" BOOLEAN;
1483 BEGIN
1484 IF TG_OP = 'DELETE' THEN
1485 "reference_lost" := TRUE;
1486 ELSE
1487 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1488 END IF;
1489 IF
1490 "reference_lost" AND NOT EXISTS (
1491 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1493 THEN
1494 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1495 END IF;
1496 RETURN NULL;
1497 END;
1498 $$;
1500 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1501 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1502 FOR EACH ROW EXECUTE PROCEDURE
1503 "last_opinion_deletes_suggestion_trigger"();
1505 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1506 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1510 ---------------------------------------------------------------
1511 -- Ensure that votes are not modified when issues are frozen --
1512 ---------------------------------------------------------------
1514 -- NOTE: Frontends should ensure this anyway, but in case of programming
1515 -- errors the following triggers ensure data integrity.
1518 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1519 RETURNS TRIGGER
1520 LANGUAGE 'plpgsql' VOLATILE AS $$
1521 DECLARE
1522 "issue_id_v" "issue"."id"%TYPE;
1523 "issue_row" "issue"%ROWTYPE;
1524 BEGIN
1525 IF TG_OP = 'DELETE' THEN
1526 "issue_id_v" := OLD."issue_id";
1527 ELSE
1528 "issue_id_v" := NEW."issue_id";
1529 END IF;
1530 SELECT INTO "issue_row" * FROM "issue"
1531 WHERE "id" = "issue_id_v" FOR SHARE;
1532 IF "issue_row"."closed" NOTNULL THEN
1533 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1534 END IF;
1535 RETURN NULL;
1536 END;
1537 $$;
1539 CREATE TRIGGER "forbid_changes_on_closed_issue"
1540 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1541 FOR EACH ROW EXECUTE PROCEDURE
1542 "forbid_changes_on_closed_issue_trigger"();
1544 CREATE TRIGGER "forbid_changes_on_closed_issue"
1545 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1546 FOR EACH ROW EXECUTE PROCEDURE
1547 "forbid_changes_on_closed_issue_trigger"();
1549 CREATE TRIGGER "forbid_changes_on_closed_issue"
1550 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1551 FOR EACH ROW EXECUTE PROCEDURE
1552 "forbid_changes_on_closed_issue_trigger"();
1554 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"';
1555 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';
1556 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';
1557 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';
1561 --------------------------------------------------------------------
1562 -- Auto-retrieval of fields only needed for referential integrity --
1563 --------------------------------------------------------------------
1566 CREATE FUNCTION "autofill_issue_id_trigger"()
1567 RETURNS TRIGGER
1568 LANGUAGE 'plpgsql' VOLATILE AS $$
1569 BEGIN
1570 IF NEW."issue_id" ISNULL THEN
1571 SELECT "issue_id" INTO NEW."issue_id"
1572 FROM "initiative" WHERE "id" = NEW."initiative_id";
1573 END IF;
1574 RETURN NEW;
1575 END;
1576 $$;
1578 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1579 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1581 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1582 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1584 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1585 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1586 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1589 CREATE FUNCTION "autofill_initiative_id_trigger"()
1590 RETURNS TRIGGER
1591 LANGUAGE 'plpgsql' VOLATILE AS $$
1592 BEGIN
1593 IF NEW."initiative_id" ISNULL THEN
1594 SELECT "initiative_id" INTO NEW."initiative_id"
1595 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1596 END IF;
1597 RETURN NEW;
1598 END;
1599 $$;
1601 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1602 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1604 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1605 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1609 -----------------------------------------------------
1610 -- Automatic calculation of certain default values --
1611 -----------------------------------------------------
1614 CREATE FUNCTION "copy_timings_trigger"()
1615 RETURNS TRIGGER
1616 LANGUAGE 'plpgsql' VOLATILE AS $$
1617 DECLARE
1618 "policy_row" "policy"%ROWTYPE;
1619 BEGIN
1620 SELECT * INTO "policy_row" FROM "policy"
1621 WHERE "id" = NEW."policy_id";
1622 IF NEW."admission_time" ISNULL THEN
1623 NEW."admission_time" := "policy_row"."admission_time";
1624 END IF;
1625 IF NEW."discussion_time" ISNULL THEN
1626 NEW."discussion_time" := "policy_row"."discussion_time";
1627 END IF;
1628 IF NEW."verification_time" ISNULL THEN
1629 NEW."verification_time" := "policy_row"."verification_time";
1630 END IF;
1631 IF NEW."voting_time" ISNULL THEN
1632 NEW."voting_time" := "policy_row"."voting_time";
1633 END IF;
1634 RETURN NEW;
1635 END;
1636 $$;
1638 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1639 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1641 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1642 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1645 CREATE FUNCTION "default_for_draft_id_trigger"()
1646 RETURNS TRIGGER
1647 LANGUAGE 'plpgsql' VOLATILE AS $$
1648 BEGIN
1649 IF NEW."draft_id" ISNULL THEN
1650 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1651 WHERE "initiative_id" = NEW."initiative_id";
1652 END IF;
1653 RETURN NEW;
1654 END;
1655 $$;
1657 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1658 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1659 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1660 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1662 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1663 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';
1664 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';
1668 ----------------------------------------
1669 -- Automatic creation of dependencies --
1670 ----------------------------------------
1673 CREATE FUNCTION "autocreate_interest_trigger"()
1674 RETURNS TRIGGER
1675 LANGUAGE 'plpgsql' VOLATILE AS $$
1676 BEGIN
1677 IF NOT EXISTS (
1678 SELECT NULL FROM "initiative" JOIN "interest"
1679 ON "initiative"."issue_id" = "interest"."issue_id"
1680 WHERE "initiative"."id" = NEW."initiative_id"
1681 AND "interest"."member_id" = NEW."member_id"
1682 ) THEN
1683 BEGIN
1684 INSERT INTO "interest" ("issue_id", "member_id")
1685 SELECT "issue_id", NEW."member_id"
1686 FROM "initiative" WHERE "id" = NEW."initiative_id";
1687 EXCEPTION WHEN unique_violation THEN END;
1688 END IF;
1689 RETURN NEW;
1690 END;
1691 $$;
1693 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1694 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1696 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1697 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';
1700 CREATE FUNCTION "autocreate_supporter_trigger"()
1701 RETURNS TRIGGER
1702 LANGUAGE 'plpgsql' VOLATILE AS $$
1703 BEGIN
1704 IF NOT EXISTS (
1705 SELECT NULL FROM "suggestion" JOIN "supporter"
1706 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1707 WHERE "suggestion"."id" = NEW."suggestion_id"
1708 AND "supporter"."member_id" = NEW."member_id"
1709 ) THEN
1710 BEGIN
1711 INSERT INTO "supporter" ("initiative_id", "member_id")
1712 SELECT "initiative_id", NEW."member_id"
1713 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1714 EXCEPTION WHEN unique_violation THEN END;
1715 END IF;
1716 RETURN NEW;
1717 END;
1718 $$;
1720 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1721 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1723 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1724 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.';
1728 ------------------------------------------
1729 -- Views and helper functions for views --
1730 ------------------------------------------
1733 CREATE VIEW "unit_delegation" AS
1734 SELECT
1735 "unit"."id" AS "unit_id",
1736 "delegation"."id",
1737 "delegation"."truster_id",
1738 "delegation"."trustee_id",
1739 "delegation"."scope"
1740 FROM "unit"
1741 JOIN "delegation"
1742 ON "delegation"."unit_id" = "unit"."id"
1743 JOIN "member"
1744 ON "delegation"."truster_id" = "member"."id"
1745 JOIN "privilege"
1746 ON "delegation"."unit_id" = "privilege"."unit_id"
1747 AND "delegation"."truster_id" = "privilege"."member_id"
1748 WHERE "member"."active" AND "privilege"."voting_right";
1750 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1753 CREATE VIEW "area_delegation" AS
1754 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1755 "area"."id" AS "area_id",
1756 "delegation"."id",
1757 "delegation"."truster_id",
1758 "delegation"."trustee_id",
1759 "delegation"."scope"
1760 FROM "area"
1761 JOIN "delegation"
1762 ON "delegation"."unit_id" = "area"."unit_id"
1763 OR "delegation"."area_id" = "area"."id"
1764 JOIN "member"
1765 ON "delegation"."truster_id" = "member"."id"
1766 JOIN "privilege"
1767 ON "area"."unit_id" = "privilege"."unit_id"
1768 AND "delegation"."truster_id" = "privilege"."member_id"
1769 WHERE "member"."active" AND "privilege"."voting_right"
1770 ORDER BY
1771 "area"."id",
1772 "delegation"."truster_id",
1773 "delegation"."scope" DESC;
1775 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1778 CREATE VIEW "issue_delegation" AS
1779 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1780 "issue"."id" AS "issue_id",
1781 "delegation"."id",
1782 "delegation"."truster_id",
1783 "delegation"."trustee_id",
1784 "delegation"."scope"
1785 FROM "issue"
1786 JOIN "area"
1787 ON "area"."id" = "issue"."area_id"
1788 JOIN "delegation"
1789 ON "delegation"."unit_id" = "area"."unit_id"
1790 OR "delegation"."area_id" = "area"."id"
1791 OR "delegation"."issue_id" = "issue"."id"
1792 JOIN "member"
1793 ON "delegation"."truster_id" = "member"."id"
1794 JOIN "privilege"
1795 ON "area"."unit_id" = "privilege"."unit_id"
1796 AND "delegation"."truster_id" = "privilege"."member_id"
1797 WHERE "member"."active" AND "privilege"."voting_right"
1798 ORDER BY
1799 "issue"."id",
1800 "delegation"."truster_id",
1801 "delegation"."scope" DESC;
1803 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1806 CREATE FUNCTION "membership_weight_with_skipping"
1807 ( "area_id_p" "area"."id"%TYPE,
1808 "member_id_p" "member"."id"%TYPE,
1809 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1810 RETURNS INT4
1811 LANGUAGE 'plpgsql' STABLE AS $$
1812 DECLARE
1813 "sum_v" INT4;
1814 "delegation_row" "area_delegation"%ROWTYPE;
1815 BEGIN
1816 "sum_v" := 1;
1817 FOR "delegation_row" IN
1818 SELECT "area_delegation".*
1819 FROM "area_delegation" LEFT JOIN "membership"
1820 ON "membership"."area_id" = "area_id_p"
1821 AND "membership"."member_id" = "area_delegation"."truster_id"
1822 WHERE "area_delegation"."area_id" = "area_id_p"
1823 AND "area_delegation"."trustee_id" = "member_id_p"
1824 AND "membership"."member_id" ISNULL
1825 LOOP
1826 IF NOT
1827 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1828 THEN
1829 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1830 "area_id_p",
1831 "delegation_row"."truster_id",
1832 "skip_member_ids_p" || "delegation_row"."truster_id"
1833 );
1834 END IF;
1835 END LOOP;
1836 RETURN "sum_v";
1837 END;
1838 $$;
1840 COMMENT ON FUNCTION "membership_weight_with_skipping"
1841 ( "area"."id"%TYPE,
1842 "member"."id"%TYPE,
1843 INT4[] )
1844 IS 'Helper function for "membership_weight" function';
1847 CREATE FUNCTION "membership_weight"
1848 ( "area_id_p" "area"."id"%TYPE,
1849 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1850 RETURNS INT4
1851 LANGUAGE 'plpgsql' STABLE AS $$
1852 BEGIN
1853 RETURN "membership_weight_with_skipping"(
1854 "area_id_p",
1855 "member_id_p",
1856 ARRAY["member_id_p"]
1857 );
1858 END;
1859 $$;
1861 COMMENT ON FUNCTION "membership_weight"
1862 ( "area"."id"%TYPE,
1863 "member"."id"%TYPE )
1864 IS 'Calculates the potential voting weight of a member in a given area';
1867 CREATE VIEW "member_count_view" AS
1868 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1870 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1873 CREATE VIEW "unit_member_count" AS
1874 SELECT
1875 "unit"."id" AS "unit_id",
1876 count("member"."id") AS "member_count"
1877 FROM "unit"
1878 LEFT JOIN "privilege"
1879 ON "privilege"."unit_id" = "unit"."id"
1880 AND "privilege"."voting_right"
1881 LEFT JOIN "member"
1882 ON "member"."id" = "privilege"."member_id"
1883 AND "member"."active"
1884 GROUP BY "unit"."id";
1886 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1889 CREATE VIEW "area_member_count" AS
1890 SELECT
1891 "area"."id" AS "area_id",
1892 count("member"."id") AS "direct_member_count",
1893 coalesce(
1894 sum(
1895 CASE WHEN "member"."id" NOTNULL THEN
1896 "membership_weight"("area"."id", "member"."id")
1897 ELSE 0 END
1899 ) AS "member_weight"
1900 FROM "area"
1901 LEFT JOIN "membership"
1902 ON "area"."id" = "membership"."area_id"
1903 LEFT JOIN "privilege"
1904 ON "privilege"."unit_id" = "area"."unit_id"
1905 AND "privilege"."member_id" = "membership"."member_id"
1906 AND "privilege"."voting_right"
1907 LEFT JOIN "member"
1908 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1909 AND "member"."active"
1910 GROUP BY "area"."id";
1912 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1915 CREATE VIEW "opening_draft" AS
1916 SELECT "draft".* FROM (
1917 SELECT
1918 "initiative"."id" AS "initiative_id",
1919 min("draft"."id") AS "draft_id"
1920 FROM "initiative" JOIN "draft"
1921 ON "initiative"."id" = "draft"."initiative_id"
1922 GROUP BY "initiative"."id"
1923 ) AS "subquery"
1924 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1926 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1929 CREATE VIEW "current_draft" AS
1930 SELECT "draft".* FROM (
1931 SELECT
1932 "initiative"."id" AS "initiative_id",
1933 max("draft"."id") AS "draft_id"
1934 FROM "initiative" JOIN "draft"
1935 ON "initiative"."id" = "draft"."initiative_id"
1936 GROUP BY "initiative"."id"
1937 ) AS "subquery"
1938 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1940 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1943 CREATE VIEW "critical_opinion" AS
1944 SELECT * FROM "opinion"
1945 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1946 OR ("degree" = -2 AND "fulfilled" = TRUE);
1948 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1951 CREATE VIEW "battle_participant" AS
1952 SELECT "initiative"."id", "initiative"."issue_id"
1953 FROM "issue" JOIN "initiative"
1954 ON "issue"."id" = "initiative"."issue_id"
1955 WHERE "initiative"."admitted"
1956 UNION ALL
1957 SELECT NULL, "id" AS "issue_id"
1958 FROM "issue";
1960 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1963 CREATE VIEW "battle_view" AS
1964 SELECT
1965 "issue"."id" AS "issue_id",
1966 "winning_initiative"."id" AS "winning_initiative_id",
1967 "losing_initiative"."id" AS "losing_initiative_id",
1968 sum(
1969 CASE WHEN
1970 coalesce("better_vote"."grade", 0) >
1971 coalesce("worse_vote"."grade", 0)
1972 THEN "direct_voter"."weight" ELSE 0 END
1973 ) AS "count"
1974 FROM "issue"
1975 LEFT JOIN "direct_voter"
1976 ON "issue"."id" = "direct_voter"."issue_id"
1977 JOIN "battle_participant" AS "winning_initiative"
1978 ON "issue"."id" = "winning_initiative"."issue_id"
1979 JOIN "battle_participant" AS "losing_initiative"
1980 ON "issue"."id" = "losing_initiative"."issue_id"
1981 LEFT JOIN "vote" AS "better_vote"
1982 ON "direct_voter"."member_id" = "better_vote"."member_id"
1983 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1984 LEFT JOIN "vote" AS "worse_vote"
1985 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1986 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1987 WHERE "issue"."closed" NOTNULL
1988 AND "issue"."cleaned" ISNULL
1989 AND (
1990 "winning_initiative"."id" != "losing_initiative"."id" OR
1991 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1992 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1993 GROUP BY
1994 "issue"."id",
1995 "winning_initiative"."id",
1996 "losing_initiative"."id";
1998 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';
2001 CREATE VIEW "expired_session" AS
2002 SELECT * FROM "session" WHERE now() > "expiry";
2004 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2005 DELETE FROM "session" WHERE "ident" = OLD."ident";
2007 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2008 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2011 CREATE VIEW "open_issue" AS
2012 SELECT * FROM "issue" WHERE "closed" ISNULL;
2014 COMMENT ON VIEW "open_issue" IS 'All open issues';
2017 CREATE VIEW "issue_with_ranks_missing" AS
2018 SELECT * FROM "issue"
2019 WHERE "fully_frozen" NOTNULL
2020 AND "closed" NOTNULL
2021 AND "ranks_available" = FALSE;
2023 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2026 CREATE VIEW "member_contingent" AS
2027 SELECT
2028 "member"."id" AS "member_id",
2029 "contingent"."time_frame",
2030 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2032 SELECT count(1) FROM "draft"
2033 WHERE "draft"."author_id" = "member"."id"
2034 AND "draft"."created" > now() - "contingent"."time_frame"
2035 ) + (
2036 SELECT count(1) FROM "suggestion"
2037 WHERE "suggestion"."author_id" = "member"."id"
2038 AND "suggestion"."created" > now() - "contingent"."time_frame"
2040 ELSE NULL END AS "text_entry_count",
2041 "contingent"."text_entry_limit",
2042 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2043 SELECT count(1) FROM "opening_draft"
2044 WHERE "opening_draft"."author_id" = "member"."id"
2045 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2046 ) ELSE NULL END AS "initiative_count",
2047 "contingent"."initiative_limit"
2048 FROM "member" CROSS JOIN "contingent";
2050 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2052 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2053 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2056 CREATE VIEW "member_contingent_left" AS
2057 SELECT
2058 "member_id",
2059 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2060 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2061 FROM "member_contingent" GROUP BY "member_id";
2063 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.';
2066 CREATE VIEW "event_seen_by_member" AS
2067 SELECT
2068 "member"."id" AS "seen_by_member_id",
2069 CASE WHEN "event"."state" IN (
2070 'voting',
2071 'finished_without_winner',
2072 'finished_with_winner'
2073 ) THEN
2074 'voting'::"notify_level"
2075 ELSE
2076 CASE WHEN "event"."state" IN (
2077 'verification',
2078 'canceled_after_revocation_during_verification',
2079 'canceled_no_initiative_admitted'
2080 ) THEN
2081 'verification'::"notify_level"
2082 ELSE
2083 CASE WHEN "event"."state" IN (
2084 'discussion',
2085 'canceled_after_revocation_during_discussion'
2086 ) THEN
2087 'discussion'::"notify_level"
2088 ELSE
2089 'all'::"notify_level"
2090 END
2091 END
2092 END AS "notify_level",
2093 "event".*
2094 FROM "member" CROSS JOIN "event"
2095 LEFT JOIN "issue"
2096 ON "event"."issue_id" = "issue"."id"
2097 LEFT JOIN "membership"
2098 ON "member"."id" = "membership"."member_id"
2099 AND "issue"."area_id" = "membership"."area_id"
2100 LEFT JOIN "interest"
2101 ON "member"."id" = "interest"."member_id"
2102 AND "event"."issue_id" = "interest"."issue_id"
2103 LEFT JOIN "supporter"
2104 ON "member"."id" = "supporter"."member_id"
2105 AND "event"."initiative_id" = "supporter"."initiative_id"
2106 LEFT JOIN "ignored_member"
2107 ON "member"."id" = "ignored_member"."member_id"
2108 AND "event"."member_id" = "ignored_member"."other_member_id"
2109 LEFT JOIN "ignored_initiative"
2110 ON "member"."id" = "ignored_initiative"."member_id"
2111 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2112 WHERE (
2113 "supporter"."member_id" NOTNULL OR
2114 "interest"."member_id" NOTNULL OR
2115 ( "membership"."member_id" NOTNULL AND
2116 "event"."event" IN (
2117 'issue_state_changed',
2118 'initiative_created_in_new_issue',
2119 'initiative_created_in_existing_issue',
2120 'initiative_revoked' ) ) )
2121 AND "ignored_member"."member_id" ISNULL
2122 AND "ignored_initiative"."member_id" ISNULL;
2124 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"';
2127 CREATE VIEW "selected_event_seen_by_member" AS
2128 SELECT
2129 "member"."id" AS "seen_by_member_id",
2130 CASE WHEN "event"."state" IN (
2131 'voting',
2132 'finished_without_winner',
2133 'finished_with_winner'
2134 ) THEN
2135 'voting'::"notify_level"
2136 ELSE
2137 CASE WHEN "event"."state" IN (
2138 'verification',
2139 'canceled_after_revocation_during_verification',
2140 'canceled_no_initiative_admitted'
2141 ) THEN
2142 'verification'::"notify_level"
2143 ELSE
2144 CASE WHEN "event"."state" IN (
2145 'discussion',
2146 'canceled_after_revocation_during_discussion'
2147 ) THEN
2148 'discussion'::"notify_level"
2149 ELSE
2150 'all'::"notify_level"
2151 END
2152 END
2153 END AS "notify_level",
2154 "event".*
2155 FROM "member" CROSS JOIN "event"
2156 LEFT JOIN "issue"
2157 ON "event"."issue_id" = "issue"."id"
2158 LEFT JOIN "membership"
2159 ON "member"."id" = "membership"."member_id"
2160 AND "issue"."area_id" = "membership"."area_id"
2161 LEFT JOIN "interest"
2162 ON "member"."id" = "interest"."member_id"
2163 AND "event"."issue_id" = "interest"."issue_id"
2164 LEFT JOIN "supporter"
2165 ON "member"."id" = "supporter"."member_id"
2166 AND "event"."initiative_id" = "supporter"."initiative_id"
2167 LEFT JOIN "ignored_member"
2168 ON "member"."id" = "ignored_member"."member_id"
2169 AND "event"."member_id" = "ignored_member"."other_member_id"
2170 LEFT JOIN "ignored_initiative"
2171 ON "member"."id" = "ignored_initiative"."member_id"
2172 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2173 WHERE (
2174 ( "member"."notify_level" >= 'all' ) OR
2175 ( "member"."notify_level" >= 'voting' AND
2176 "event"."state" IN (
2177 'voting',
2178 'finished_without_winner',
2179 'finished_with_winner' ) ) OR
2180 ( "member"."notify_level" >= 'verification' AND
2181 "event"."state" IN (
2182 'verification',
2183 'canceled_after_revocation_during_verification',
2184 'canceled_no_initiative_admitted' ) ) OR
2185 ( "member"."notify_level" >= 'discussion' AND
2186 "event"."state" IN (
2187 'discussion',
2188 'canceled_after_revocation_during_discussion' ) ) )
2189 AND (
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 "selected_event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests, support and members "notify_level"';
2204 CREATE TYPE "timeline_event" AS ENUM (
2205 'issue_created',
2206 'issue_canceled',
2207 'issue_accepted',
2208 'issue_half_frozen',
2209 'issue_finished_without_voting',
2210 'issue_voting_started',
2211 'issue_finished_after_voting',
2212 'initiative_created',
2213 'initiative_revoked',
2214 'draft_created',
2215 'suggestion_created');
2217 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2220 CREATE VIEW "timeline_issue" AS
2221 SELECT
2222 "created" AS "occurrence",
2223 'issue_created'::"timeline_event" AS "event",
2224 "id" AS "issue_id"
2225 FROM "issue"
2226 UNION ALL
2227 SELECT
2228 "closed" AS "occurrence",
2229 'issue_canceled'::"timeline_event" AS "event",
2230 "id" AS "issue_id"
2231 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2232 UNION ALL
2233 SELECT
2234 "accepted" AS "occurrence",
2235 'issue_accepted'::"timeline_event" AS "event",
2236 "id" AS "issue_id"
2237 FROM "issue" WHERE "accepted" NOTNULL
2238 UNION ALL
2239 SELECT
2240 "half_frozen" AS "occurrence",
2241 'issue_half_frozen'::"timeline_event" AS "event",
2242 "id" AS "issue_id"
2243 FROM "issue" WHERE "half_frozen" NOTNULL
2244 UNION ALL
2245 SELECT
2246 "fully_frozen" AS "occurrence",
2247 'issue_voting_started'::"timeline_event" AS "event",
2248 "id" AS "issue_id"
2249 FROM "issue"
2250 WHERE "fully_frozen" NOTNULL
2251 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2252 UNION ALL
2253 SELECT
2254 "closed" AS "occurrence",
2255 CASE WHEN "fully_frozen" = "closed" THEN
2256 'issue_finished_without_voting'::"timeline_event"
2257 ELSE
2258 'issue_finished_after_voting'::"timeline_event"
2259 END AS "event",
2260 "id" AS "issue_id"
2261 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2263 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2266 CREATE VIEW "timeline_initiative" AS
2267 SELECT
2268 "created" AS "occurrence",
2269 'initiative_created'::"timeline_event" AS "event",
2270 "id" AS "initiative_id"
2271 FROM "initiative"
2272 UNION ALL
2273 SELECT
2274 "revoked" AS "occurrence",
2275 'initiative_revoked'::"timeline_event" AS "event",
2276 "id" AS "initiative_id"
2277 FROM "initiative" WHERE "revoked" NOTNULL;
2279 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2282 CREATE VIEW "timeline_draft" AS
2283 SELECT
2284 "created" AS "occurrence",
2285 'draft_created'::"timeline_event" AS "event",
2286 "id" AS "draft_id"
2287 FROM "draft";
2289 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2292 CREATE VIEW "timeline_suggestion" AS
2293 SELECT
2294 "created" AS "occurrence",
2295 'suggestion_created'::"timeline_event" AS "event",
2296 "id" AS "suggestion_id"
2297 FROM "suggestion";
2299 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2302 CREATE VIEW "timeline" AS
2303 SELECT
2304 "occurrence",
2305 "event",
2306 "issue_id",
2307 NULL AS "initiative_id",
2308 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2309 NULL::INT8 AS "suggestion_id"
2310 FROM "timeline_issue"
2311 UNION ALL
2312 SELECT
2313 "occurrence",
2314 "event",
2315 NULL AS "issue_id",
2316 "initiative_id",
2317 NULL AS "draft_id",
2318 NULL AS "suggestion_id"
2319 FROM "timeline_initiative"
2320 UNION ALL
2321 SELECT
2322 "occurrence",
2323 "event",
2324 NULL AS "issue_id",
2325 NULL AS "initiative_id",
2326 "draft_id",
2327 NULL AS "suggestion_id"
2328 FROM "timeline_draft"
2329 UNION ALL
2330 SELECT
2331 "occurrence",
2332 "event",
2333 NULL AS "issue_id",
2334 NULL AS "initiative_id",
2335 NULL AS "draft_id",
2336 "suggestion_id"
2337 FROM "timeline_suggestion";
2339 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2343 ------------------------------------------------------
2344 -- Row set returning function for delegation chains --
2345 ------------------------------------------------------
2348 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2349 ('first', 'intermediate', 'last', 'repetition');
2351 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2354 CREATE TYPE "delegation_chain_row" AS (
2355 "index" INT4,
2356 "member_id" INT4,
2357 "member_valid" BOOLEAN,
2358 "participation" BOOLEAN,
2359 "overridden" BOOLEAN,
2360 "scope_in" "delegation_scope",
2361 "scope_out" "delegation_scope",
2362 "disabled_out" BOOLEAN,
2363 "loop" "delegation_chain_loop_tag" );
2365 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2367 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2368 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';
2369 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2370 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2371 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2372 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2373 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2376 CREATE FUNCTION "delegation_chain_for_closed_issue"
2377 ( "member_id_p" "member"."id"%TYPE,
2378 "issue_id_p" "issue"."id"%TYPE )
2379 RETURNS SETOF "delegation_chain_row"
2380 LANGUAGE 'plpgsql' STABLE AS $$
2381 DECLARE
2382 "output_row" "delegation_chain_row";
2383 "direct_voter_row" "direct_voter"%ROWTYPE;
2384 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2385 BEGIN
2386 "output_row"."index" := 0;
2387 "output_row"."member_id" := "member_id_p";
2388 "output_row"."member_valid" := TRUE;
2389 "output_row"."participation" := FALSE;
2390 "output_row"."overridden" := FALSE;
2391 "output_row"."disabled_out" := FALSE;
2392 LOOP
2393 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2394 WHERE "issue_id" = "issue_id_p"
2395 AND "member_id" = "output_row"."member_id";
2396 IF "direct_voter_row"."member_id" NOTNULL THEN
2397 "output_row"."participation" := TRUE;
2398 "output_row"."scope_out" := NULL;
2399 "output_row"."disabled_out" := NULL;
2400 RETURN NEXT "output_row";
2401 RETURN;
2402 END IF;
2403 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2404 WHERE "issue_id" = "issue_id_p"
2405 AND "member_id" = "output_row"."member_id";
2406 IF "delegating_voter_row"."member_id" ISNULL THEN
2407 RETURN;
2408 END IF;
2409 "output_row"."scope_out" := "delegating_voter_row"."scope";
2410 RETURN NEXT "output_row";
2411 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2412 "output_row"."scope_in" := "output_row"."scope_out";
2413 END LOOP;
2414 END;
2415 $$;
2417 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2418 ( "member"."id"%TYPE,
2419 "member"."id"%TYPE )
2420 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2423 CREATE FUNCTION "delegation_chain"
2424 ( "member_id_p" "member"."id"%TYPE,
2425 "unit_id_p" "unit"."id"%TYPE,
2426 "area_id_p" "area"."id"%TYPE,
2427 "issue_id_p" "issue"."id"%TYPE,
2428 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2429 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2430 RETURNS SETOF "delegation_chain_row"
2431 LANGUAGE 'plpgsql' STABLE AS $$
2432 DECLARE
2433 "scope_v" "delegation_scope";
2434 "unit_id_v" "unit"."id"%TYPE;
2435 "area_id_v" "area"."id"%TYPE;
2436 "issue_row" "issue"%ROWTYPE;
2437 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2438 "loop_member_id_v" "member"."id"%TYPE;
2439 "output_row" "delegation_chain_row";
2440 "output_rows" "delegation_chain_row"[];
2441 "simulate_v" BOOLEAN;
2442 "simulate_here_v" BOOLEAN;
2443 "delegation_row" "delegation"%ROWTYPE;
2444 "row_count" INT4;
2445 "i" INT4;
2446 "loop_v" BOOLEAN;
2447 BEGIN
2448 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2449 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2450 END IF;
2451 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2452 "simulate_v" := TRUE;
2453 ELSE
2454 "simulate_v" := FALSE;
2455 END IF;
2456 IF
2457 "unit_id_p" NOTNULL AND
2458 "area_id_p" ISNULL AND
2459 "issue_id_p" ISNULL
2460 THEN
2461 "scope_v" := 'unit';
2462 "unit_id_v" := "unit_id_p";
2463 ELSIF
2464 "unit_id_p" ISNULL AND
2465 "area_id_p" NOTNULL AND
2466 "issue_id_p" ISNULL
2467 THEN
2468 "scope_v" := 'area';
2469 "area_id_v" := "area_id_p";
2470 SELECT "unit_id" INTO "unit_id_v"
2471 FROM "area" WHERE "id" = "area_id_v";
2472 ELSIF
2473 "unit_id_p" ISNULL AND
2474 "area_id_p" ISNULL AND
2475 "issue_id_p" NOTNULL
2476 THEN
2477 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2478 IF "issue_row"."id" ISNULL THEN
2479 RETURN;
2480 END IF;
2481 IF "issue_row"."closed" NOTNULL THEN
2482 IF "simulate_v" THEN
2483 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2484 END IF;
2485 FOR "output_row" IN
2486 SELECT * FROM
2487 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2488 LOOP
2489 RETURN NEXT "output_row";
2490 END LOOP;
2491 RETURN;
2492 END IF;
2493 "scope_v" := 'issue';
2494 SELECT "area_id" INTO "area_id_v"
2495 FROM "issue" WHERE "id" = "issue_id_p";
2496 SELECT "unit_id" INTO "unit_id_v"
2497 FROM "area" WHERE "id" = "area_id_v";
2498 ELSE
2499 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2500 END IF;
2501 "visited_member_ids" := '{}';
2502 "loop_member_id_v" := NULL;
2503 "output_rows" := '{}';
2504 "output_row"."index" := 0;
2505 "output_row"."member_id" := "member_id_p";
2506 "output_row"."member_valid" := TRUE;
2507 "output_row"."participation" := FALSE;
2508 "output_row"."overridden" := FALSE;
2509 "output_row"."disabled_out" := FALSE;
2510 "output_row"."scope_out" := NULL;
2511 LOOP
2512 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2513 "loop_member_id_v" := "output_row"."member_id";
2514 ELSE
2515 "visited_member_ids" :=
2516 "visited_member_ids" || "output_row"."member_id";
2517 END IF;
2518 IF "output_row"."participation" ISNULL THEN
2519 "output_row"."overridden" := NULL;
2520 ELSIF "output_row"."participation" THEN
2521 "output_row"."overridden" := TRUE;
2522 END IF;
2523 "output_row"."scope_in" := "output_row"."scope_out";
2524 "output_row"."member_valid" := EXISTS (
2525 SELECT NULL FROM "member" JOIN "privilege"
2526 ON "privilege"."member_id" = "member"."id"
2527 AND "privilege"."unit_id" = "unit_id_v"
2528 WHERE "id" = "output_row"."member_id"
2529 AND "member"."active" AND "privilege"."voting_right"
2530 );
2531 "simulate_here_v" := (
2532 "simulate_v" AND
2533 "output_row"."member_id" = "member_id_p"
2534 );
2535 "delegation_row" := ROW(NULL);
2536 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2537 IF "scope_v" = 'unit' THEN
2538 IF NOT "simulate_here_v" THEN
2539 SELECT * INTO "delegation_row" FROM "delegation"
2540 WHERE "truster_id" = "output_row"."member_id"
2541 AND "unit_id" = "unit_id_v";
2542 END IF;
2543 ELSIF "scope_v" = 'area' THEN
2544 "output_row"."participation" := EXISTS (
2545 SELECT NULL FROM "membership"
2546 WHERE "area_id" = "area_id_p"
2547 AND "member_id" = "output_row"."member_id"
2548 );
2549 IF "simulate_here_v" THEN
2550 IF "simulate_trustee_id_p" ISNULL THEN
2551 SELECT * INTO "delegation_row" FROM "delegation"
2552 WHERE "truster_id" = "output_row"."member_id"
2553 AND "unit_id" = "unit_id_v";
2554 END IF;
2555 ELSE
2556 SELECT * INTO "delegation_row" FROM "delegation"
2557 WHERE "truster_id" = "output_row"."member_id"
2558 AND (
2559 "unit_id" = "unit_id_v" OR
2560 "area_id" = "area_id_v"
2562 ORDER BY "scope" DESC;
2563 END IF;
2564 ELSIF "scope_v" = 'issue' THEN
2565 IF "issue_row"."fully_frozen" ISNULL THEN
2566 "output_row"."participation" := EXISTS (
2567 SELECT NULL FROM "interest"
2568 WHERE "issue_id" = "issue_id_p"
2569 AND "member_id" = "output_row"."member_id"
2570 );
2571 ELSE
2572 IF "output_row"."member_id" = "member_id_p" THEN
2573 "output_row"."participation" := EXISTS (
2574 SELECT NULL FROM "direct_voter"
2575 WHERE "issue_id" = "issue_id_p"
2576 AND "member_id" = "output_row"."member_id"
2577 );
2578 ELSE
2579 "output_row"."participation" := NULL;
2580 END IF;
2581 END IF;
2582 IF "simulate_here_v" THEN
2583 IF "simulate_trustee_id_p" ISNULL THEN
2584 SELECT * INTO "delegation_row" FROM "delegation"
2585 WHERE "truster_id" = "output_row"."member_id"
2586 AND (
2587 "unit_id" = "unit_id_v" OR
2588 "area_id" = "area_id_v"
2590 ORDER BY "scope" DESC;
2591 END IF;
2592 ELSE
2593 SELECT * INTO "delegation_row" FROM "delegation"
2594 WHERE "truster_id" = "output_row"."member_id"
2595 AND (
2596 "unit_id" = "unit_id_v" OR
2597 "area_id" = "area_id_v" OR
2598 "issue_id" = "issue_id_p"
2600 ORDER BY "scope" DESC;
2601 END IF;
2602 END IF;
2603 ELSE
2604 "output_row"."participation" := FALSE;
2605 END IF;
2606 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2607 "output_row"."scope_out" := "scope_v";
2608 "output_rows" := "output_rows" || "output_row";
2609 "output_row"."member_id" := "simulate_trustee_id_p";
2610 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2611 "output_row"."scope_out" := "delegation_row"."scope";
2612 "output_rows" := "output_rows" || "output_row";
2613 "output_row"."member_id" := "delegation_row"."trustee_id";
2614 ELSIF "delegation_row"."scope" NOTNULL THEN
2615 "output_row"."scope_out" := "delegation_row"."scope";
2616 "output_row"."disabled_out" := TRUE;
2617 "output_rows" := "output_rows" || "output_row";
2618 EXIT;
2619 ELSE
2620 "output_row"."scope_out" := NULL;
2621 "output_rows" := "output_rows" || "output_row";
2622 EXIT;
2623 END IF;
2624 EXIT WHEN "loop_member_id_v" NOTNULL;
2625 "output_row"."index" := "output_row"."index" + 1;
2626 END LOOP;
2627 "row_count" := array_upper("output_rows", 1);
2628 "i" := 1;
2629 "loop_v" := FALSE;
2630 LOOP
2631 "output_row" := "output_rows"["i"];
2632 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2633 IF "loop_v" THEN
2634 IF "i" + 1 = "row_count" THEN
2635 "output_row"."loop" := 'last';
2636 ELSIF "i" = "row_count" THEN
2637 "output_row"."loop" := 'repetition';
2638 ELSE
2639 "output_row"."loop" := 'intermediate';
2640 END IF;
2641 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2642 "output_row"."loop" := 'first';
2643 "loop_v" := TRUE;
2644 END IF;
2645 IF "scope_v" = 'unit' THEN
2646 "output_row"."participation" := NULL;
2647 END IF;
2648 RETURN NEXT "output_row";
2649 "i" := "i" + 1;
2650 END LOOP;
2651 RETURN;
2652 END;
2653 $$;
2655 COMMENT ON FUNCTION "delegation_chain"
2656 ( "member"."id"%TYPE,
2657 "unit"."id"%TYPE,
2658 "area"."id"%TYPE,
2659 "issue"."id"%TYPE,
2660 "member"."id"%TYPE,
2661 BOOLEAN )
2662 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2666 ---------------------------------------------------------
2667 -- Single row returning function for delegation chains --
2668 ---------------------------------------------------------
2671 CREATE TYPE "delegation_info_loop_type" AS ENUM
2672 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2674 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''';
2677 CREATE TYPE "delegation_info_type" AS (
2678 "own_participation" BOOLEAN,
2679 "own_delegation_scope" "delegation_scope",
2680 "first_trustee_id" INT4,
2681 "first_trustee_participation" BOOLEAN,
2682 "first_trustee_ellipsis" BOOLEAN,
2683 "other_trustee_id" INT4,
2684 "other_trustee_participation" BOOLEAN,
2685 "other_trustee_ellipsis" BOOLEAN,
2686 "delegation_loop" "delegation_info_loop_type",
2687 "participating_member_id" INT4 );
2689 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';
2691 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2692 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2693 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2694 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2695 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2696 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2697 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)';
2698 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2699 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';
2700 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2703 CREATE FUNCTION "delegation_info"
2704 ( "member_id_p" "member"."id"%TYPE,
2705 "unit_id_p" "unit"."id"%TYPE,
2706 "area_id_p" "area"."id"%TYPE,
2707 "issue_id_p" "issue"."id"%TYPE,
2708 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2709 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2710 RETURNS "delegation_info_type"
2711 LANGUAGE 'plpgsql' STABLE AS $$
2712 DECLARE
2713 "current_row" "delegation_chain_row";
2714 "result" "delegation_info_type";
2715 BEGIN
2716 "result"."own_participation" := FALSE;
2717 FOR "current_row" IN
2718 SELECT * FROM "delegation_chain"(
2719 "member_id_p",
2720 "unit_id_p", "area_id_p", "issue_id_p",
2721 "simulate_trustee_id_p", "simulate_default_p")
2722 LOOP
2723 IF
2724 "result"."participating_member_id" ISNULL AND
2725 "current_row"."participation"
2726 THEN
2727 "result"."participating_member_id" := "current_row"."member_id";
2728 END IF;
2729 IF "current_row"."member_id" = "member_id_p" THEN
2730 "result"."own_participation" := "current_row"."participation";
2731 "result"."own_delegation_scope" := "current_row"."scope_out";
2732 IF "current_row"."loop" = 'first' THEN
2733 "result"."delegation_loop" := 'own';
2734 END IF;
2735 ELSIF
2736 "current_row"."member_valid" AND
2737 ( "current_row"."loop" ISNULL OR
2738 "current_row"."loop" != 'repetition' )
2739 THEN
2740 IF "result"."first_trustee_id" ISNULL THEN
2741 "result"."first_trustee_id" := "current_row"."member_id";
2742 "result"."first_trustee_participation" := "current_row"."participation";
2743 "result"."first_trustee_ellipsis" := FALSE;
2744 IF "current_row"."loop" = 'first' THEN
2745 "result"."delegation_loop" := 'first';
2746 END IF;
2747 ELSIF "result"."other_trustee_id" ISNULL THEN
2748 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2749 "result"."other_trustee_id" := "current_row"."member_id";
2750 "result"."other_trustee_participation" := TRUE;
2751 "result"."other_trustee_ellipsis" := FALSE;
2752 IF "current_row"."loop" = 'first' THEN
2753 "result"."delegation_loop" := 'other';
2754 END IF;
2755 ELSE
2756 "result"."first_trustee_ellipsis" := TRUE;
2757 IF "current_row"."loop" = 'first' THEN
2758 "result"."delegation_loop" := 'first_ellipsis';
2759 END IF;
2760 END IF;
2761 ELSE
2762 "result"."other_trustee_ellipsis" := TRUE;
2763 IF "current_row"."loop" = 'first' THEN
2764 "result"."delegation_loop" := 'other_ellipsis';
2765 END IF;
2766 END IF;
2767 END IF;
2768 END LOOP;
2769 RETURN "result";
2770 END;
2771 $$;
2773 COMMENT ON FUNCTION "delegation_info"
2774 ( "member"."id"%TYPE,
2775 "unit"."id"%TYPE,
2776 "area"."id"%TYPE,
2777 "issue"."id"%TYPE,
2778 "member"."id"%TYPE,
2779 BOOLEAN )
2780 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2784 ------------------------------
2785 -- Comparison by vote count --
2786 ------------------------------
2788 CREATE FUNCTION "vote_ratio"
2789 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2790 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2791 RETURNS FLOAT8
2792 LANGUAGE 'plpgsql' STABLE AS $$
2793 BEGIN
2794 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2795 RETURN
2796 "positive_votes_p"::FLOAT8 /
2797 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2798 ELSIF "positive_votes_p" > 0 THEN
2799 RETURN "positive_votes_p";
2800 ELSIF "negative_votes_p" > 0 THEN
2801 RETURN 1 - "negative_votes_p";
2802 ELSE
2803 RETURN 0.5;
2804 END IF;
2805 END;
2806 $$;
2808 COMMENT ON FUNCTION "vote_ratio"
2809 ( "initiative"."positive_votes"%TYPE,
2810 "initiative"."negative_votes"%TYPE )
2811 IS 'Returns a number, which can be used for comparison of initiatives based on count of approvals and disapprovals. Greater numbers indicate a better result. This function is NOT injective.';
2815 ------------------------------------------------
2816 -- Locking for snapshots and voting procedure --
2817 ------------------------------------------------
2820 CREATE FUNCTION "share_row_lock_issue_trigger"()
2821 RETURNS TRIGGER
2822 LANGUAGE 'plpgsql' VOLATILE AS $$
2823 BEGIN
2824 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2825 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2826 END IF;
2827 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2828 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2829 RETURN NEW;
2830 ELSE
2831 RETURN OLD;
2832 END IF;
2833 END;
2834 $$;
2836 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2839 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2840 RETURNS TRIGGER
2841 LANGUAGE 'plpgsql' VOLATILE AS $$
2842 BEGIN
2843 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2844 PERFORM NULL FROM "issue"
2845 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2846 WHERE "initiative"."id" = OLD."initiative_id"
2847 FOR SHARE OF "issue";
2848 END IF;
2849 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2850 PERFORM NULL FROM "issue"
2851 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2852 WHERE "initiative"."id" = NEW."initiative_id"
2853 FOR SHARE OF "issue";
2854 RETURN NEW;
2855 ELSE
2856 RETURN OLD;
2857 END IF;
2858 END;
2859 $$;
2861 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2864 CREATE TRIGGER "share_row_lock_issue"
2865 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2866 FOR EACH ROW EXECUTE PROCEDURE
2867 "share_row_lock_issue_trigger"();
2869 CREATE TRIGGER "share_row_lock_issue"
2870 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2871 FOR EACH ROW EXECUTE PROCEDURE
2872 "share_row_lock_issue_trigger"();
2874 CREATE TRIGGER "share_row_lock_issue"
2875 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2876 FOR EACH ROW EXECUTE PROCEDURE
2877 "share_row_lock_issue_trigger"();
2879 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2880 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2881 FOR EACH ROW EXECUTE PROCEDURE
2882 "share_row_lock_issue_via_initiative_trigger"();
2884 CREATE TRIGGER "share_row_lock_issue"
2885 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2886 FOR EACH ROW EXECUTE PROCEDURE
2887 "share_row_lock_issue_trigger"();
2889 CREATE TRIGGER "share_row_lock_issue"
2890 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2891 FOR EACH ROW EXECUTE PROCEDURE
2892 "share_row_lock_issue_trigger"();
2894 CREATE TRIGGER "share_row_lock_issue"
2895 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2896 FOR EACH ROW EXECUTE PROCEDURE
2897 "share_row_lock_issue_trigger"();
2899 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2900 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2901 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2902 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2903 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2904 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2905 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2908 CREATE FUNCTION "lock_issue"
2909 ( "issue_id_p" "issue"."id"%TYPE )
2910 RETURNS VOID
2911 LANGUAGE 'plpgsql' VOLATILE AS $$
2912 BEGIN
2913 LOCK TABLE "member" IN SHARE MODE;
2914 LOCK TABLE "privilege" IN SHARE MODE;
2915 LOCK TABLE "membership" IN SHARE MODE;
2916 LOCK TABLE "policy" IN SHARE MODE;
2917 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2918 -- NOTE: The row-level exclusive lock in combination with the
2919 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2920 -- acquire a row-level share lock on the issue) ensure that no data
2921 -- is changed, which could affect calculation of snapshots or
2922 -- counting of votes. Table "delegation" must be table-level-locked,
2923 -- as it also contains issue- and global-scope delegations.
2924 LOCK TABLE "delegation" IN SHARE MODE;
2925 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2926 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2927 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2928 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2929 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2930 RETURN;
2931 END;
2932 $$;
2934 COMMENT ON FUNCTION "lock_issue"
2935 ( "issue"."id"%TYPE )
2936 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2940 ------------------------------------------------------------------------
2941 -- Regular tasks, except calculcation of snapshots and voting results --
2942 ------------------------------------------------------------------------
2944 CREATE FUNCTION "check_activity"()
2945 RETURNS VOID
2946 LANGUAGE 'plpgsql' VOLATILE AS $$
2947 DECLARE
2948 "system_setting_row" "system_setting"%ROWTYPE;
2949 BEGIN
2950 SELECT * INTO "system_setting_row" FROM "system_setting";
2951 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2952 IF "system_setting_row"."member_ttl" NOTNULL THEN
2953 UPDATE "member" SET "active" = FALSE
2954 WHERE "active" = TRUE
2955 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2956 END IF;
2957 RETURN;
2958 END;
2959 $$;
2961 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2964 CREATE FUNCTION "calculate_member_counts"()
2965 RETURNS VOID
2966 LANGUAGE 'plpgsql' VOLATILE AS $$
2967 BEGIN
2968 LOCK TABLE "member" IN SHARE MODE;
2969 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2970 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2971 LOCK TABLE "area" IN EXCLUSIVE MODE;
2972 LOCK TABLE "privilege" IN SHARE MODE;
2973 LOCK TABLE "membership" IN SHARE MODE;
2974 DELETE FROM "member_count";
2975 INSERT INTO "member_count" ("total_count")
2976 SELECT "total_count" FROM "member_count_view";
2977 UPDATE "unit" SET "member_count" = "view"."member_count"
2978 FROM "unit_member_count" AS "view"
2979 WHERE "view"."unit_id" = "unit"."id";
2980 UPDATE "area" SET
2981 "direct_member_count" = "view"."direct_member_count",
2982 "member_weight" = "view"."member_weight"
2983 FROM "area_member_count" AS "view"
2984 WHERE "view"."area_id" = "area"."id";
2985 RETURN;
2986 END;
2987 $$;
2989 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"';
2993 ------------------------------
2994 -- Calculation of snapshots --
2995 ------------------------------
2997 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2998 ( "issue_id_p" "issue"."id"%TYPE,
2999 "member_id_p" "member"."id"%TYPE,
3000 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3001 RETURNS "direct_population_snapshot"."weight"%TYPE
3002 LANGUAGE 'plpgsql' VOLATILE AS $$
3003 DECLARE
3004 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3005 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3006 "weight_v" INT4;
3007 "sub_weight_v" INT4;
3008 BEGIN
3009 "weight_v" := 0;
3010 FOR "issue_delegation_row" IN
3011 SELECT * FROM "issue_delegation"
3012 WHERE "trustee_id" = "member_id_p"
3013 AND "issue_id" = "issue_id_p"
3014 LOOP
3015 IF NOT EXISTS (
3016 SELECT NULL FROM "direct_population_snapshot"
3017 WHERE "issue_id" = "issue_id_p"
3018 AND "event" = 'periodic'
3019 AND "member_id" = "issue_delegation_row"."truster_id"
3020 ) AND NOT EXISTS (
3021 SELECT NULL FROM "delegating_population_snapshot"
3022 WHERE "issue_id" = "issue_id_p"
3023 AND "event" = 'periodic'
3024 AND "member_id" = "issue_delegation_row"."truster_id"
3025 ) THEN
3026 "delegate_member_ids_v" :=
3027 "member_id_p" || "delegate_member_ids_p";
3028 INSERT INTO "delegating_population_snapshot" (
3029 "issue_id",
3030 "event",
3031 "member_id",
3032 "scope",
3033 "delegate_member_ids"
3034 ) VALUES (
3035 "issue_id_p",
3036 'periodic',
3037 "issue_delegation_row"."truster_id",
3038 "issue_delegation_row"."scope",
3039 "delegate_member_ids_v"
3040 );
3041 "sub_weight_v" := 1 +
3042 "weight_of_added_delegations_for_population_snapshot"(
3043 "issue_id_p",
3044 "issue_delegation_row"."truster_id",
3045 "delegate_member_ids_v"
3046 );
3047 UPDATE "delegating_population_snapshot"
3048 SET "weight" = "sub_weight_v"
3049 WHERE "issue_id" = "issue_id_p"
3050 AND "event" = 'periodic'
3051 AND "member_id" = "issue_delegation_row"."truster_id";
3052 "weight_v" := "weight_v" + "sub_weight_v";
3053 END IF;
3054 END LOOP;
3055 RETURN "weight_v";
3056 END;
3057 $$;
3059 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3060 ( "issue"."id"%TYPE,
3061 "member"."id"%TYPE,
3062 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3063 IS 'Helper function for "create_population_snapshot" function';
3066 CREATE FUNCTION "create_population_snapshot"
3067 ( "issue_id_p" "issue"."id"%TYPE )
3068 RETURNS VOID
3069 LANGUAGE 'plpgsql' VOLATILE AS $$
3070 DECLARE
3071 "member_id_v" "member"."id"%TYPE;
3072 BEGIN
3073 DELETE FROM "direct_population_snapshot"
3074 WHERE "issue_id" = "issue_id_p"
3075 AND "event" = 'periodic';
3076 DELETE FROM "delegating_population_snapshot"
3077 WHERE "issue_id" = "issue_id_p"
3078 AND "event" = 'periodic';
3079 INSERT INTO "direct_population_snapshot"
3080 ("issue_id", "event", "member_id")
3081 SELECT
3082 "issue_id_p" AS "issue_id",
3083 'periodic'::"snapshot_event" AS "event",
3084 "member"."id" AS "member_id"
3085 FROM "issue"
3086 JOIN "area" ON "issue"."area_id" = "area"."id"
3087 JOIN "membership" ON "area"."id" = "membership"."area_id"
3088 JOIN "member" ON "membership"."member_id" = "member"."id"
3089 JOIN "privilege"
3090 ON "privilege"."unit_id" = "area"."unit_id"
3091 AND "privilege"."member_id" = "member"."id"
3092 WHERE "issue"."id" = "issue_id_p"
3093 AND "member"."active" AND "privilege"."voting_right"
3094 UNION
3095 SELECT
3096 "issue_id_p" AS "issue_id",
3097 'periodic'::"snapshot_event" AS "event",
3098 "member"."id" AS "member_id"
3099 FROM "issue"
3100 JOIN "area" ON "issue"."area_id" = "area"."id"
3101 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3102 JOIN "member" ON "interest"."member_id" = "member"."id"
3103 JOIN "privilege"
3104 ON "privilege"."unit_id" = "area"."unit_id"
3105 AND "privilege"."member_id" = "member"."id"
3106 WHERE "issue"."id" = "issue_id_p"
3107 AND "member"."active" AND "privilege"."voting_right";
3108 FOR "member_id_v" IN
3109 SELECT "member_id" FROM "direct_population_snapshot"
3110 WHERE "issue_id" = "issue_id_p"
3111 AND "event" = 'periodic'
3112 LOOP
3113 UPDATE "direct_population_snapshot" SET
3114 "weight" = 1 +
3115 "weight_of_added_delegations_for_population_snapshot"(
3116 "issue_id_p",
3117 "member_id_v",
3118 '{}'
3120 WHERE "issue_id" = "issue_id_p"
3121 AND "event" = 'periodic'
3122 AND "member_id" = "member_id_v";
3123 END LOOP;
3124 RETURN;
3125 END;
3126 $$;
3128 COMMENT ON FUNCTION "create_population_snapshot"
3129 ( "issue"."id"%TYPE )
3130 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.';
3133 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3134 ( "issue_id_p" "issue"."id"%TYPE,
3135 "member_id_p" "member"."id"%TYPE,
3136 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3137 RETURNS "direct_interest_snapshot"."weight"%TYPE
3138 LANGUAGE 'plpgsql' VOLATILE AS $$
3139 DECLARE
3140 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3141 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3142 "weight_v" INT4;
3143 "sub_weight_v" INT4;
3144 BEGIN
3145 "weight_v" := 0;
3146 FOR "issue_delegation_row" IN
3147 SELECT * FROM "issue_delegation"
3148 WHERE "trustee_id" = "member_id_p"
3149 AND "issue_id" = "issue_id_p"
3150 LOOP
3151 IF NOT EXISTS (
3152 SELECT NULL FROM "direct_interest_snapshot"
3153 WHERE "issue_id" = "issue_id_p"
3154 AND "event" = 'periodic'
3155 AND "member_id" = "issue_delegation_row"."truster_id"
3156 ) AND NOT EXISTS (
3157 SELECT NULL FROM "delegating_interest_snapshot"
3158 WHERE "issue_id" = "issue_id_p"
3159 AND "event" = 'periodic'
3160 AND "member_id" = "issue_delegation_row"."truster_id"
3161 ) THEN
3162 "delegate_member_ids_v" :=
3163 "member_id_p" || "delegate_member_ids_p";
3164 INSERT INTO "delegating_interest_snapshot" (
3165 "issue_id",
3166 "event",
3167 "member_id",
3168 "scope",
3169 "delegate_member_ids"
3170 ) VALUES (
3171 "issue_id_p",
3172 'periodic',
3173 "issue_delegation_row"."truster_id",
3174 "issue_delegation_row"."scope",
3175 "delegate_member_ids_v"
3176 );
3177 "sub_weight_v" := 1 +
3178 "weight_of_added_delegations_for_interest_snapshot"(
3179 "issue_id_p",
3180 "issue_delegation_row"."truster_id",
3181 "delegate_member_ids_v"
3182 );
3183 UPDATE "delegating_interest_snapshot"
3184 SET "weight" = "sub_weight_v"
3185 WHERE "issue_id" = "issue_id_p"
3186 AND "event" = 'periodic'
3187 AND "member_id" = "issue_delegation_row"."truster_id";
3188 "weight_v" := "weight_v" + "sub_weight_v";
3189 END IF;
3190 END LOOP;
3191 RETURN "weight_v";
3192 END;
3193 $$;
3195 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3196 ( "issue"."id"%TYPE,
3197 "member"."id"%TYPE,
3198 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3199 IS 'Helper function for "create_interest_snapshot" function';
3202 CREATE FUNCTION "create_interest_snapshot"
3203 ( "issue_id_p" "issue"."id"%TYPE )
3204 RETURNS VOID
3205 LANGUAGE 'plpgsql' VOLATILE AS $$
3206 DECLARE
3207 "member_id_v" "member"."id"%TYPE;
3208 BEGIN
3209 DELETE FROM "direct_interest_snapshot"
3210 WHERE "issue_id" = "issue_id_p"
3211 AND "event" = 'periodic';
3212 DELETE FROM "delegating_interest_snapshot"
3213 WHERE "issue_id" = "issue_id_p"
3214 AND "event" = 'periodic';
3215 DELETE FROM "direct_supporter_snapshot"
3216 WHERE "issue_id" = "issue_id_p"
3217 AND "event" = 'periodic';
3218 INSERT INTO "direct_interest_snapshot"
3219 ("issue_id", "event", "member_id")
3220 SELECT
3221 "issue_id_p" AS "issue_id",
3222 'periodic' AS "event",
3223 "member"."id" AS "member_id"
3224 FROM "issue"
3225 JOIN "area" ON "issue"."area_id" = "area"."id"
3226 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3227 JOIN "member" ON "interest"."member_id" = "member"."id"
3228 JOIN "privilege"
3229 ON "privilege"."unit_id" = "area"."unit_id"
3230 AND "privilege"."member_id" = "member"."id"
3231 WHERE "issue"."id" = "issue_id_p"
3232 AND "member"."active" AND "privilege"."voting_right";
3233 FOR "member_id_v" IN
3234 SELECT "member_id" FROM "direct_interest_snapshot"
3235 WHERE "issue_id" = "issue_id_p"
3236 AND "event" = 'periodic'
3237 LOOP
3238 UPDATE "direct_interest_snapshot" SET
3239 "weight" = 1 +
3240 "weight_of_added_delegations_for_interest_snapshot"(
3241 "issue_id_p",
3242 "member_id_v",
3243 '{}'
3245 WHERE "issue_id" = "issue_id_p"
3246 AND "event" = 'periodic'
3247 AND "member_id" = "member_id_v";
3248 END LOOP;
3249 INSERT INTO "direct_supporter_snapshot"
3250 ( "issue_id", "initiative_id", "event", "member_id",
3251 "draft_id", "informed", "satisfied" )
3252 SELECT
3253 "issue_id_p" AS "issue_id",
3254 "initiative"."id" AS "initiative_id",
3255 'periodic' AS "event",
3256 "supporter"."member_id" AS "member_id",
3257 "supporter"."draft_id" AS "draft_id",
3258 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3259 NOT EXISTS (
3260 SELECT NULL FROM "critical_opinion"
3261 WHERE "initiative_id" = "initiative"."id"
3262 AND "member_id" = "supporter"."member_id"
3263 ) AS "satisfied"
3264 FROM "initiative"
3265 JOIN "supporter"
3266 ON "supporter"."initiative_id" = "initiative"."id"
3267 JOIN "current_draft"
3268 ON "initiative"."id" = "current_draft"."initiative_id"
3269 JOIN "direct_interest_snapshot"
3270 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3271 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3272 AND "event" = 'periodic'
3273 WHERE "initiative"."issue_id" = "issue_id_p";
3274 RETURN;
3275 END;
3276 $$;
3278 COMMENT ON FUNCTION "create_interest_snapshot"
3279 ( "issue"."id"%TYPE )
3280 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.';
3283 CREATE FUNCTION "create_snapshot"
3284 ( "issue_id_p" "issue"."id"%TYPE )
3285 RETURNS VOID
3286 LANGUAGE 'plpgsql' VOLATILE AS $$
3287 DECLARE
3288 "initiative_id_v" "initiative"."id"%TYPE;
3289 "suggestion_id_v" "suggestion"."id"%TYPE;
3290 BEGIN
3291 PERFORM "lock_issue"("issue_id_p");
3292 PERFORM "create_population_snapshot"("issue_id_p");
3293 PERFORM "create_interest_snapshot"("issue_id_p");
3294 UPDATE "issue" SET
3295 "snapshot" = now(),
3296 "latest_snapshot_event" = 'periodic',
3297 "population" = (
3298 SELECT coalesce(sum("weight"), 0)
3299 FROM "direct_population_snapshot"
3300 WHERE "issue_id" = "issue_id_p"
3301 AND "event" = 'periodic'
3303 WHERE "id" = "issue_id_p";
3304 FOR "initiative_id_v" IN
3305 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3306 LOOP
3307 UPDATE "initiative" SET
3308 "supporter_count" = (
3309 SELECT coalesce(sum("di"."weight"), 0)
3310 FROM "direct_interest_snapshot" AS "di"
3311 JOIN "direct_supporter_snapshot" AS "ds"
3312 ON "di"."member_id" = "ds"."member_id"
3313 WHERE "di"."issue_id" = "issue_id_p"
3314 AND "di"."event" = 'periodic'
3315 AND "ds"."initiative_id" = "initiative_id_v"
3316 AND "ds"."event" = 'periodic'
3317 ),
3318 "informed_supporter_count" = (
3319 SELECT coalesce(sum("di"."weight"), 0)
3320 FROM "direct_interest_snapshot" AS "di"
3321 JOIN "direct_supporter_snapshot" AS "ds"
3322 ON "di"."member_id" = "ds"."member_id"
3323 WHERE "di"."issue_id" = "issue_id_p"
3324 AND "di"."event" = 'periodic'
3325 AND "ds"."initiative_id" = "initiative_id_v"
3326 AND "ds"."event" = 'periodic'
3327 AND "ds"."informed"
3328 ),
3329 "satisfied_supporter_count" = (
3330 SELECT coalesce(sum("di"."weight"), 0)
3331 FROM "direct_interest_snapshot" AS "di"
3332 JOIN "direct_supporter_snapshot" AS "ds"
3333 ON "di"."member_id" = "ds"."member_id"
3334 WHERE "di"."issue_id" = "issue_id_p"
3335 AND "di"."event" = 'periodic'
3336 AND "ds"."initiative_id" = "initiative_id_v"
3337 AND "ds"."event" = 'periodic'
3338 AND "ds"."satisfied"
3339 ),
3340 "satisfied_informed_supporter_count" = (
3341 SELECT coalesce(sum("di"."weight"), 0)
3342 FROM "direct_interest_snapshot" AS "di"
3343 JOIN "direct_supporter_snapshot" AS "ds"
3344 ON "di"."member_id" = "ds"."member_id"
3345 WHERE "di"."issue_id" = "issue_id_p"
3346 AND "di"."event" = 'periodic'
3347 AND "ds"."initiative_id" = "initiative_id_v"
3348 AND "ds"."event" = 'periodic'
3349 AND "ds"."informed"
3350 AND "ds"."satisfied"
3352 WHERE "id" = "initiative_id_v";
3353 FOR "suggestion_id_v" IN
3354 SELECT "id" FROM "suggestion"
3355 WHERE "initiative_id" = "initiative_id_v"
3356 LOOP
3357 UPDATE "suggestion" SET
3358 "minus2_unfulfilled_count" = (
3359 SELECT coalesce(sum("snapshot"."weight"), 0)
3360 FROM "issue" CROSS JOIN "opinion"
3361 JOIN "direct_interest_snapshot" AS "snapshot"
3362 ON "snapshot"."issue_id" = "issue"."id"
3363 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3364 AND "snapshot"."member_id" = "opinion"."member_id"
3365 WHERE "issue"."id" = "issue_id_p"
3366 AND "opinion"."suggestion_id" = "suggestion_id_v"
3367 AND "opinion"."degree" = -2
3368 AND "opinion"."fulfilled" = FALSE
3369 ),
3370 "minus2_fulfilled_count" = (
3371 SELECT coalesce(sum("snapshot"."weight"), 0)
3372 FROM "issue" CROSS JOIN "opinion"
3373 JOIN "direct_interest_snapshot" AS "snapshot"
3374 ON "snapshot"."issue_id" = "issue"."id"
3375 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3376 AND "snapshot"."member_id" = "opinion"."member_id"
3377 WHERE "issue"."id" = "issue_id_p"
3378 AND "opinion"."suggestion_id" = "suggestion_id_v"
3379 AND "opinion"."degree" = -2
3380 AND "opinion"."fulfilled" = TRUE
3381 ),
3382 "minus1_unfulfilled_count" = (
3383 SELECT coalesce(sum("snapshot"."weight"), 0)
3384 FROM "issue" CROSS JOIN "opinion"
3385 JOIN "direct_interest_snapshot" AS "snapshot"
3386 ON "snapshot"."issue_id" = "issue"."id"
3387 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3388 AND "snapshot"."member_id" = "opinion"."member_id"
3389 WHERE "issue"."id" = "issue_id_p"
3390 AND "opinion"."suggestion_id" = "suggestion_id_v"
3391 AND "opinion"."degree" = -1
3392 AND "opinion"."fulfilled" = FALSE
3393 ),
3394 "minus1_fulfilled_count" = (
3395 SELECT coalesce(sum("snapshot"."weight"), 0)
3396 FROM "issue" CROSS JOIN "opinion"
3397 JOIN "direct_interest_snapshot" AS "snapshot"
3398 ON "snapshot"."issue_id" = "issue"."id"
3399 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3400 AND "snapshot"."member_id" = "opinion"."member_id"
3401 WHERE "issue"."id" = "issue_id_p"
3402 AND "opinion"."suggestion_id" = "suggestion_id_v"
3403 AND "opinion"."degree" = -1
3404 AND "opinion"."fulfilled" = TRUE
3405 ),
3406 "plus1_unfulfilled_count" = (
3407 SELECT coalesce(sum("snapshot"."weight"), 0)
3408 FROM "issue" CROSS JOIN "opinion"
3409 JOIN "direct_interest_snapshot" AS "snapshot"
3410 ON "snapshot"."issue_id" = "issue"."id"
3411 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3412 AND "snapshot"."member_id" = "opinion"."member_id"
3413 WHERE "issue"."id" = "issue_id_p"
3414 AND "opinion"."suggestion_id" = "suggestion_id_v"
3415 AND "opinion"."degree" = 1
3416 AND "opinion"."fulfilled" = FALSE
3417 ),
3418 "plus1_fulfilled_count" = (
3419 SELECT coalesce(sum("snapshot"."weight"), 0)
3420 FROM "issue" CROSS JOIN "opinion"
3421 JOIN "direct_interest_snapshot" AS "snapshot"
3422 ON "snapshot"."issue_id" = "issue"."id"
3423 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3424 AND "snapshot"."member_id" = "opinion"."member_id"
3425 WHERE "issue"."id" = "issue_id_p"
3426 AND "opinion"."suggestion_id" = "suggestion_id_v"
3427 AND "opinion"."degree" = 1
3428 AND "opinion"."fulfilled" = TRUE
3429 ),
3430 "plus2_unfulfilled_count" = (
3431 SELECT coalesce(sum("snapshot"."weight"), 0)
3432 FROM "issue" CROSS JOIN "opinion"
3433 JOIN "direct_interest_snapshot" AS "snapshot"
3434 ON "snapshot"."issue_id" = "issue"."id"
3435 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3436 AND "snapshot"."member_id" = "opinion"."member_id"
3437 WHERE "issue"."id" = "issue_id_p"
3438 AND "opinion"."suggestion_id" = "suggestion_id_v"
3439 AND "opinion"."degree" = 2
3440 AND "opinion"."fulfilled" = FALSE
3441 ),
3442 "plus2_fulfilled_count" = (
3443 SELECT coalesce(sum("snapshot"."weight"), 0)
3444 FROM "issue" CROSS JOIN "opinion"
3445 JOIN "direct_interest_snapshot" AS "snapshot"
3446 ON "snapshot"."issue_id" = "issue"."id"
3447 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3448 AND "snapshot"."member_id" = "opinion"."member_id"
3449 WHERE "issue"."id" = "issue_id_p"
3450 AND "opinion"."suggestion_id" = "suggestion_id_v"
3451 AND "opinion"."degree" = 2
3452 AND "opinion"."fulfilled" = TRUE
3454 WHERE "suggestion"."id" = "suggestion_id_v";
3455 END LOOP;
3456 END LOOP;
3457 RETURN;
3458 END;
3459 $$;
3461 COMMENT ON FUNCTION "create_snapshot"
3462 ( "issue"."id"%TYPE )
3463 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.';
3466 CREATE FUNCTION "set_snapshot_event"
3467 ( "issue_id_p" "issue"."id"%TYPE,
3468 "event_p" "snapshot_event" )
3469 RETURNS VOID
3470 LANGUAGE 'plpgsql' VOLATILE AS $$
3471 DECLARE
3472 "event_v" "issue"."latest_snapshot_event"%TYPE;
3473 BEGIN
3474 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3475 WHERE "id" = "issue_id_p" FOR UPDATE;
3476 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3477 WHERE "id" = "issue_id_p";
3478 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3479 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3480 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3481 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3482 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3483 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3484 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3485 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3486 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3487 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3488 RETURN;
3489 END;
3490 $$;
3492 COMMENT ON FUNCTION "set_snapshot_event"
3493 ( "issue"."id"%TYPE,
3494 "snapshot_event" )
3495 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3499 ---------------------
3500 -- Freezing issues --
3501 ---------------------
3503 CREATE FUNCTION "freeze_after_snapshot"
3504 ( "issue_id_p" "issue"."id"%TYPE )
3505 RETURNS VOID
3506 LANGUAGE 'plpgsql' VOLATILE AS $$
3507 DECLARE
3508 "issue_row" "issue"%ROWTYPE;
3509 "policy_row" "policy"%ROWTYPE;
3510 "initiative_row" "initiative"%ROWTYPE;
3511 BEGIN
3512 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3513 SELECT * INTO "policy_row"
3514 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3515 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3516 FOR "initiative_row" IN
3517 SELECT * FROM "initiative"
3518 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3519 LOOP
3520 IF
3521 "initiative_row"."polling" OR (
3522 "initiative_row"."satisfied_supporter_count" > 0 AND
3523 "initiative_row"."satisfied_supporter_count" *
3524 "policy_row"."initiative_quorum_den" >=
3525 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3527 THEN
3528 UPDATE "initiative" SET "admitted" = TRUE
3529 WHERE "id" = "initiative_row"."id";
3530 ELSE
3531 UPDATE "initiative" SET "admitted" = FALSE
3532 WHERE "id" = "initiative_row"."id";
3533 END IF;
3534 END LOOP;
3535 IF EXISTS (
3536 SELECT NULL FROM "initiative"
3537 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3538 ) THEN
3539 UPDATE "issue" SET
3540 "state" = 'voting',
3541 "accepted" = coalesce("accepted", now()),
3542 "half_frozen" = coalesce("half_frozen", now()),
3543 "fully_frozen" = now()
3544 WHERE "id" = "issue_id_p";
3545 ELSE
3546 UPDATE "issue" SET
3547 "state" = 'canceled_no_initiative_admitted',
3548 "accepted" = coalesce("accepted", now()),
3549 "half_frozen" = coalesce("half_frozen", now()),
3550 "fully_frozen" = now(),
3551 "closed" = now(),
3552 "ranks_available" = TRUE
3553 WHERE "id" = "issue_id_p";
3554 -- NOTE: The following DELETE statements have effect only when
3555 -- issue state has been manipulated
3556 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3557 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3558 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3559 END IF;
3560 RETURN;
3561 END;
3562 $$;
3564 COMMENT ON FUNCTION "freeze_after_snapshot"
3565 ( "issue"."id"%TYPE )
3566 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3569 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3570 RETURNS VOID
3571 LANGUAGE 'plpgsql' VOLATILE AS $$
3572 DECLARE
3573 "issue_row" "issue"%ROWTYPE;
3574 BEGIN
3575 PERFORM "create_snapshot"("issue_id_p");
3576 PERFORM "freeze_after_snapshot"("issue_id_p");
3577 RETURN;
3578 END;
3579 $$;
3581 COMMENT ON FUNCTION "manual_freeze"
3582 ( "issue"."id"%TYPE )
3583 IS 'Freeze an issue manually (fully) and start voting';
3587 -----------------------
3588 -- Counting of votes --
3589 -----------------------
3592 CREATE FUNCTION "weight_of_added_vote_delegations"
3593 ( "issue_id_p" "issue"."id"%TYPE,
3594 "member_id_p" "member"."id"%TYPE,
3595 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3596 RETURNS "direct_voter"."weight"%TYPE
3597 LANGUAGE 'plpgsql' VOLATILE AS $$
3598 DECLARE
3599 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3600 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3601 "weight_v" INT4;
3602 "sub_weight_v" INT4;
3603 BEGIN
3604 "weight_v" := 0;
3605 FOR "issue_delegation_row" IN
3606 SELECT * FROM "issue_delegation"
3607 WHERE "trustee_id" = "member_id_p"
3608 AND "issue_id" = "issue_id_p"
3609 LOOP
3610 IF NOT EXISTS (
3611 SELECT NULL FROM "direct_voter"
3612 WHERE "member_id" = "issue_delegation_row"."truster_id"
3613 AND "issue_id" = "issue_id_p"
3614 ) AND NOT EXISTS (
3615 SELECT NULL FROM "delegating_voter"
3616 WHERE "member_id" = "issue_delegation_row"."truster_id"
3617 AND "issue_id" = "issue_id_p"
3618 ) THEN
3619 "delegate_member_ids_v" :=
3620 "member_id_p" || "delegate_member_ids_p";
3621 INSERT INTO "delegating_voter" (
3622 "issue_id",
3623 "member_id",
3624 "scope",
3625 "delegate_member_ids"
3626 ) VALUES (
3627 "issue_id_p",
3628 "issue_delegation_row"."truster_id",
3629 "issue_delegation_row"."scope",
3630 "delegate_member_ids_v"
3631 );
3632 "sub_weight_v" := 1 +
3633 "weight_of_added_vote_delegations"(
3634 "issue_id_p",
3635 "issue_delegation_row"."truster_id",
3636 "delegate_member_ids_v"
3637 );
3638 UPDATE "delegating_voter"
3639 SET "weight" = "sub_weight_v"
3640 WHERE "issue_id" = "issue_id_p"
3641 AND "member_id" = "issue_delegation_row"."truster_id";
3642 "weight_v" := "weight_v" + "sub_weight_v";
3643 END IF;
3644 END LOOP;
3645 RETURN "weight_v";
3646 END;
3647 $$;
3649 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3650 ( "issue"."id"%TYPE,
3651 "member"."id"%TYPE,
3652 "delegating_voter"."delegate_member_ids"%TYPE )
3653 IS 'Helper function for "add_vote_delegations" function';
3656 CREATE FUNCTION "add_vote_delegations"
3657 ( "issue_id_p" "issue"."id"%TYPE )
3658 RETURNS VOID
3659 LANGUAGE 'plpgsql' VOLATILE AS $$
3660 DECLARE
3661 "member_id_v" "member"."id"%TYPE;
3662 BEGIN
3663 FOR "member_id_v" IN
3664 SELECT "member_id" FROM "direct_voter"
3665 WHERE "issue_id" = "issue_id_p"
3666 LOOP
3667 UPDATE "direct_voter" SET
3668 "weight" = "weight" + "weight_of_added_vote_delegations"(
3669 "issue_id_p",
3670 "member_id_v",
3671 '{}'
3673 WHERE "member_id" = "member_id_v"
3674 AND "issue_id" = "issue_id_p";
3675 END LOOP;
3676 RETURN;
3677 END;
3678 $$;
3680 COMMENT ON FUNCTION "add_vote_delegations"
3681 ( "issue_id_p" "issue"."id"%TYPE )
3682 IS 'Helper function for "close_voting" function';
3685 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3686 RETURNS VOID
3687 LANGUAGE 'plpgsql' VOLATILE AS $$
3688 DECLARE
3689 "area_id_v" "area"."id"%TYPE;
3690 "unit_id_v" "unit"."id"%TYPE;
3691 "member_id_v" "member"."id"%TYPE;
3692 BEGIN
3693 PERFORM "lock_issue"("issue_id_p");
3694 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3695 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3696 -- delete delegating votes (in cases of manual reset of issue state):
3697 DELETE FROM "delegating_voter"
3698 WHERE "issue_id" = "issue_id_p";
3699 -- delete votes from non-privileged voters:
3700 DELETE FROM "direct_voter"
3701 USING (
3702 SELECT
3703 "direct_voter"."member_id"
3704 FROM "direct_voter"
3705 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3706 LEFT JOIN "privilege"
3707 ON "privilege"."unit_id" = "unit_id_v"
3708 AND "privilege"."member_id" = "direct_voter"."member_id"
3709 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3710 "member"."active" = FALSE OR
3711 "privilege"."voting_right" ISNULL OR
3712 "privilege"."voting_right" = FALSE
3714 ) AS "subquery"
3715 WHERE "direct_voter"."issue_id" = "issue_id_p"
3716 AND "direct_voter"."member_id" = "subquery"."member_id";
3717 -- consider delegations:
3718 UPDATE "direct_voter" SET "weight" = 1
3719 WHERE "issue_id" = "issue_id_p";
3720 PERFORM "add_vote_delegations"("issue_id_p");
3721 -- set voter count and mark issue as being calculated:
3722 UPDATE "issue" SET
3723 "state" = 'calculation',
3724 "closed" = now(),
3725 "voter_count" = (
3726 SELECT coalesce(sum("weight"), 0)
3727 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3729 WHERE "id" = "issue_id_p";
3730 -- materialize battle_view:
3731 -- NOTE: "closed" column of issue must be set at this point
3732 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3733 INSERT INTO "battle" (
3734 "issue_id",
3735 "winning_initiative_id", "losing_initiative_id",
3736 "count"
3737 ) SELECT
3738 "issue_id",
3739 "winning_initiative_id", "losing_initiative_id",
3740 "count"
3741 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3742 -- copy "positive_votes" and "negative_votes" from "battle" table:
3743 UPDATE "initiative" SET
3744 "positive_votes" = "battle_win"."count",
3745 "negative_votes" = "battle_lose"."count"
3746 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3747 WHERE
3748 "battle_win"."issue_id" = "issue_id_p" AND
3749 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3750 "battle_win"."losing_initiative_id" ISNULL AND
3751 "battle_lose"."issue_id" = "issue_id_p" AND
3752 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3753 "battle_lose"."winning_initiative_id" ISNULL;
3754 END;
3755 $$;
3757 COMMENT ON FUNCTION "close_voting"
3758 ( "issue"."id"%TYPE )
3759 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.';
3762 CREATE FUNCTION "defeat_strength"
3763 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3764 RETURNS INT8
3765 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3766 BEGIN
3767 IF "positive_votes_p" > "negative_votes_p" THEN
3768 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3769 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3770 RETURN 0;
3771 ELSE
3772 RETURN -1;
3773 END IF;
3774 END;
3775 $$;
3777 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';
3780 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3781 RETURNS VOID
3782 LANGUAGE 'plpgsql' VOLATILE AS $$
3783 DECLARE
3784 "issue_row" "issue"%ROWTYPE;
3785 "policy_row" "policy"%ROWTYPE;
3786 "dimension_v" INTEGER;
3787 "vote_matrix" INT4[][]; -- absolute votes
3788 "matrix" INT8[][]; -- defeat strength / best paths
3789 "i" INTEGER;
3790 "j" INTEGER;
3791 "k" INTEGER;
3792 "battle_row" "battle"%ROWTYPE;
3793 "rank_ary" INT4[];
3794 "rank_v" INT4;
3795 "done_v" INTEGER;
3796 "winners_ary" INTEGER[];
3797 "initiative_id_v" "initiative"."id"%TYPE;
3798 BEGIN
3799 SELECT * INTO "issue_row"
3800 FROM "issue" WHERE "id" = "issue_id_p"
3801 FOR UPDATE;
3802 SELECT * INTO "policy_row"
3803 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3804 SELECT count(1) INTO "dimension_v"
3805 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3806 -- Create "vote_matrix" with absolute number of votes in pairwise
3807 -- comparison:
3808 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3809 "i" := 1;
3810 "j" := 2;
3811 FOR "battle_row" IN
3812 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3813 ORDER BY
3814 "winning_initiative_id" NULLS LAST,
3815 "losing_initiative_id" NULLS LAST
3816 LOOP
3817 "vote_matrix"["i"]["j"] := "battle_row"."count";
3818 IF "j" = "dimension_v" THEN
3819 "i" := "i" + 1;
3820 "j" := 1;
3821 ELSE
3822 "j" := "j" + 1;
3823 IF "j" = "i" THEN
3824 "j" := "j" + 1;
3825 END IF;
3826 END IF;
3827 END LOOP;
3828 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3829 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3830 END IF;
3831 -- Store defeat strengths in "matrix" using "defeat_strength"
3832 -- function:
3833 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3834 "i" := 1;
3835 LOOP
3836 "j" := 1;
3837 LOOP
3838 IF "i" != "j" THEN
3839 "matrix"["i"]["j"] := "defeat_strength"(
3840 "vote_matrix"["i"]["j"],
3841 "vote_matrix"["j"]["i"]
3842 );
3843 END IF;
3844 EXIT WHEN "j" = "dimension_v";
3845 "j" := "j" + 1;
3846 END LOOP;
3847 EXIT WHEN "i" = "dimension_v";
3848 "i" := "i" + 1;
3849 END LOOP;
3850 -- Find best paths:
3851 "i" := 1;
3852 LOOP
3853 "j" := 1;
3854 LOOP
3855 IF "i" != "j" THEN
3856 "k" := 1;
3857 LOOP
3858 IF "i" != "k" AND "j" != "k" THEN
3859 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3860 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3861 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3862 END IF;
3863 ELSE
3864 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3865 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3866 END IF;
3867 END IF;
3868 END IF;
3869 EXIT WHEN "k" = "dimension_v";
3870 "k" := "k" + 1;
3871 END LOOP;
3872 END IF;
3873 EXIT WHEN "j" = "dimension_v";
3874 "j" := "j" + 1;
3875 END LOOP;
3876 EXIT WHEN "i" = "dimension_v";
3877 "i" := "i" + 1;
3878 END LOOP;
3879 -- Determine order of winners:
3880 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3881 "rank_v" := 1;
3882 "done_v" := 0;
3883 LOOP
3884 "winners_ary" := '{}';
3885 "i" := 1;
3886 LOOP
3887 IF "rank_ary"["i"] ISNULL THEN
3888 "j" := 1;
3889 LOOP
3890 IF
3891 "i" != "j" AND
3892 "rank_ary"["j"] ISNULL AND
3893 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3894 THEN
3895 -- someone else is better
3896 EXIT;
3897 END IF;
3898 IF "j" = "dimension_v" THEN
3899 -- noone is better
3900 "winners_ary" := "winners_ary" || "i";
3901 EXIT;
3902 END IF;
3903 "j" := "j" + 1;
3904 END LOOP;
3905 END IF;
3906 EXIT WHEN "i" = "dimension_v";
3907 "i" := "i" + 1;
3908 END LOOP;
3909 "i" := 1;
3910 LOOP
3911 "rank_ary"["winners_ary"["i"]] := "rank_v";
3912 "done_v" := "done_v" + 1;
3913 EXIT WHEN "i" = array_upper("winners_ary", 1);
3914 "i" := "i" + 1;
3915 END LOOP;
3916 EXIT WHEN "done_v" = "dimension_v";
3917 "rank_v" := "rank_v" + 1;
3918 END LOOP;
3919 -- write preliminary results:
3920 "i" := 1;
3921 FOR "initiative_id_v" IN
3922 SELECT "id" FROM "initiative"
3923 WHERE "issue_id" = "issue_id_p" AND "admitted"
3924 ORDER BY "id"
3925 LOOP
3926 UPDATE "initiative" SET
3927 "direct_majority" =
3928 CASE WHEN "policy_row"."direct_majority_strict" THEN
3929 "positive_votes" * "policy_row"."direct_majority_den" >
3930 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3931 ELSE
3932 "positive_votes" * "policy_row"."direct_majority_den" >=
3933 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3934 END
3935 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3936 AND "issue_row"."voter_count"-"negative_votes" >=
3937 "policy_row"."direct_majority_non_negative",
3938 "indirect_majority" =
3939 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3940 "positive_votes" * "policy_row"."indirect_majority_den" >
3941 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3942 ELSE
3943 "positive_votes" * "policy_row"."indirect_majority_den" >=
3944 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3945 END
3946 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3947 AND "issue_row"."voter_count"-"negative_votes" >=
3948 "policy_row"."indirect_majority_non_negative",
3949 "schulze_rank" = "rank_ary"["i"],
3950 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3951 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3952 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3953 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3954 "eligible" = FALSE,
3955 "winner" = FALSE,
3956 "rank" = NULL -- NOTE: in cases of manual reset of issue state
3957 WHERE "id" = "initiative_id_v";
3958 "i" := "i" + 1;
3959 END LOOP;
3960 IF "i" != "dimension_v" THEN
3961 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3962 END IF;
3963 -- take indirect majorities into account:
3964 LOOP
3965 UPDATE "initiative" SET "indirect_majority" = TRUE
3966 FROM (
3967 SELECT "new_initiative"."id" AS "initiative_id"
3968 FROM "initiative" "old_initiative"
3969 JOIN "initiative" "new_initiative"
3970 ON "new_initiative"."issue_id" = "issue_id_p"
3971 AND "new_initiative"."indirect_majority" = FALSE
3972 JOIN "battle" "battle_win"
3973 ON "battle_win"."issue_id" = "issue_id_p"
3974 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3975 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3976 JOIN "battle" "battle_lose"
3977 ON "battle_lose"."issue_id" = "issue_id_p"
3978 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3979 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3980 WHERE "old_initiative"."issue_id" = "issue_id_p"
3981 AND "old_initiative"."indirect_majority" = TRUE
3982 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3983 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3984 "policy_row"."indirect_majority_num" *
3985 ("battle_win"."count"+"battle_lose"."count")
3986 ELSE
3987 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3988 "policy_row"."indirect_majority_num" *
3989 ("battle_win"."count"+"battle_lose"."count")
3990 END
3991 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3992 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3993 "policy_row"."indirect_majority_non_negative"
3994 ) AS "subquery"
3995 WHERE "id" = "subquery"."initiative_id";
3996 EXIT WHEN NOT FOUND;
3997 END LOOP;
3998 -- set "multistage_majority" for remaining matching initiatives:
3999 UPDATE "initiative" SET "multistage_majority" = TRUE
4000 FROM (
4001 SELECT "losing_initiative"."id" AS "initiative_id"
4002 FROM "initiative" "losing_initiative"
4003 JOIN "initiative" "winning_initiative"
4004 ON "winning_initiative"."issue_id" = "issue_id_p"
4005 AND "winning_initiative"."admitted"
4006 JOIN "battle" "battle_win"
4007 ON "battle_win"."issue_id" = "issue_id_p"
4008 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4009 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4010 JOIN "battle" "battle_lose"
4011 ON "battle_lose"."issue_id" = "issue_id_p"
4012 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4013 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4014 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4015 AND "losing_initiative"."admitted"
4016 AND "winning_initiative"."schulze_rank" <
4017 "losing_initiative"."schulze_rank"
4018 AND "battle_win"."count" > "battle_lose"."count"
4019 AND (
4020 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4021 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4022 ) AS "subquery"
4023 WHERE "id" = "subquery"."initiative_id";
4024 -- mark eligible initiatives:
4025 UPDATE "initiative" SET "eligible" = TRUE
4026 WHERE "issue_id" = "issue_id_p"
4027 AND "initiative"."direct_majority"
4028 AND "initiative"."indirect_majority"
4029 AND "initiative"."better_than_status_quo"
4030 AND (
4031 "policy_row"."no_multistage_majority" = FALSE OR
4032 "initiative"."multistage_majority" = FALSE )
4033 AND (
4034 "policy_row"."no_reverse_beat_path" = FALSE OR
4035 "initiative"."reverse_beat_path" = FALSE );
4036 -- mark final winner:
4037 UPDATE "initiative" SET "winner" = TRUE
4038 FROM (
4039 SELECT "id" AS "initiative_id"
4040 FROM "initiative"
4041 WHERE "issue_id" = "issue_id_p" AND "eligible"
4042 ORDER BY
4043 "schulze_rank",
4044 "vote_ratio"("positive_votes", "negative_votes"),
4045 "id"
4046 LIMIT 1
4047 ) AS "subquery"
4048 WHERE "id" = "subquery"."initiative_id";
4049 -- write (final) ranks:
4050 "rank_v" := 1;
4051 FOR "initiative_id_v" IN
4052 SELECT "id"
4053 FROM "initiative"
4054 WHERE "issue_id" = "issue_id_p" AND "admitted"
4055 ORDER BY
4056 "winner" DESC,
4057 "eligible" DESC,
4058 "schulze_rank",
4059 "vote_ratio"("positive_votes", "negative_votes"),
4060 "id"
4061 LOOP
4062 UPDATE "initiative" SET "rank" = "rank_v"
4063 WHERE "id" = "initiative_id_v";
4064 "rank_v" := "rank_v" + 1;
4065 END LOOP;
4066 -- set schulze rank of status quo and mark issue as finished:
4067 UPDATE "issue" SET
4068 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4069 "state" =
4070 CASE WHEN EXISTS (
4071 SELECT NULL FROM "initiative"
4072 WHERE "issue_id" = "issue_id_p" AND "winner"
4073 ) THEN
4074 'finished_with_winner'::"issue_state"
4075 ELSE
4076 'finished_without_winner'::"issue_state"
4077 END,
4078 "ranks_available" = TRUE
4079 WHERE "id" = "issue_id_p";
4080 RETURN;
4081 END;
4082 $$;
4084 COMMENT ON FUNCTION "calculate_ranks"
4085 ( "issue"."id"%TYPE )
4086 IS 'Determine ranking (Votes have to be counted first)';
4090 -----------------------------
4091 -- Automatic state changes --
4092 -----------------------------
4095 CREATE FUNCTION "check_issue"
4096 ( "issue_id_p" "issue"."id"%TYPE )
4097 RETURNS VOID
4098 LANGUAGE 'plpgsql' VOLATILE AS $$
4099 DECLARE
4100 "issue_row" "issue"%ROWTYPE;
4101 "policy_row" "policy"%ROWTYPE;
4102 BEGIN
4103 PERFORM "lock_issue"("issue_id_p");
4104 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4105 -- only process open issues:
4106 IF "issue_row"."closed" ISNULL THEN
4107 SELECT * INTO "policy_row" FROM "policy"
4108 WHERE "id" = "issue_row"."policy_id";
4109 -- create a snapshot, unless issue is already fully frozen:
4110 IF "issue_row"."fully_frozen" ISNULL THEN
4111 PERFORM "create_snapshot"("issue_id_p");
4112 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4113 END IF;
4114 -- eventually close or accept issues, which have not been accepted:
4115 IF "issue_row"."accepted" ISNULL THEN
4116 IF EXISTS (
4117 SELECT NULL FROM "initiative"
4118 WHERE "issue_id" = "issue_id_p"
4119 AND "supporter_count" > 0
4120 AND "supporter_count" * "policy_row"."issue_quorum_den"
4121 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4122 ) THEN
4123 -- accept issues, if supporter count is high enough
4124 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4125 -- NOTE: "issue_row" used later
4126 "issue_row"."state" := 'discussion';
4127 "issue_row"."accepted" := now();
4128 UPDATE "issue" SET
4129 "state" = "issue_row"."state",
4130 "accepted" = "issue_row"."accepted"
4131 WHERE "id" = "issue_row"."id";
4132 ELSIF
4133 now() >= "issue_row"."created" + "issue_row"."admission_time"
4134 THEN
4135 -- close issues, if admission time has expired
4136 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4137 UPDATE "issue" SET
4138 "state" = 'canceled_issue_not_accepted',
4139 "closed" = now()
4140 WHERE "id" = "issue_row"."id";
4141 END IF;
4142 END IF;
4143 -- eventually half freeze issues:
4144 IF
4145 -- NOTE: issue can't be closed at this point, if it has been accepted
4146 "issue_row"."accepted" NOTNULL AND
4147 "issue_row"."half_frozen" ISNULL
4148 THEN
4149 IF
4150 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4151 THEN
4152 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4153 -- NOTE: "issue_row" used later
4154 "issue_row"."state" := 'verification';
4155 "issue_row"."half_frozen" := now();
4156 UPDATE "issue" SET
4157 "state" = "issue_row"."state",
4158 "half_frozen" = "issue_row"."half_frozen"
4159 WHERE "id" = "issue_row"."id";
4160 END IF;
4161 END IF;
4162 -- close issues after some time, if all initiatives have been revoked:
4163 IF
4164 "issue_row"."closed" ISNULL AND
4165 NOT EXISTS (
4166 -- all initiatives are revoked
4167 SELECT NULL FROM "initiative"
4168 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4169 ) AND (
4170 -- and issue has not been accepted yet
4171 "issue_row"."accepted" ISNULL OR
4172 NOT EXISTS (
4173 -- or no initiatives have been revoked lately
4174 SELECT NULL FROM "initiative"
4175 WHERE "issue_id" = "issue_id_p"
4176 AND now() < "revoked" + "issue_row"."verification_time"
4177 ) OR (
4178 -- or verification time has elapsed
4179 "issue_row"."half_frozen" NOTNULL AND
4180 "issue_row"."fully_frozen" ISNULL AND
4181 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4184 THEN
4185 -- NOTE: "issue_row" used later
4186 IF "issue_row"."accepted" ISNULL THEN
4187 "issue_row"."state" := 'canceled_revoked_before_accepted';
4188 ELSIF "issue_row"."half_frozen" ISNULL THEN
4189 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4190 ELSE
4191 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4192 END IF;
4193 "issue_row"."closed" := now();
4194 UPDATE "issue" SET
4195 "state" = "issue_row"."state",
4196 "closed" = "issue_row"."closed"
4197 WHERE "id" = "issue_row"."id";
4198 END IF;
4199 -- fully freeze issue after verification time:
4200 IF
4201 "issue_row"."half_frozen" NOTNULL AND
4202 "issue_row"."fully_frozen" ISNULL AND
4203 "issue_row"."closed" ISNULL AND
4204 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4205 THEN
4206 PERFORM "freeze_after_snapshot"("issue_id_p");
4207 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4208 END IF;
4209 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4210 -- close issue by calling close_voting(...) after voting time:
4211 IF
4212 "issue_row"."closed" ISNULL AND
4213 "issue_row"."fully_frozen" NOTNULL AND
4214 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4215 THEN
4216 PERFORM "close_voting"("issue_id_p");
4217 -- calculate ranks will not consume much time and can be done now
4218 PERFORM "calculate_ranks"("issue_id_p");
4219 END IF;
4220 END IF;
4221 RETURN;
4222 END;
4223 $$;
4225 COMMENT ON FUNCTION "check_issue"
4226 ( "issue"."id"%TYPE )
4227 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required; At end of voting the ranking is not calculated by this function, but must be calculated in a seperate transaction using the "calculate_ranks" function.';
4230 CREATE FUNCTION "check_everything"()
4231 RETURNS VOID
4232 LANGUAGE 'plpgsql' VOLATILE AS $$
4233 DECLARE
4234 "issue_id_v" "issue"."id"%TYPE;
4235 BEGIN
4236 DELETE FROM "expired_session";
4237 PERFORM "check_activity"();
4238 PERFORM "calculate_member_counts"();
4239 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4240 PERFORM "check_issue"("issue_id_v");
4241 END LOOP;
4242 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4243 PERFORM "calculate_ranks"("issue_id_v");
4244 END LOOP;
4245 RETURN;
4246 END;
4247 $$;
4249 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue, and if possible, automatically calculates ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result. In productive environments you should call the lf_update program instead.';
4253 ----------------------
4254 -- Deletion of data --
4255 ----------------------
4258 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4259 RETURNS VOID
4260 LANGUAGE 'plpgsql' VOLATILE AS $$
4261 DECLARE
4262 "issue_row" "issue"%ROWTYPE;
4263 BEGIN
4264 SELECT * INTO "issue_row"
4265 FROM "issue" WHERE "id" = "issue_id_p"
4266 FOR UPDATE;
4267 IF "issue_row"."cleaned" ISNULL THEN
4268 UPDATE "issue" SET
4269 "state" = 'voting',
4270 "closed" = NULL,
4271 "ranks_available" = FALSE
4272 WHERE "id" = "issue_id_p";
4273 DELETE FROM "voting_comment"
4274 WHERE "issue_id" = "issue_id_p";
4275 DELETE FROM "delegating_voter"
4276 WHERE "issue_id" = "issue_id_p";
4277 DELETE FROM "direct_voter"
4278 WHERE "issue_id" = "issue_id_p";
4279 DELETE FROM "delegating_interest_snapshot"
4280 WHERE "issue_id" = "issue_id_p";
4281 DELETE FROM "direct_interest_snapshot"
4282 WHERE "issue_id" = "issue_id_p";
4283 DELETE FROM "delegating_population_snapshot"
4284 WHERE "issue_id" = "issue_id_p";
4285 DELETE FROM "direct_population_snapshot"
4286 WHERE "issue_id" = "issue_id_p";
4287 DELETE FROM "non_voter"
4288 WHERE "issue_id" = "issue_id_p";
4289 DELETE FROM "delegation"
4290 WHERE "issue_id" = "issue_id_p";
4291 DELETE FROM "supporter"
4292 WHERE "issue_id" = "issue_id_p";
4293 UPDATE "issue" SET
4294 "state" = "issue_row"."state",
4295 "closed" = "issue_row"."closed",
4296 "ranks_available" = "issue_row"."ranks_available",
4297 "cleaned" = now()
4298 WHERE "id" = "issue_id_p";
4299 END IF;
4300 RETURN;
4301 END;
4302 $$;
4304 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4307 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4308 RETURNS VOID
4309 LANGUAGE 'plpgsql' VOLATILE AS $$
4310 BEGIN
4311 UPDATE "member" SET
4312 "last_login" = NULL,
4313 "login" = NULL,
4314 "password" = NULL,
4315 "locked" = TRUE,
4316 "active" = FALSE,
4317 "notify_email" = NULL,
4318 "notify_email_unconfirmed" = NULL,
4319 "notify_email_secret" = NULL,
4320 "notify_email_secret_expiry" = NULL,
4321 "notify_email_lock_expiry" = NULL,
4322 "password_reset_secret" = NULL,
4323 "password_reset_secret_expiry" = NULL,
4324 "organizational_unit" = NULL,
4325 "internal_posts" = NULL,
4326 "realname" = NULL,
4327 "birthday" = NULL,
4328 "address" = NULL,
4329 "email" = NULL,
4330 "xmpp_address" = NULL,
4331 "website" = NULL,
4332 "phone" = NULL,
4333 "mobile_phone" = NULL,
4334 "profession" = NULL,
4335 "external_memberships" = NULL,
4336 "external_posts" = NULL,
4337 "statement" = NULL
4338 WHERE "id" = "member_id_p";
4339 -- "text_search_data" is updated by triggers
4340 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4341 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4342 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4343 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4344 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4345 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4346 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4347 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4348 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4349 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4350 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4351 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4352 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4353 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4354 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4355 DELETE FROM "direct_voter" USING "issue"
4356 WHERE "direct_voter"."issue_id" = "issue"."id"
4357 AND "issue"."closed" ISNULL
4358 AND "member_id" = "member_id_p";
4359 RETURN;
4360 END;
4361 $$;
4363 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)';
4366 CREATE FUNCTION "delete_private_data"()
4367 RETURNS VOID
4368 LANGUAGE 'plpgsql' VOLATILE AS $$
4369 BEGIN
4370 DELETE FROM "member" WHERE "activated" ISNULL;
4371 UPDATE "member" SET
4372 "invite_code" = NULL,
4373 "invite_code_expiry" = NULL,
4374 "admin_comment" = NULL,
4375 "last_login" = NULL,
4376 "login" = NULL,
4377 "password" = NULL,
4378 "lang" = NULL,
4379 "notify_email" = NULL,
4380 "notify_email_unconfirmed" = NULL,
4381 "notify_email_secret" = NULL,
4382 "notify_email_secret_expiry" = NULL,
4383 "notify_email_lock_expiry" = NULL,
4384 "notify_level" = NULL,
4385 "password_reset_secret" = NULL,
4386 "password_reset_secret_expiry" = NULL,
4387 "organizational_unit" = NULL,
4388 "internal_posts" = NULL,
4389 "realname" = NULL,
4390 "birthday" = NULL,
4391 "address" = NULL,
4392 "email" = NULL,
4393 "xmpp_address" = NULL,
4394 "website" = NULL,
4395 "phone" = NULL,
4396 "mobile_phone" = NULL,
4397 "profession" = NULL,
4398 "external_memberships" = NULL,
4399 "external_posts" = NULL,
4400 "formatting_engine" = NULL,
4401 "statement" = NULL;
4402 -- "text_search_data" is updated by triggers
4403 DELETE FROM "setting";
4404 DELETE FROM "setting_map";
4405 DELETE FROM "member_relation_setting";
4406 DELETE FROM "member_image";
4407 DELETE FROM "contact";
4408 DELETE FROM "ignored_member";
4409 DELETE FROM "session";
4410 DELETE FROM "area_setting";
4411 DELETE FROM "issue_setting";
4412 DELETE FROM "ignored_initiative";
4413 DELETE FROM "initiative_setting";
4414 DELETE FROM "suggestion_setting";
4415 DELETE FROM "non_voter";
4416 DELETE FROM "direct_voter" USING "issue"
4417 WHERE "direct_voter"."issue_id" = "issue"."id"
4418 AND "issue"."closed" ISNULL;
4419 RETURN;
4420 END;
4421 $$;
4423 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.';
4427 COMMIT;

Impressum / About Us