liquid_feedback_core

view core.sql @ 289:f2292b94fc58

Updated comments for polling mode in core.sql and core-update.v2.0.11-v2.1.0.sql
author jbe
date Sun Aug 19 23:32:26 2012 +0200 (2012-08-19)
parents 4868a7d591de
children 2301a1f2acfa
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 -- DEPRECATED API TABLES --
175 CREATE TYPE "application_access_level" AS ENUM
176 ('member', 'full', 'pseudonymous', 'anonymous');
178 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
181 CREATE TABLE "member_application" (
182 "id" SERIAL8 PRIMARY KEY,
183 UNIQUE ("member_id", "name"),
184 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
185 ON DELETE CASCADE ON UPDATE CASCADE,
186 "name" TEXT NOT NULL,
187 "comment" TEXT,
188 "access_level" "application_access_level" NOT NULL,
189 "key" TEXT NOT NULL UNIQUE,
190 "last_usage" TIMESTAMPTZ );
192 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
194 -- END OF DEPRECARED API TABLES --
197 CREATE TABLE "member_history" (
198 "id" SERIAL8 PRIMARY KEY,
199 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
200 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
201 "active" BOOLEAN NOT NULL,
202 "name" TEXT NOT NULL );
203 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
205 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
207 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
208 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
211 CREATE TABLE "rendered_member_statement" (
212 PRIMARY KEY ("member_id", "format"),
213 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
214 "format" TEXT,
215 "content" TEXT NOT NULL );
217 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)';
220 CREATE TABLE "setting" (
221 PRIMARY KEY ("member_id", "key"),
222 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
223 "key" TEXT NOT NULL,
224 "value" TEXT NOT NULL );
225 CREATE INDEX "setting_key_idx" ON "setting" ("key");
227 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
229 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
232 CREATE TABLE "setting_map" (
233 PRIMARY KEY ("member_id", "key", "subkey"),
234 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
235 "key" TEXT NOT NULL,
236 "subkey" TEXT NOT NULL,
237 "value" TEXT NOT NULL );
238 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
240 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
242 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
243 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
244 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
247 CREATE TABLE "member_relation_setting" (
248 PRIMARY KEY ("member_id", "key", "other_member_id"),
249 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
250 "key" TEXT NOT NULL,
251 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
252 "value" TEXT NOT NULL );
254 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
257 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
259 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
262 CREATE TABLE "member_image" (
263 PRIMARY KEY ("member_id", "image_type", "scaled"),
264 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
265 "image_type" "member_image_type",
266 "scaled" BOOLEAN,
267 "content_type" TEXT,
268 "data" BYTEA NOT NULL );
270 COMMENT ON TABLE "member_image" IS 'Images of members';
272 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
275 CREATE TABLE "member_count" (
276 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
277 "total_count" INT4 NOT NULL );
279 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';
281 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
282 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
285 CREATE TABLE "contact" (
286 PRIMARY KEY ("member_id", "other_member_id"),
287 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
288 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
289 "public" BOOLEAN NOT NULL DEFAULT FALSE,
290 CONSTRAINT "cant_save_yourself_as_contact"
291 CHECK ("member_id" != "other_member_id") );
292 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
294 COMMENT ON TABLE "contact" IS 'Contact lists';
296 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
297 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
298 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
301 CREATE TABLE "ignored_member" (
302 PRIMARY KEY ("member_id", "other_member_id"),
303 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
304 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
305 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
307 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
309 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
310 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
313 CREATE TABLE "session" (
314 "ident" TEXT PRIMARY KEY,
315 "additional_secret" TEXT,
316 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
317 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
318 "lang" TEXT );
319 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
321 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
323 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
324 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
325 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
326 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
329 CREATE TABLE "policy" (
330 "id" SERIAL4 PRIMARY KEY,
331 "index" INT4 NOT NULL,
332 "active" BOOLEAN NOT NULL DEFAULT TRUE,
333 "name" TEXT NOT NULL UNIQUE,
334 "description" TEXT NOT NULL DEFAULT '',
335 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
336 "admission_time" INTERVAL,
337 "discussion_time" INTERVAL,
338 "verification_time" INTERVAL,
339 "voting_time" INTERVAL,
340 "issue_quorum_num" INT4 NOT NULL,
341 "issue_quorum_den" INT4 NOT NULL,
342 "initiative_quorum_num" INT4 NOT NULL,
343 "initiative_quorum_den" INT4 NOT NULL,
344 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
345 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
346 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
347 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
348 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
349 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
350 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
351 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
352 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
353 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
354 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
355 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
356 CONSTRAINT "timing" CHECK (
357 ( "polling" = FALSE AND
358 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
359 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
360 ( "polling" = TRUE AND
361 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
362 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
363 ( "polling" = TRUE AND
364 "admission_time" ISNULL AND "discussion_time" ISNULL AND
365 "verification_time" ISNULL AND "voting_time" ISNULL ) ) );
366 CREATE INDEX "policy_active_idx" ON "policy" ("active");
368 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
370 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
371 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
372 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
373 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
374 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
375 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"';
376 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'')';
377 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''';
378 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''';
379 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
380 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
381 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
382 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
383 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.';
384 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
385 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';
386 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';
387 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';
388 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.';
389 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';
390 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';
391 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.';
392 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").';
395 CREATE TABLE "unit" (
396 "id" SERIAL4 PRIMARY KEY,
397 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
398 "active" BOOLEAN NOT NULL DEFAULT TRUE,
399 "name" TEXT NOT NULL,
400 "description" TEXT NOT NULL DEFAULT '',
401 "member_count" INT4,
402 "text_search_data" TSVECTOR );
403 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
404 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
405 CREATE INDEX "unit_active_idx" ON "unit" ("active");
406 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
407 CREATE TRIGGER "update_text_search_data"
408 BEFORE INSERT OR UPDATE ON "unit"
409 FOR EACH ROW EXECUTE PROCEDURE
410 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
411 "name", "description" );
413 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
415 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
416 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
417 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
420 CREATE TABLE "unit_setting" (
421 PRIMARY KEY ("member_id", "key", "unit_id"),
422 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
423 "key" TEXT NOT NULL,
424 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
425 "value" TEXT NOT NULL );
427 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
430 CREATE TABLE "area" (
431 "id" SERIAL4 PRIMARY KEY,
432 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
433 "active" BOOLEAN NOT NULL DEFAULT TRUE,
434 "name" TEXT NOT NULL,
435 "description" TEXT NOT NULL DEFAULT '',
436 "direct_member_count" INT4,
437 "member_weight" INT4,
438 "text_search_data" TSVECTOR );
439 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
440 CREATE INDEX "area_active_idx" ON "area" ("active");
441 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
442 CREATE TRIGGER "update_text_search_data"
443 BEFORE INSERT OR UPDATE ON "area"
444 FOR EACH ROW EXECUTE PROCEDURE
445 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
446 "name", "description" );
448 COMMENT ON TABLE "area" IS 'Subject areas';
450 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
451 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"';
452 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
455 CREATE TABLE "area_setting" (
456 PRIMARY KEY ("member_id", "key", "area_id"),
457 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
458 "key" TEXT NOT NULL,
459 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
460 "value" TEXT NOT NULL );
462 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
465 CREATE TABLE "allowed_policy" (
466 PRIMARY KEY ("area_id", "policy_id"),
467 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
468 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
469 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
470 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
472 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
474 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
477 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
479 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';
482 CREATE TYPE "issue_state" AS ENUM (
483 'admission', 'discussion', 'verification', 'voting',
484 'canceled_revoked_before_accepted',
485 'canceled_issue_not_accepted',
486 'canceled_after_revocation_during_discussion',
487 'canceled_after_revocation_during_verification',
488 'calculation',
489 'canceled_no_initiative_admitted',
490 'finished_without_winner', 'finished_with_winner');
492 COMMENT ON TYPE "issue_state" IS 'State of issues';
495 CREATE TABLE "issue" (
496 "id" SERIAL4 PRIMARY KEY,
497 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
498 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
499 "state" "issue_state" NOT NULL DEFAULT 'admission',
500 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
501 "accepted" TIMESTAMPTZ,
502 "half_frozen" TIMESTAMPTZ,
503 "fully_frozen" TIMESTAMPTZ,
504 "closed" TIMESTAMPTZ,
505 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
506 "cleaned" TIMESTAMPTZ,
507 "admission_time" INTERVAL NOT NULL,
508 "discussion_time" INTERVAL NOT NULL,
509 "verification_time" INTERVAL NOT NULL,
510 "voting_time" INTERVAL NOT NULL,
511 "snapshot" TIMESTAMPTZ,
512 "latest_snapshot_event" "snapshot_event",
513 "population" INT4,
514 "voter_count" INT4,
515 "status_quo_schulze_rank" INT4,
516 CONSTRAINT "valid_state" CHECK ((
517 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
518 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
519 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
520 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
521 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
522 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
523 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
524 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
525 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
526 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
527 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
528 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
529 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
530 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
531 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
532 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
533 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
534 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
535 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
536 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
537 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
538 )),
539 CONSTRAINT "state_change_order" CHECK (
540 "created" <= "accepted" AND
541 "accepted" <= "half_frozen" AND
542 "half_frozen" <= "fully_frozen" AND
543 "fully_frozen" <= "closed" ),
544 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
545 "cleaned" ISNULL OR "closed" NOTNULL ),
546 CONSTRAINT "last_snapshot_on_full_freeze"
547 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
548 CONSTRAINT "freeze_requires_snapshot"
549 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
550 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
551 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
552 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
553 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
554 CREATE INDEX "issue_created_idx" ON "issue" ("created");
555 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
556 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
557 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
558 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
559 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
560 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
562 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
564 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
565 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.';
566 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.';
567 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.';
568 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
569 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
570 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
571 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
572 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
573 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
574 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
575 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';
576 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
577 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';
578 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
581 CREATE TABLE "issue_setting" (
582 PRIMARY KEY ("member_id", "key", "issue_id"),
583 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
584 "key" TEXT NOT NULL,
585 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
586 "value" TEXT NOT NULL );
588 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
591 CREATE TABLE "initiative" (
592 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
593 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
594 "id" SERIAL4 PRIMARY KEY,
595 "name" TEXT NOT NULL,
596 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
597 "discussion_url" TEXT,
598 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
599 "revoked" TIMESTAMPTZ,
600 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
601 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
602 "admitted" BOOLEAN,
603 "supporter_count" INT4,
604 "informed_supporter_count" INT4,
605 "satisfied_supporter_count" INT4,
606 "satisfied_informed_supporter_count" INT4,
607 "positive_votes" INT4,
608 "negative_votes" INT4,
609 "direct_majority" BOOLEAN,
610 "indirect_majority" BOOLEAN,
611 "schulze_rank" INT4,
612 "better_than_status_quo" BOOLEAN,
613 "worse_than_status_quo" BOOLEAN,
614 "reverse_beat_path" BOOLEAN,
615 "multistage_majority" BOOLEAN,
616 "eligible" BOOLEAN,
617 "winner" BOOLEAN,
618 "rank" INT4,
619 "text_search_data" TSVECTOR,
620 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
621 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
622 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
623 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
624 CONSTRAINT "revoked_initiatives_cant_be_admitted"
625 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
626 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
627 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
628 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
629 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
630 "schulze_rank" ISNULL AND
631 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
632 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
633 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
634 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
635 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
636 "eligible" = FALSE OR
637 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
638 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
639 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
640 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
641 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
642 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
643 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
644 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
645 CREATE TRIGGER "update_text_search_data"
646 BEFORE INSERT OR UPDATE ON "initiative"
647 FOR EACH ROW EXECUTE PROCEDURE
648 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
649 "name", "discussion_url");
651 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.';
653 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
654 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
655 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
656 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
657 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
658 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
659 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
660 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
661 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
662 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
663 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
664 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"';
665 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
666 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
667 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
668 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
669 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';
670 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';
671 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"';
672 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
673 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';
676 CREATE TABLE "battle" (
677 "issue_id" INT4 NOT NULL,
678 "winning_initiative_id" INT4,
679 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
680 "losing_initiative_id" INT4,
681 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
682 "count" INT4 NOT NULL,
683 CONSTRAINT "initiative_ids_not_equal" CHECK (
684 "winning_initiative_id" != "losing_initiative_id" OR
685 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
686 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
687 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
688 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
689 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
691 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';
694 CREATE TABLE "ignored_initiative" (
695 PRIMARY KEY ("initiative_id", "member_id"),
696 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
697 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
698 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
700 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
703 CREATE TABLE "initiative_setting" (
704 PRIMARY KEY ("member_id", "key", "initiative_id"),
705 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
706 "key" TEXT NOT NULL,
707 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
708 "value" TEXT NOT NULL );
710 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
713 CREATE TABLE "draft" (
714 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
715 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
716 "id" SERIAL8 PRIMARY KEY,
717 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
718 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
719 "formatting_engine" TEXT,
720 "content" TEXT NOT NULL,
721 "text_search_data" TSVECTOR );
722 CREATE INDEX "draft_created_idx" ON "draft" ("created");
723 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
724 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
725 CREATE TRIGGER "update_text_search_data"
726 BEFORE INSERT OR UPDATE ON "draft"
727 FOR EACH ROW EXECUTE PROCEDURE
728 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
730 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.';
732 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
733 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
736 CREATE TABLE "rendered_draft" (
737 PRIMARY KEY ("draft_id", "format"),
738 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
739 "format" TEXT,
740 "content" TEXT NOT NULL );
742 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)';
745 CREATE TABLE "suggestion" (
746 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
747 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
748 "id" SERIAL8 PRIMARY KEY,
749 "draft_id" INT8 NOT NULL,
750 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
751 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
752 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
753 "name" TEXT NOT NULL,
754 "formatting_engine" TEXT,
755 "content" TEXT NOT NULL DEFAULT '',
756 "text_search_data" TSVECTOR,
757 "minus2_unfulfilled_count" INT4,
758 "minus2_fulfilled_count" INT4,
759 "minus1_unfulfilled_count" INT4,
760 "minus1_fulfilled_count" INT4,
761 "plus1_unfulfilled_count" INT4,
762 "plus1_fulfilled_count" INT4,
763 "plus2_unfulfilled_count" INT4,
764 "plus2_fulfilled_count" INT4 );
765 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
766 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
767 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
768 CREATE TRIGGER "update_text_search_data"
769 BEFORE INSERT OR UPDATE ON "suggestion"
770 FOR EACH ROW EXECUTE PROCEDURE
771 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
772 "name", "content");
774 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';
776 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")';
777 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
778 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
779 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
780 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
781 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
782 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
783 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
784 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
787 CREATE TABLE "rendered_suggestion" (
788 PRIMARY KEY ("suggestion_id", "format"),
789 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
790 "format" TEXT,
791 "content" TEXT NOT NULL );
793 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)';
796 CREATE TABLE "suggestion_setting" (
797 PRIMARY KEY ("member_id", "key", "suggestion_id"),
798 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
799 "key" TEXT NOT NULL,
800 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "value" TEXT NOT NULL );
803 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
806 CREATE TABLE "privilege" (
807 PRIMARY KEY ("unit_id", "member_id"),
808 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
809 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
810 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
811 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
812 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
813 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
814 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
815 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
816 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
818 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
820 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
821 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
822 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
823 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
824 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
825 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
826 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues';
829 CREATE TABLE "membership" (
830 PRIMARY KEY ("area_id", "member_id"),
831 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
832 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
833 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
835 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
838 CREATE TABLE "interest" (
839 PRIMARY KEY ("issue_id", "member_id"),
840 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
841 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
842 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
844 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.';
847 CREATE TABLE "initiator" (
848 PRIMARY KEY ("initiative_id", "member_id"),
849 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
850 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
851 "accepted" BOOLEAN );
852 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
854 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.';
856 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.';
859 CREATE TABLE "supporter" (
860 "issue_id" INT4 NOT NULL,
861 PRIMARY KEY ("initiative_id", "member_id"),
862 "initiative_id" INT4,
863 "member_id" INT4,
864 "draft_id" INT8 NOT NULL,
865 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
866 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
867 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
869 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.';
871 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
872 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")';
875 CREATE TABLE "opinion" (
876 "initiative_id" INT4 NOT NULL,
877 PRIMARY KEY ("suggestion_id", "member_id"),
878 "suggestion_id" INT8,
879 "member_id" INT4,
880 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
881 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
882 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
883 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
884 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
886 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.';
888 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
891 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
893 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
896 CREATE TABLE "delegation" (
897 "id" SERIAL8 PRIMARY KEY,
898 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
899 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
900 "scope" "delegation_scope" NOT NULL,
901 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
902 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
903 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
904 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
905 CONSTRAINT "no_unit_delegation_to_null"
906 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
907 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
908 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
909 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
910 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
911 UNIQUE ("unit_id", "truster_id"),
912 UNIQUE ("area_id", "truster_id"),
913 UNIQUE ("issue_id", "truster_id") );
914 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
915 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
917 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
919 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
920 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
921 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
924 CREATE TABLE "direct_population_snapshot" (
925 PRIMARY KEY ("issue_id", "event", "member_id"),
926 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
927 "event" "snapshot_event",
928 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
929 "weight" INT4 );
930 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
932 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
934 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
935 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
938 CREATE TABLE "delegating_population_snapshot" (
939 PRIMARY KEY ("issue_id", "event", "member_id"),
940 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
941 "event" "snapshot_event",
942 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
943 "weight" INT4,
944 "scope" "delegation_scope" NOT NULL,
945 "delegate_member_ids" INT4[] NOT NULL );
946 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
948 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
950 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
951 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
952 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
953 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"';
956 CREATE TABLE "direct_interest_snapshot" (
957 PRIMARY KEY ("issue_id", "event", "member_id"),
958 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
959 "event" "snapshot_event",
960 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
961 "weight" INT4 );
962 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
964 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
966 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
967 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
970 CREATE TABLE "delegating_interest_snapshot" (
971 PRIMARY KEY ("issue_id", "event", "member_id"),
972 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
973 "event" "snapshot_event",
974 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
975 "weight" INT4,
976 "scope" "delegation_scope" NOT NULL,
977 "delegate_member_ids" INT4[] NOT NULL );
978 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
980 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
982 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
983 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
984 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
985 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"';
988 CREATE TABLE "direct_supporter_snapshot" (
989 "issue_id" INT4 NOT NULL,
990 PRIMARY KEY ("initiative_id", "event", "member_id"),
991 "initiative_id" INT4,
992 "event" "snapshot_event",
993 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
994 "draft_id" INT8 NOT NULL,
995 "informed" BOOLEAN NOT NULL,
996 "satisfied" BOOLEAN NOT NULL,
997 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
998 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
999 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1000 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1002 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1004 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';
1005 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1006 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1007 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1010 CREATE TABLE "non_voter" (
1011 PRIMARY KEY ("issue_id", "member_id"),
1012 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1013 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1014 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1016 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1019 CREATE TABLE "direct_voter" (
1020 PRIMARY KEY ("issue_id", "member_id"),
1021 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1022 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1023 "weight" INT4,
1024 "comment_changed" TIMESTAMPTZ,
1025 "formatting_engine" TEXT,
1026 "comment" TEXT,
1027 "text_search_data" TSVECTOR );
1028 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1029 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1030 CREATE TRIGGER "update_text_search_data"
1031 BEFORE INSERT OR UPDATE ON "direct_voter"
1032 FOR EACH ROW EXECUTE PROCEDURE
1033 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1035 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.';
1037 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1038 COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL';
1039 COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL';
1040 COMMENT ON COLUMN "direct_voter"."comment" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
1043 CREATE TABLE "rendered_voter_comment" (
1044 PRIMARY KEY ("issue_id", "member_id", "format"),
1045 FOREIGN KEY ("issue_id", "member_id")
1046 REFERENCES "direct_voter" ("issue_id", "member_id")
1047 ON DELETE CASCADE ON UPDATE CASCADE,
1048 "issue_id" INT4,
1049 "member_id" INT4,
1050 "format" TEXT,
1051 "content" TEXT NOT NULL );
1053 COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)';
1056 CREATE TABLE "delegating_voter" (
1057 PRIMARY KEY ("issue_id", "member_id"),
1058 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1059 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1060 "weight" INT4,
1061 "scope" "delegation_scope" NOT NULL,
1062 "delegate_member_ids" INT4[] NOT NULL );
1063 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1065 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1067 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1068 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1069 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"';
1072 CREATE TABLE "vote" (
1073 "issue_id" INT4 NOT NULL,
1074 PRIMARY KEY ("initiative_id", "member_id"),
1075 "initiative_id" INT4,
1076 "member_id" INT4,
1077 "grade" INT4,
1078 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1079 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1080 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1082 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.';
1084 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1085 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.';
1088 CREATE TYPE "event_type" AS ENUM (
1089 'issue_state_changed',
1090 'initiative_created_in_new_issue',
1091 'initiative_created_in_existing_issue',
1092 'initiative_revoked',
1093 'new_draft_created',
1094 'suggestion_created');
1096 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1099 CREATE TABLE "event" (
1100 "id" SERIAL8 PRIMARY KEY,
1101 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1102 "event" "event_type" NOT NULL,
1103 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1104 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1105 "state" "issue_state" CHECK ("state" != 'calculation'),
1106 "initiative_id" INT4,
1107 "draft_id" INT8,
1108 "suggestion_id" INT8,
1109 FOREIGN KEY ("issue_id", "initiative_id")
1110 REFERENCES "initiative" ("issue_id", "id")
1111 ON DELETE CASCADE ON UPDATE CASCADE,
1112 FOREIGN KEY ("initiative_id", "draft_id")
1113 REFERENCES "draft" ("initiative_id", "id")
1114 ON DELETE CASCADE ON UPDATE CASCADE,
1115 FOREIGN KEY ("initiative_id", "suggestion_id")
1116 REFERENCES "suggestion" ("initiative_id", "id")
1117 ON DELETE CASCADE ON UPDATE CASCADE,
1118 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1119 "event" != 'issue_state_changed' OR (
1120 "member_id" ISNULL AND
1121 "issue_id" NOTNULL AND
1122 "state" NOTNULL AND
1123 "initiative_id" ISNULL AND
1124 "draft_id" ISNULL AND
1125 "suggestion_id" ISNULL )),
1126 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1127 "event" NOT IN (
1128 'initiative_created_in_new_issue',
1129 'initiative_created_in_existing_issue',
1130 'initiative_revoked',
1131 'new_draft_created'
1132 ) OR (
1133 "member_id" NOTNULL AND
1134 "issue_id" NOTNULL AND
1135 "state" NOTNULL AND
1136 "initiative_id" NOTNULL AND
1137 "draft_id" NOTNULL AND
1138 "suggestion_id" ISNULL )),
1139 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1140 "event" != 'suggestion_created' OR (
1141 "member_id" NOTNULL AND
1142 "issue_id" NOTNULL AND
1143 "state" NOTNULL AND
1144 "initiative_id" NOTNULL AND
1145 "draft_id" ISNULL AND
1146 "suggestion_id" NOTNULL )) );
1147 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1149 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1151 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1152 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1153 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1154 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1157 CREATE TABLE "notification_sent" (
1158 "event_id" INT8 NOT NULL );
1159 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1161 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1162 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1166 ----------------------------------------------
1167 -- Writing of history entries and event log --
1168 ----------------------------------------------
1171 CREATE FUNCTION "write_member_history_trigger"()
1172 RETURNS TRIGGER
1173 LANGUAGE 'plpgsql' VOLATILE AS $$
1174 BEGIN
1175 IF
1176 ( NEW."active" != OLD."active" OR
1177 NEW."name" != OLD."name" ) AND
1178 OLD."activated" NOTNULL
1179 THEN
1180 INSERT INTO "member_history"
1181 ("member_id", "active", "name")
1182 VALUES (NEW."id", OLD."active", OLD."name");
1183 END IF;
1184 RETURN NULL;
1185 END;
1186 $$;
1188 CREATE TRIGGER "write_member_history"
1189 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1190 "write_member_history_trigger"();
1192 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1193 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1196 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1197 RETURNS TRIGGER
1198 LANGUAGE 'plpgsql' VOLATILE AS $$
1199 BEGIN
1200 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1201 INSERT INTO "event" ("event", "issue_id", "state")
1202 VALUES ('issue_state_changed', NEW."id", NEW."state");
1203 END IF;
1204 RETURN NULL;
1205 END;
1206 $$;
1208 CREATE TRIGGER "write_event_issue_state_changed"
1209 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1210 "write_event_issue_state_changed_trigger"();
1212 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1213 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1216 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1217 RETURNS TRIGGER
1218 LANGUAGE 'plpgsql' VOLATILE AS $$
1219 DECLARE
1220 "initiative_row" "initiative"%ROWTYPE;
1221 "issue_row" "issue"%ROWTYPE;
1222 "event_v" "event_type";
1223 BEGIN
1224 SELECT * INTO "initiative_row" FROM "initiative"
1225 WHERE "id" = NEW."initiative_id";
1226 SELECT * INTO "issue_row" FROM "issue"
1227 WHERE "id" = "initiative_row"."issue_id";
1228 IF EXISTS (
1229 SELECT NULL FROM "draft"
1230 WHERE "initiative_id" = NEW."initiative_id"
1231 AND "id" != NEW."id"
1232 ) THEN
1233 "event_v" := 'new_draft_created';
1234 ELSE
1235 IF EXISTS (
1236 SELECT NULL FROM "initiative"
1237 WHERE "issue_id" = "initiative_row"."issue_id"
1238 AND "id" != "initiative_row"."id"
1239 ) THEN
1240 "event_v" := 'initiative_created_in_existing_issue';
1241 ELSE
1242 "event_v" := 'initiative_created_in_new_issue';
1243 END IF;
1244 END IF;
1245 INSERT INTO "event" (
1246 "event", "member_id",
1247 "issue_id", "state", "initiative_id", "draft_id"
1248 ) VALUES (
1249 "event_v",
1250 NEW."author_id",
1251 "initiative_row"."issue_id",
1252 "issue_row"."state",
1253 "initiative_row"."id",
1254 NEW."id" );
1255 RETURN NULL;
1256 END;
1257 $$;
1259 CREATE TRIGGER "write_event_initiative_or_draft_created"
1260 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1261 "write_event_initiative_or_draft_created_trigger"();
1263 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1264 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1267 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1268 RETURNS TRIGGER
1269 LANGUAGE 'plpgsql' VOLATILE AS $$
1270 DECLARE
1271 "issue_row" "issue"%ROWTYPE;
1272 "draft_id_v" "draft"."id"%TYPE;
1273 BEGIN
1274 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1275 SELECT * INTO "issue_row" FROM "issue"
1276 WHERE "id" = NEW."issue_id";
1277 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1278 WHERE "initiative_id" = NEW."id";
1279 INSERT INTO "event" (
1280 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1281 ) VALUES (
1282 'initiative_revoked',
1283 NEW."revoked_by_member_id",
1284 NEW."issue_id",
1285 "issue_row"."state",
1286 NEW."id",
1287 "draft_id_v");
1288 END IF;
1289 RETURN NULL;
1290 END;
1291 $$;
1293 CREATE TRIGGER "write_event_initiative_revoked"
1294 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1295 "write_event_initiative_revoked_trigger"();
1297 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1298 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1301 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1302 RETURNS TRIGGER
1303 LANGUAGE 'plpgsql' VOLATILE AS $$
1304 DECLARE
1305 "initiative_row" "initiative"%ROWTYPE;
1306 "issue_row" "issue"%ROWTYPE;
1307 BEGIN
1308 SELECT * INTO "initiative_row" FROM "initiative"
1309 WHERE "id" = NEW."initiative_id";
1310 SELECT * INTO "issue_row" FROM "issue"
1311 WHERE "id" = "initiative_row"."issue_id";
1312 INSERT INTO "event" (
1313 "event", "member_id",
1314 "issue_id", "state", "initiative_id", "suggestion_id"
1315 ) VALUES (
1316 'suggestion_created',
1317 NEW."author_id",
1318 "initiative_row"."issue_id",
1319 "issue_row"."state",
1320 "initiative_row"."id",
1321 NEW."id" );
1322 RETURN NULL;
1323 END;
1324 $$;
1326 CREATE TRIGGER "write_event_suggestion_created"
1327 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1328 "write_event_suggestion_created_trigger"();
1330 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1331 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1335 ----------------------------
1336 -- Additional constraints --
1337 ----------------------------
1340 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1341 RETURNS TRIGGER
1342 LANGUAGE 'plpgsql' VOLATILE AS $$
1343 BEGIN
1344 IF NOT EXISTS (
1345 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1346 ) THEN
1347 --RAISE 'Cannot create issue without an initial initiative.' USING
1348 -- ERRCODE = 'integrity_constraint_violation',
1349 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1350 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1351 END IF;
1352 RETURN NULL;
1353 END;
1354 $$;
1356 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1357 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1358 FOR EACH ROW EXECUTE PROCEDURE
1359 "issue_requires_first_initiative_trigger"();
1361 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1362 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1365 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1366 RETURNS TRIGGER
1367 LANGUAGE 'plpgsql' VOLATILE AS $$
1368 DECLARE
1369 "reference_lost" BOOLEAN;
1370 BEGIN
1371 IF TG_OP = 'DELETE' THEN
1372 "reference_lost" := TRUE;
1373 ELSE
1374 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1375 END IF;
1376 IF
1377 "reference_lost" AND NOT EXISTS (
1378 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1380 THEN
1381 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1382 END IF;
1383 RETURN NULL;
1384 END;
1385 $$;
1387 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1388 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1389 FOR EACH ROW EXECUTE PROCEDURE
1390 "last_initiative_deletes_issue_trigger"();
1392 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1393 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1396 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1397 RETURNS TRIGGER
1398 LANGUAGE 'plpgsql' VOLATILE AS $$
1399 BEGIN
1400 IF NOT EXISTS (
1401 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1402 ) THEN
1403 --RAISE 'Cannot create initiative without an initial draft.' USING
1404 -- ERRCODE = 'integrity_constraint_violation',
1405 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1406 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1407 END IF;
1408 RETURN NULL;
1409 END;
1410 $$;
1412 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1413 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1414 FOR EACH ROW EXECUTE PROCEDURE
1415 "initiative_requires_first_draft_trigger"();
1417 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1418 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1421 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1422 RETURNS TRIGGER
1423 LANGUAGE 'plpgsql' VOLATILE AS $$
1424 DECLARE
1425 "reference_lost" BOOLEAN;
1426 BEGIN
1427 IF TG_OP = 'DELETE' THEN
1428 "reference_lost" := TRUE;
1429 ELSE
1430 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1431 END IF;
1432 IF
1433 "reference_lost" AND NOT EXISTS (
1434 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1436 THEN
1437 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1438 END IF;
1439 RETURN NULL;
1440 END;
1441 $$;
1443 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1444 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1445 FOR EACH ROW EXECUTE PROCEDURE
1446 "last_draft_deletes_initiative_trigger"();
1448 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1449 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1452 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1453 RETURNS TRIGGER
1454 LANGUAGE 'plpgsql' VOLATILE AS $$
1455 BEGIN
1456 IF NOT EXISTS (
1457 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1458 ) THEN
1459 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1460 END IF;
1461 RETURN NULL;
1462 END;
1463 $$;
1465 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1466 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1467 FOR EACH ROW EXECUTE PROCEDURE
1468 "suggestion_requires_first_opinion_trigger"();
1470 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1471 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1474 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1475 RETURNS TRIGGER
1476 LANGUAGE 'plpgsql' VOLATILE AS $$
1477 DECLARE
1478 "reference_lost" BOOLEAN;
1479 BEGIN
1480 IF TG_OP = 'DELETE' THEN
1481 "reference_lost" := TRUE;
1482 ELSE
1483 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1484 END IF;
1485 IF
1486 "reference_lost" AND NOT EXISTS (
1487 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1489 THEN
1490 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1491 END IF;
1492 RETURN NULL;
1493 END;
1494 $$;
1496 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1497 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1498 FOR EACH ROW EXECUTE PROCEDURE
1499 "last_opinion_deletes_suggestion_trigger"();
1501 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1502 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1505 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1506 RETURNS TRIGGER
1507 LANGUAGE 'plpgsql' VOLATILE AS $$
1508 BEGIN
1509 DELETE FROM "direct_voter"
1510 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1511 RETURN NULL;
1512 END;
1513 $$;
1515 CREATE TRIGGER "non_voter_deletes_direct_voter"
1516 AFTER INSERT OR UPDATE ON "non_voter"
1517 FOR EACH ROW EXECUTE PROCEDURE
1518 "non_voter_deletes_direct_voter_trigger"();
1520 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1521 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
1524 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1525 RETURNS TRIGGER
1526 LANGUAGE 'plpgsql' VOLATILE AS $$
1527 BEGIN
1528 DELETE FROM "non_voter"
1529 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1530 RETURN NULL;
1531 END;
1532 $$;
1534 CREATE TRIGGER "direct_voter_deletes_non_voter"
1535 AFTER INSERT OR UPDATE ON "direct_voter"
1536 FOR EACH ROW EXECUTE PROCEDURE
1537 "direct_voter_deletes_non_voter_trigger"();
1539 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1540 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
1543 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1544 RETURNS TRIGGER
1545 LANGUAGE 'plpgsql' VOLATILE AS $$
1546 BEGIN
1547 IF NEW."comment" ISNULL THEN
1548 NEW."comment_changed" := NULL;
1549 NEW."formatting_engine" := NULL;
1550 END IF;
1551 RETURN NEW;
1552 END;
1553 $$;
1555 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1556 BEFORE INSERT OR UPDATE ON "direct_voter"
1557 FOR EACH ROW EXECUTE PROCEDURE
1558 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1560 COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"';
1561 COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.';
1564 ---------------------------------------------------------------
1565 -- Ensure that votes are not modified when issues are frozen --
1566 ---------------------------------------------------------------
1568 -- NOTE: Frontends should ensure this anyway, but in case of programming
1569 -- errors the following triggers ensure data integrity.
1572 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1573 RETURNS TRIGGER
1574 LANGUAGE 'plpgsql' VOLATILE AS $$
1575 DECLARE
1576 "issue_id_v" "issue"."id"%TYPE;
1577 "issue_row" "issue"%ROWTYPE;
1578 BEGIN
1579 IF TG_OP = 'DELETE' THEN
1580 "issue_id_v" := OLD."issue_id";
1581 ELSE
1582 "issue_id_v" := NEW."issue_id";
1583 END IF;
1584 SELECT INTO "issue_row" * FROM "issue"
1585 WHERE "id" = "issue_id_v" FOR SHARE;
1586 IF "issue_row"."closed" NOTNULL THEN
1587 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1588 END IF;
1589 RETURN NULL;
1590 END;
1591 $$;
1593 CREATE TRIGGER "forbid_changes_on_closed_issue"
1594 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1595 FOR EACH ROW EXECUTE PROCEDURE
1596 "forbid_changes_on_closed_issue_trigger"();
1598 CREATE TRIGGER "forbid_changes_on_closed_issue"
1599 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1600 FOR EACH ROW EXECUTE PROCEDURE
1601 "forbid_changes_on_closed_issue_trigger"();
1603 CREATE TRIGGER "forbid_changes_on_closed_issue"
1604 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1605 FOR EACH ROW EXECUTE PROCEDURE
1606 "forbid_changes_on_closed_issue_trigger"();
1608 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"';
1609 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';
1610 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';
1611 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';
1615 --------------------------------------------------------------------
1616 -- Auto-retrieval of fields only needed for referential integrity --
1617 --------------------------------------------------------------------
1620 CREATE FUNCTION "autofill_issue_id_trigger"()
1621 RETURNS TRIGGER
1622 LANGUAGE 'plpgsql' VOLATILE AS $$
1623 BEGIN
1624 IF NEW."issue_id" ISNULL THEN
1625 SELECT "issue_id" INTO NEW."issue_id"
1626 FROM "initiative" WHERE "id" = NEW."initiative_id";
1627 END IF;
1628 RETURN NEW;
1629 END;
1630 $$;
1632 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1633 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1635 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1636 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1638 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1639 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1640 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1643 CREATE FUNCTION "autofill_initiative_id_trigger"()
1644 RETURNS TRIGGER
1645 LANGUAGE 'plpgsql' VOLATILE AS $$
1646 BEGIN
1647 IF NEW."initiative_id" ISNULL THEN
1648 SELECT "initiative_id" INTO NEW."initiative_id"
1649 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1650 END IF;
1651 RETURN NEW;
1652 END;
1653 $$;
1655 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1656 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1658 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1659 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1663 -----------------------------------------------------
1664 -- Automatic calculation of certain default values --
1665 -----------------------------------------------------
1668 CREATE FUNCTION "copy_timings_trigger"()
1669 RETURNS TRIGGER
1670 LANGUAGE 'plpgsql' VOLATILE AS $$
1671 DECLARE
1672 "policy_row" "policy"%ROWTYPE;
1673 BEGIN
1674 SELECT * INTO "policy_row" FROM "policy"
1675 WHERE "id" = NEW."policy_id";
1676 IF NEW."admission_time" ISNULL THEN
1677 NEW."admission_time" := "policy_row"."admission_time";
1678 END IF;
1679 IF NEW."discussion_time" ISNULL THEN
1680 NEW."discussion_time" := "policy_row"."discussion_time";
1681 END IF;
1682 IF NEW."verification_time" ISNULL THEN
1683 NEW."verification_time" := "policy_row"."verification_time";
1684 END IF;
1685 IF NEW."voting_time" ISNULL THEN
1686 NEW."voting_time" := "policy_row"."voting_time";
1687 END IF;
1688 RETURN NEW;
1689 END;
1690 $$;
1692 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1693 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1695 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1696 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1699 CREATE FUNCTION "default_for_draft_id_trigger"()
1700 RETURNS TRIGGER
1701 LANGUAGE 'plpgsql' VOLATILE AS $$
1702 BEGIN
1703 IF NEW."draft_id" ISNULL THEN
1704 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1705 WHERE "initiative_id" = NEW."initiative_id";
1706 END IF;
1707 RETURN NEW;
1708 END;
1709 $$;
1711 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1712 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1713 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1714 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1716 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1717 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';
1718 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';
1722 ----------------------------------------
1723 -- Automatic creation of dependencies --
1724 ----------------------------------------
1727 CREATE FUNCTION "autocreate_interest_trigger"()
1728 RETURNS TRIGGER
1729 LANGUAGE 'plpgsql' VOLATILE AS $$
1730 BEGIN
1731 IF NOT EXISTS (
1732 SELECT NULL FROM "initiative" JOIN "interest"
1733 ON "initiative"."issue_id" = "interest"."issue_id"
1734 WHERE "initiative"."id" = NEW."initiative_id"
1735 AND "interest"."member_id" = NEW."member_id"
1736 ) THEN
1737 BEGIN
1738 INSERT INTO "interest" ("issue_id", "member_id")
1739 SELECT "issue_id", NEW."member_id"
1740 FROM "initiative" WHERE "id" = NEW."initiative_id";
1741 EXCEPTION WHEN unique_violation THEN END;
1742 END IF;
1743 RETURN NEW;
1744 END;
1745 $$;
1747 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1748 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1750 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1751 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';
1754 CREATE FUNCTION "autocreate_supporter_trigger"()
1755 RETURNS TRIGGER
1756 LANGUAGE 'plpgsql' VOLATILE AS $$
1757 BEGIN
1758 IF NOT EXISTS (
1759 SELECT NULL FROM "suggestion" JOIN "supporter"
1760 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1761 WHERE "suggestion"."id" = NEW."suggestion_id"
1762 AND "supporter"."member_id" = NEW."member_id"
1763 ) THEN
1764 BEGIN
1765 INSERT INTO "supporter" ("initiative_id", "member_id")
1766 SELECT "initiative_id", NEW."member_id"
1767 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1768 EXCEPTION WHEN unique_violation THEN END;
1769 END IF;
1770 RETURN NEW;
1771 END;
1772 $$;
1774 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1775 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1777 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1778 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.';
1782 ------------------------------------------
1783 -- Views and helper functions for views --
1784 ------------------------------------------
1787 CREATE VIEW "unit_delegation" AS
1788 SELECT
1789 "unit"."id" AS "unit_id",
1790 "delegation"."id",
1791 "delegation"."truster_id",
1792 "delegation"."trustee_id",
1793 "delegation"."scope"
1794 FROM "unit"
1795 JOIN "delegation"
1796 ON "delegation"."unit_id" = "unit"."id"
1797 JOIN "member"
1798 ON "delegation"."truster_id" = "member"."id"
1799 JOIN "privilege"
1800 ON "delegation"."unit_id" = "privilege"."unit_id"
1801 AND "delegation"."truster_id" = "privilege"."member_id"
1802 WHERE "member"."active" AND "privilege"."voting_right";
1804 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1807 CREATE VIEW "area_delegation" AS
1808 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1809 "area"."id" AS "area_id",
1810 "delegation"."id",
1811 "delegation"."truster_id",
1812 "delegation"."trustee_id",
1813 "delegation"."scope"
1814 FROM "area"
1815 JOIN "delegation"
1816 ON "delegation"."unit_id" = "area"."unit_id"
1817 OR "delegation"."area_id" = "area"."id"
1818 JOIN "member"
1819 ON "delegation"."truster_id" = "member"."id"
1820 JOIN "privilege"
1821 ON "area"."unit_id" = "privilege"."unit_id"
1822 AND "delegation"."truster_id" = "privilege"."member_id"
1823 WHERE "member"."active" AND "privilege"."voting_right"
1824 ORDER BY
1825 "area"."id",
1826 "delegation"."truster_id",
1827 "delegation"."scope" DESC;
1829 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1832 CREATE VIEW "issue_delegation" AS
1833 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1834 "issue"."id" AS "issue_id",
1835 "delegation"."id",
1836 "delegation"."truster_id",
1837 "delegation"."trustee_id",
1838 "delegation"."scope"
1839 FROM "issue"
1840 JOIN "area"
1841 ON "area"."id" = "issue"."area_id"
1842 JOIN "delegation"
1843 ON "delegation"."unit_id" = "area"."unit_id"
1844 OR "delegation"."area_id" = "area"."id"
1845 OR "delegation"."issue_id" = "issue"."id"
1846 JOIN "member"
1847 ON "delegation"."truster_id" = "member"."id"
1848 JOIN "privilege"
1849 ON "area"."unit_id" = "privilege"."unit_id"
1850 AND "delegation"."truster_id" = "privilege"."member_id"
1851 WHERE "member"."active" AND "privilege"."voting_right"
1852 ORDER BY
1853 "issue"."id",
1854 "delegation"."truster_id",
1855 "delegation"."scope" DESC;
1857 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1860 CREATE FUNCTION "membership_weight_with_skipping"
1861 ( "area_id_p" "area"."id"%TYPE,
1862 "member_id_p" "member"."id"%TYPE,
1863 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1864 RETURNS INT4
1865 LANGUAGE 'plpgsql' STABLE AS $$
1866 DECLARE
1867 "sum_v" INT4;
1868 "delegation_row" "area_delegation"%ROWTYPE;
1869 BEGIN
1870 "sum_v" := 1;
1871 FOR "delegation_row" IN
1872 SELECT "area_delegation".*
1873 FROM "area_delegation" LEFT JOIN "membership"
1874 ON "membership"."area_id" = "area_id_p"
1875 AND "membership"."member_id" = "area_delegation"."truster_id"
1876 WHERE "area_delegation"."area_id" = "area_id_p"
1877 AND "area_delegation"."trustee_id" = "member_id_p"
1878 AND "membership"."member_id" ISNULL
1879 LOOP
1880 IF NOT
1881 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1882 THEN
1883 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1884 "area_id_p",
1885 "delegation_row"."truster_id",
1886 "skip_member_ids_p" || "delegation_row"."truster_id"
1887 );
1888 END IF;
1889 END LOOP;
1890 RETURN "sum_v";
1891 END;
1892 $$;
1894 COMMENT ON FUNCTION "membership_weight_with_skipping"
1895 ( "area"."id"%TYPE,
1896 "member"."id"%TYPE,
1897 INT4[] )
1898 IS 'Helper function for "membership_weight" function';
1901 CREATE FUNCTION "membership_weight"
1902 ( "area_id_p" "area"."id"%TYPE,
1903 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1904 RETURNS INT4
1905 LANGUAGE 'plpgsql' STABLE AS $$
1906 BEGIN
1907 RETURN "membership_weight_with_skipping"(
1908 "area_id_p",
1909 "member_id_p",
1910 ARRAY["member_id_p"]
1911 );
1912 END;
1913 $$;
1915 COMMENT ON FUNCTION "membership_weight"
1916 ( "area"."id"%TYPE,
1917 "member"."id"%TYPE )
1918 IS 'Calculates the potential voting weight of a member in a given area';
1921 CREATE VIEW "member_count_view" AS
1922 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1924 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1927 CREATE VIEW "unit_member_count" AS
1928 SELECT
1929 "unit"."id" AS "unit_id",
1930 count("member"."id") AS "member_count"
1931 FROM "unit"
1932 LEFT JOIN "privilege"
1933 ON "privilege"."unit_id" = "unit"."id"
1934 AND "privilege"."voting_right"
1935 LEFT JOIN "member"
1936 ON "member"."id" = "privilege"."member_id"
1937 AND "member"."active"
1938 GROUP BY "unit"."id";
1940 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1943 CREATE VIEW "area_member_count" AS
1944 SELECT
1945 "area"."id" AS "area_id",
1946 count("member"."id") AS "direct_member_count",
1947 coalesce(
1948 sum(
1949 CASE WHEN "member"."id" NOTNULL THEN
1950 "membership_weight"("area"."id", "member"."id")
1951 ELSE 0 END
1953 ) AS "member_weight"
1954 FROM "area"
1955 LEFT JOIN "membership"
1956 ON "area"."id" = "membership"."area_id"
1957 LEFT JOIN "privilege"
1958 ON "privilege"."unit_id" = "area"."unit_id"
1959 AND "privilege"."member_id" = "membership"."member_id"
1960 AND "privilege"."voting_right"
1961 LEFT JOIN "member"
1962 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1963 AND "member"."active"
1964 GROUP BY "area"."id";
1966 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1969 CREATE VIEW "opening_draft" AS
1970 SELECT "draft".* FROM (
1971 SELECT
1972 "initiative"."id" AS "initiative_id",
1973 min("draft"."id") AS "draft_id"
1974 FROM "initiative" JOIN "draft"
1975 ON "initiative"."id" = "draft"."initiative_id"
1976 GROUP BY "initiative"."id"
1977 ) AS "subquery"
1978 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1980 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1983 CREATE VIEW "current_draft" AS
1984 SELECT "draft".* FROM (
1985 SELECT
1986 "initiative"."id" AS "initiative_id",
1987 max("draft"."id") AS "draft_id"
1988 FROM "initiative" JOIN "draft"
1989 ON "initiative"."id" = "draft"."initiative_id"
1990 GROUP BY "initiative"."id"
1991 ) AS "subquery"
1992 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1994 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1997 CREATE VIEW "critical_opinion" AS
1998 SELECT * FROM "opinion"
1999 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2000 OR ("degree" = -2 AND "fulfilled" = TRUE);
2002 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2005 CREATE VIEW "battle_participant" AS
2006 SELECT "initiative"."id", "initiative"."issue_id"
2007 FROM "issue" JOIN "initiative"
2008 ON "issue"."id" = "initiative"."issue_id"
2009 WHERE "initiative"."admitted"
2010 UNION ALL
2011 SELECT NULL, "id" AS "issue_id"
2012 FROM "issue";
2014 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2017 CREATE VIEW "battle_view" AS
2018 SELECT
2019 "issue"."id" AS "issue_id",
2020 "winning_initiative"."id" AS "winning_initiative_id",
2021 "losing_initiative"."id" AS "losing_initiative_id",
2022 sum(
2023 CASE WHEN
2024 coalesce("better_vote"."grade", 0) >
2025 coalesce("worse_vote"."grade", 0)
2026 THEN "direct_voter"."weight" ELSE 0 END
2027 ) AS "count"
2028 FROM "issue"
2029 LEFT JOIN "direct_voter"
2030 ON "issue"."id" = "direct_voter"."issue_id"
2031 JOIN "battle_participant" AS "winning_initiative"
2032 ON "issue"."id" = "winning_initiative"."issue_id"
2033 JOIN "battle_participant" AS "losing_initiative"
2034 ON "issue"."id" = "losing_initiative"."issue_id"
2035 LEFT JOIN "vote" AS "better_vote"
2036 ON "direct_voter"."member_id" = "better_vote"."member_id"
2037 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2038 LEFT JOIN "vote" AS "worse_vote"
2039 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2040 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2041 WHERE "issue"."closed" NOTNULL
2042 AND "issue"."cleaned" ISNULL
2043 AND (
2044 "winning_initiative"."id" != "losing_initiative"."id" OR
2045 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2046 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2047 GROUP BY
2048 "issue"."id",
2049 "winning_initiative"."id",
2050 "losing_initiative"."id";
2052 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';
2055 CREATE VIEW "expired_session" AS
2056 SELECT * FROM "session" WHERE now() > "expiry";
2058 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2059 DELETE FROM "session" WHERE "ident" = OLD."ident";
2061 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2062 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2065 CREATE VIEW "open_issue" AS
2066 SELECT * FROM "issue" WHERE "closed" ISNULL;
2068 COMMENT ON VIEW "open_issue" IS 'All open issues';
2071 CREATE VIEW "issue_with_ranks_missing" AS
2072 SELECT * FROM "issue"
2073 WHERE "fully_frozen" NOTNULL
2074 AND "closed" NOTNULL
2075 AND "ranks_available" = FALSE;
2077 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2080 CREATE VIEW "member_contingent" AS
2081 SELECT
2082 "member"."id" AS "member_id",
2083 "contingent"."time_frame",
2084 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2086 SELECT count(1) FROM "draft"
2087 WHERE "draft"."author_id" = "member"."id"
2088 AND "draft"."created" > now() - "contingent"."time_frame"
2089 ) + (
2090 SELECT count(1) FROM "suggestion"
2091 WHERE "suggestion"."author_id" = "member"."id"
2092 AND "suggestion"."created" > now() - "contingent"."time_frame"
2094 ELSE NULL END AS "text_entry_count",
2095 "contingent"."text_entry_limit",
2096 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2097 SELECT count(1) FROM "opening_draft"
2098 WHERE "opening_draft"."author_id" = "member"."id"
2099 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2100 ) ELSE NULL END AS "initiative_count",
2101 "contingent"."initiative_limit"
2102 FROM "member" CROSS JOIN "contingent";
2104 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2106 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2107 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2110 CREATE VIEW "member_contingent_left" AS
2111 SELECT
2112 "member_id",
2113 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2114 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2115 FROM "member_contingent" GROUP BY "member_id";
2117 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.';
2120 CREATE VIEW "event_seen_by_member" AS
2121 SELECT
2122 "member"."id" AS "seen_by_member_id",
2123 CASE WHEN "event"."state" IN (
2124 'voting',
2125 'finished_without_winner',
2126 'finished_with_winner'
2127 ) THEN
2128 'voting'::"notify_level"
2129 ELSE
2130 CASE WHEN "event"."state" IN (
2131 'verification',
2132 'canceled_after_revocation_during_verification',
2133 'canceled_no_initiative_admitted'
2134 ) THEN
2135 'verification'::"notify_level"
2136 ELSE
2137 CASE WHEN "event"."state" IN (
2138 'discussion',
2139 'canceled_after_revocation_during_discussion'
2140 ) THEN
2141 'discussion'::"notify_level"
2142 ELSE
2143 'all'::"notify_level"
2144 END
2145 END
2146 END AS "notify_level",
2147 "event".*
2148 FROM "member" CROSS JOIN "event"
2149 LEFT JOIN "issue"
2150 ON "event"."issue_id" = "issue"."id"
2151 LEFT JOIN "membership"
2152 ON "member"."id" = "membership"."member_id"
2153 AND "issue"."area_id" = "membership"."area_id"
2154 LEFT JOIN "interest"
2155 ON "member"."id" = "interest"."member_id"
2156 AND "event"."issue_id" = "interest"."issue_id"
2157 LEFT JOIN "supporter"
2158 ON "member"."id" = "supporter"."member_id"
2159 AND "event"."initiative_id" = "supporter"."initiative_id"
2160 LEFT JOIN "ignored_member"
2161 ON "member"."id" = "ignored_member"."member_id"
2162 AND "event"."member_id" = "ignored_member"."other_member_id"
2163 LEFT JOIN "ignored_initiative"
2164 ON "member"."id" = "ignored_initiative"."member_id"
2165 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2166 WHERE (
2167 "supporter"."member_id" NOTNULL OR
2168 "interest"."member_id" NOTNULL OR
2169 ( "membership"."member_id" NOTNULL AND
2170 "event"."event" IN (
2171 'issue_state_changed',
2172 'initiative_created_in_new_issue',
2173 'initiative_created_in_existing_issue',
2174 'initiative_revoked' ) ) )
2175 AND "ignored_member"."member_id" ISNULL
2176 AND "ignored_initiative"."member_id" ISNULL;
2178 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"';
2181 CREATE VIEW "selected_event_seen_by_member" AS
2182 SELECT
2183 "member"."id" AS "seen_by_member_id",
2184 CASE WHEN "event"."state" IN (
2185 'voting',
2186 'finished_without_winner',
2187 'finished_with_winner'
2188 ) THEN
2189 'voting'::"notify_level"
2190 ELSE
2191 CASE WHEN "event"."state" IN (
2192 'verification',
2193 'canceled_after_revocation_during_verification',
2194 'canceled_no_initiative_admitted'
2195 ) THEN
2196 'verification'::"notify_level"
2197 ELSE
2198 CASE WHEN "event"."state" IN (
2199 'discussion',
2200 'canceled_after_revocation_during_discussion'
2201 ) THEN
2202 'discussion'::"notify_level"
2203 ELSE
2204 'all'::"notify_level"
2205 END
2206 END
2207 END AS "notify_level",
2208 "event".*
2209 FROM "member" CROSS JOIN "event"
2210 LEFT JOIN "issue"
2211 ON "event"."issue_id" = "issue"."id"
2212 LEFT JOIN "membership"
2213 ON "member"."id" = "membership"."member_id"
2214 AND "issue"."area_id" = "membership"."area_id"
2215 LEFT JOIN "interest"
2216 ON "member"."id" = "interest"."member_id"
2217 AND "event"."issue_id" = "interest"."issue_id"
2218 LEFT JOIN "supporter"
2219 ON "member"."id" = "supporter"."member_id"
2220 AND "event"."initiative_id" = "supporter"."initiative_id"
2221 LEFT JOIN "ignored_member"
2222 ON "member"."id" = "ignored_member"."member_id"
2223 AND "event"."member_id" = "ignored_member"."other_member_id"
2224 LEFT JOIN "ignored_initiative"
2225 ON "member"."id" = "ignored_initiative"."member_id"
2226 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2227 WHERE (
2228 ( "member"."notify_level" >= 'all' ) OR
2229 ( "member"."notify_level" >= 'voting' AND
2230 "event"."state" IN (
2231 'voting',
2232 'finished_without_winner',
2233 'finished_with_winner' ) ) OR
2234 ( "member"."notify_level" >= 'verification' AND
2235 "event"."state" IN (
2236 'verification',
2237 'canceled_after_revocation_during_verification',
2238 'canceled_no_initiative_admitted' ) ) OR
2239 ( "member"."notify_level" >= 'discussion' AND
2240 "event"."state" IN (
2241 'discussion',
2242 'canceled_after_revocation_during_discussion' ) ) )
2243 AND (
2244 "supporter"."member_id" NOTNULL OR
2245 "interest"."member_id" NOTNULL OR
2246 ( "membership"."member_id" NOTNULL AND
2247 "event"."event" IN (
2248 'issue_state_changed',
2249 'initiative_created_in_new_issue',
2250 'initiative_created_in_existing_issue',
2251 'initiative_revoked' ) ) )
2252 AND "ignored_member"."member_id" ISNULL
2253 AND "ignored_initiative"."member_id" ISNULL;
2255 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"';
2258 CREATE TYPE "timeline_event" AS ENUM (
2259 'issue_created',
2260 'issue_canceled',
2261 'issue_accepted',
2262 'issue_half_frozen',
2263 'issue_finished_without_voting',
2264 'issue_voting_started',
2265 'issue_finished_after_voting',
2266 'initiative_created',
2267 'initiative_revoked',
2268 'draft_created',
2269 'suggestion_created');
2271 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2274 CREATE VIEW "timeline_issue" AS
2275 SELECT
2276 "created" AS "occurrence",
2277 'issue_created'::"timeline_event" AS "event",
2278 "id" AS "issue_id"
2279 FROM "issue"
2280 UNION ALL
2281 SELECT
2282 "closed" AS "occurrence",
2283 'issue_canceled'::"timeline_event" AS "event",
2284 "id" AS "issue_id"
2285 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2286 UNION ALL
2287 SELECT
2288 "accepted" AS "occurrence",
2289 'issue_accepted'::"timeline_event" AS "event",
2290 "id" AS "issue_id"
2291 FROM "issue" WHERE "accepted" NOTNULL
2292 UNION ALL
2293 SELECT
2294 "half_frozen" AS "occurrence",
2295 'issue_half_frozen'::"timeline_event" AS "event",
2296 "id" AS "issue_id"
2297 FROM "issue" WHERE "half_frozen" NOTNULL
2298 UNION ALL
2299 SELECT
2300 "fully_frozen" AS "occurrence",
2301 'issue_voting_started'::"timeline_event" AS "event",
2302 "id" AS "issue_id"
2303 FROM "issue"
2304 WHERE "fully_frozen" NOTNULL
2305 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2306 UNION ALL
2307 SELECT
2308 "closed" AS "occurrence",
2309 CASE WHEN "fully_frozen" = "closed" THEN
2310 'issue_finished_without_voting'::"timeline_event"
2311 ELSE
2312 'issue_finished_after_voting'::"timeline_event"
2313 END AS "event",
2314 "id" AS "issue_id"
2315 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2317 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2320 CREATE VIEW "timeline_initiative" AS
2321 SELECT
2322 "created" AS "occurrence",
2323 'initiative_created'::"timeline_event" AS "event",
2324 "id" AS "initiative_id"
2325 FROM "initiative"
2326 UNION ALL
2327 SELECT
2328 "revoked" AS "occurrence",
2329 'initiative_revoked'::"timeline_event" AS "event",
2330 "id" AS "initiative_id"
2331 FROM "initiative" WHERE "revoked" NOTNULL;
2333 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2336 CREATE VIEW "timeline_draft" AS
2337 SELECT
2338 "created" AS "occurrence",
2339 'draft_created'::"timeline_event" AS "event",
2340 "id" AS "draft_id"
2341 FROM "draft";
2343 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2346 CREATE VIEW "timeline_suggestion" AS
2347 SELECT
2348 "created" AS "occurrence",
2349 'suggestion_created'::"timeline_event" AS "event",
2350 "id" AS "suggestion_id"
2351 FROM "suggestion";
2353 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2356 CREATE VIEW "timeline" AS
2357 SELECT
2358 "occurrence",
2359 "event",
2360 "issue_id",
2361 NULL AS "initiative_id",
2362 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2363 NULL::INT8 AS "suggestion_id"
2364 FROM "timeline_issue"
2365 UNION ALL
2366 SELECT
2367 "occurrence",
2368 "event",
2369 NULL AS "issue_id",
2370 "initiative_id",
2371 NULL AS "draft_id",
2372 NULL AS "suggestion_id"
2373 FROM "timeline_initiative"
2374 UNION ALL
2375 SELECT
2376 "occurrence",
2377 "event",
2378 NULL AS "issue_id",
2379 NULL AS "initiative_id",
2380 "draft_id",
2381 NULL AS "suggestion_id"
2382 FROM "timeline_draft"
2383 UNION ALL
2384 SELECT
2385 "occurrence",
2386 "event",
2387 NULL AS "issue_id",
2388 NULL AS "initiative_id",
2389 NULL AS "draft_id",
2390 "suggestion_id"
2391 FROM "timeline_suggestion";
2393 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2397 ------------------------------------------------------
2398 -- Row set returning function for delegation chains --
2399 ------------------------------------------------------
2402 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2403 ('first', 'intermediate', 'last', 'repetition');
2405 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2408 CREATE TYPE "delegation_chain_row" AS (
2409 "index" INT4,
2410 "member_id" INT4,
2411 "member_valid" BOOLEAN,
2412 "participation" BOOLEAN,
2413 "overridden" BOOLEAN,
2414 "scope_in" "delegation_scope",
2415 "scope_out" "delegation_scope",
2416 "disabled_out" BOOLEAN,
2417 "loop" "delegation_chain_loop_tag" );
2419 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2421 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2422 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';
2423 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2424 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2425 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2426 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2427 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2430 CREATE FUNCTION "delegation_chain_for_closed_issue"
2431 ( "member_id_p" "member"."id"%TYPE,
2432 "issue_id_p" "issue"."id"%TYPE )
2433 RETURNS SETOF "delegation_chain_row"
2434 LANGUAGE 'plpgsql' STABLE AS $$
2435 DECLARE
2436 "output_row" "delegation_chain_row";
2437 "direct_voter_row" "direct_voter"%ROWTYPE;
2438 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2439 BEGIN
2440 "output_row"."index" := 0;
2441 "output_row"."member_id" := "member_id_p";
2442 "output_row"."member_valid" := TRUE;
2443 "output_row"."participation" := FALSE;
2444 "output_row"."overridden" := FALSE;
2445 "output_row"."disabled_out" := FALSE;
2446 LOOP
2447 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2448 WHERE "issue_id" = "issue_id_p"
2449 AND "member_id" = "output_row"."member_id";
2450 IF "direct_voter_row"."member_id" NOTNULL THEN
2451 "output_row"."participation" := TRUE;
2452 "output_row"."scope_out" := NULL;
2453 "output_row"."disabled_out" := NULL;
2454 RETURN NEXT "output_row";
2455 RETURN;
2456 END IF;
2457 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2458 WHERE "issue_id" = "issue_id_p"
2459 AND "member_id" = "output_row"."member_id";
2460 IF "delegating_voter_row"."member_id" ISNULL THEN
2461 RETURN;
2462 END IF;
2463 "output_row"."scope_out" := "delegating_voter_row"."scope";
2464 RETURN NEXT "output_row";
2465 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2466 "output_row"."scope_in" := "output_row"."scope_out";
2467 END LOOP;
2468 END;
2469 $$;
2471 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2472 ( "member"."id"%TYPE,
2473 "member"."id"%TYPE )
2474 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2477 CREATE FUNCTION "delegation_chain"
2478 ( "member_id_p" "member"."id"%TYPE,
2479 "unit_id_p" "unit"."id"%TYPE,
2480 "area_id_p" "area"."id"%TYPE,
2481 "issue_id_p" "issue"."id"%TYPE,
2482 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2483 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2484 RETURNS SETOF "delegation_chain_row"
2485 LANGUAGE 'plpgsql' STABLE AS $$
2486 DECLARE
2487 "scope_v" "delegation_scope";
2488 "unit_id_v" "unit"."id"%TYPE;
2489 "area_id_v" "area"."id"%TYPE;
2490 "issue_row" "issue"%ROWTYPE;
2491 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2492 "loop_member_id_v" "member"."id"%TYPE;
2493 "output_row" "delegation_chain_row";
2494 "output_rows" "delegation_chain_row"[];
2495 "simulate_v" BOOLEAN;
2496 "simulate_here_v" BOOLEAN;
2497 "delegation_row" "delegation"%ROWTYPE;
2498 "row_count" INT4;
2499 "i" INT4;
2500 "loop_v" BOOLEAN;
2501 BEGIN
2502 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2503 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2504 END IF;
2505 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2506 "simulate_v" := TRUE;
2507 ELSE
2508 "simulate_v" := FALSE;
2509 END IF;
2510 IF
2511 "unit_id_p" NOTNULL AND
2512 "area_id_p" ISNULL AND
2513 "issue_id_p" ISNULL
2514 THEN
2515 "scope_v" := 'unit';
2516 "unit_id_v" := "unit_id_p";
2517 ELSIF
2518 "unit_id_p" ISNULL AND
2519 "area_id_p" NOTNULL AND
2520 "issue_id_p" ISNULL
2521 THEN
2522 "scope_v" := 'area';
2523 "area_id_v" := "area_id_p";
2524 SELECT "unit_id" INTO "unit_id_v"
2525 FROM "area" WHERE "id" = "area_id_v";
2526 ELSIF
2527 "unit_id_p" ISNULL AND
2528 "area_id_p" ISNULL AND
2529 "issue_id_p" NOTNULL
2530 THEN
2531 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2532 IF "issue_row"."id" ISNULL THEN
2533 RETURN;
2534 END IF;
2535 IF "issue_row"."closed" NOTNULL THEN
2536 IF "simulate_v" THEN
2537 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2538 END IF;
2539 FOR "output_row" IN
2540 SELECT * FROM
2541 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2542 LOOP
2543 RETURN NEXT "output_row";
2544 END LOOP;
2545 RETURN;
2546 END IF;
2547 "scope_v" := 'issue';
2548 SELECT "area_id" INTO "area_id_v"
2549 FROM "issue" WHERE "id" = "issue_id_p";
2550 SELECT "unit_id" INTO "unit_id_v"
2551 FROM "area" WHERE "id" = "area_id_v";
2552 ELSE
2553 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2554 END IF;
2555 "visited_member_ids" := '{}';
2556 "loop_member_id_v" := NULL;
2557 "output_rows" := '{}';
2558 "output_row"."index" := 0;
2559 "output_row"."member_id" := "member_id_p";
2560 "output_row"."member_valid" := TRUE;
2561 "output_row"."participation" := FALSE;
2562 "output_row"."overridden" := FALSE;
2563 "output_row"."disabled_out" := FALSE;
2564 "output_row"."scope_out" := NULL;
2565 LOOP
2566 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2567 "loop_member_id_v" := "output_row"."member_id";
2568 ELSE
2569 "visited_member_ids" :=
2570 "visited_member_ids" || "output_row"."member_id";
2571 END IF;
2572 IF "output_row"."participation" ISNULL THEN
2573 "output_row"."overridden" := NULL;
2574 ELSIF "output_row"."participation" THEN
2575 "output_row"."overridden" := TRUE;
2576 END IF;
2577 "output_row"."scope_in" := "output_row"."scope_out";
2578 "output_row"."member_valid" := EXISTS (
2579 SELECT NULL FROM "member" JOIN "privilege"
2580 ON "privilege"."member_id" = "member"."id"
2581 AND "privilege"."unit_id" = "unit_id_v"
2582 WHERE "id" = "output_row"."member_id"
2583 AND "member"."active" AND "privilege"."voting_right"
2584 );
2585 "simulate_here_v" := (
2586 "simulate_v" AND
2587 "output_row"."member_id" = "member_id_p"
2588 );
2589 "delegation_row" := ROW(NULL);
2590 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2591 IF "scope_v" = 'unit' THEN
2592 IF NOT "simulate_here_v" THEN
2593 SELECT * INTO "delegation_row" FROM "delegation"
2594 WHERE "truster_id" = "output_row"."member_id"
2595 AND "unit_id" = "unit_id_v";
2596 END IF;
2597 ELSIF "scope_v" = 'area' THEN
2598 "output_row"."participation" := EXISTS (
2599 SELECT NULL FROM "membership"
2600 WHERE "area_id" = "area_id_p"
2601 AND "member_id" = "output_row"."member_id"
2602 );
2603 IF "simulate_here_v" THEN
2604 IF "simulate_trustee_id_p" ISNULL THEN
2605 SELECT * INTO "delegation_row" FROM "delegation"
2606 WHERE "truster_id" = "output_row"."member_id"
2607 AND "unit_id" = "unit_id_v";
2608 END IF;
2609 ELSE
2610 SELECT * INTO "delegation_row" FROM "delegation"
2611 WHERE "truster_id" = "output_row"."member_id"
2612 AND (
2613 "unit_id" = "unit_id_v" OR
2614 "area_id" = "area_id_v"
2616 ORDER BY "scope" DESC;
2617 END IF;
2618 ELSIF "scope_v" = 'issue' THEN
2619 IF "issue_row"."fully_frozen" ISNULL THEN
2620 "output_row"."participation" := EXISTS (
2621 SELECT NULL FROM "interest"
2622 WHERE "issue_id" = "issue_id_p"
2623 AND "member_id" = "output_row"."member_id"
2624 );
2625 ELSE
2626 IF "output_row"."member_id" = "member_id_p" THEN
2627 "output_row"."participation" := EXISTS (
2628 SELECT NULL FROM "direct_voter"
2629 WHERE "issue_id" = "issue_id_p"
2630 AND "member_id" = "output_row"."member_id"
2631 );
2632 ELSE
2633 "output_row"."participation" := NULL;
2634 END IF;
2635 END IF;
2636 IF "simulate_here_v" THEN
2637 IF "simulate_trustee_id_p" ISNULL THEN
2638 SELECT * INTO "delegation_row" FROM "delegation"
2639 WHERE "truster_id" = "output_row"."member_id"
2640 AND (
2641 "unit_id" = "unit_id_v" OR
2642 "area_id" = "area_id_v"
2644 ORDER BY "scope" DESC;
2645 END IF;
2646 ELSE
2647 SELECT * INTO "delegation_row" FROM "delegation"
2648 WHERE "truster_id" = "output_row"."member_id"
2649 AND (
2650 "unit_id" = "unit_id_v" OR
2651 "area_id" = "area_id_v" OR
2652 "issue_id" = "issue_id_p"
2654 ORDER BY "scope" DESC;
2655 END IF;
2656 END IF;
2657 ELSE
2658 "output_row"."participation" := FALSE;
2659 END IF;
2660 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2661 "output_row"."scope_out" := "scope_v";
2662 "output_rows" := "output_rows" || "output_row";
2663 "output_row"."member_id" := "simulate_trustee_id_p";
2664 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2665 "output_row"."scope_out" := "delegation_row"."scope";
2666 "output_rows" := "output_rows" || "output_row";
2667 "output_row"."member_id" := "delegation_row"."trustee_id";
2668 ELSIF "delegation_row"."scope" NOTNULL THEN
2669 "output_row"."scope_out" := "delegation_row"."scope";
2670 "output_row"."disabled_out" := TRUE;
2671 "output_rows" := "output_rows" || "output_row";
2672 EXIT;
2673 ELSE
2674 "output_row"."scope_out" := NULL;
2675 "output_rows" := "output_rows" || "output_row";
2676 EXIT;
2677 END IF;
2678 EXIT WHEN "loop_member_id_v" NOTNULL;
2679 "output_row"."index" := "output_row"."index" + 1;
2680 END LOOP;
2681 "row_count" := array_upper("output_rows", 1);
2682 "i" := 1;
2683 "loop_v" := FALSE;
2684 LOOP
2685 "output_row" := "output_rows"["i"];
2686 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2687 IF "loop_v" THEN
2688 IF "i" + 1 = "row_count" THEN
2689 "output_row"."loop" := 'last';
2690 ELSIF "i" = "row_count" THEN
2691 "output_row"."loop" := 'repetition';
2692 ELSE
2693 "output_row"."loop" := 'intermediate';
2694 END IF;
2695 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2696 "output_row"."loop" := 'first';
2697 "loop_v" := TRUE;
2698 END IF;
2699 IF "scope_v" = 'unit' THEN
2700 "output_row"."participation" := NULL;
2701 END IF;
2702 RETURN NEXT "output_row";
2703 "i" := "i" + 1;
2704 END LOOP;
2705 RETURN;
2706 END;
2707 $$;
2709 COMMENT ON FUNCTION "delegation_chain"
2710 ( "member"."id"%TYPE,
2711 "unit"."id"%TYPE,
2712 "area"."id"%TYPE,
2713 "issue"."id"%TYPE,
2714 "member"."id"%TYPE,
2715 BOOLEAN )
2716 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2720 ---------------------------------------------------------
2721 -- Single row returning function for delegation chains --
2722 ---------------------------------------------------------
2725 CREATE TYPE "delegation_info_loop_type" AS ENUM
2726 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2728 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''';
2731 CREATE TYPE "delegation_info_type" AS (
2732 "own_participation" BOOLEAN,
2733 "own_delegation_scope" "delegation_scope",
2734 "first_trustee_id" INT4,
2735 "first_trustee_participation" BOOLEAN,
2736 "first_trustee_ellipsis" BOOLEAN,
2737 "other_trustee_id" INT4,
2738 "other_trustee_participation" BOOLEAN,
2739 "other_trustee_ellipsis" BOOLEAN,
2740 "delegation_loop" "delegation_info_loop_type",
2741 "participating_member_id" INT4 );
2743 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';
2745 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2746 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2747 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2748 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2749 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2750 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2751 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)';
2752 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2753 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';
2754 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2757 CREATE FUNCTION "delegation_info"
2758 ( "member_id_p" "member"."id"%TYPE,
2759 "unit_id_p" "unit"."id"%TYPE,
2760 "area_id_p" "area"."id"%TYPE,
2761 "issue_id_p" "issue"."id"%TYPE,
2762 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2763 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2764 RETURNS "delegation_info_type"
2765 LANGUAGE 'plpgsql' STABLE AS $$
2766 DECLARE
2767 "current_row" "delegation_chain_row";
2768 "result" "delegation_info_type";
2769 BEGIN
2770 "result"."own_participation" := FALSE;
2771 FOR "current_row" IN
2772 SELECT * FROM "delegation_chain"(
2773 "member_id_p",
2774 "unit_id_p", "area_id_p", "issue_id_p",
2775 "simulate_trustee_id_p", "simulate_default_p")
2776 LOOP
2777 IF
2778 "result"."participating_member_id" ISNULL AND
2779 "current_row"."participation"
2780 THEN
2781 "result"."participating_member_id" := "current_row"."member_id";
2782 END IF;
2783 IF "current_row"."member_id" = "member_id_p" THEN
2784 "result"."own_participation" := "current_row"."participation";
2785 "result"."own_delegation_scope" := "current_row"."scope_out";
2786 IF "current_row"."loop" = 'first' THEN
2787 "result"."delegation_loop" := 'own';
2788 END IF;
2789 ELSIF
2790 "current_row"."member_valid" AND
2791 ( "current_row"."loop" ISNULL OR
2792 "current_row"."loop" != 'repetition' )
2793 THEN
2794 IF "result"."first_trustee_id" ISNULL THEN
2795 "result"."first_trustee_id" := "current_row"."member_id";
2796 "result"."first_trustee_participation" := "current_row"."participation";
2797 "result"."first_trustee_ellipsis" := FALSE;
2798 IF "current_row"."loop" = 'first' THEN
2799 "result"."delegation_loop" := 'first';
2800 END IF;
2801 ELSIF "result"."other_trustee_id" ISNULL THEN
2802 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2803 "result"."other_trustee_id" := "current_row"."member_id";
2804 "result"."other_trustee_participation" := TRUE;
2805 "result"."other_trustee_ellipsis" := FALSE;
2806 IF "current_row"."loop" = 'first' THEN
2807 "result"."delegation_loop" := 'other';
2808 END IF;
2809 ELSE
2810 "result"."first_trustee_ellipsis" := TRUE;
2811 IF "current_row"."loop" = 'first' THEN
2812 "result"."delegation_loop" := 'first_ellipsis';
2813 END IF;
2814 END IF;
2815 ELSE
2816 "result"."other_trustee_ellipsis" := TRUE;
2817 IF "current_row"."loop" = 'first' THEN
2818 "result"."delegation_loop" := 'other_ellipsis';
2819 END IF;
2820 END IF;
2821 END IF;
2822 END LOOP;
2823 RETURN "result";
2824 END;
2825 $$;
2827 COMMENT ON FUNCTION "delegation_info"
2828 ( "member"."id"%TYPE,
2829 "unit"."id"%TYPE,
2830 "area"."id"%TYPE,
2831 "issue"."id"%TYPE,
2832 "member"."id"%TYPE,
2833 BOOLEAN )
2834 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2838 ------------------------------
2839 -- Comparison by vote count --
2840 ------------------------------
2842 CREATE FUNCTION "vote_ratio"
2843 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2844 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2845 RETURNS FLOAT8
2846 LANGUAGE 'plpgsql' STABLE AS $$
2847 BEGIN
2848 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2849 RETURN
2850 "positive_votes_p"::FLOAT8 /
2851 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2852 ELSIF "positive_votes_p" > 0 THEN
2853 RETURN "positive_votes_p";
2854 ELSIF "negative_votes_p" > 0 THEN
2855 RETURN 1 - "negative_votes_p";
2856 ELSE
2857 RETURN 0.5;
2858 END IF;
2859 END;
2860 $$;
2862 COMMENT ON FUNCTION "vote_ratio"
2863 ( "initiative"."positive_votes"%TYPE,
2864 "initiative"."negative_votes"%TYPE )
2865 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.';
2869 ------------------------------------------------
2870 -- Locking for snapshots and voting procedure --
2871 ------------------------------------------------
2874 CREATE FUNCTION "share_row_lock_issue_trigger"()
2875 RETURNS TRIGGER
2876 LANGUAGE 'plpgsql' VOLATILE AS $$
2877 BEGIN
2878 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2879 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2880 END IF;
2881 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2882 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2883 RETURN NEW;
2884 ELSE
2885 RETURN OLD;
2886 END IF;
2887 END;
2888 $$;
2890 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2893 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2894 RETURNS TRIGGER
2895 LANGUAGE 'plpgsql' VOLATILE AS $$
2896 BEGIN
2897 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2898 PERFORM NULL FROM "issue"
2899 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2900 WHERE "initiative"."id" = OLD."initiative_id"
2901 FOR SHARE OF "issue";
2902 END IF;
2903 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2904 PERFORM NULL FROM "issue"
2905 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2906 WHERE "initiative"."id" = NEW."initiative_id"
2907 FOR SHARE OF "issue";
2908 RETURN NEW;
2909 ELSE
2910 RETURN OLD;
2911 END IF;
2912 END;
2913 $$;
2915 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2918 CREATE TRIGGER "share_row_lock_issue"
2919 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2920 FOR EACH ROW EXECUTE PROCEDURE
2921 "share_row_lock_issue_trigger"();
2923 CREATE TRIGGER "share_row_lock_issue"
2924 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2925 FOR EACH ROW EXECUTE PROCEDURE
2926 "share_row_lock_issue_trigger"();
2928 CREATE TRIGGER "share_row_lock_issue"
2929 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2930 FOR EACH ROW EXECUTE PROCEDURE
2931 "share_row_lock_issue_trigger"();
2933 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2934 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2935 FOR EACH ROW EXECUTE PROCEDURE
2936 "share_row_lock_issue_via_initiative_trigger"();
2938 CREATE TRIGGER "share_row_lock_issue"
2939 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2940 FOR EACH ROW EXECUTE PROCEDURE
2941 "share_row_lock_issue_trigger"();
2943 CREATE TRIGGER "share_row_lock_issue"
2944 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2945 FOR EACH ROW EXECUTE PROCEDURE
2946 "share_row_lock_issue_trigger"();
2948 CREATE TRIGGER "share_row_lock_issue"
2949 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2950 FOR EACH ROW EXECUTE PROCEDURE
2951 "share_row_lock_issue_trigger"();
2953 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2954 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2955 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2956 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2957 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2958 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2959 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2962 CREATE FUNCTION "lock_issue"
2963 ( "issue_id_p" "issue"."id"%TYPE )
2964 RETURNS VOID
2965 LANGUAGE 'plpgsql' VOLATILE AS $$
2966 BEGIN
2967 LOCK TABLE "member" IN SHARE MODE;
2968 LOCK TABLE "privilege" IN SHARE MODE;
2969 LOCK TABLE "membership" IN SHARE MODE;
2970 LOCK TABLE "policy" IN SHARE MODE;
2971 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2972 -- NOTE: The row-level exclusive lock in combination with the
2973 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2974 -- acquire a row-level share lock on the issue) ensure that no data
2975 -- is changed, which could affect calculation of snapshots or
2976 -- counting of votes. Table "delegation" must be table-level-locked,
2977 -- as it also contains issue- and global-scope delegations.
2978 LOCK TABLE "delegation" IN SHARE MODE;
2979 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2980 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2981 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2982 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2983 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2984 RETURN;
2985 END;
2986 $$;
2988 COMMENT ON FUNCTION "lock_issue"
2989 ( "issue"."id"%TYPE )
2990 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2994 ------------------------------------------------------------------------
2995 -- Regular tasks, except calculcation of snapshots and voting results --
2996 ------------------------------------------------------------------------
2998 CREATE FUNCTION "check_activity"()
2999 RETURNS VOID
3000 LANGUAGE 'plpgsql' VOLATILE AS $$
3001 DECLARE
3002 "system_setting_row" "system_setting"%ROWTYPE;
3003 BEGIN
3004 SELECT * INTO "system_setting_row" FROM "system_setting";
3005 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
3006 IF "system_setting_row"."member_ttl" NOTNULL THEN
3007 UPDATE "member" SET "active" = FALSE
3008 WHERE "active" = TRUE
3009 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
3010 END IF;
3011 RETURN;
3012 END;
3013 $$;
3015 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
3018 CREATE FUNCTION "calculate_member_counts"()
3019 RETURNS VOID
3020 LANGUAGE 'plpgsql' VOLATILE AS $$
3021 BEGIN
3022 LOCK TABLE "member" IN SHARE MODE;
3023 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
3024 LOCK TABLE "unit" IN EXCLUSIVE MODE;
3025 LOCK TABLE "area" IN EXCLUSIVE MODE;
3026 LOCK TABLE "privilege" IN SHARE MODE;
3027 LOCK TABLE "membership" IN SHARE MODE;
3028 DELETE FROM "member_count";
3029 INSERT INTO "member_count" ("total_count")
3030 SELECT "total_count" FROM "member_count_view";
3031 UPDATE "unit" SET "member_count" = "view"."member_count"
3032 FROM "unit_member_count" AS "view"
3033 WHERE "view"."unit_id" = "unit"."id";
3034 UPDATE "area" SET
3035 "direct_member_count" = "view"."direct_member_count",
3036 "member_weight" = "view"."member_weight"
3037 FROM "area_member_count" AS "view"
3038 WHERE "view"."area_id" = "area"."id";
3039 RETURN;
3040 END;
3041 $$;
3043 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"';
3047 ------------------------------
3048 -- Calculation of snapshots --
3049 ------------------------------
3051 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3052 ( "issue_id_p" "issue"."id"%TYPE,
3053 "member_id_p" "member"."id"%TYPE,
3054 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3055 RETURNS "direct_population_snapshot"."weight"%TYPE
3056 LANGUAGE 'plpgsql' VOLATILE AS $$
3057 DECLARE
3058 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3059 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3060 "weight_v" INT4;
3061 "sub_weight_v" INT4;
3062 BEGIN
3063 "weight_v" := 0;
3064 FOR "issue_delegation_row" IN
3065 SELECT * FROM "issue_delegation"
3066 WHERE "trustee_id" = "member_id_p"
3067 AND "issue_id" = "issue_id_p"
3068 LOOP
3069 IF NOT EXISTS (
3070 SELECT NULL FROM "direct_population_snapshot"
3071 WHERE "issue_id" = "issue_id_p"
3072 AND "event" = 'periodic'
3073 AND "member_id" = "issue_delegation_row"."truster_id"
3074 ) AND NOT EXISTS (
3075 SELECT NULL FROM "delegating_population_snapshot"
3076 WHERE "issue_id" = "issue_id_p"
3077 AND "event" = 'periodic'
3078 AND "member_id" = "issue_delegation_row"."truster_id"
3079 ) THEN
3080 "delegate_member_ids_v" :=
3081 "member_id_p" || "delegate_member_ids_p";
3082 INSERT INTO "delegating_population_snapshot" (
3083 "issue_id",
3084 "event",
3085 "member_id",
3086 "scope",
3087 "delegate_member_ids"
3088 ) VALUES (
3089 "issue_id_p",
3090 'periodic',
3091 "issue_delegation_row"."truster_id",
3092 "issue_delegation_row"."scope",
3093 "delegate_member_ids_v"
3094 );
3095 "sub_weight_v" := 1 +
3096 "weight_of_added_delegations_for_population_snapshot"(
3097 "issue_id_p",
3098 "issue_delegation_row"."truster_id",
3099 "delegate_member_ids_v"
3100 );
3101 UPDATE "delegating_population_snapshot"
3102 SET "weight" = "sub_weight_v"
3103 WHERE "issue_id" = "issue_id_p"
3104 AND "event" = 'periodic'
3105 AND "member_id" = "issue_delegation_row"."truster_id";
3106 "weight_v" := "weight_v" + "sub_weight_v";
3107 END IF;
3108 END LOOP;
3109 RETURN "weight_v";
3110 END;
3111 $$;
3113 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3114 ( "issue"."id"%TYPE,
3115 "member"."id"%TYPE,
3116 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3117 IS 'Helper function for "create_population_snapshot" function';
3120 CREATE FUNCTION "create_population_snapshot"
3121 ( "issue_id_p" "issue"."id"%TYPE )
3122 RETURNS VOID
3123 LANGUAGE 'plpgsql' VOLATILE AS $$
3124 DECLARE
3125 "member_id_v" "member"."id"%TYPE;
3126 BEGIN
3127 DELETE FROM "direct_population_snapshot"
3128 WHERE "issue_id" = "issue_id_p"
3129 AND "event" = 'periodic';
3130 DELETE FROM "delegating_population_snapshot"
3131 WHERE "issue_id" = "issue_id_p"
3132 AND "event" = 'periodic';
3133 INSERT INTO "direct_population_snapshot"
3134 ("issue_id", "event", "member_id")
3135 SELECT
3136 "issue_id_p" AS "issue_id",
3137 'periodic'::"snapshot_event" AS "event",
3138 "member"."id" AS "member_id"
3139 FROM "issue"
3140 JOIN "area" ON "issue"."area_id" = "area"."id"
3141 JOIN "membership" ON "area"."id" = "membership"."area_id"
3142 JOIN "member" ON "membership"."member_id" = "member"."id"
3143 JOIN "privilege"
3144 ON "privilege"."unit_id" = "area"."unit_id"
3145 AND "privilege"."member_id" = "member"."id"
3146 WHERE "issue"."id" = "issue_id_p"
3147 AND "member"."active" AND "privilege"."voting_right"
3148 UNION
3149 SELECT
3150 "issue_id_p" AS "issue_id",
3151 'periodic'::"snapshot_event" AS "event",
3152 "member"."id" AS "member_id"
3153 FROM "issue"
3154 JOIN "area" ON "issue"."area_id" = "area"."id"
3155 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3156 JOIN "member" ON "interest"."member_id" = "member"."id"
3157 JOIN "privilege"
3158 ON "privilege"."unit_id" = "area"."unit_id"
3159 AND "privilege"."member_id" = "member"."id"
3160 WHERE "issue"."id" = "issue_id_p"
3161 AND "member"."active" AND "privilege"."voting_right";
3162 FOR "member_id_v" IN
3163 SELECT "member_id" FROM "direct_population_snapshot"
3164 WHERE "issue_id" = "issue_id_p"
3165 AND "event" = 'periodic'
3166 LOOP
3167 UPDATE "direct_population_snapshot" SET
3168 "weight" = 1 +
3169 "weight_of_added_delegations_for_population_snapshot"(
3170 "issue_id_p",
3171 "member_id_v",
3172 '{}'
3174 WHERE "issue_id" = "issue_id_p"
3175 AND "event" = 'periodic'
3176 AND "member_id" = "member_id_v";
3177 END LOOP;
3178 RETURN;
3179 END;
3180 $$;
3182 COMMENT ON FUNCTION "create_population_snapshot"
3183 ( "issue"."id"%TYPE )
3184 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.';
3187 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3188 ( "issue_id_p" "issue"."id"%TYPE,
3189 "member_id_p" "member"."id"%TYPE,
3190 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3191 RETURNS "direct_interest_snapshot"."weight"%TYPE
3192 LANGUAGE 'plpgsql' VOLATILE AS $$
3193 DECLARE
3194 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3195 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3196 "weight_v" INT4;
3197 "sub_weight_v" INT4;
3198 BEGIN
3199 "weight_v" := 0;
3200 FOR "issue_delegation_row" IN
3201 SELECT * FROM "issue_delegation"
3202 WHERE "trustee_id" = "member_id_p"
3203 AND "issue_id" = "issue_id_p"
3204 LOOP
3205 IF NOT EXISTS (
3206 SELECT NULL FROM "direct_interest_snapshot"
3207 WHERE "issue_id" = "issue_id_p"
3208 AND "event" = 'periodic'
3209 AND "member_id" = "issue_delegation_row"."truster_id"
3210 ) AND NOT EXISTS (
3211 SELECT NULL FROM "delegating_interest_snapshot"
3212 WHERE "issue_id" = "issue_id_p"
3213 AND "event" = 'periodic'
3214 AND "member_id" = "issue_delegation_row"."truster_id"
3215 ) THEN
3216 "delegate_member_ids_v" :=
3217 "member_id_p" || "delegate_member_ids_p";
3218 INSERT INTO "delegating_interest_snapshot" (
3219 "issue_id",
3220 "event",
3221 "member_id",
3222 "scope",
3223 "delegate_member_ids"
3224 ) VALUES (
3225 "issue_id_p",
3226 'periodic',
3227 "issue_delegation_row"."truster_id",
3228 "issue_delegation_row"."scope",
3229 "delegate_member_ids_v"
3230 );
3231 "sub_weight_v" := 1 +
3232 "weight_of_added_delegations_for_interest_snapshot"(
3233 "issue_id_p",
3234 "issue_delegation_row"."truster_id",
3235 "delegate_member_ids_v"
3236 );
3237 UPDATE "delegating_interest_snapshot"
3238 SET "weight" = "sub_weight_v"
3239 WHERE "issue_id" = "issue_id_p"
3240 AND "event" = 'periodic'
3241 AND "member_id" = "issue_delegation_row"."truster_id";
3242 "weight_v" := "weight_v" + "sub_weight_v";
3243 END IF;
3244 END LOOP;
3245 RETURN "weight_v";
3246 END;
3247 $$;
3249 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3250 ( "issue"."id"%TYPE,
3251 "member"."id"%TYPE,
3252 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3253 IS 'Helper function for "create_interest_snapshot" function';
3256 CREATE FUNCTION "create_interest_snapshot"
3257 ( "issue_id_p" "issue"."id"%TYPE )
3258 RETURNS VOID
3259 LANGUAGE 'plpgsql' VOLATILE AS $$
3260 DECLARE
3261 "member_id_v" "member"."id"%TYPE;
3262 BEGIN
3263 DELETE FROM "direct_interest_snapshot"
3264 WHERE "issue_id" = "issue_id_p"
3265 AND "event" = 'periodic';
3266 DELETE FROM "delegating_interest_snapshot"
3267 WHERE "issue_id" = "issue_id_p"
3268 AND "event" = 'periodic';
3269 DELETE FROM "direct_supporter_snapshot"
3270 WHERE "issue_id" = "issue_id_p"
3271 AND "event" = 'periodic';
3272 INSERT INTO "direct_interest_snapshot"
3273 ("issue_id", "event", "member_id")
3274 SELECT
3275 "issue_id_p" AS "issue_id",
3276 'periodic' AS "event",
3277 "member"."id" AS "member_id"
3278 FROM "issue"
3279 JOIN "area" ON "issue"."area_id" = "area"."id"
3280 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3281 JOIN "member" ON "interest"."member_id" = "member"."id"
3282 JOIN "privilege"
3283 ON "privilege"."unit_id" = "area"."unit_id"
3284 AND "privilege"."member_id" = "member"."id"
3285 WHERE "issue"."id" = "issue_id_p"
3286 AND "member"."active" AND "privilege"."voting_right";
3287 FOR "member_id_v" IN
3288 SELECT "member_id" FROM "direct_interest_snapshot"
3289 WHERE "issue_id" = "issue_id_p"
3290 AND "event" = 'periodic'
3291 LOOP
3292 UPDATE "direct_interest_snapshot" SET
3293 "weight" = 1 +
3294 "weight_of_added_delegations_for_interest_snapshot"(
3295 "issue_id_p",
3296 "member_id_v",
3297 '{}'
3299 WHERE "issue_id" = "issue_id_p"
3300 AND "event" = 'periodic'
3301 AND "member_id" = "member_id_v";
3302 END LOOP;
3303 INSERT INTO "direct_supporter_snapshot"
3304 ( "issue_id", "initiative_id", "event", "member_id",
3305 "draft_id", "informed", "satisfied" )
3306 SELECT
3307 "issue_id_p" AS "issue_id",
3308 "initiative"."id" AS "initiative_id",
3309 'periodic' AS "event",
3310 "supporter"."member_id" AS "member_id",
3311 "supporter"."draft_id" AS "draft_id",
3312 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3313 NOT EXISTS (
3314 SELECT NULL FROM "critical_opinion"
3315 WHERE "initiative_id" = "initiative"."id"
3316 AND "member_id" = "supporter"."member_id"
3317 ) AS "satisfied"
3318 FROM "initiative"
3319 JOIN "supporter"
3320 ON "supporter"."initiative_id" = "initiative"."id"
3321 JOIN "current_draft"
3322 ON "initiative"."id" = "current_draft"."initiative_id"
3323 JOIN "direct_interest_snapshot"
3324 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3325 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3326 AND "event" = 'periodic'
3327 WHERE "initiative"."issue_id" = "issue_id_p";
3328 RETURN;
3329 END;
3330 $$;
3332 COMMENT ON FUNCTION "create_interest_snapshot"
3333 ( "issue"."id"%TYPE )
3334 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.';
3337 CREATE FUNCTION "create_snapshot"
3338 ( "issue_id_p" "issue"."id"%TYPE )
3339 RETURNS VOID
3340 LANGUAGE 'plpgsql' VOLATILE AS $$
3341 DECLARE
3342 "initiative_id_v" "initiative"."id"%TYPE;
3343 "suggestion_id_v" "suggestion"."id"%TYPE;
3344 BEGIN
3345 PERFORM "lock_issue"("issue_id_p");
3346 PERFORM "create_population_snapshot"("issue_id_p");
3347 PERFORM "create_interest_snapshot"("issue_id_p");
3348 UPDATE "issue" SET
3349 "snapshot" = now(),
3350 "latest_snapshot_event" = 'periodic',
3351 "population" = (
3352 SELECT coalesce(sum("weight"), 0)
3353 FROM "direct_population_snapshot"
3354 WHERE "issue_id" = "issue_id_p"
3355 AND "event" = 'periodic'
3357 WHERE "id" = "issue_id_p";
3358 FOR "initiative_id_v" IN
3359 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3360 LOOP
3361 UPDATE "initiative" SET
3362 "supporter_count" = (
3363 SELECT coalesce(sum("di"."weight"), 0)
3364 FROM "direct_interest_snapshot" AS "di"
3365 JOIN "direct_supporter_snapshot" AS "ds"
3366 ON "di"."member_id" = "ds"."member_id"
3367 WHERE "di"."issue_id" = "issue_id_p"
3368 AND "di"."event" = 'periodic'
3369 AND "ds"."initiative_id" = "initiative_id_v"
3370 AND "ds"."event" = 'periodic'
3371 ),
3372 "informed_supporter_count" = (
3373 SELECT coalesce(sum("di"."weight"), 0)
3374 FROM "direct_interest_snapshot" AS "di"
3375 JOIN "direct_supporter_snapshot" AS "ds"
3376 ON "di"."member_id" = "ds"."member_id"
3377 WHERE "di"."issue_id" = "issue_id_p"
3378 AND "di"."event" = 'periodic'
3379 AND "ds"."initiative_id" = "initiative_id_v"
3380 AND "ds"."event" = 'periodic'
3381 AND "ds"."informed"
3382 ),
3383 "satisfied_supporter_count" = (
3384 SELECT coalesce(sum("di"."weight"), 0)
3385 FROM "direct_interest_snapshot" AS "di"
3386 JOIN "direct_supporter_snapshot" AS "ds"
3387 ON "di"."member_id" = "ds"."member_id"
3388 WHERE "di"."issue_id" = "issue_id_p"
3389 AND "di"."event" = 'periodic'
3390 AND "ds"."initiative_id" = "initiative_id_v"
3391 AND "ds"."event" = 'periodic'
3392 AND "ds"."satisfied"
3393 ),
3394 "satisfied_informed_supporter_count" = (
3395 SELECT coalesce(sum("di"."weight"), 0)
3396 FROM "direct_interest_snapshot" AS "di"
3397 JOIN "direct_supporter_snapshot" AS "ds"
3398 ON "di"."member_id" = "ds"."member_id"
3399 WHERE "di"."issue_id" = "issue_id_p"
3400 AND "di"."event" = 'periodic'
3401 AND "ds"."initiative_id" = "initiative_id_v"
3402 AND "ds"."event" = 'periodic'
3403 AND "ds"."informed"
3404 AND "ds"."satisfied"
3406 WHERE "id" = "initiative_id_v";
3407 FOR "suggestion_id_v" IN
3408 SELECT "id" FROM "suggestion"
3409 WHERE "initiative_id" = "initiative_id_v"
3410 LOOP
3411 UPDATE "suggestion" SET
3412 "minus2_unfulfilled_count" = (
3413 SELECT coalesce(sum("snapshot"."weight"), 0)
3414 FROM "issue" CROSS JOIN "opinion"
3415 JOIN "direct_interest_snapshot" AS "snapshot"
3416 ON "snapshot"."issue_id" = "issue"."id"
3417 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3418 AND "snapshot"."member_id" = "opinion"."member_id"
3419 WHERE "issue"."id" = "issue_id_p"
3420 AND "opinion"."suggestion_id" = "suggestion_id_v"
3421 AND "opinion"."degree" = -2
3422 AND "opinion"."fulfilled" = FALSE
3423 ),
3424 "minus2_fulfilled_count" = (
3425 SELECT coalesce(sum("snapshot"."weight"), 0)
3426 FROM "issue" CROSS JOIN "opinion"
3427 JOIN "direct_interest_snapshot" AS "snapshot"
3428 ON "snapshot"."issue_id" = "issue"."id"
3429 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3430 AND "snapshot"."member_id" = "opinion"."member_id"
3431 WHERE "issue"."id" = "issue_id_p"
3432 AND "opinion"."suggestion_id" = "suggestion_id_v"
3433 AND "opinion"."degree" = -2
3434 AND "opinion"."fulfilled" = TRUE
3435 ),
3436 "minus1_unfulfilled_count" = (
3437 SELECT coalesce(sum("snapshot"."weight"), 0)
3438 FROM "issue" CROSS JOIN "opinion"
3439 JOIN "direct_interest_snapshot" AS "snapshot"
3440 ON "snapshot"."issue_id" = "issue"."id"
3441 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3442 AND "snapshot"."member_id" = "opinion"."member_id"
3443 WHERE "issue"."id" = "issue_id_p"
3444 AND "opinion"."suggestion_id" = "suggestion_id_v"
3445 AND "opinion"."degree" = -1
3446 AND "opinion"."fulfilled" = FALSE
3447 ),
3448 "minus1_fulfilled_count" = (
3449 SELECT coalesce(sum("snapshot"."weight"), 0)
3450 FROM "issue" CROSS JOIN "opinion"
3451 JOIN "direct_interest_snapshot" AS "snapshot"
3452 ON "snapshot"."issue_id" = "issue"."id"
3453 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3454 AND "snapshot"."member_id" = "opinion"."member_id"
3455 WHERE "issue"."id" = "issue_id_p"
3456 AND "opinion"."suggestion_id" = "suggestion_id_v"
3457 AND "opinion"."degree" = -1
3458 AND "opinion"."fulfilled" = TRUE
3459 ),
3460 "plus1_unfulfilled_count" = (
3461 SELECT coalesce(sum("snapshot"."weight"), 0)
3462 FROM "issue" CROSS JOIN "opinion"
3463 JOIN "direct_interest_snapshot" AS "snapshot"
3464 ON "snapshot"."issue_id" = "issue"."id"
3465 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3466 AND "snapshot"."member_id" = "opinion"."member_id"
3467 WHERE "issue"."id" = "issue_id_p"
3468 AND "opinion"."suggestion_id" = "suggestion_id_v"
3469 AND "opinion"."degree" = 1
3470 AND "opinion"."fulfilled" = FALSE
3471 ),
3472 "plus1_fulfilled_count" = (
3473 SELECT coalesce(sum("snapshot"."weight"), 0)
3474 FROM "issue" CROSS JOIN "opinion"
3475 JOIN "direct_interest_snapshot" AS "snapshot"
3476 ON "snapshot"."issue_id" = "issue"."id"
3477 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3478 AND "snapshot"."member_id" = "opinion"."member_id"
3479 WHERE "issue"."id" = "issue_id_p"
3480 AND "opinion"."suggestion_id" = "suggestion_id_v"
3481 AND "opinion"."degree" = 1
3482 AND "opinion"."fulfilled" = TRUE
3483 ),
3484 "plus2_unfulfilled_count" = (
3485 SELECT coalesce(sum("snapshot"."weight"), 0)
3486 FROM "issue" CROSS JOIN "opinion"
3487 JOIN "direct_interest_snapshot" AS "snapshot"
3488 ON "snapshot"."issue_id" = "issue"."id"
3489 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3490 AND "snapshot"."member_id" = "opinion"."member_id"
3491 WHERE "issue"."id" = "issue_id_p"
3492 AND "opinion"."suggestion_id" = "suggestion_id_v"
3493 AND "opinion"."degree" = 2
3494 AND "opinion"."fulfilled" = FALSE
3495 ),
3496 "plus2_fulfilled_count" = (
3497 SELECT coalesce(sum("snapshot"."weight"), 0)
3498 FROM "issue" CROSS JOIN "opinion"
3499 JOIN "direct_interest_snapshot" AS "snapshot"
3500 ON "snapshot"."issue_id" = "issue"."id"
3501 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3502 AND "snapshot"."member_id" = "opinion"."member_id"
3503 WHERE "issue"."id" = "issue_id_p"
3504 AND "opinion"."suggestion_id" = "suggestion_id_v"
3505 AND "opinion"."degree" = 2
3506 AND "opinion"."fulfilled" = TRUE
3508 WHERE "suggestion"."id" = "suggestion_id_v";
3509 END LOOP;
3510 END LOOP;
3511 RETURN;
3512 END;
3513 $$;
3515 COMMENT ON FUNCTION "create_snapshot"
3516 ( "issue"."id"%TYPE )
3517 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.';
3520 CREATE FUNCTION "set_snapshot_event"
3521 ( "issue_id_p" "issue"."id"%TYPE,
3522 "event_p" "snapshot_event" )
3523 RETURNS VOID
3524 LANGUAGE 'plpgsql' VOLATILE AS $$
3525 DECLARE
3526 "event_v" "issue"."latest_snapshot_event"%TYPE;
3527 BEGIN
3528 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3529 WHERE "id" = "issue_id_p" FOR UPDATE;
3530 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3531 WHERE "id" = "issue_id_p";
3532 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3533 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3534 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3535 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3536 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3537 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3538 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3539 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3540 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3541 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3542 RETURN;
3543 END;
3544 $$;
3546 COMMENT ON FUNCTION "set_snapshot_event"
3547 ( "issue"."id"%TYPE,
3548 "snapshot_event" )
3549 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3553 ---------------------
3554 -- Freezing issues --
3555 ---------------------
3557 CREATE FUNCTION "freeze_after_snapshot"
3558 ( "issue_id_p" "issue"."id"%TYPE )
3559 RETURNS VOID
3560 LANGUAGE 'plpgsql' VOLATILE AS $$
3561 DECLARE
3562 "issue_row" "issue"%ROWTYPE;
3563 "policy_row" "policy"%ROWTYPE;
3564 "initiative_row" "initiative"%ROWTYPE;
3565 BEGIN
3566 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3567 SELECT * INTO "policy_row"
3568 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3569 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3570 FOR "initiative_row" IN
3571 SELECT * FROM "initiative"
3572 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3573 LOOP
3574 IF
3575 "initiative_row"."polling" OR (
3576 "initiative_row"."satisfied_supporter_count" > 0 AND
3577 "initiative_row"."satisfied_supporter_count" *
3578 "policy_row"."initiative_quorum_den" >=
3579 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3581 THEN
3582 UPDATE "initiative" SET "admitted" = TRUE
3583 WHERE "id" = "initiative_row"."id";
3584 ELSE
3585 UPDATE "initiative" SET "admitted" = FALSE
3586 WHERE "id" = "initiative_row"."id";
3587 END IF;
3588 END LOOP;
3589 IF EXISTS (
3590 SELECT NULL FROM "initiative"
3591 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3592 ) THEN
3593 UPDATE "issue" SET
3594 "state" = 'voting',
3595 "accepted" = coalesce("accepted", now()),
3596 "half_frozen" = coalesce("half_frozen", now()),
3597 "fully_frozen" = now()
3598 WHERE "id" = "issue_id_p";
3599 ELSE
3600 UPDATE "issue" SET
3601 "state" = 'canceled_no_initiative_admitted',
3602 "accepted" = coalesce("accepted", now()),
3603 "half_frozen" = coalesce("half_frozen", now()),
3604 "fully_frozen" = now(),
3605 "closed" = now(),
3606 "ranks_available" = TRUE
3607 WHERE "id" = "issue_id_p";
3608 -- NOTE: The following DELETE statements have effect only when
3609 -- issue state has been manipulated
3610 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3611 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3612 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3613 END IF;
3614 RETURN;
3615 END;
3616 $$;
3618 COMMENT ON FUNCTION "freeze_after_snapshot"
3619 ( "issue"."id"%TYPE )
3620 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3623 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3624 RETURNS VOID
3625 LANGUAGE 'plpgsql' VOLATILE AS $$
3626 DECLARE
3627 "issue_row" "issue"%ROWTYPE;
3628 BEGIN
3629 PERFORM "create_snapshot"("issue_id_p");
3630 PERFORM "freeze_after_snapshot"("issue_id_p");
3631 RETURN;
3632 END;
3633 $$;
3635 COMMENT ON FUNCTION "manual_freeze"
3636 ( "issue"."id"%TYPE )
3637 IS 'Freeze an issue manually (fully) and start voting';
3641 -----------------------
3642 -- Counting of votes --
3643 -----------------------
3646 CREATE FUNCTION "weight_of_added_vote_delegations"
3647 ( "issue_id_p" "issue"."id"%TYPE,
3648 "member_id_p" "member"."id"%TYPE,
3649 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3650 RETURNS "direct_voter"."weight"%TYPE
3651 LANGUAGE 'plpgsql' VOLATILE AS $$
3652 DECLARE
3653 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3654 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3655 "weight_v" INT4;
3656 "sub_weight_v" INT4;
3657 BEGIN
3658 "weight_v" := 0;
3659 FOR "issue_delegation_row" IN
3660 SELECT * FROM "issue_delegation"
3661 WHERE "trustee_id" = "member_id_p"
3662 AND "issue_id" = "issue_id_p"
3663 LOOP
3664 IF NOT EXISTS (
3665 SELECT NULL FROM "direct_voter"
3666 WHERE "member_id" = "issue_delegation_row"."truster_id"
3667 AND "issue_id" = "issue_id_p"
3668 ) AND NOT EXISTS (
3669 SELECT NULL FROM "delegating_voter"
3670 WHERE "member_id" = "issue_delegation_row"."truster_id"
3671 AND "issue_id" = "issue_id_p"
3672 ) THEN
3673 "delegate_member_ids_v" :=
3674 "member_id_p" || "delegate_member_ids_p";
3675 INSERT INTO "delegating_voter" (
3676 "issue_id",
3677 "member_id",
3678 "scope",
3679 "delegate_member_ids"
3680 ) VALUES (
3681 "issue_id_p",
3682 "issue_delegation_row"."truster_id",
3683 "issue_delegation_row"."scope",
3684 "delegate_member_ids_v"
3685 );
3686 "sub_weight_v" := 1 +
3687 "weight_of_added_vote_delegations"(
3688 "issue_id_p",
3689 "issue_delegation_row"."truster_id",
3690 "delegate_member_ids_v"
3691 );
3692 UPDATE "delegating_voter"
3693 SET "weight" = "sub_weight_v"
3694 WHERE "issue_id" = "issue_id_p"
3695 AND "member_id" = "issue_delegation_row"."truster_id";
3696 "weight_v" := "weight_v" + "sub_weight_v";
3697 END IF;
3698 END LOOP;
3699 RETURN "weight_v";
3700 END;
3701 $$;
3703 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3704 ( "issue"."id"%TYPE,
3705 "member"."id"%TYPE,
3706 "delegating_voter"."delegate_member_ids"%TYPE )
3707 IS 'Helper function for "add_vote_delegations" function';
3710 CREATE FUNCTION "add_vote_delegations"
3711 ( "issue_id_p" "issue"."id"%TYPE )
3712 RETURNS VOID
3713 LANGUAGE 'plpgsql' VOLATILE AS $$
3714 DECLARE
3715 "member_id_v" "member"."id"%TYPE;
3716 BEGIN
3717 FOR "member_id_v" IN
3718 SELECT "member_id" FROM "direct_voter"
3719 WHERE "issue_id" = "issue_id_p"
3720 LOOP
3721 UPDATE "direct_voter" SET
3722 "weight" = "weight" + "weight_of_added_vote_delegations"(
3723 "issue_id_p",
3724 "member_id_v",
3725 '{}'
3727 WHERE "member_id" = "member_id_v"
3728 AND "issue_id" = "issue_id_p";
3729 END LOOP;
3730 RETURN;
3731 END;
3732 $$;
3734 COMMENT ON FUNCTION "add_vote_delegations"
3735 ( "issue_id_p" "issue"."id"%TYPE )
3736 IS 'Helper function for "close_voting" function';
3739 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3740 RETURNS VOID
3741 LANGUAGE 'plpgsql' VOLATILE AS $$
3742 DECLARE
3743 "area_id_v" "area"."id"%TYPE;
3744 "unit_id_v" "unit"."id"%TYPE;
3745 "member_id_v" "member"."id"%TYPE;
3746 BEGIN
3747 PERFORM "lock_issue"("issue_id_p");
3748 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3749 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3750 -- delete timestamp of voting comment:
3751 UPDATE "direct_voter" SET "comment_changed" = NULL
3752 WHERE "issue_id" = "issue_id_p";
3753 -- delete delegating votes (in cases of manual reset of issue state):
3754 DELETE FROM "delegating_voter"
3755 WHERE "issue_id" = "issue_id_p";
3756 -- delete votes from non-privileged voters:
3757 DELETE FROM "direct_voter"
3758 USING (
3759 SELECT
3760 "direct_voter"."member_id"
3761 FROM "direct_voter"
3762 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3763 LEFT JOIN "privilege"
3764 ON "privilege"."unit_id" = "unit_id_v"
3765 AND "privilege"."member_id" = "direct_voter"."member_id"
3766 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3767 "member"."active" = FALSE OR
3768 "privilege"."voting_right" ISNULL OR
3769 "privilege"."voting_right" = FALSE
3771 ) AS "subquery"
3772 WHERE "direct_voter"."issue_id" = "issue_id_p"
3773 AND "direct_voter"."member_id" = "subquery"."member_id";
3774 -- consider delegations:
3775 UPDATE "direct_voter" SET "weight" = 1
3776 WHERE "issue_id" = "issue_id_p";
3777 PERFORM "add_vote_delegations"("issue_id_p");
3778 -- set voter count and mark issue as being calculated:
3779 UPDATE "issue" SET
3780 "state" = 'calculation',
3781 "closed" = now(),
3782 "voter_count" = (
3783 SELECT coalesce(sum("weight"), 0)
3784 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3786 WHERE "id" = "issue_id_p";
3787 -- materialize battle_view:
3788 -- NOTE: "closed" column of issue must be set at this point
3789 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3790 INSERT INTO "battle" (
3791 "issue_id",
3792 "winning_initiative_id", "losing_initiative_id",
3793 "count"
3794 ) SELECT
3795 "issue_id",
3796 "winning_initiative_id", "losing_initiative_id",
3797 "count"
3798 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3799 -- copy "positive_votes" and "negative_votes" from "battle" table:
3800 UPDATE "initiative" SET
3801 "positive_votes" = "battle_win"."count",
3802 "negative_votes" = "battle_lose"."count"
3803 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3804 WHERE
3805 "battle_win"."issue_id" = "issue_id_p" AND
3806 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3807 "battle_win"."losing_initiative_id" ISNULL AND
3808 "battle_lose"."issue_id" = "issue_id_p" AND
3809 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3810 "battle_lose"."winning_initiative_id" ISNULL;
3811 END;
3812 $$;
3814 COMMENT ON FUNCTION "close_voting"
3815 ( "issue"."id"%TYPE )
3816 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.';
3819 CREATE FUNCTION "defeat_strength"
3820 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3821 RETURNS INT8
3822 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3823 BEGIN
3824 IF "positive_votes_p" > "negative_votes_p" THEN
3825 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3826 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3827 RETURN 0;
3828 ELSE
3829 RETURN -1;
3830 END IF;
3831 END;
3832 $$;
3834 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';
3837 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3838 RETURNS VOID
3839 LANGUAGE 'plpgsql' VOLATILE AS $$
3840 DECLARE
3841 "issue_row" "issue"%ROWTYPE;
3842 "policy_row" "policy"%ROWTYPE;
3843 "dimension_v" INTEGER;
3844 "vote_matrix" INT4[][]; -- absolute votes
3845 "matrix" INT8[][]; -- defeat strength / best paths
3846 "i" INTEGER;
3847 "j" INTEGER;
3848 "k" INTEGER;
3849 "battle_row" "battle"%ROWTYPE;
3850 "rank_ary" INT4[];
3851 "rank_v" INT4;
3852 "done_v" INTEGER;
3853 "winners_ary" INTEGER[];
3854 "initiative_id_v" "initiative"."id"%TYPE;
3855 BEGIN
3856 SELECT * INTO "issue_row"
3857 FROM "issue" WHERE "id" = "issue_id_p"
3858 FOR UPDATE;
3859 SELECT * INTO "policy_row"
3860 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3861 SELECT count(1) INTO "dimension_v"
3862 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3863 -- Create "vote_matrix" with absolute number of votes in pairwise
3864 -- comparison:
3865 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3866 "i" := 1;
3867 "j" := 2;
3868 FOR "battle_row" IN
3869 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3870 ORDER BY
3871 "winning_initiative_id" NULLS LAST,
3872 "losing_initiative_id" NULLS LAST
3873 LOOP
3874 "vote_matrix"["i"]["j"] := "battle_row"."count";
3875 IF "j" = "dimension_v" THEN
3876 "i" := "i" + 1;
3877 "j" := 1;
3878 ELSE
3879 "j" := "j" + 1;
3880 IF "j" = "i" THEN
3881 "j" := "j" + 1;
3882 END IF;
3883 END IF;
3884 END LOOP;
3885 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3886 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3887 END IF;
3888 -- Store defeat strengths in "matrix" using "defeat_strength"
3889 -- function:
3890 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3891 "i" := 1;
3892 LOOP
3893 "j" := 1;
3894 LOOP
3895 IF "i" != "j" THEN
3896 "matrix"["i"]["j"] := "defeat_strength"(
3897 "vote_matrix"["i"]["j"],
3898 "vote_matrix"["j"]["i"]
3899 );
3900 END IF;
3901 EXIT WHEN "j" = "dimension_v";
3902 "j" := "j" + 1;
3903 END LOOP;
3904 EXIT WHEN "i" = "dimension_v";
3905 "i" := "i" + 1;
3906 END LOOP;
3907 -- Find best paths:
3908 "i" := 1;
3909 LOOP
3910 "j" := 1;
3911 LOOP
3912 IF "i" != "j" THEN
3913 "k" := 1;
3914 LOOP
3915 IF "i" != "k" AND "j" != "k" THEN
3916 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3917 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3918 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3919 END IF;
3920 ELSE
3921 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3922 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3923 END IF;
3924 END IF;
3925 END IF;
3926 EXIT WHEN "k" = "dimension_v";
3927 "k" := "k" + 1;
3928 END LOOP;
3929 END IF;
3930 EXIT WHEN "j" = "dimension_v";
3931 "j" := "j" + 1;
3932 END LOOP;
3933 EXIT WHEN "i" = "dimension_v";
3934 "i" := "i" + 1;
3935 END LOOP;
3936 -- Determine order of winners:
3937 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3938 "rank_v" := 1;
3939 "done_v" := 0;
3940 LOOP
3941 "winners_ary" := '{}';
3942 "i" := 1;
3943 LOOP
3944 IF "rank_ary"["i"] ISNULL THEN
3945 "j" := 1;
3946 LOOP
3947 IF
3948 "i" != "j" AND
3949 "rank_ary"["j"] ISNULL AND
3950 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3951 THEN
3952 -- someone else is better
3953 EXIT;
3954 END IF;
3955 IF "j" = "dimension_v" THEN
3956 -- noone is better
3957 "winners_ary" := "winners_ary" || "i";
3958 EXIT;
3959 END IF;
3960 "j" := "j" + 1;
3961 END LOOP;
3962 END IF;
3963 EXIT WHEN "i" = "dimension_v";
3964 "i" := "i" + 1;
3965 END LOOP;
3966 "i" := 1;
3967 LOOP
3968 "rank_ary"["winners_ary"["i"]] := "rank_v";
3969 "done_v" := "done_v" + 1;
3970 EXIT WHEN "i" = array_upper("winners_ary", 1);
3971 "i" := "i" + 1;
3972 END LOOP;
3973 EXIT WHEN "done_v" = "dimension_v";
3974 "rank_v" := "rank_v" + 1;
3975 END LOOP;
3976 -- write preliminary results:
3977 "i" := 1;
3978 FOR "initiative_id_v" IN
3979 SELECT "id" FROM "initiative"
3980 WHERE "issue_id" = "issue_id_p" AND "admitted"
3981 ORDER BY "id"
3982 LOOP
3983 UPDATE "initiative" SET
3984 "direct_majority" =
3985 CASE WHEN "policy_row"."direct_majority_strict" THEN
3986 "positive_votes" * "policy_row"."direct_majority_den" >
3987 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3988 ELSE
3989 "positive_votes" * "policy_row"."direct_majority_den" >=
3990 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3991 END
3992 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3993 AND "issue_row"."voter_count"-"negative_votes" >=
3994 "policy_row"."direct_majority_non_negative",
3995 "indirect_majority" =
3996 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3997 "positive_votes" * "policy_row"."indirect_majority_den" >
3998 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3999 ELSE
4000 "positive_votes" * "policy_row"."indirect_majority_den" >=
4001 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4002 END
4003 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4004 AND "issue_row"."voter_count"-"negative_votes" >=
4005 "policy_row"."indirect_majority_non_negative",
4006 "schulze_rank" = "rank_ary"["i"],
4007 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
4008 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
4009 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
4010 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
4011 "eligible" = FALSE,
4012 "winner" = FALSE,
4013 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4014 WHERE "id" = "initiative_id_v";
4015 "i" := "i" + 1;
4016 END LOOP;
4017 IF "i" != "dimension_v" THEN
4018 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4019 END IF;
4020 -- take indirect majorities into account:
4021 LOOP
4022 UPDATE "initiative" SET "indirect_majority" = TRUE
4023 FROM (
4024 SELECT "new_initiative"."id" AS "initiative_id"
4025 FROM "initiative" "old_initiative"
4026 JOIN "initiative" "new_initiative"
4027 ON "new_initiative"."issue_id" = "issue_id_p"
4028 AND "new_initiative"."indirect_majority" = FALSE
4029 JOIN "battle" "battle_win"
4030 ON "battle_win"."issue_id" = "issue_id_p"
4031 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4032 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4033 JOIN "battle" "battle_lose"
4034 ON "battle_lose"."issue_id" = "issue_id_p"
4035 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4036 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4037 WHERE "old_initiative"."issue_id" = "issue_id_p"
4038 AND "old_initiative"."indirect_majority" = TRUE
4039 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4040 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4041 "policy_row"."indirect_majority_num" *
4042 ("battle_win"."count"+"battle_lose"."count")
4043 ELSE
4044 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4045 "policy_row"."indirect_majority_num" *
4046 ("battle_win"."count"+"battle_lose"."count")
4047 END
4048 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4049 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4050 "policy_row"."indirect_majority_non_negative"
4051 ) AS "subquery"
4052 WHERE "id" = "subquery"."initiative_id";
4053 EXIT WHEN NOT FOUND;
4054 END LOOP;
4055 -- set "multistage_majority" for remaining matching initiatives:
4056 UPDATE "initiative" SET "multistage_majority" = TRUE
4057 FROM (
4058 SELECT "losing_initiative"."id" AS "initiative_id"
4059 FROM "initiative" "losing_initiative"
4060 JOIN "initiative" "winning_initiative"
4061 ON "winning_initiative"."issue_id" = "issue_id_p"
4062 AND "winning_initiative"."admitted"
4063 JOIN "battle" "battle_win"
4064 ON "battle_win"."issue_id" = "issue_id_p"
4065 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4066 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4067 JOIN "battle" "battle_lose"
4068 ON "battle_lose"."issue_id" = "issue_id_p"
4069 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4070 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4071 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4072 AND "losing_initiative"."admitted"
4073 AND "winning_initiative"."schulze_rank" <
4074 "losing_initiative"."schulze_rank"
4075 AND "battle_win"."count" > "battle_lose"."count"
4076 AND (
4077 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4078 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4079 ) AS "subquery"
4080 WHERE "id" = "subquery"."initiative_id";
4081 -- mark eligible initiatives:
4082 UPDATE "initiative" SET "eligible" = TRUE
4083 WHERE "issue_id" = "issue_id_p"
4084 AND "initiative"."direct_majority"
4085 AND "initiative"."indirect_majority"
4086 AND "initiative"."better_than_status_quo"
4087 AND (
4088 "policy_row"."no_multistage_majority" = FALSE OR
4089 "initiative"."multistage_majority" = FALSE )
4090 AND (
4091 "policy_row"."no_reverse_beat_path" = FALSE OR
4092 "initiative"."reverse_beat_path" = FALSE );
4093 -- mark final winner:
4094 UPDATE "initiative" SET "winner" = TRUE
4095 FROM (
4096 SELECT "id" AS "initiative_id"
4097 FROM "initiative"
4098 WHERE "issue_id" = "issue_id_p" AND "eligible"
4099 ORDER BY
4100 "schulze_rank",
4101 "vote_ratio"("positive_votes", "negative_votes"),
4102 "id"
4103 LIMIT 1
4104 ) AS "subquery"
4105 WHERE "id" = "subquery"."initiative_id";
4106 -- write (final) ranks:
4107 "rank_v" := 1;
4108 FOR "initiative_id_v" IN
4109 SELECT "id"
4110 FROM "initiative"
4111 WHERE "issue_id" = "issue_id_p" AND "admitted"
4112 ORDER BY
4113 "winner" DESC,
4114 "eligible" DESC,
4115 "schulze_rank",
4116 "vote_ratio"("positive_votes", "negative_votes"),
4117 "id"
4118 LOOP
4119 UPDATE "initiative" SET "rank" = "rank_v"
4120 WHERE "id" = "initiative_id_v";
4121 "rank_v" := "rank_v" + 1;
4122 END LOOP;
4123 -- set schulze rank of status quo and mark issue as finished:
4124 UPDATE "issue" SET
4125 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4126 "state" =
4127 CASE WHEN EXISTS (
4128 SELECT NULL FROM "initiative"
4129 WHERE "issue_id" = "issue_id_p" AND "winner"
4130 ) THEN
4131 'finished_with_winner'::"issue_state"
4132 ELSE
4133 'finished_without_winner'::"issue_state"
4134 END,
4135 "ranks_available" = TRUE
4136 WHERE "id" = "issue_id_p";
4137 RETURN;
4138 END;
4139 $$;
4141 COMMENT ON FUNCTION "calculate_ranks"
4142 ( "issue"."id"%TYPE )
4143 IS 'Determine ranking (Votes have to be counted first)';
4147 -----------------------------
4148 -- Automatic state changes --
4149 -----------------------------
4152 CREATE FUNCTION "check_issue"
4153 ( "issue_id_p" "issue"."id"%TYPE )
4154 RETURNS VOID
4155 LANGUAGE 'plpgsql' VOLATILE AS $$
4156 DECLARE
4157 "issue_row" "issue"%ROWTYPE;
4158 "policy_row" "policy"%ROWTYPE;
4159 BEGIN
4160 PERFORM "lock_issue"("issue_id_p");
4161 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4162 -- only process open issues:
4163 IF "issue_row"."closed" ISNULL THEN
4164 SELECT * INTO "policy_row" FROM "policy"
4165 WHERE "id" = "issue_row"."policy_id";
4166 -- create a snapshot, unless issue is already fully frozen:
4167 IF "issue_row"."fully_frozen" ISNULL THEN
4168 PERFORM "create_snapshot"("issue_id_p");
4169 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4170 END IF;
4171 -- eventually close or accept issues, which have not been accepted:
4172 IF "issue_row"."accepted" ISNULL THEN
4173 IF EXISTS (
4174 SELECT NULL FROM "initiative"
4175 WHERE "issue_id" = "issue_id_p"
4176 AND "supporter_count" > 0
4177 AND "supporter_count" * "policy_row"."issue_quorum_den"
4178 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4179 ) THEN
4180 -- accept issues, if supporter count is high enough
4181 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4182 -- NOTE: "issue_row" used later
4183 "issue_row"."state" := 'discussion';
4184 "issue_row"."accepted" := now();
4185 UPDATE "issue" SET
4186 "state" = "issue_row"."state",
4187 "accepted" = "issue_row"."accepted"
4188 WHERE "id" = "issue_row"."id";
4189 ELSIF
4190 now() >= "issue_row"."created" + "issue_row"."admission_time"
4191 THEN
4192 -- close issues, if admission time has expired
4193 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4194 UPDATE "issue" SET
4195 "state" = 'canceled_issue_not_accepted',
4196 "closed" = now()
4197 WHERE "id" = "issue_row"."id";
4198 END IF;
4199 END IF;
4200 -- eventually half freeze issues:
4201 IF
4202 -- NOTE: issue can't be closed at this point, if it has been accepted
4203 "issue_row"."accepted" NOTNULL AND
4204 "issue_row"."half_frozen" ISNULL
4205 THEN
4206 IF
4207 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4208 THEN
4209 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4210 -- NOTE: "issue_row" used later
4211 "issue_row"."state" := 'verification';
4212 "issue_row"."half_frozen" := now();
4213 UPDATE "issue" SET
4214 "state" = "issue_row"."state",
4215 "half_frozen" = "issue_row"."half_frozen"
4216 WHERE "id" = "issue_row"."id";
4217 END IF;
4218 END IF;
4219 -- close issues after some time, if all initiatives have been revoked:
4220 IF
4221 "issue_row"."closed" ISNULL AND
4222 NOT EXISTS (
4223 -- all initiatives are revoked
4224 SELECT NULL FROM "initiative"
4225 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4226 ) AND (
4227 -- and issue has not been accepted yet
4228 "issue_row"."accepted" ISNULL OR
4229 NOT EXISTS (
4230 -- or no initiatives have been revoked lately
4231 SELECT NULL FROM "initiative"
4232 WHERE "issue_id" = "issue_id_p"
4233 AND now() < "revoked" + "issue_row"."verification_time"
4234 ) OR (
4235 -- or verification time has elapsed
4236 "issue_row"."half_frozen" NOTNULL AND
4237 "issue_row"."fully_frozen" ISNULL AND
4238 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4241 THEN
4242 -- NOTE: "issue_row" used later
4243 IF "issue_row"."accepted" ISNULL THEN
4244 "issue_row"."state" := 'canceled_revoked_before_accepted';
4245 ELSIF "issue_row"."half_frozen" ISNULL THEN
4246 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4247 ELSE
4248 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4249 END IF;
4250 "issue_row"."closed" := now();
4251 UPDATE "issue" SET
4252 "state" = "issue_row"."state",
4253 "closed" = "issue_row"."closed"
4254 WHERE "id" = "issue_row"."id";
4255 END IF;
4256 -- fully freeze issue after verification time:
4257 IF
4258 "issue_row"."half_frozen" NOTNULL AND
4259 "issue_row"."fully_frozen" ISNULL AND
4260 "issue_row"."closed" ISNULL AND
4261 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4262 THEN
4263 PERFORM "freeze_after_snapshot"("issue_id_p");
4264 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4265 END IF;
4266 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4267 -- close issue by calling close_voting(...) after voting time:
4268 IF
4269 "issue_row"."closed" ISNULL AND
4270 "issue_row"."fully_frozen" NOTNULL AND
4271 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4272 THEN
4273 PERFORM "close_voting"("issue_id_p");
4274 -- calculate ranks will not consume much time and can be done now
4275 PERFORM "calculate_ranks"("issue_id_p");
4276 END IF;
4277 END IF;
4278 RETURN;
4279 END;
4280 $$;
4282 COMMENT ON FUNCTION "check_issue"
4283 ( "issue"."id"%TYPE )
4284 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.';
4287 CREATE FUNCTION "check_everything"()
4288 RETURNS VOID
4289 LANGUAGE 'plpgsql' VOLATILE AS $$
4290 DECLARE
4291 "issue_id_v" "issue"."id"%TYPE;
4292 BEGIN
4293 DELETE FROM "expired_session";
4294 PERFORM "check_activity"();
4295 PERFORM "calculate_member_counts"();
4296 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4297 PERFORM "check_issue"("issue_id_v");
4298 END LOOP;
4299 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4300 PERFORM "calculate_ranks"("issue_id_v");
4301 END LOOP;
4302 RETURN;
4303 END;
4304 $$;
4306 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.';
4310 ----------------------
4311 -- Deletion of data --
4312 ----------------------
4315 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4316 RETURNS VOID
4317 LANGUAGE 'plpgsql' VOLATILE AS $$
4318 DECLARE
4319 "issue_row" "issue"%ROWTYPE;
4320 BEGIN
4321 SELECT * INTO "issue_row"
4322 FROM "issue" WHERE "id" = "issue_id_p"
4323 FOR UPDATE;
4324 IF "issue_row"."cleaned" ISNULL THEN
4325 UPDATE "issue" SET
4326 "state" = 'voting',
4327 "closed" = NULL,
4328 "ranks_available" = FALSE
4329 WHERE "id" = "issue_id_p";
4330 DELETE FROM "delegating_voter"
4331 WHERE "issue_id" = "issue_id_p";
4332 DELETE FROM "direct_voter"
4333 WHERE "issue_id" = "issue_id_p";
4334 DELETE FROM "delegating_interest_snapshot"
4335 WHERE "issue_id" = "issue_id_p";
4336 DELETE FROM "direct_interest_snapshot"
4337 WHERE "issue_id" = "issue_id_p";
4338 DELETE FROM "delegating_population_snapshot"
4339 WHERE "issue_id" = "issue_id_p";
4340 DELETE FROM "direct_population_snapshot"
4341 WHERE "issue_id" = "issue_id_p";
4342 DELETE FROM "non_voter"
4343 WHERE "issue_id" = "issue_id_p";
4344 DELETE FROM "delegation"
4345 WHERE "issue_id" = "issue_id_p";
4346 DELETE FROM "supporter"
4347 WHERE "issue_id" = "issue_id_p";
4348 UPDATE "issue" SET
4349 "state" = "issue_row"."state",
4350 "closed" = "issue_row"."closed",
4351 "ranks_available" = "issue_row"."ranks_available",
4352 "cleaned" = now()
4353 WHERE "id" = "issue_id_p";
4354 END IF;
4355 RETURN;
4356 END;
4357 $$;
4359 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4362 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4363 RETURNS VOID
4364 LANGUAGE 'plpgsql' VOLATILE AS $$
4365 BEGIN
4366 UPDATE "member" SET
4367 "last_login" = NULL,
4368 "login" = NULL,
4369 "password" = NULL,
4370 "locked" = TRUE,
4371 "active" = FALSE,
4372 "notify_email" = NULL,
4373 "notify_email_unconfirmed" = NULL,
4374 "notify_email_secret" = NULL,
4375 "notify_email_secret_expiry" = NULL,
4376 "notify_email_lock_expiry" = NULL,
4377 "password_reset_secret" = NULL,
4378 "password_reset_secret_expiry" = NULL,
4379 "organizational_unit" = NULL,
4380 "internal_posts" = NULL,
4381 "realname" = NULL,
4382 "birthday" = NULL,
4383 "address" = NULL,
4384 "email" = NULL,
4385 "xmpp_address" = NULL,
4386 "website" = NULL,
4387 "phone" = NULL,
4388 "mobile_phone" = NULL,
4389 "profession" = NULL,
4390 "external_memberships" = NULL,
4391 "external_posts" = NULL,
4392 "statement" = NULL
4393 WHERE "id" = "member_id_p";
4394 -- "text_search_data" is updated by triggers
4395 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4396 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4397 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4398 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4399 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4400 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4401 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4402 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4403 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4404 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4405 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4406 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4407 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4408 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4409 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4410 DELETE FROM "direct_voter" USING "issue"
4411 WHERE "direct_voter"."issue_id" = "issue"."id"
4412 AND "issue"."closed" ISNULL
4413 AND "member_id" = "member_id_p";
4414 RETURN;
4415 END;
4416 $$;
4418 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)';
4421 CREATE FUNCTION "delete_private_data"()
4422 RETURNS VOID
4423 LANGUAGE 'plpgsql' VOLATILE AS $$
4424 BEGIN
4425 DELETE FROM "member" WHERE "activated" ISNULL;
4426 UPDATE "member" SET
4427 "invite_code" = NULL,
4428 "invite_code_expiry" = NULL,
4429 "admin_comment" = NULL,
4430 "last_login" = NULL,
4431 "login" = NULL,
4432 "password" = NULL,
4433 "lang" = NULL,
4434 "notify_email" = NULL,
4435 "notify_email_unconfirmed" = NULL,
4436 "notify_email_secret" = NULL,
4437 "notify_email_secret_expiry" = NULL,
4438 "notify_email_lock_expiry" = NULL,
4439 "notify_level" = NULL,
4440 "password_reset_secret" = NULL,
4441 "password_reset_secret_expiry" = NULL,
4442 "organizational_unit" = NULL,
4443 "internal_posts" = NULL,
4444 "realname" = NULL,
4445 "birthday" = NULL,
4446 "address" = NULL,
4447 "email" = NULL,
4448 "xmpp_address" = NULL,
4449 "website" = NULL,
4450 "phone" = NULL,
4451 "mobile_phone" = NULL,
4452 "profession" = NULL,
4453 "external_memberships" = NULL,
4454 "external_posts" = NULL,
4455 "formatting_engine" = NULL,
4456 "statement" = NULL;
4457 -- "text_search_data" is updated by triggers
4458 DELETE FROM "setting";
4459 DELETE FROM "setting_map";
4460 DELETE FROM "member_relation_setting";
4461 DELETE FROM "member_image";
4462 DELETE FROM "contact";
4463 DELETE FROM "ignored_member";
4464 DELETE FROM "session";
4465 DELETE FROM "area_setting";
4466 DELETE FROM "issue_setting";
4467 DELETE FROM "ignored_initiative";
4468 DELETE FROM "initiative_setting";
4469 DELETE FROM "suggestion_setting";
4470 DELETE FROM "non_voter";
4471 DELETE FROM "direct_voter" USING "issue"
4472 WHERE "direct_voter"."issue_id" = "issue"."id"
4473 AND "issue"."closed" ISNULL;
4474 RETURN;
4475 END;
4476 $$;
4478 COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
4482 COMMIT;

Impressum / About Us