liquid_feedback_core

view core.sql @ 224:06b9c347fd61

Update script for v2.0.4
author jbe
date Sat Feb 25 16:37:18 2012 +0100 (2012-02-25)
parents ae08a20808d4
children 18e1cd384528
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.0.4', 2, 0, 4))
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 "admin_comment" TEXT,
89 "activated" TIMESTAMPTZ,
90 "last_activity" DATE,
91 "last_login" TIMESTAMPTZ,
92 "login" TEXT UNIQUE,
93 "password" TEXT,
94 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
95 "active" BOOLEAN NOT NULL DEFAULT FALSE,
96 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
97 "lang" TEXT,
98 "notify_email" TEXT,
99 "notify_email_unconfirmed" TEXT,
100 "notify_email_secret" TEXT UNIQUE,
101 "notify_email_secret_expiry" TIMESTAMPTZ,
102 "notify_email_lock_expiry" TIMESTAMPTZ,
103 "notify_level" "notify_level" NOT NULL DEFAULT 'none',
104 "password_reset_secret" TEXT UNIQUE,
105 "password_reset_secret_expiry" TIMESTAMPTZ,
106 "name" TEXT NOT NULL UNIQUE,
107 "identification" TEXT UNIQUE,
108 "authentication" TEXT,
109 "organizational_unit" TEXT,
110 "internal_posts" TEXT,
111 "realname" TEXT,
112 "birthday" DATE,
113 "address" TEXT,
114 "email" TEXT,
115 "xmpp_address" TEXT,
116 "website" TEXT,
117 "phone" TEXT,
118 "mobile_phone" TEXT,
119 "profession" TEXT,
120 "external_memberships" TEXT,
121 "external_posts" TEXT,
122 "formatting_engine" TEXT,
123 "statement" TEXT,
124 "text_search_data" TSVECTOR,
125 CONSTRAINT "active_requires_activated_and_last_activity"
126 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)) );
127 CREATE INDEX "member_active_idx" ON "member" ("active");
128 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
129 CREATE TRIGGER "update_text_search_data"
130 BEFORE INSERT OR UPDATE ON "member"
131 FOR EACH ROW EXECUTE PROCEDURE
132 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
133 "name", "identification", "organizational_unit", "internal_posts",
134 "realname", "external_memberships", "external_posts", "statement" );
136 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
138 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
139 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
140 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
141 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';
142 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
143 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
144 COMMENT ON COLUMN "member"."login" IS 'Login name';
145 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
146 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
147 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".';
148 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
149 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
150 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
151 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
152 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
153 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
154 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
155 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
156 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
157 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
158 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
159 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
160 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
161 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
162 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
163 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
164 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
165 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
166 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
169 CREATE TYPE "application_access_level" AS ENUM
170 ('member', 'full', 'pseudonymous', 'anonymous');
172 COMMENT ON TYPE "application_access_level" IS 'Access privileges for applications using the API';
175 CREATE TABLE "member_application" (
176 "id" SERIAL8 PRIMARY KEY,
177 UNIQUE ("member_id", "name"),
178 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
179 ON DELETE CASCADE ON UPDATE CASCADE,
180 "name" TEXT NOT NULL,
181 "comment" TEXT,
182 "access_level" "application_access_level" NOT NULL,
183 "key" TEXT NOT NULL UNIQUE,
184 "last_usage" TIMESTAMPTZ );
186 COMMENT ON TABLE "member_application" IS 'Registered application being allowed to use the API';
189 CREATE TABLE "member_history" (
190 "id" SERIAL8 PRIMARY KEY,
191 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
192 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
193 "active" BOOLEAN NOT NULL,
194 "name" TEXT NOT NULL );
195 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
197 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
199 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
200 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
203 CREATE TABLE "rendered_member_statement" (
204 PRIMARY KEY ("member_id", "format"),
205 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
206 "format" TEXT,
207 "content" TEXT NOT NULL );
209 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)';
212 CREATE TABLE "setting" (
213 PRIMARY KEY ("member_id", "key"),
214 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
215 "key" TEXT NOT NULL,
216 "value" TEXT NOT NULL );
217 CREATE INDEX "setting_key_idx" ON "setting" ("key");
219 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
221 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
224 CREATE TABLE "setting_map" (
225 PRIMARY KEY ("member_id", "key", "subkey"),
226 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
227 "key" TEXT NOT NULL,
228 "subkey" TEXT NOT NULL,
229 "value" TEXT NOT NULL );
230 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
232 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
234 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
235 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
236 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
239 CREATE TABLE "member_relation_setting" (
240 PRIMARY KEY ("member_id", "key", "other_member_id"),
241 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
242 "key" TEXT NOT NULL,
243 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
244 "value" TEXT NOT NULL );
246 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
249 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
251 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
254 CREATE TABLE "member_image" (
255 PRIMARY KEY ("member_id", "image_type", "scaled"),
256 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
257 "image_type" "member_image_type",
258 "scaled" BOOLEAN,
259 "content_type" TEXT,
260 "data" BYTEA NOT NULL );
262 COMMENT ON TABLE "member_image" IS 'Images of members';
264 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
267 CREATE TABLE "member_count" (
268 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
269 "total_count" INT4 NOT NULL );
271 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';
273 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
274 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
277 CREATE TABLE "contact" (
278 PRIMARY KEY ("member_id", "other_member_id"),
279 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
280 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
281 "public" BOOLEAN NOT NULL DEFAULT FALSE,
282 CONSTRAINT "cant_save_yourself_as_contact"
283 CHECK ("member_id" != "other_member_id") );
284 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
286 COMMENT ON TABLE "contact" IS 'Contact lists';
288 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
289 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
290 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
293 CREATE TABLE "ignored_member" (
294 PRIMARY KEY ("member_id", "other_member_id"),
295 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
296 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
297 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
299 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
301 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
302 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
305 CREATE TABLE "session" (
306 "ident" TEXT PRIMARY KEY,
307 "additional_secret" TEXT,
308 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
309 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
310 "lang" TEXT );
311 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
313 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
315 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
316 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
317 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
318 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
321 CREATE TABLE "policy" (
322 "id" SERIAL4 PRIMARY KEY,
323 "index" INT4 NOT NULL,
324 "active" BOOLEAN NOT NULL DEFAULT TRUE,
325 "name" TEXT NOT NULL UNIQUE,
326 "description" TEXT NOT NULL DEFAULT '',
327 "admission_time" INTERVAL NOT NULL,
328 "discussion_time" INTERVAL NOT NULL,
329 "verification_time" INTERVAL NOT NULL,
330 "voting_time" INTERVAL NOT NULL,
331 "issue_quorum_num" INT4 NOT NULL,
332 "issue_quorum_den" INT4 NOT NULL,
333 "initiative_quorum_num" INT4 NOT NULL,
334 "initiative_quorum_den" INT4 NOT NULL,
335 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
336 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
337 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
338 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
339 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
340 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
341 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
342 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
343 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
344 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
345 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
346 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE );
347 CREATE INDEX "policy_active_idx" ON "policy" ("active");
349 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
351 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
352 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
353 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
354 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
355 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"';
356 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'')';
357 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''';
358 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''';
359 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
360 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
361 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
362 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
363 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.';
364 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
365 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';
366 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';
367 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';
368 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.';
369 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';
370 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';
371 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.';
372 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").';
375 CREATE TABLE "unit" (
376 "id" SERIAL4 PRIMARY KEY,
377 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
378 "active" BOOLEAN NOT NULL DEFAULT TRUE,
379 "name" TEXT NOT NULL,
380 "description" TEXT NOT NULL DEFAULT '',
381 "member_count" INT4,
382 "text_search_data" TSVECTOR );
383 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
384 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
385 CREATE INDEX "unit_active_idx" ON "unit" ("active");
386 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
387 CREATE TRIGGER "update_text_search_data"
388 BEFORE INSERT OR UPDATE ON "unit"
389 FOR EACH ROW EXECUTE PROCEDURE
390 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
391 "name", "description" );
393 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
395 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
396 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
397 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
400 CREATE TABLE "unit_setting" (
401 PRIMARY KEY ("member_id", "key", "unit_id"),
402 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
403 "key" TEXT NOT NULL,
404 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
405 "value" TEXT NOT NULL );
407 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
410 CREATE TABLE "area" (
411 "id" SERIAL4 PRIMARY KEY,
412 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
413 "active" BOOLEAN NOT NULL DEFAULT TRUE,
414 "name" TEXT NOT NULL,
415 "description" TEXT NOT NULL DEFAULT '',
416 "direct_member_count" INT4,
417 "member_weight" INT4,
418 "text_search_data" TSVECTOR );
419 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
420 CREATE INDEX "area_active_idx" ON "area" ("active");
421 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
422 CREATE TRIGGER "update_text_search_data"
423 BEFORE INSERT OR UPDATE ON "area"
424 FOR EACH ROW EXECUTE PROCEDURE
425 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
426 "name", "description" );
428 COMMENT ON TABLE "area" IS 'Subject areas';
430 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
431 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"';
432 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
435 CREATE TABLE "area_setting" (
436 PRIMARY KEY ("member_id", "key", "area_id"),
437 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
438 "key" TEXT NOT NULL,
439 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
440 "value" TEXT NOT NULL );
442 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
445 CREATE TABLE "allowed_policy" (
446 PRIMARY KEY ("area_id", "policy_id"),
447 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
448 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
449 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
450 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
452 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
454 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
457 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
459 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';
462 CREATE TYPE "issue_state" AS ENUM (
463 'admission', 'discussion', 'verification', 'voting',
464 'canceled_revoked_before_accepted',
465 'canceled_issue_not_accepted',
466 'canceled_after_revocation_during_discussion',
467 'canceled_after_revocation_during_verification',
468 'calculation',
469 'canceled_no_initiative_admitted',
470 'finished_without_winner', 'finished_with_winner');
472 COMMENT ON TYPE "issue_state" IS 'State of issues';
475 CREATE TABLE "issue" (
476 "id" SERIAL4 PRIMARY KEY,
477 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
478 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
479 "state" "issue_state" NOT NULL DEFAULT 'admission',
480 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
481 "accepted" TIMESTAMPTZ,
482 "half_frozen" TIMESTAMPTZ,
483 "fully_frozen" TIMESTAMPTZ,
484 "closed" TIMESTAMPTZ,
485 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
486 "cleaned" TIMESTAMPTZ,
487 "admission_time" INTERVAL NOT NULL,
488 "discussion_time" INTERVAL NOT NULL,
489 "verification_time" INTERVAL NOT NULL,
490 "voting_time" INTERVAL NOT NULL,
491 "snapshot" TIMESTAMPTZ,
492 "latest_snapshot_event" "snapshot_event",
493 "population" INT4,
494 "voter_count" INT4,
495 "status_quo_schulze_rank" INT4,
496 CONSTRAINT "valid_state" CHECK ((
497 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
498 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
499 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
500 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
501 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
502 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
503 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
504 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
505 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
506 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
507 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
508 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
509 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
510 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
511 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
512 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
513 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
514 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
515 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
516 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
517 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
518 )),
519 CONSTRAINT "state_change_order" CHECK (
520 "created" <= "accepted" AND
521 "accepted" <= "half_frozen" AND
522 "half_frozen" <= "fully_frozen" AND
523 "fully_frozen" <= "closed" ),
524 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
525 "cleaned" ISNULL OR "closed" NOTNULL ),
526 CONSTRAINT "last_snapshot_on_full_freeze"
527 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
528 CONSTRAINT "freeze_requires_snapshot"
529 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
530 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
531 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
532 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
533 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
534 CREATE INDEX "issue_created_idx" ON "issue" ("created");
535 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
536 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
537 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
538 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
539 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
540 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
542 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
544 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
545 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.';
546 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.';
547 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.';
548 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
549 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
550 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
551 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
552 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
553 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
554 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
555 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';
556 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
557 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';
558 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
561 CREATE TABLE "issue_setting" (
562 PRIMARY KEY ("member_id", "key", "issue_id"),
563 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
564 "key" TEXT NOT NULL,
565 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
566 "value" TEXT NOT NULL );
568 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
571 CREATE TABLE "initiative" (
572 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
573 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
574 "id" SERIAL4 PRIMARY KEY,
575 "name" TEXT NOT NULL,
576 "discussion_url" TEXT,
577 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
578 "revoked" TIMESTAMPTZ,
579 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
580 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
581 "admitted" BOOLEAN,
582 "supporter_count" INT4,
583 "informed_supporter_count" INT4,
584 "satisfied_supporter_count" INT4,
585 "satisfied_informed_supporter_count" INT4,
586 "positive_votes" INT4,
587 "negative_votes" INT4,
588 "direct_majority" BOOLEAN,
589 "indirect_majority" BOOLEAN,
590 "schulze_rank" INT4,
591 "better_than_status_quo" BOOLEAN,
592 "worse_than_status_quo" BOOLEAN,
593 "reverse_beat_path" BOOLEAN,
594 "multistage_majority" BOOLEAN,
595 "eligible" BOOLEAN,
596 "winner" BOOLEAN,
597 "rank" INT4,
598 "text_search_data" TSVECTOR,
599 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
600 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
601 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
602 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
603 CONSTRAINT "revoked_initiatives_cant_be_admitted"
604 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
605 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
606 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
607 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
608 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
609 "schulze_rank" ISNULL AND
610 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
611 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
612 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
613 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
614 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
615 "eligible" = FALSE OR
616 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
617 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
618 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
619 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
620 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
621 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
622 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
623 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
624 CREATE TRIGGER "update_text_search_data"
625 BEFORE INSERT OR UPDATE ON "initiative"
626 FOR EACH ROW EXECUTE PROCEDURE
627 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
628 "name", "discussion_url");
630 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.';
632 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
633 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
634 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
635 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
636 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
637 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
638 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
639 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
640 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
641 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
642 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"';
643 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
644 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
645 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
646 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
647 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';
648 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';
649 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"';
650 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
651 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';
654 CREATE TABLE "battle" (
655 "issue_id" INT4 NOT NULL,
656 "winning_initiative_id" INT4,
657 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
658 "losing_initiative_id" INT4,
659 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
660 "count" INT4 NOT NULL,
661 CONSTRAINT "initiative_ids_not_equal" CHECK (
662 "winning_initiative_id" != "losing_initiative_id" OR
663 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
664 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
665 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
666 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
667 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
669 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';
672 CREATE TABLE "ignored_initiative" (
673 PRIMARY KEY ("initiative_id", "member_id"),
674 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
675 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
676 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
678 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
681 CREATE TABLE "initiative_setting" (
682 PRIMARY KEY ("member_id", "key", "initiative_id"),
683 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
684 "key" TEXT NOT NULL,
685 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
686 "value" TEXT NOT NULL );
688 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
691 CREATE TABLE "draft" (
692 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
693 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
694 "id" SERIAL8 PRIMARY KEY,
695 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
696 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
697 "formatting_engine" TEXT,
698 "content" TEXT NOT NULL,
699 "text_search_data" TSVECTOR );
700 CREATE INDEX "draft_created_idx" ON "draft" ("created");
701 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
702 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
703 CREATE TRIGGER "update_text_search_data"
704 BEFORE INSERT OR UPDATE ON "draft"
705 FOR EACH ROW EXECUTE PROCEDURE
706 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
708 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.';
710 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
711 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
714 CREATE TABLE "rendered_draft" (
715 PRIMARY KEY ("draft_id", "format"),
716 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
717 "format" TEXT,
718 "content" TEXT NOT NULL );
720 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)';
723 CREATE TABLE "suggestion" (
724 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
725 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
726 "id" SERIAL8 PRIMARY KEY,
727 "draft_id" INT8 NOT NULL,
728 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
729 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
730 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
731 "name" TEXT NOT NULL,
732 "formatting_engine" TEXT,
733 "content" TEXT NOT NULL DEFAULT '',
734 "text_search_data" TSVECTOR,
735 "minus2_unfulfilled_count" INT4,
736 "minus2_fulfilled_count" INT4,
737 "minus1_unfulfilled_count" INT4,
738 "minus1_fulfilled_count" INT4,
739 "plus1_unfulfilled_count" INT4,
740 "plus1_fulfilled_count" INT4,
741 "plus2_unfulfilled_count" INT4,
742 "plus2_fulfilled_count" INT4 );
743 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
744 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
745 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
746 CREATE TRIGGER "update_text_search_data"
747 BEFORE INSERT OR UPDATE ON "suggestion"
748 FOR EACH ROW EXECUTE PROCEDURE
749 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
750 "name", "content");
752 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';
754 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")';
755 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
756 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
757 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
758 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
759 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
760 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
761 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
762 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
765 CREATE TABLE "rendered_suggestion" (
766 PRIMARY KEY ("suggestion_id", "format"),
767 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
768 "format" TEXT,
769 "content" TEXT NOT NULL );
771 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)';
774 CREATE TABLE "suggestion_setting" (
775 PRIMARY KEY ("member_id", "key", "suggestion_id"),
776 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
777 "key" TEXT NOT NULL,
778 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
779 "value" TEXT NOT NULL );
781 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
784 CREATE TABLE "privilege" (
785 PRIMARY KEY ("unit_id", "member_id"),
786 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
787 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
788 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
789 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
790 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
791 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
792 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
794 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
796 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other members';
797 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
798 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
799 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote within the unit';
800 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
803 CREATE TABLE "membership" (
804 PRIMARY KEY ("area_id", "member_id"),
805 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
806 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
807 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
809 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
812 CREATE TABLE "interest" (
813 PRIMARY KEY ("issue_id", "member_id"),
814 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
815 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
816 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
818 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.';
821 CREATE TABLE "initiator" (
822 PRIMARY KEY ("initiative_id", "member_id"),
823 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
824 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
825 "accepted" BOOLEAN );
826 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
828 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.';
830 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.';
833 CREATE TABLE "supporter" (
834 "issue_id" INT4 NOT NULL,
835 PRIMARY KEY ("initiative_id", "member_id"),
836 "initiative_id" INT4,
837 "member_id" INT4,
838 "draft_id" INT8 NOT NULL,
839 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
840 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
841 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
843 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.';
845 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
846 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")';
849 CREATE TABLE "opinion" (
850 "initiative_id" INT4 NOT NULL,
851 PRIMARY KEY ("suggestion_id", "member_id"),
852 "suggestion_id" INT8,
853 "member_id" INT4,
854 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
855 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
856 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
857 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
858 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
860 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.';
862 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
865 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
867 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
870 CREATE TABLE "delegation" (
871 "id" SERIAL8 PRIMARY KEY,
872 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
873 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
874 "scope" "delegation_scope" NOT NULL,
875 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
876 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
877 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
878 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
879 CONSTRAINT "no_unit_delegation_to_null"
880 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
881 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
882 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
883 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
884 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
885 UNIQUE ("unit_id", "truster_id"),
886 UNIQUE ("area_id", "truster_id"),
887 UNIQUE ("issue_id", "truster_id") );
888 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
889 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
891 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
893 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
894 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
895 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
898 CREATE TABLE "direct_population_snapshot" (
899 PRIMARY KEY ("issue_id", "event", "member_id"),
900 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
901 "event" "snapshot_event",
902 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
903 "weight" INT4 );
904 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
906 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
908 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
909 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
912 CREATE TABLE "delegating_population_snapshot" (
913 PRIMARY KEY ("issue_id", "event", "member_id"),
914 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
915 "event" "snapshot_event",
916 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
917 "weight" INT4,
918 "scope" "delegation_scope" NOT NULL,
919 "delegate_member_ids" INT4[] NOT NULL );
920 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
922 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
924 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
925 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
926 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
927 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"';
930 CREATE TABLE "direct_interest_snapshot" (
931 PRIMARY KEY ("issue_id", "event", "member_id"),
932 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
933 "event" "snapshot_event",
934 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
935 "weight" INT4 );
936 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
938 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
940 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
941 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
944 CREATE TABLE "delegating_interest_snapshot" (
945 PRIMARY KEY ("issue_id", "event", "member_id"),
946 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
947 "event" "snapshot_event",
948 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
949 "weight" INT4,
950 "scope" "delegation_scope" NOT NULL,
951 "delegate_member_ids" INT4[] NOT NULL );
952 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
954 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
956 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
957 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
958 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
959 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"';
962 CREATE TABLE "direct_supporter_snapshot" (
963 "issue_id" INT4 NOT NULL,
964 PRIMARY KEY ("initiative_id", "event", "member_id"),
965 "initiative_id" INT4,
966 "event" "snapshot_event",
967 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
968 "draft_id" INT8 NOT NULL,
969 "informed" BOOLEAN NOT NULL,
970 "satisfied" BOOLEAN NOT NULL,
971 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
972 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
973 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
974 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
976 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
978 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';
979 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
980 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
981 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
984 CREATE TABLE "non_voter" (
985 PRIMARY KEY ("issue_id", "member_id"),
986 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
987 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
988 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
990 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
993 CREATE TABLE "direct_voter" (
994 PRIMARY KEY ("issue_id", "member_id"),
995 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
996 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
997 "weight" INT4 );
998 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1000 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.';
1002 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1005 CREATE TABLE "delegating_voter" (
1006 PRIMARY KEY ("issue_id", "member_id"),
1007 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1008 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1009 "weight" INT4,
1010 "scope" "delegation_scope" NOT NULL,
1011 "delegate_member_ids" INT4[] NOT NULL );
1012 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1014 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1016 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1017 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1018 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"';
1021 CREATE TABLE "vote" (
1022 "issue_id" INT4 NOT NULL,
1023 PRIMARY KEY ("initiative_id", "member_id"),
1024 "initiative_id" INT4,
1025 "member_id" INT4,
1026 "grade" INT4,
1027 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1028 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1029 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1031 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.';
1033 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1034 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.';
1037 CREATE TABLE "issue_comment" (
1038 PRIMARY KEY ("issue_id", "member_id"),
1039 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1040 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1041 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
1042 "formatting_engine" TEXT,
1043 "content" TEXT NOT NULL,
1044 "text_search_data" TSVECTOR );
1045 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
1046 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
1047 CREATE TRIGGER "update_text_search_data"
1048 BEFORE INSERT OR UPDATE ON "issue_comment"
1049 FOR EACH ROW EXECUTE PROCEDURE
1050 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1052 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
1054 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
1057 CREATE TABLE "rendered_issue_comment" (
1058 PRIMARY KEY ("issue_id", "member_id", "format"),
1059 FOREIGN KEY ("issue_id", "member_id")
1060 REFERENCES "issue_comment" ("issue_id", "member_id")
1061 ON DELETE CASCADE ON UPDATE CASCADE,
1062 "issue_id" INT4,
1063 "member_id" INT4,
1064 "format" TEXT,
1065 "content" TEXT NOT NULL );
1067 COMMENT ON TABLE "rendered_issue_comment" IS 'This table may be used by frontends to cache "rendered" issue comments (e.g. HTML output generated from wiki text)';
1070 CREATE TABLE "voting_comment" (
1071 PRIMARY KEY ("issue_id", "member_id"),
1072 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1073 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1074 "changed" TIMESTAMPTZ,
1075 "formatting_engine" TEXT,
1076 "content" TEXT NOT NULL,
1077 "text_search_data" TSVECTOR );
1078 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1079 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1080 CREATE TRIGGER "update_text_search_data"
1081 BEFORE INSERT OR UPDATE ON "voting_comment"
1082 FOR EACH ROW EXECUTE PROCEDURE
1083 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1085 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1087 COMMENT ON COLUMN "voting_comment"."changed" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
1090 CREATE TABLE "rendered_voting_comment" (
1091 PRIMARY KEY ("issue_id", "member_id", "format"),
1092 FOREIGN KEY ("issue_id", "member_id")
1093 REFERENCES "voting_comment" ("issue_id", "member_id")
1094 ON DELETE CASCADE ON UPDATE CASCADE,
1095 "issue_id" INT4,
1096 "member_id" INT4,
1097 "format" TEXT,
1098 "content" TEXT NOT NULL );
1100 COMMENT ON TABLE "rendered_voting_comment" IS 'This table may be used by frontends to cache "rendered" voting comments (e.g. HTML output generated from wiki text)';
1103 CREATE TYPE "event_type" AS ENUM (
1104 'issue_state_changed',
1105 'initiative_created_in_new_issue',
1106 'initiative_created_in_existing_issue',
1107 'initiative_revoked',
1108 'new_draft_created',
1109 'suggestion_created');
1111 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1114 CREATE TABLE "event" (
1115 "id" SERIAL8 PRIMARY KEY,
1116 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1117 "event" "event_type" NOT NULL,
1118 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1119 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1120 "state" "issue_state" CHECK ("state" != 'calculation'),
1121 "initiative_id" INT4,
1122 "draft_id" INT8,
1123 "suggestion_id" INT8,
1124 FOREIGN KEY ("issue_id", "initiative_id")
1125 REFERENCES "initiative" ("issue_id", "id")
1126 ON DELETE CASCADE ON UPDATE CASCADE,
1127 FOREIGN KEY ("initiative_id", "draft_id")
1128 REFERENCES "draft" ("initiative_id", "id")
1129 ON DELETE CASCADE ON UPDATE CASCADE,
1130 FOREIGN KEY ("initiative_id", "suggestion_id")
1131 REFERENCES "suggestion" ("initiative_id", "id")
1132 ON DELETE CASCADE ON UPDATE CASCADE,
1133 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1134 "event" != 'issue_state_changed' OR (
1135 "member_id" ISNULL AND
1136 "issue_id" NOTNULL AND
1137 "state" NOTNULL AND
1138 "initiative_id" ISNULL AND
1139 "draft_id" ISNULL AND
1140 "suggestion_id" ISNULL )),
1141 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1142 "event" NOT IN (
1143 'initiative_created_in_new_issue',
1144 'initiative_created_in_existing_issue',
1145 'initiative_revoked',
1146 'new_draft_created'
1147 ) OR (
1148 "member_id" NOTNULL AND
1149 "issue_id" NOTNULL AND
1150 "state" NOTNULL AND
1151 "initiative_id" NOTNULL AND
1152 "draft_id" NOTNULL AND
1153 "suggestion_id" ISNULL )),
1154 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1155 "event" != 'suggestion_created' OR (
1156 "member_id" NOTNULL AND
1157 "issue_id" NOTNULL AND
1158 "state" NOTNULL AND
1159 "initiative_id" NOTNULL AND
1160 "draft_id" ISNULL AND
1161 "suggestion_id" NOTNULL )) );
1162 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1164 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1166 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1167 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1168 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1169 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1172 CREATE TABLE "notification_sent" (
1173 "event_id" INT8 NOT NULL );
1174 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1176 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1177 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1181 ----------------------------------------------
1182 -- Writing of history entries and event log --
1183 ----------------------------------------------
1186 CREATE FUNCTION "write_member_history_trigger"()
1187 RETURNS TRIGGER
1188 LANGUAGE 'plpgsql' VOLATILE AS $$
1189 BEGIN
1190 IF
1191 NEW."active" != OLD."active" OR
1192 NEW."name" != OLD."name"
1193 THEN
1194 INSERT INTO "member_history"
1195 ("member_id", "active", "name")
1196 VALUES (NEW."id", OLD."active", OLD."name");
1197 END IF;
1198 RETURN NULL;
1199 END;
1200 $$;
1202 CREATE TRIGGER "write_member_history"
1203 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1204 "write_member_history_trigger"();
1206 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1207 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1210 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1211 RETURNS TRIGGER
1212 LANGUAGE 'plpgsql' VOLATILE AS $$
1213 BEGIN
1214 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1215 INSERT INTO "event" ("event", "issue_id", "state")
1216 VALUES ('issue_state_changed', NEW."id", NEW."state");
1217 END IF;
1218 RETURN NULL;
1219 END;
1220 $$;
1222 CREATE TRIGGER "write_event_issue_state_changed"
1223 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1224 "write_event_issue_state_changed_trigger"();
1226 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1227 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1230 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1231 RETURNS TRIGGER
1232 LANGUAGE 'plpgsql' VOLATILE AS $$
1233 DECLARE
1234 "initiative_row" "initiative"%ROWTYPE;
1235 "issue_row" "issue"%ROWTYPE;
1236 "event_v" "event_type";
1237 BEGIN
1238 SELECT * INTO "initiative_row" FROM "initiative"
1239 WHERE "id" = NEW."initiative_id";
1240 SELECT * INTO "issue_row" FROM "issue"
1241 WHERE "id" = "initiative_row"."issue_id";
1242 IF EXISTS (
1243 SELECT NULL FROM "draft"
1244 WHERE "initiative_id" = NEW."initiative_id"
1245 AND "id" != NEW."id"
1246 ) THEN
1247 "event_v" := 'new_draft_created';
1248 ELSE
1249 IF EXISTS (
1250 SELECT NULL FROM "initiative"
1251 WHERE "issue_id" = "initiative_row"."issue_id"
1252 AND "id" != "initiative_row"."id"
1253 ) THEN
1254 "event_v" := 'initiative_created_in_existing_issue';
1255 ELSE
1256 "event_v" := 'initiative_created_in_new_issue';
1257 END IF;
1258 END IF;
1259 INSERT INTO "event" (
1260 "event", "member_id",
1261 "issue_id", "state", "initiative_id", "draft_id"
1262 ) VALUES (
1263 "event_v",
1264 NEW."author_id",
1265 "initiative_row"."issue_id",
1266 "issue_row"."state",
1267 "initiative_row"."id",
1268 NEW."id" );
1269 RETURN NULL;
1270 END;
1271 $$;
1273 CREATE TRIGGER "write_event_initiative_or_draft_created"
1274 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1275 "write_event_initiative_or_draft_created_trigger"();
1277 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1278 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1281 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1282 RETURNS TRIGGER
1283 LANGUAGE 'plpgsql' VOLATILE AS $$
1284 DECLARE
1285 "issue_row" "issue"%ROWTYPE;
1286 BEGIN
1287 SELECT * INTO "issue_row" FROM "issue"
1288 WHERE "id" = NEW."issue_id";
1289 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1290 INSERT INTO "event" (
1291 "event", "member_id", "issue_id", "state", "initiative_id"
1292 ) VALUES (
1293 'initiative_revoked',
1294 NEW."revoked_by_member_id",
1295 NEW."issue_id",
1296 "issue_row"."state",
1297 NEW."id" );
1298 END IF;
1299 RETURN NULL;
1300 END;
1301 $$;
1303 CREATE TRIGGER "write_event_initiative_revoked"
1304 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1305 "write_event_initiative_revoked_trigger"();
1307 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1308 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1311 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1312 RETURNS TRIGGER
1313 LANGUAGE 'plpgsql' VOLATILE AS $$
1314 DECLARE
1315 "initiative_row" "initiative"%ROWTYPE;
1316 "issue_row" "issue"%ROWTYPE;
1317 BEGIN
1318 SELECT * INTO "initiative_row" FROM "initiative"
1319 WHERE "id" = NEW."initiative_id";
1320 SELECT * INTO "issue_row" FROM "issue"
1321 WHERE "id" = "initiative_row"."issue_id";
1322 INSERT INTO "event" (
1323 "event", "member_id",
1324 "issue_id", "state", "initiative_id", "suggestion_id"
1325 ) VALUES (
1326 'suggestion_created',
1327 NEW."author_id",
1328 "initiative_row"."issue_id",
1329 "issue_row"."state",
1330 "initiative_row"."id",
1331 NEW."id" );
1332 RETURN NULL;
1333 END;
1334 $$;
1336 CREATE TRIGGER "write_event_suggestion_created"
1337 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1338 "write_event_suggestion_created_trigger"();
1340 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1341 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1345 ----------------------------
1346 -- Additional constraints --
1347 ----------------------------
1350 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1351 RETURNS TRIGGER
1352 LANGUAGE 'plpgsql' VOLATILE AS $$
1353 BEGIN
1354 IF NOT EXISTS (
1355 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1356 ) THEN
1357 --RAISE 'Cannot create issue without an initial initiative.' USING
1358 -- ERRCODE = 'integrity_constraint_violation',
1359 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1360 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1361 END IF;
1362 RETURN NULL;
1363 END;
1364 $$;
1366 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1367 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1368 FOR EACH ROW EXECUTE PROCEDURE
1369 "issue_requires_first_initiative_trigger"();
1371 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1372 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1375 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1376 RETURNS TRIGGER
1377 LANGUAGE 'plpgsql' VOLATILE AS $$
1378 DECLARE
1379 "reference_lost" BOOLEAN;
1380 BEGIN
1381 IF TG_OP = 'DELETE' THEN
1382 "reference_lost" := TRUE;
1383 ELSE
1384 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1385 END IF;
1386 IF
1387 "reference_lost" AND NOT EXISTS (
1388 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1390 THEN
1391 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1392 END IF;
1393 RETURN NULL;
1394 END;
1395 $$;
1397 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1398 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1399 FOR EACH ROW EXECUTE PROCEDURE
1400 "last_initiative_deletes_issue_trigger"();
1402 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1403 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1406 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1407 RETURNS TRIGGER
1408 LANGUAGE 'plpgsql' VOLATILE AS $$
1409 BEGIN
1410 IF NOT EXISTS (
1411 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1412 ) THEN
1413 --RAISE 'Cannot create initiative without an initial draft.' USING
1414 -- ERRCODE = 'integrity_constraint_violation',
1415 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1416 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1417 END IF;
1418 RETURN NULL;
1419 END;
1420 $$;
1422 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1423 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1424 FOR EACH ROW EXECUTE PROCEDURE
1425 "initiative_requires_first_draft_trigger"();
1427 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1428 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1431 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1432 RETURNS TRIGGER
1433 LANGUAGE 'plpgsql' VOLATILE AS $$
1434 DECLARE
1435 "reference_lost" BOOLEAN;
1436 BEGIN
1437 IF TG_OP = 'DELETE' THEN
1438 "reference_lost" := TRUE;
1439 ELSE
1440 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1441 END IF;
1442 IF
1443 "reference_lost" AND NOT EXISTS (
1444 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1446 THEN
1447 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1448 END IF;
1449 RETURN NULL;
1450 END;
1451 $$;
1453 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1454 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1455 FOR EACH ROW EXECUTE PROCEDURE
1456 "last_draft_deletes_initiative_trigger"();
1458 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1459 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1462 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1463 RETURNS TRIGGER
1464 LANGUAGE 'plpgsql' VOLATILE AS $$
1465 BEGIN
1466 IF NOT EXISTS (
1467 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1468 ) THEN
1469 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1470 END IF;
1471 RETURN NULL;
1472 END;
1473 $$;
1475 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1476 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1477 FOR EACH ROW EXECUTE PROCEDURE
1478 "suggestion_requires_first_opinion_trigger"();
1480 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1481 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1484 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1485 RETURNS TRIGGER
1486 LANGUAGE 'plpgsql' VOLATILE AS $$
1487 DECLARE
1488 "reference_lost" BOOLEAN;
1489 BEGIN
1490 IF TG_OP = 'DELETE' THEN
1491 "reference_lost" := TRUE;
1492 ELSE
1493 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1494 END IF;
1495 IF
1496 "reference_lost" AND NOT EXISTS (
1497 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1499 THEN
1500 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1501 END IF;
1502 RETURN NULL;
1503 END;
1504 $$;
1506 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1507 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1508 FOR EACH ROW EXECUTE PROCEDURE
1509 "last_opinion_deletes_suggestion_trigger"();
1511 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1512 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1516 ---------------------------------------------------------------
1517 -- Ensure that votes are not modified when issues are frozen --
1518 ---------------------------------------------------------------
1520 -- NOTE: Frontends should ensure this anyway, but in case of programming
1521 -- errors the following triggers ensure data integrity.
1524 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1525 RETURNS TRIGGER
1526 LANGUAGE 'plpgsql' VOLATILE AS $$
1527 DECLARE
1528 "issue_id_v" "issue"."id"%TYPE;
1529 "issue_row" "issue"%ROWTYPE;
1530 BEGIN
1531 IF TG_OP = 'DELETE' THEN
1532 "issue_id_v" := OLD."issue_id";
1533 ELSE
1534 "issue_id_v" := NEW."issue_id";
1535 END IF;
1536 SELECT INTO "issue_row" * FROM "issue"
1537 WHERE "id" = "issue_id_v" FOR SHARE;
1538 IF "issue_row"."closed" NOTNULL THEN
1539 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1540 END IF;
1541 RETURN NULL;
1542 END;
1543 $$;
1545 CREATE TRIGGER "forbid_changes_on_closed_issue"
1546 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1547 FOR EACH ROW EXECUTE PROCEDURE
1548 "forbid_changes_on_closed_issue_trigger"();
1550 CREATE TRIGGER "forbid_changes_on_closed_issue"
1551 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1552 FOR EACH ROW EXECUTE PROCEDURE
1553 "forbid_changes_on_closed_issue_trigger"();
1555 CREATE TRIGGER "forbid_changes_on_closed_issue"
1556 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1557 FOR EACH ROW EXECUTE PROCEDURE
1558 "forbid_changes_on_closed_issue_trigger"();
1560 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"';
1561 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';
1562 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';
1563 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';
1567 --------------------------------------------------------------------
1568 -- Auto-retrieval of fields only needed for referential integrity --
1569 --------------------------------------------------------------------
1572 CREATE FUNCTION "autofill_issue_id_trigger"()
1573 RETURNS TRIGGER
1574 LANGUAGE 'plpgsql' VOLATILE AS $$
1575 BEGIN
1576 IF NEW."issue_id" ISNULL THEN
1577 SELECT "issue_id" INTO NEW."issue_id"
1578 FROM "initiative" WHERE "id" = NEW."initiative_id";
1579 END IF;
1580 RETURN NEW;
1581 END;
1582 $$;
1584 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1585 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1587 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1588 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1590 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1591 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1592 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1595 CREATE FUNCTION "autofill_initiative_id_trigger"()
1596 RETURNS TRIGGER
1597 LANGUAGE 'plpgsql' VOLATILE AS $$
1598 BEGIN
1599 IF NEW."initiative_id" ISNULL THEN
1600 SELECT "initiative_id" INTO NEW."initiative_id"
1601 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1602 END IF;
1603 RETURN NEW;
1604 END;
1605 $$;
1607 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1608 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1610 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1611 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1615 -----------------------------------------------------
1616 -- Automatic calculation of certain default values --
1617 -----------------------------------------------------
1620 CREATE FUNCTION "copy_timings_trigger"()
1621 RETURNS TRIGGER
1622 LANGUAGE 'plpgsql' VOLATILE AS $$
1623 DECLARE
1624 "policy_row" "policy"%ROWTYPE;
1625 BEGIN
1626 SELECT * INTO "policy_row" FROM "policy"
1627 WHERE "id" = NEW."policy_id";
1628 IF NEW."admission_time" ISNULL THEN
1629 NEW."admission_time" := "policy_row"."admission_time";
1630 END IF;
1631 IF NEW."discussion_time" ISNULL THEN
1632 NEW."discussion_time" := "policy_row"."discussion_time";
1633 END IF;
1634 IF NEW."verification_time" ISNULL THEN
1635 NEW."verification_time" := "policy_row"."verification_time";
1636 END IF;
1637 IF NEW."voting_time" ISNULL THEN
1638 NEW."voting_time" := "policy_row"."voting_time";
1639 END IF;
1640 RETURN NEW;
1641 END;
1642 $$;
1644 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1645 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1647 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1648 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1651 CREATE FUNCTION "default_for_draft_id_trigger"()
1652 RETURNS TRIGGER
1653 LANGUAGE 'plpgsql' VOLATILE AS $$
1654 BEGIN
1655 IF NEW."draft_id" ISNULL THEN
1656 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1657 WHERE "initiative_id" = NEW."initiative_id";
1658 END IF;
1659 RETURN NEW;
1660 END;
1661 $$;
1663 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1664 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1665 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1666 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1668 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1669 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';
1670 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';
1674 ----------------------------------------
1675 -- Automatic creation of dependencies --
1676 ----------------------------------------
1679 CREATE FUNCTION "autocreate_interest_trigger"()
1680 RETURNS TRIGGER
1681 LANGUAGE 'plpgsql' VOLATILE AS $$
1682 BEGIN
1683 IF NOT EXISTS (
1684 SELECT NULL FROM "initiative" JOIN "interest"
1685 ON "initiative"."issue_id" = "interest"."issue_id"
1686 WHERE "initiative"."id" = NEW."initiative_id"
1687 AND "interest"."member_id" = NEW."member_id"
1688 ) THEN
1689 BEGIN
1690 INSERT INTO "interest" ("issue_id", "member_id")
1691 SELECT "issue_id", NEW."member_id"
1692 FROM "initiative" WHERE "id" = NEW."initiative_id";
1693 EXCEPTION WHEN unique_violation THEN END;
1694 END IF;
1695 RETURN NEW;
1696 END;
1697 $$;
1699 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1700 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1702 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1703 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';
1706 CREATE FUNCTION "autocreate_supporter_trigger"()
1707 RETURNS TRIGGER
1708 LANGUAGE 'plpgsql' VOLATILE AS $$
1709 BEGIN
1710 IF NOT EXISTS (
1711 SELECT NULL FROM "suggestion" JOIN "supporter"
1712 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1713 WHERE "suggestion"."id" = NEW."suggestion_id"
1714 AND "supporter"."member_id" = NEW."member_id"
1715 ) THEN
1716 BEGIN
1717 INSERT INTO "supporter" ("initiative_id", "member_id")
1718 SELECT "initiative_id", NEW."member_id"
1719 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1720 EXCEPTION WHEN unique_violation THEN END;
1721 END IF;
1722 RETURN NEW;
1723 END;
1724 $$;
1726 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1727 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1729 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1730 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.';
1734 ------------------------------------------
1735 -- Views and helper functions for views --
1736 ------------------------------------------
1739 CREATE VIEW "unit_delegation" AS
1740 SELECT
1741 "unit"."id" AS "unit_id",
1742 "delegation"."id",
1743 "delegation"."truster_id",
1744 "delegation"."trustee_id",
1745 "delegation"."scope"
1746 FROM "unit"
1747 JOIN "delegation"
1748 ON "delegation"."unit_id" = "unit"."id"
1749 JOIN "member"
1750 ON "delegation"."truster_id" = "member"."id"
1751 JOIN "privilege"
1752 ON "delegation"."unit_id" = "privilege"."unit_id"
1753 AND "delegation"."truster_id" = "privilege"."member_id"
1754 WHERE "member"."active" AND "privilege"."voting_right";
1756 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1759 CREATE VIEW "area_delegation" AS
1760 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1761 "area"."id" AS "area_id",
1762 "delegation"."id",
1763 "delegation"."truster_id",
1764 "delegation"."trustee_id",
1765 "delegation"."scope"
1766 FROM "area"
1767 JOIN "delegation"
1768 ON "delegation"."unit_id" = "area"."unit_id"
1769 OR "delegation"."area_id" = "area"."id"
1770 JOIN "member"
1771 ON "delegation"."truster_id" = "member"."id"
1772 JOIN "privilege"
1773 ON "area"."unit_id" = "privilege"."unit_id"
1774 AND "delegation"."truster_id" = "privilege"."member_id"
1775 WHERE "member"."active" AND "privilege"."voting_right"
1776 ORDER BY
1777 "area"."id",
1778 "delegation"."truster_id",
1779 "delegation"."scope" DESC;
1781 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1784 CREATE VIEW "issue_delegation" AS
1785 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1786 "issue"."id" AS "issue_id",
1787 "delegation"."id",
1788 "delegation"."truster_id",
1789 "delegation"."trustee_id",
1790 "delegation"."scope"
1791 FROM "issue"
1792 JOIN "area"
1793 ON "area"."id" = "issue"."area_id"
1794 JOIN "delegation"
1795 ON "delegation"."unit_id" = "area"."unit_id"
1796 OR "delegation"."area_id" = "area"."id"
1797 OR "delegation"."issue_id" = "issue"."id"
1798 JOIN "member"
1799 ON "delegation"."truster_id" = "member"."id"
1800 JOIN "privilege"
1801 ON "area"."unit_id" = "privilege"."unit_id"
1802 AND "delegation"."truster_id" = "privilege"."member_id"
1803 WHERE "member"."active" AND "privilege"."voting_right"
1804 ORDER BY
1805 "issue"."id",
1806 "delegation"."truster_id",
1807 "delegation"."scope" DESC;
1809 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1812 CREATE FUNCTION "membership_weight_with_skipping"
1813 ( "area_id_p" "area"."id"%TYPE,
1814 "member_id_p" "member"."id"%TYPE,
1815 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1816 RETURNS INT4
1817 LANGUAGE 'plpgsql' STABLE AS $$
1818 DECLARE
1819 "sum_v" INT4;
1820 "delegation_row" "area_delegation"%ROWTYPE;
1821 BEGIN
1822 "sum_v" := 1;
1823 FOR "delegation_row" IN
1824 SELECT "area_delegation".*
1825 FROM "area_delegation" LEFT JOIN "membership"
1826 ON "membership"."area_id" = "area_id_p"
1827 AND "membership"."member_id" = "area_delegation"."truster_id"
1828 WHERE "area_delegation"."area_id" = "area_id_p"
1829 AND "area_delegation"."trustee_id" = "member_id_p"
1830 AND "membership"."member_id" ISNULL
1831 LOOP
1832 IF NOT
1833 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1834 THEN
1835 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1836 "area_id_p",
1837 "delegation_row"."truster_id",
1838 "skip_member_ids_p" || "delegation_row"."truster_id"
1839 );
1840 END IF;
1841 END LOOP;
1842 RETURN "sum_v";
1843 END;
1844 $$;
1846 COMMENT ON FUNCTION "membership_weight_with_skipping"
1847 ( "area"."id"%TYPE,
1848 "member"."id"%TYPE,
1849 INT4[] )
1850 IS 'Helper function for "membership_weight" function';
1853 CREATE FUNCTION "membership_weight"
1854 ( "area_id_p" "area"."id"%TYPE,
1855 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1856 RETURNS INT4
1857 LANGUAGE 'plpgsql' STABLE AS $$
1858 BEGIN
1859 RETURN "membership_weight_with_skipping"(
1860 "area_id_p",
1861 "member_id_p",
1862 ARRAY["member_id_p"]
1863 );
1864 END;
1865 $$;
1867 COMMENT ON FUNCTION "membership_weight"
1868 ( "area"."id"%TYPE,
1869 "member"."id"%TYPE )
1870 IS 'Calculates the potential voting weight of a member in a given area';
1873 CREATE VIEW "member_count_view" AS
1874 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1876 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1879 CREATE VIEW "unit_member_count" AS
1880 SELECT
1881 "unit"."id" AS "unit_id",
1882 sum("member"."id") AS "member_count"
1883 FROM "unit"
1884 LEFT JOIN "privilege"
1885 ON "privilege"."unit_id" = "unit"."id"
1886 AND "privilege"."voting_right"
1887 LEFT JOIN "member"
1888 ON "member"."id" = "privilege"."member_id"
1889 AND "member"."active"
1890 GROUP BY "unit"."id";
1892 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1895 CREATE VIEW "area_member_count" AS
1896 SELECT
1897 "area"."id" AS "area_id",
1898 count("member"."id") AS "direct_member_count",
1899 coalesce(
1900 sum(
1901 CASE WHEN "member"."id" NOTNULL THEN
1902 "membership_weight"("area"."id", "member"."id")
1903 ELSE 0 END
1905 ) AS "member_weight"
1906 FROM "area"
1907 LEFT JOIN "membership"
1908 ON "area"."id" = "membership"."area_id"
1909 LEFT JOIN "privilege"
1910 ON "privilege"."unit_id" = "area"."unit_id"
1911 AND "privilege"."member_id" = "membership"."member_id"
1912 AND "privilege"."voting_right"
1913 LEFT JOIN "member"
1914 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1915 AND "member"."active"
1916 GROUP BY "area"."id";
1918 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1921 CREATE VIEW "opening_draft" AS
1922 SELECT "draft".* FROM (
1923 SELECT
1924 "initiative"."id" AS "initiative_id",
1925 min("draft"."id") AS "draft_id"
1926 FROM "initiative" JOIN "draft"
1927 ON "initiative"."id" = "draft"."initiative_id"
1928 GROUP BY "initiative"."id"
1929 ) AS "subquery"
1930 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1932 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1935 CREATE VIEW "current_draft" AS
1936 SELECT "draft".* FROM (
1937 SELECT
1938 "initiative"."id" AS "initiative_id",
1939 max("draft"."id") AS "draft_id"
1940 FROM "initiative" JOIN "draft"
1941 ON "initiative"."id" = "draft"."initiative_id"
1942 GROUP BY "initiative"."id"
1943 ) AS "subquery"
1944 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1946 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1949 CREATE VIEW "critical_opinion" AS
1950 SELECT * FROM "opinion"
1951 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1952 OR ("degree" = -2 AND "fulfilled" = TRUE);
1954 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1957 CREATE VIEW "battle_participant" AS
1958 SELECT "initiative"."id", "initiative"."issue_id"
1959 FROM "issue" JOIN "initiative"
1960 ON "issue"."id" = "initiative"."issue_id"
1961 WHERE "initiative"."admitted"
1962 UNION ALL
1963 SELECT NULL, "id" AS "issue_id"
1964 FROM "issue";
1966 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1969 CREATE VIEW "battle_view" AS
1970 SELECT
1971 "issue"."id" AS "issue_id",
1972 "winning_initiative"."id" AS "winning_initiative_id",
1973 "losing_initiative"."id" AS "losing_initiative_id",
1974 sum(
1975 CASE WHEN
1976 coalesce("better_vote"."grade", 0) >
1977 coalesce("worse_vote"."grade", 0)
1978 THEN "direct_voter"."weight" ELSE 0 END
1979 ) AS "count"
1980 FROM "issue"
1981 LEFT JOIN "direct_voter"
1982 ON "issue"."id" = "direct_voter"."issue_id"
1983 JOIN "battle_participant" AS "winning_initiative"
1984 ON "issue"."id" = "winning_initiative"."issue_id"
1985 JOIN "battle_participant" AS "losing_initiative"
1986 ON "issue"."id" = "losing_initiative"."issue_id"
1987 LEFT JOIN "vote" AS "better_vote"
1988 ON "direct_voter"."member_id" = "better_vote"."member_id"
1989 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1990 LEFT JOIN "vote" AS "worse_vote"
1991 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1992 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1993 WHERE "issue"."closed" NOTNULL
1994 AND "issue"."cleaned" ISNULL
1995 AND (
1996 "winning_initiative"."id" != "losing_initiative"."id" OR
1997 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1998 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1999 GROUP BY
2000 "issue"."id",
2001 "winning_initiative"."id",
2002 "losing_initiative"."id";
2004 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';
2007 CREATE VIEW "open_issue" AS
2008 SELECT * FROM "issue" WHERE "closed" ISNULL;
2010 COMMENT ON VIEW "open_issue" IS 'All open issues';
2013 CREATE VIEW "issue_with_ranks_missing" AS
2014 SELECT * FROM "issue"
2015 WHERE "fully_frozen" NOTNULL
2016 AND "closed" NOTNULL
2017 AND "ranks_available" = FALSE;
2019 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2022 CREATE VIEW "member_contingent" AS
2023 SELECT
2024 "member"."id" AS "member_id",
2025 "contingent"."time_frame",
2026 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2028 SELECT count(1) FROM "draft"
2029 WHERE "draft"."author_id" = "member"."id"
2030 AND "draft"."created" > now() - "contingent"."time_frame"
2031 ) + (
2032 SELECT count(1) FROM "suggestion"
2033 WHERE "suggestion"."author_id" = "member"."id"
2034 AND "suggestion"."created" > now() - "contingent"."time_frame"
2036 ELSE NULL END AS "text_entry_count",
2037 "contingent"."text_entry_limit",
2038 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2039 SELECT count(1) FROM "opening_draft"
2040 WHERE "opening_draft"."author_id" = "member"."id"
2041 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2042 ) ELSE NULL END AS "initiative_count",
2043 "contingent"."initiative_limit"
2044 FROM "member" CROSS JOIN "contingent";
2046 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2048 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2049 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2052 CREATE VIEW "member_contingent_left" AS
2053 SELECT
2054 "member_id",
2055 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2056 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2057 FROM "member_contingent" GROUP BY "member_id";
2059 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.';
2062 CREATE VIEW "event_seen_by_member" AS
2063 SELECT
2064 "member"."id" AS "seen_by_member_id",
2065 CASE WHEN "event"."state" IN (
2066 'voting',
2067 'finished_without_winner',
2068 'finished_with_winner'
2069 ) THEN
2070 'voting'::"notify_level"
2071 ELSE
2072 CASE WHEN "event"."state" IN (
2073 'verification',
2074 'canceled_after_revocation_during_verification',
2075 'canceled_no_initiative_admitted'
2076 ) THEN
2077 'verification'::"notify_level"
2078 ELSE
2079 CASE WHEN "event"."state" IN (
2080 'discussion',
2081 'canceled_after_revocation_during_discussion'
2082 ) THEN
2083 'discussion'::"notify_level"
2084 ELSE
2085 'all'::"notify_level"
2086 END
2087 END
2088 END AS "notify_level",
2089 "event".*
2090 FROM "member" CROSS JOIN "event"
2091 LEFT JOIN "issue"
2092 ON "event"."issue_id" = "issue"."id"
2093 LEFT JOIN "membership"
2094 ON "member"."id" = "membership"."member_id"
2095 AND "issue"."area_id" = "membership"."area_id"
2096 LEFT JOIN "interest"
2097 ON "member"."id" = "interest"."member_id"
2098 AND "event"."issue_id" = "interest"."issue_id"
2099 LEFT JOIN "supporter"
2100 ON "member"."id" = "supporter"."member_id"
2101 AND "event"."initiative_id" = "supporter"."initiative_id"
2102 LEFT JOIN "ignored_member"
2103 ON "member"."id" = "ignored_member"."member_id"
2104 AND "event"."member_id" = "ignored_member"."other_member_id"
2105 LEFT JOIN "ignored_initiative"
2106 ON "member"."id" = "ignored_initiative"."member_id"
2107 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2108 WHERE (
2109 "supporter"."member_id" NOTNULL OR
2110 "interest"."member_id" NOTNULL OR
2111 ( "membership"."member_id" NOTNULL AND
2112 "event"."event" IN (
2113 'issue_state_changed',
2114 'initiative_created_in_new_issue',
2115 'initiative_created_in_existing_issue',
2116 'initiative_revoked' ) ) )
2117 AND "ignored_member"."member_id" ISNULL
2118 AND "ignored_initiative"."member_id" ISNULL;
2120 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"';
2123 CREATE VIEW "selected_event_seen_by_member" AS
2124 SELECT
2125 "member"."id" AS "seen_by_member_id",
2126 CASE WHEN "event"."state" IN (
2127 'voting',
2128 'finished_without_winner',
2129 'finished_with_winner'
2130 ) THEN
2131 'voting'::"notify_level"
2132 ELSE
2133 CASE WHEN "event"."state" IN (
2134 'verification',
2135 'canceled_after_revocation_during_verification',
2136 'canceled_no_initiative_admitted'
2137 ) THEN
2138 'verification'::"notify_level"
2139 ELSE
2140 CASE WHEN "event"."state" IN (
2141 'discussion',
2142 'canceled_after_revocation_during_discussion'
2143 ) THEN
2144 'discussion'::"notify_level"
2145 ELSE
2146 'all'::"notify_level"
2147 END
2148 END
2149 END AS "notify_level",
2150 "event".*
2151 FROM "member" CROSS JOIN "event"
2152 LEFT JOIN "issue"
2153 ON "event"."issue_id" = "issue"."id"
2154 LEFT JOIN "membership"
2155 ON "member"."id" = "membership"."member_id"
2156 AND "issue"."area_id" = "membership"."area_id"
2157 LEFT JOIN "interest"
2158 ON "member"."id" = "interest"."member_id"
2159 AND "event"."issue_id" = "interest"."issue_id"
2160 LEFT JOIN "supporter"
2161 ON "member"."id" = "supporter"."member_id"
2162 AND "event"."initiative_id" = "supporter"."initiative_id"
2163 LEFT JOIN "ignored_member"
2164 ON "member"."id" = "ignored_member"."member_id"
2165 AND "event"."member_id" = "ignored_member"."other_member_id"
2166 LEFT JOIN "ignored_initiative"
2167 ON "member"."id" = "ignored_initiative"."member_id"
2168 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2169 WHERE (
2170 ( "member"."notify_level" >= 'all' ) OR
2171 ( "member"."notify_level" >= 'voting' AND
2172 "event"."state" IN (
2173 'voting',
2174 'finished_without_winner',
2175 'finished_with_winner' ) ) OR
2176 ( "member"."notify_level" >= 'verification' AND
2177 "event"."state" IN (
2178 'verification',
2179 'canceled_after_revocation_during_verification',
2180 'canceled_no_initiative_admitted' ) ) OR
2181 ( "member"."notify_level" >= 'discussion' AND
2182 "event"."state" IN (
2183 'discussion',
2184 'canceled_after_revocation_during_discussion' ) ) )
2185 AND (
2186 "supporter"."member_id" NOTNULL OR
2187 "interest"."member_id" NOTNULL OR
2188 ( "membership"."member_id" NOTNULL AND
2189 "event"."event" IN (
2190 'issue_state_changed',
2191 'initiative_created_in_new_issue',
2192 'initiative_created_in_existing_issue',
2193 'initiative_revoked' ) ) )
2194 AND "ignored_member"."member_id" ISNULL
2195 AND "ignored_initiative"."member_id" ISNULL;
2197 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"';
2200 CREATE TYPE "timeline_event" AS ENUM (
2201 'issue_created',
2202 'issue_canceled',
2203 'issue_accepted',
2204 'issue_half_frozen',
2205 'issue_finished_without_voting',
2206 'issue_voting_started',
2207 'issue_finished_after_voting',
2208 'initiative_created',
2209 'initiative_revoked',
2210 'draft_created',
2211 'suggestion_created');
2213 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2216 CREATE VIEW "timeline_issue" AS
2217 SELECT
2218 "created" AS "occurrence",
2219 'issue_created'::"timeline_event" AS "event",
2220 "id" AS "issue_id"
2221 FROM "issue"
2222 UNION ALL
2223 SELECT
2224 "closed" AS "occurrence",
2225 'issue_canceled'::"timeline_event" AS "event",
2226 "id" AS "issue_id"
2227 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2228 UNION ALL
2229 SELECT
2230 "accepted" AS "occurrence",
2231 'issue_accepted'::"timeline_event" AS "event",
2232 "id" AS "issue_id"
2233 FROM "issue" WHERE "accepted" NOTNULL
2234 UNION ALL
2235 SELECT
2236 "half_frozen" AS "occurrence",
2237 'issue_half_frozen'::"timeline_event" AS "event",
2238 "id" AS "issue_id"
2239 FROM "issue" WHERE "half_frozen" NOTNULL
2240 UNION ALL
2241 SELECT
2242 "fully_frozen" AS "occurrence",
2243 'issue_voting_started'::"timeline_event" AS "event",
2244 "id" AS "issue_id"
2245 FROM "issue"
2246 WHERE "fully_frozen" NOTNULL
2247 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2248 UNION ALL
2249 SELECT
2250 "closed" AS "occurrence",
2251 CASE WHEN "fully_frozen" = "closed" THEN
2252 'issue_finished_without_voting'::"timeline_event"
2253 ELSE
2254 'issue_finished_after_voting'::"timeline_event"
2255 END AS "event",
2256 "id" AS "issue_id"
2257 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2259 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2262 CREATE VIEW "timeline_initiative" AS
2263 SELECT
2264 "created" AS "occurrence",
2265 'initiative_created'::"timeline_event" AS "event",
2266 "id" AS "initiative_id"
2267 FROM "initiative"
2268 UNION ALL
2269 SELECT
2270 "revoked" AS "occurrence",
2271 'initiative_revoked'::"timeline_event" AS "event",
2272 "id" AS "initiative_id"
2273 FROM "initiative" WHERE "revoked" NOTNULL;
2275 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2278 CREATE VIEW "timeline_draft" AS
2279 SELECT
2280 "created" AS "occurrence",
2281 'draft_created'::"timeline_event" AS "event",
2282 "id" AS "draft_id"
2283 FROM "draft";
2285 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2288 CREATE VIEW "timeline_suggestion" AS
2289 SELECT
2290 "created" AS "occurrence",
2291 'suggestion_created'::"timeline_event" AS "event",
2292 "id" AS "suggestion_id"
2293 FROM "suggestion";
2295 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2298 CREATE VIEW "timeline" AS
2299 SELECT
2300 "occurrence",
2301 "event",
2302 "issue_id",
2303 NULL AS "initiative_id",
2304 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2305 NULL::INT8 AS "suggestion_id"
2306 FROM "timeline_issue"
2307 UNION ALL
2308 SELECT
2309 "occurrence",
2310 "event",
2311 NULL AS "issue_id",
2312 "initiative_id",
2313 NULL AS "draft_id",
2314 NULL AS "suggestion_id"
2315 FROM "timeline_initiative"
2316 UNION ALL
2317 SELECT
2318 "occurrence",
2319 "event",
2320 NULL AS "issue_id",
2321 NULL AS "initiative_id",
2322 "draft_id",
2323 NULL AS "suggestion_id"
2324 FROM "timeline_draft"
2325 UNION ALL
2326 SELECT
2327 "occurrence",
2328 "event",
2329 NULL AS "issue_id",
2330 NULL AS "initiative_id",
2331 NULL AS "draft_id",
2332 "suggestion_id"
2333 FROM "timeline_suggestion";
2335 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2339 --------------------------------------------------
2340 -- Set returning function for delegation chains --
2341 --------------------------------------------------
2344 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2345 ('first', 'intermediate', 'last', 'repetition');
2347 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2350 CREATE TYPE "delegation_chain_row" AS (
2351 "index" INT4,
2352 "member_id" INT4,
2353 "member_valid" BOOLEAN,
2354 "participation" BOOLEAN,
2355 "overridden" BOOLEAN,
2356 "scope_in" "delegation_scope",
2357 "scope_out" "delegation_scope",
2358 "disabled_out" BOOLEAN,
2359 "loop" "delegation_chain_loop_tag" );
2361 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2363 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2364 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';
2365 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2366 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2367 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2368 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2369 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2372 CREATE FUNCTION "delegation_chain"
2373 ( "member_id_p" "member"."id"%TYPE,
2374 "unit_id_p" "unit"."id"%TYPE,
2375 "area_id_p" "area"."id"%TYPE,
2376 "issue_id_p" "issue"."id"%TYPE,
2377 "simulate_trustee_id_p" "member"."id"%TYPE )
2378 RETURNS SETOF "delegation_chain_row"
2379 LANGUAGE 'plpgsql' STABLE AS $$
2380 DECLARE
2381 "scope_v" "delegation_scope";
2382 "unit_id_v" "unit"."id"%TYPE;
2383 "area_id_v" "area"."id"%TYPE;
2384 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2385 "loop_member_id_v" "member"."id"%TYPE;
2386 "output_row" "delegation_chain_row";
2387 "output_rows" "delegation_chain_row"[];
2388 "delegation_row" "delegation"%ROWTYPE;
2389 "row_count" INT4;
2390 "i" INT4;
2391 "loop_v" BOOLEAN;
2392 BEGIN
2393 IF
2394 "unit_id_p" NOTNULL AND
2395 "area_id_p" ISNULL AND
2396 "issue_id_p" ISNULL
2397 THEN
2398 "scope_v" := 'unit';
2399 "unit_id_v" := "unit_id_p";
2400 ELSIF
2401 "unit_id_p" ISNULL AND
2402 "area_id_p" NOTNULL AND
2403 "issue_id_p" ISNULL
2404 THEN
2405 "scope_v" := 'area';
2406 "area_id_v" := "area_id_p";
2407 SELECT "unit_id" INTO "unit_id_v"
2408 FROM "area" WHERE "id" = "area_id_v";
2409 ELSIF
2410 "unit_id_p" ISNULL AND
2411 "area_id_p" ISNULL AND
2412 "issue_id_p" NOTNULL
2413 THEN
2414 "scope_v" := 'issue';
2415 SELECT "area_id" INTO "area_id_v"
2416 FROM "issue" WHERE "id" = "issue_id_p";
2417 SELECT "unit_id" INTO "unit_id_v"
2418 FROM "area" WHERE "id" = "area_id_v";
2419 ELSE
2420 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2421 END IF;
2422 "visited_member_ids" := '{}';
2423 "loop_member_id_v" := NULL;
2424 "output_rows" := '{}';
2425 "output_row"."index" := 0;
2426 "output_row"."member_id" := "member_id_p";
2427 "output_row"."member_valid" := TRUE;
2428 "output_row"."participation" := FALSE;
2429 "output_row"."overridden" := FALSE;
2430 "output_row"."disabled_out" := FALSE;
2431 "output_row"."scope_out" := NULL;
2432 LOOP
2433 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2434 "loop_member_id_v" := "output_row"."member_id";
2435 ELSE
2436 "visited_member_ids" :=
2437 "visited_member_ids" || "output_row"."member_id";
2438 END IF;
2439 IF "output_row"."participation" THEN
2440 "output_row"."overridden" := TRUE;
2441 END IF;
2442 "output_row"."scope_in" := "output_row"."scope_out";
2443 IF EXISTS (
2444 SELECT NULL FROM "member" JOIN "privilege"
2445 ON "privilege"."member_id" = "member"."id"
2446 AND "privilege"."unit_id" = "unit_id_v"
2447 WHERE "id" = "output_row"."member_id"
2448 AND "member"."active" AND "privilege"."voting_right"
2449 ) THEN
2450 IF "scope_v" = 'unit' THEN
2451 SELECT * INTO "delegation_row" FROM "delegation"
2452 WHERE "truster_id" = "output_row"."member_id"
2453 AND "unit_id" = "unit_id_v";
2454 ELSIF "scope_v" = 'area' THEN
2455 "output_row"."participation" := EXISTS (
2456 SELECT NULL FROM "membership"
2457 WHERE "area_id" = "area_id_p"
2458 AND "member_id" = "output_row"."member_id"
2459 );
2460 SELECT * INTO "delegation_row" FROM "delegation"
2461 WHERE "truster_id" = "output_row"."member_id"
2462 AND (
2463 "unit_id" = "unit_id_v" OR
2464 "area_id" = "area_id_v"
2466 ORDER BY "scope" DESC;
2467 ELSIF "scope_v" = 'issue' THEN
2468 "output_row"."participation" := EXISTS (
2469 SELECT NULL FROM "interest"
2470 WHERE "issue_id" = "issue_id_p"
2471 AND "member_id" = "output_row"."member_id"
2472 );
2473 SELECT * INTO "delegation_row" FROM "delegation"
2474 WHERE "truster_id" = "output_row"."member_id"
2475 AND (
2476 "unit_id" = "unit_id_v" OR
2477 "area_id" = "area_id_v" OR
2478 "issue_id" = "issue_id_p"
2480 ORDER BY "scope" DESC;
2481 END IF;
2482 ELSE
2483 "output_row"."member_valid" := FALSE;
2484 "output_row"."participation" := FALSE;
2485 "output_row"."scope_out" := NULL;
2486 "delegation_row" := ROW(NULL);
2487 END IF;
2488 IF
2489 "output_row"."member_id" = "member_id_p" AND
2490 "simulate_trustee_id_p" NOTNULL
2491 THEN
2492 "output_row"."scope_out" := "scope_v";
2493 "output_rows" := "output_rows" || "output_row";
2494 "output_row"."member_id" := "simulate_trustee_id_p";
2495 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2496 "output_row"."scope_out" := "delegation_row"."scope";
2497 "output_rows" := "output_rows" || "output_row";
2498 "output_row"."member_id" := "delegation_row"."trustee_id";
2499 ELSIF "delegation_row"."scope" NOTNULL THEN
2500 "output_row"."scope_out" := "delegation_row"."scope";
2501 "output_row"."disabled_out" := TRUE;
2502 "output_rows" := "output_rows" || "output_row";
2503 EXIT;
2504 ELSE
2505 "output_row"."scope_out" := NULL;
2506 "output_rows" := "output_rows" || "output_row";
2507 EXIT;
2508 END IF;
2509 EXIT WHEN "loop_member_id_v" NOTNULL;
2510 "output_row"."index" := "output_row"."index" + 1;
2511 END LOOP;
2512 "row_count" := array_upper("output_rows", 1);
2513 "i" := 1;
2514 "loop_v" := FALSE;
2515 LOOP
2516 "output_row" := "output_rows"["i"];
2517 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2518 IF "loop_v" THEN
2519 IF "i" + 1 = "row_count" THEN
2520 "output_row"."loop" := 'last';
2521 ELSIF "i" = "row_count" THEN
2522 "output_row"."loop" := 'repetition';
2523 ELSE
2524 "output_row"."loop" := 'intermediate';
2525 END IF;
2526 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2527 "output_row"."loop" := 'first';
2528 "loop_v" := TRUE;
2529 END IF;
2530 IF "scope_v" = 'unit' THEN
2531 "output_row"."participation" := NULL;
2532 END IF;
2533 RETURN NEXT "output_row";
2534 "i" := "i" + 1;
2535 END LOOP;
2536 RETURN;
2537 END;
2538 $$;
2540 COMMENT ON FUNCTION "delegation_chain"
2541 ( "member"."id"%TYPE,
2542 "unit"."id"%TYPE,
2543 "area"."id"%TYPE,
2544 "issue"."id"%TYPE,
2545 "member"."id"%TYPE )
2546 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2549 CREATE FUNCTION "delegation_chain"
2550 ( "member_id_p" "member"."id"%TYPE,
2551 "unit_id_p" "unit"."id"%TYPE,
2552 "area_id_p" "area"."id"%TYPE,
2553 "issue_id_p" "issue"."id"%TYPE )
2554 RETURNS SETOF "delegation_chain_row"
2555 LANGUAGE 'plpgsql' STABLE AS $$
2556 DECLARE
2557 "result_row" "delegation_chain_row";
2558 BEGIN
2559 FOR "result_row" IN
2560 SELECT * FROM "delegation_chain"(
2561 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2563 LOOP
2564 RETURN NEXT "result_row";
2565 END LOOP;
2566 RETURN;
2567 END;
2568 $$;
2570 COMMENT ON FUNCTION "delegation_chain"
2571 ( "member"."id"%TYPE,
2572 "unit"."id"%TYPE,
2573 "area"."id"%TYPE,
2574 "issue"."id"%TYPE )
2575 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2579 ------------------------------
2580 -- Comparison by vote count --
2581 ------------------------------
2583 CREATE FUNCTION "vote_ratio"
2584 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2585 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2586 RETURNS FLOAT8
2587 LANGUAGE 'plpgsql' STABLE AS $$
2588 BEGIN
2589 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2590 RETURN
2591 "positive_votes_p"::FLOAT8 /
2592 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2593 ELSIF "positive_votes_p" > 0 THEN
2594 RETURN "positive_votes_p";
2595 ELSIF "negative_votes_p" > 0 THEN
2596 RETURN 1 - "negative_votes_p";
2597 ELSE
2598 RETURN 0.5;
2599 END IF;
2600 END;
2601 $$;
2603 COMMENT ON FUNCTION "vote_ratio"
2604 ( "initiative"."positive_votes"%TYPE,
2605 "initiative"."negative_votes"%TYPE )
2606 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.';
2610 ------------------------------------------------
2611 -- Locking for snapshots and voting procedure --
2612 ------------------------------------------------
2615 CREATE FUNCTION "share_row_lock_issue_trigger"()
2616 RETURNS TRIGGER
2617 LANGUAGE 'plpgsql' VOLATILE AS $$
2618 BEGIN
2619 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2620 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2621 END IF;
2622 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2623 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2624 RETURN NEW;
2625 ELSE
2626 RETURN OLD;
2627 END IF;
2628 END;
2629 $$;
2631 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2634 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2635 RETURNS TRIGGER
2636 LANGUAGE 'plpgsql' VOLATILE AS $$
2637 BEGIN
2638 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2639 PERFORM NULL FROM "issue"
2640 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2641 WHERE "initiative"."id" = OLD."initiative_id"
2642 FOR SHARE OF "issue";
2643 END IF;
2644 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2645 PERFORM NULL FROM "issue"
2646 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2647 WHERE "initiative"."id" = NEW."initiative_id"
2648 FOR SHARE OF "issue";
2649 RETURN NEW;
2650 ELSE
2651 RETURN OLD;
2652 END IF;
2653 END;
2654 $$;
2656 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2659 CREATE TRIGGER "share_row_lock_issue"
2660 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2661 FOR EACH ROW EXECUTE PROCEDURE
2662 "share_row_lock_issue_trigger"();
2664 CREATE TRIGGER "share_row_lock_issue"
2665 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2666 FOR EACH ROW EXECUTE PROCEDURE
2667 "share_row_lock_issue_trigger"();
2669 CREATE TRIGGER "share_row_lock_issue"
2670 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2671 FOR EACH ROW EXECUTE PROCEDURE
2672 "share_row_lock_issue_trigger"();
2674 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2675 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2676 FOR EACH ROW EXECUTE PROCEDURE
2677 "share_row_lock_issue_via_initiative_trigger"();
2679 CREATE TRIGGER "share_row_lock_issue"
2680 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2681 FOR EACH ROW EXECUTE PROCEDURE
2682 "share_row_lock_issue_trigger"();
2684 CREATE TRIGGER "share_row_lock_issue"
2685 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2686 FOR EACH ROW EXECUTE PROCEDURE
2687 "share_row_lock_issue_trigger"();
2689 CREATE TRIGGER "share_row_lock_issue"
2690 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2691 FOR EACH ROW EXECUTE PROCEDURE
2692 "share_row_lock_issue_trigger"();
2694 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2695 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2696 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2697 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2698 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2699 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2700 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2703 CREATE FUNCTION "lock_issue"
2704 ( "issue_id_p" "issue"."id"%TYPE )
2705 RETURNS VOID
2706 LANGUAGE 'plpgsql' VOLATILE AS $$
2707 BEGIN
2708 LOCK TABLE "member" IN SHARE MODE;
2709 LOCK TABLE "privilege" IN SHARE MODE;
2710 LOCK TABLE "membership" IN SHARE MODE;
2711 LOCK TABLE "policy" IN SHARE MODE;
2712 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2713 -- NOTE: The row-level exclusive lock in combination with the
2714 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2715 -- acquire a row-level share lock on the issue) ensure that no data
2716 -- is changed, which could affect calculation of snapshots or
2717 -- counting of votes. Table "delegation" must be table-level-locked,
2718 -- as it also contains issue- and global-scope delegations.
2719 LOCK TABLE "delegation" IN SHARE MODE;
2720 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2721 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2722 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2723 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2724 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2725 RETURN;
2726 END;
2727 $$;
2729 COMMENT ON FUNCTION "lock_issue"
2730 ( "issue"."id"%TYPE )
2731 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2735 ------------------------------------------------------------------------
2736 -- Regular tasks, except calculcation of snapshots and voting results --
2737 ------------------------------------------------------------------------
2739 CREATE FUNCTION "check_activity"()
2740 RETURNS VOID
2741 LANGUAGE 'plpgsql' VOLATILE AS $$
2742 DECLARE
2743 "system_setting_row" "system_setting"%ROWTYPE;
2744 BEGIN
2745 SELECT * INTO "system_setting_row" FROM "system_setting";
2746 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2747 IF "system_setting_row"."member_ttl" NOTNULL THEN
2748 UPDATE "member" SET "active" = FALSE
2749 WHERE "active" = TRUE
2750 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2751 END IF;
2752 RETURN;
2753 END;
2754 $$;
2756 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2759 CREATE FUNCTION "calculate_member_counts"()
2760 RETURNS VOID
2761 LANGUAGE 'plpgsql' VOLATILE AS $$
2762 BEGIN
2763 LOCK TABLE "member" IN SHARE MODE;
2764 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2765 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2766 LOCK TABLE "area" IN EXCLUSIVE MODE;
2767 LOCK TABLE "privilege" IN SHARE MODE;
2768 LOCK TABLE "membership" IN SHARE MODE;
2769 DELETE FROM "member_count";
2770 INSERT INTO "member_count" ("total_count")
2771 SELECT "total_count" FROM "member_count_view";
2772 UPDATE "unit" SET "member_count" = "view"."member_count"
2773 FROM "unit_member_count" AS "view"
2774 WHERE "view"."unit_id" = "unit"."id";
2775 UPDATE "area" SET
2776 "direct_member_count" = "view"."direct_member_count",
2777 "member_weight" = "view"."member_weight"
2778 FROM "area_member_count" AS "view"
2779 WHERE "view"."area_id" = "area"."id";
2780 RETURN;
2781 END;
2782 $$;
2784 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"';
2788 ------------------------------
2789 -- Calculation of snapshots --
2790 ------------------------------
2792 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2793 ( "issue_id_p" "issue"."id"%TYPE,
2794 "member_id_p" "member"."id"%TYPE,
2795 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2796 RETURNS "direct_population_snapshot"."weight"%TYPE
2797 LANGUAGE 'plpgsql' VOLATILE AS $$
2798 DECLARE
2799 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2800 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2801 "weight_v" INT4;
2802 "sub_weight_v" INT4;
2803 BEGIN
2804 "weight_v" := 0;
2805 FOR "issue_delegation_row" IN
2806 SELECT * FROM "issue_delegation"
2807 WHERE "trustee_id" = "member_id_p"
2808 AND "issue_id" = "issue_id_p"
2809 LOOP
2810 IF NOT EXISTS (
2811 SELECT NULL FROM "direct_population_snapshot"
2812 WHERE "issue_id" = "issue_id_p"
2813 AND "event" = 'periodic'
2814 AND "member_id" = "issue_delegation_row"."truster_id"
2815 ) AND NOT EXISTS (
2816 SELECT NULL FROM "delegating_population_snapshot"
2817 WHERE "issue_id" = "issue_id_p"
2818 AND "event" = 'periodic'
2819 AND "member_id" = "issue_delegation_row"."truster_id"
2820 ) THEN
2821 "delegate_member_ids_v" :=
2822 "member_id_p" || "delegate_member_ids_p";
2823 INSERT INTO "delegating_population_snapshot" (
2824 "issue_id",
2825 "event",
2826 "member_id",
2827 "scope",
2828 "delegate_member_ids"
2829 ) VALUES (
2830 "issue_id_p",
2831 'periodic',
2832 "issue_delegation_row"."truster_id",
2833 "issue_delegation_row"."scope",
2834 "delegate_member_ids_v"
2835 );
2836 "sub_weight_v" := 1 +
2837 "weight_of_added_delegations_for_population_snapshot"(
2838 "issue_id_p",
2839 "issue_delegation_row"."truster_id",
2840 "delegate_member_ids_v"
2841 );
2842 UPDATE "delegating_population_snapshot"
2843 SET "weight" = "sub_weight_v"
2844 WHERE "issue_id" = "issue_id_p"
2845 AND "event" = 'periodic'
2846 AND "member_id" = "issue_delegation_row"."truster_id";
2847 "weight_v" := "weight_v" + "sub_weight_v";
2848 END IF;
2849 END LOOP;
2850 RETURN "weight_v";
2851 END;
2852 $$;
2854 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2855 ( "issue"."id"%TYPE,
2856 "member"."id"%TYPE,
2857 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2858 IS 'Helper function for "create_population_snapshot" function';
2861 CREATE FUNCTION "create_population_snapshot"
2862 ( "issue_id_p" "issue"."id"%TYPE )
2863 RETURNS VOID
2864 LANGUAGE 'plpgsql' VOLATILE AS $$
2865 DECLARE
2866 "member_id_v" "member"."id"%TYPE;
2867 BEGIN
2868 DELETE FROM "direct_population_snapshot"
2869 WHERE "issue_id" = "issue_id_p"
2870 AND "event" = 'periodic';
2871 DELETE FROM "delegating_population_snapshot"
2872 WHERE "issue_id" = "issue_id_p"
2873 AND "event" = 'periodic';
2874 INSERT INTO "direct_population_snapshot"
2875 ("issue_id", "event", "member_id")
2876 SELECT
2877 "issue_id_p" AS "issue_id",
2878 'periodic'::"snapshot_event" AS "event",
2879 "member"."id" AS "member_id"
2880 FROM "issue"
2881 JOIN "area" ON "issue"."area_id" = "area"."id"
2882 JOIN "membership" ON "area"."id" = "membership"."area_id"
2883 JOIN "member" ON "membership"."member_id" = "member"."id"
2884 JOIN "privilege"
2885 ON "privilege"."unit_id" = "area"."unit_id"
2886 AND "privilege"."member_id" = "member"."id"
2887 WHERE "issue"."id" = "issue_id_p"
2888 AND "member"."active" AND "privilege"."voting_right"
2889 UNION
2890 SELECT
2891 "issue_id_p" AS "issue_id",
2892 'periodic'::"snapshot_event" AS "event",
2893 "member"."id" AS "member_id"
2894 FROM "issue"
2895 JOIN "area" ON "issue"."area_id" = "area"."id"
2896 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2897 JOIN "member" ON "interest"."member_id" = "member"."id"
2898 JOIN "privilege"
2899 ON "privilege"."unit_id" = "area"."unit_id"
2900 AND "privilege"."member_id" = "member"."id"
2901 WHERE "issue"."id" = "issue_id_p"
2902 AND "member"."active" AND "privilege"."voting_right";
2903 FOR "member_id_v" IN
2904 SELECT "member_id" FROM "direct_population_snapshot"
2905 WHERE "issue_id" = "issue_id_p"
2906 AND "event" = 'periodic'
2907 LOOP
2908 UPDATE "direct_population_snapshot" SET
2909 "weight" = 1 +
2910 "weight_of_added_delegations_for_population_snapshot"(
2911 "issue_id_p",
2912 "member_id_v",
2913 '{}'
2915 WHERE "issue_id" = "issue_id_p"
2916 AND "event" = 'periodic'
2917 AND "member_id" = "member_id_v";
2918 END LOOP;
2919 RETURN;
2920 END;
2921 $$;
2923 COMMENT ON FUNCTION "create_population_snapshot"
2924 ( "issue"."id"%TYPE )
2925 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.';
2928 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2929 ( "issue_id_p" "issue"."id"%TYPE,
2930 "member_id_p" "member"."id"%TYPE,
2931 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2932 RETURNS "direct_interest_snapshot"."weight"%TYPE
2933 LANGUAGE 'plpgsql' VOLATILE AS $$
2934 DECLARE
2935 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2936 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2937 "weight_v" INT4;
2938 "sub_weight_v" INT4;
2939 BEGIN
2940 "weight_v" := 0;
2941 FOR "issue_delegation_row" IN
2942 SELECT * FROM "issue_delegation"
2943 WHERE "trustee_id" = "member_id_p"
2944 AND "issue_id" = "issue_id_p"
2945 LOOP
2946 IF NOT EXISTS (
2947 SELECT NULL FROM "direct_interest_snapshot"
2948 WHERE "issue_id" = "issue_id_p"
2949 AND "event" = 'periodic'
2950 AND "member_id" = "issue_delegation_row"."truster_id"
2951 ) AND NOT EXISTS (
2952 SELECT NULL FROM "delegating_interest_snapshot"
2953 WHERE "issue_id" = "issue_id_p"
2954 AND "event" = 'periodic'
2955 AND "member_id" = "issue_delegation_row"."truster_id"
2956 ) THEN
2957 "delegate_member_ids_v" :=
2958 "member_id_p" || "delegate_member_ids_p";
2959 INSERT INTO "delegating_interest_snapshot" (
2960 "issue_id",
2961 "event",
2962 "member_id",
2963 "scope",
2964 "delegate_member_ids"
2965 ) VALUES (
2966 "issue_id_p",
2967 'periodic',
2968 "issue_delegation_row"."truster_id",
2969 "issue_delegation_row"."scope",
2970 "delegate_member_ids_v"
2971 );
2972 "sub_weight_v" := 1 +
2973 "weight_of_added_delegations_for_interest_snapshot"(
2974 "issue_id_p",
2975 "issue_delegation_row"."truster_id",
2976 "delegate_member_ids_v"
2977 );
2978 UPDATE "delegating_interest_snapshot"
2979 SET "weight" = "sub_weight_v"
2980 WHERE "issue_id" = "issue_id_p"
2981 AND "event" = 'periodic'
2982 AND "member_id" = "issue_delegation_row"."truster_id";
2983 "weight_v" := "weight_v" + "sub_weight_v";
2984 END IF;
2985 END LOOP;
2986 RETURN "weight_v";
2987 END;
2988 $$;
2990 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2991 ( "issue"."id"%TYPE,
2992 "member"."id"%TYPE,
2993 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2994 IS 'Helper function for "create_interest_snapshot" function';
2997 CREATE FUNCTION "create_interest_snapshot"
2998 ( "issue_id_p" "issue"."id"%TYPE )
2999 RETURNS VOID
3000 LANGUAGE 'plpgsql' VOLATILE AS $$
3001 DECLARE
3002 "member_id_v" "member"."id"%TYPE;
3003 BEGIN
3004 DELETE FROM "direct_interest_snapshot"
3005 WHERE "issue_id" = "issue_id_p"
3006 AND "event" = 'periodic';
3007 DELETE FROM "delegating_interest_snapshot"
3008 WHERE "issue_id" = "issue_id_p"
3009 AND "event" = 'periodic';
3010 DELETE FROM "direct_supporter_snapshot"
3011 WHERE "issue_id" = "issue_id_p"
3012 AND "event" = 'periodic';
3013 INSERT INTO "direct_interest_snapshot"
3014 ("issue_id", "event", "member_id")
3015 SELECT
3016 "issue_id_p" AS "issue_id",
3017 'periodic' AS "event",
3018 "member"."id" AS "member_id"
3019 FROM "issue"
3020 JOIN "area" ON "issue"."area_id" = "area"."id"
3021 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3022 JOIN "member" ON "interest"."member_id" = "member"."id"
3023 JOIN "privilege"
3024 ON "privilege"."unit_id" = "area"."unit_id"
3025 AND "privilege"."member_id" = "member"."id"
3026 WHERE "issue"."id" = "issue_id_p"
3027 AND "member"."active" AND "privilege"."voting_right";
3028 FOR "member_id_v" IN
3029 SELECT "member_id" FROM "direct_interest_snapshot"
3030 WHERE "issue_id" = "issue_id_p"
3031 AND "event" = 'periodic'
3032 LOOP
3033 UPDATE "direct_interest_snapshot" SET
3034 "weight" = 1 +
3035 "weight_of_added_delegations_for_interest_snapshot"(
3036 "issue_id_p",
3037 "member_id_v",
3038 '{}'
3040 WHERE "issue_id" = "issue_id_p"
3041 AND "event" = 'periodic'
3042 AND "member_id" = "member_id_v";
3043 END LOOP;
3044 INSERT INTO "direct_supporter_snapshot"
3045 ( "issue_id", "initiative_id", "event", "member_id",
3046 "draft_id", "informed", "satisfied" )
3047 SELECT
3048 "issue_id_p" AS "issue_id",
3049 "initiative"."id" AS "initiative_id",
3050 'periodic' AS "event",
3051 "supporter"."member_id" AS "member_id",
3052 "supporter"."draft_id" AS "draft_id",
3053 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3054 NOT EXISTS (
3055 SELECT NULL FROM "critical_opinion"
3056 WHERE "initiative_id" = "initiative"."id"
3057 AND "member_id" = "supporter"."member_id"
3058 ) AS "satisfied"
3059 FROM "initiative"
3060 JOIN "supporter"
3061 ON "supporter"."initiative_id" = "initiative"."id"
3062 JOIN "current_draft"
3063 ON "initiative"."id" = "current_draft"."initiative_id"
3064 JOIN "direct_interest_snapshot"
3065 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3066 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3067 AND "event" = 'periodic'
3068 WHERE "initiative"."issue_id" = "issue_id_p";
3069 RETURN;
3070 END;
3071 $$;
3073 COMMENT ON FUNCTION "create_interest_snapshot"
3074 ( "issue"."id"%TYPE )
3075 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.';
3078 CREATE FUNCTION "create_snapshot"
3079 ( "issue_id_p" "issue"."id"%TYPE )
3080 RETURNS VOID
3081 LANGUAGE 'plpgsql' VOLATILE AS $$
3082 DECLARE
3083 "initiative_id_v" "initiative"."id"%TYPE;
3084 "suggestion_id_v" "suggestion"."id"%TYPE;
3085 BEGIN
3086 PERFORM "lock_issue"("issue_id_p");
3087 PERFORM "create_population_snapshot"("issue_id_p");
3088 PERFORM "create_interest_snapshot"("issue_id_p");
3089 UPDATE "issue" SET
3090 "snapshot" = now(),
3091 "latest_snapshot_event" = 'periodic',
3092 "population" = (
3093 SELECT coalesce(sum("weight"), 0)
3094 FROM "direct_population_snapshot"
3095 WHERE "issue_id" = "issue_id_p"
3096 AND "event" = 'periodic'
3098 WHERE "id" = "issue_id_p";
3099 FOR "initiative_id_v" IN
3100 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3101 LOOP
3102 UPDATE "initiative" SET
3103 "supporter_count" = (
3104 SELECT coalesce(sum("di"."weight"), 0)
3105 FROM "direct_interest_snapshot" AS "di"
3106 JOIN "direct_supporter_snapshot" AS "ds"
3107 ON "di"."member_id" = "ds"."member_id"
3108 WHERE "di"."issue_id" = "issue_id_p"
3109 AND "di"."event" = 'periodic'
3110 AND "ds"."initiative_id" = "initiative_id_v"
3111 AND "ds"."event" = 'periodic'
3112 ),
3113 "informed_supporter_count" = (
3114 SELECT coalesce(sum("di"."weight"), 0)
3115 FROM "direct_interest_snapshot" AS "di"
3116 JOIN "direct_supporter_snapshot" AS "ds"
3117 ON "di"."member_id" = "ds"."member_id"
3118 WHERE "di"."issue_id" = "issue_id_p"
3119 AND "di"."event" = 'periodic'
3120 AND "ds"."initiative_id" = "initiative_id_v"
3121 AND "ds"."event" = 'periodic'
3122 AND "ds"."informed"
3123 ),
3124 "satisfied_supporter_count" = (
3125 SELECT coalesce(sum("di"."weight"), 0)
3126 FROM "direct_interest_snapshot" AS "di"
3127 JOIN "direct_supporter_snapshot" AS "ds"
3128 ON "di"."member_id" = "ds"."member_id"
3129 WHERE "di"."issue_id" = "issue_id_p"
3130 AND "di"."event" = 'periodic'
3131 AND "ds"."initiative_id" = "initiative_id_v"
3132 AND "ds"."event" = 'periodic'
3133 AND "ds"."satisfied"
3134 ),
3135 "satisfied_informed_supporter_count" = (
3136 SELECT coalesce(sum("di"."weight"), 0)
3137 FROM "direct_interest_snapshot" AS "di"
3138 JOIN "direct_supporter_snapshot" AS "ds"
3139 ON "di"."member_id" = "ds"."member_id"
3140 WHERE "di"."issue_id" = "issue_id_p"
3141 AND "di"."event" = 'periodic'
3142 AND "ds"."initiative_id" = "initiative_id_v"
3143 AND "ds"."event" = 'periodic'
3144 AND "ds"."informed"
3145 AND "ds"."satisfied"
3147 WHERE "id" = "initiative_id_v";
3148 FOR "suggestion_id_v" IN
3149 SELECT "id" FROM "suggestion"
3150 WHERE "initiative_id" = "initiative_id_v"
3151 LOOP
3152 UPDATE "suggestion" SET
3153 "minus2_unfulfilled_count" = (
3154 SELECT coalesce(sum("snapshot"."weight"), 0)
3155 FROM "issue" CROSS JOIN "opinion"
3156 JOIN "direct_interest_snapshot" AS "snapshot"
3157 ON "snapshot"."issue_id" = "issue"."id"
3158 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3159 AND "snapshot"."member_id" = "opinion"."member_id"
3160 WHERE "issue"."id" = "issue_id_p"
3161 AND "opinion"."suggestion_id" = "suggestion_id_v"
3162 AND "opinion"."degree" = -2
3163 AND "opinion"."fulfilled" = FALSE
3164 ),
3165 "minus2_fulfilled_count" = (
3166 SELECT coalesce(sum("snapshot"."weight"), 0)
3167 FROM "issue" CROSS JOIN "opinion"
3168 JOIN "direct_interest_snapshot" AS "snapshot"
3169 ON "snapshot"."issue_id" = "issue"."id"
3170 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3171 AND "snapshot"."member_id" = "opinion"."member_id"
3172 WHERE "issue"."id" = "issue_id_p"
3173 AND "opinion"."suggestion_id" = "suggestion_id_v"
3174 AND "opinion"."degree" = -2
3175 AND "opinion"."fulfilled" = TRUE
3176 ),
3177 "minus1_unfulfilled_count" = (
3178 SELECT coalesce(sum("snapshot"."weight"), 0)
3179 FROM "issue" CROSS JOIN "opinion"
3180 JOIN "direct_interest_snapshot" AS "snapshot"
3181 ON "snapshot"."issue_id" = "issue"."id"
3182 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3183 AND "snapshot"."member_id" = "opinion"."member_id"
3184 WHERE "issue"."id" = "issue_id_p"
3185 AND "opinion"."suggestion_id" = "suggestion_id_v"
3186 AND "opinion"."degree" = -1
3187 AND "opinion"."fulfilled" = FALSE
3188 ),
3189 "minus1_fulfilled_count" = (
3190 SELECT coalesce(sum("snapshot"."weight"), 0)
3191 FROM "issue" CROSS JOIN "opinion"
3192 JOIN "direct_interest_snapshot" AS "snapshot"
3193 ON "snapshot"."issue_id" = "issue"."id"
3194 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3195 AND "snapshot"."member_id" = "opinion"."member_id"
3196 WHERE "issue"."id" = "issue_id_p"
3197 AND "opinion"."suggestion_id" = "suggestion_id_v"
3198 AND "opinion"."degree" = -1
3199 AND "opinion"."fulfilled" = TRUE
3200 ),
3201 "plus1_unfulfilled_count" = (
3202 SELECT coalesce(sum("snapshot"."weight"), 0)
3203 FROM "issue" CROSS JOIN "opinion"
3204 JOIN "direct_interest_snapshot" AS "snapshot"
3205 ON "snapshot"."issue_id" = "issue"."id"
3206 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3207 AND "snapshot"."member_id" = "opinion"."member_id"
3208 WHERE "issue"."id" = "issue_id_p"
3209 AND "opinion"."suggestion_id" = "suggestion_id_v"
3210 AND "opinion"."degree" = 1
3211 AND "opinion"."fulfilled" = FALSE
3212 ),
3213 "plus1_fulfilled_count" = (
3214 SELECT coalesce(sum("snapshot"."weight"), 0)
3215 FROM "issue" CROSS JOIN "opinion"
3216 JOIN "direct_interest_snapshot" AS "snapshot"
3217 ON "snapshot"."issue_id" = "issue"."id"
3218 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3219 AND "snapshot"."member_id" = "opinion"."member_id"
3220 WHERE "issue"."id" = "issue_id_p"
3221 AND "opinion"."suggestion_id" = "suggestion_id_v"
3222 AND "opinion"."degree" = 1
3223 AND "opinion"."fulfilled" = TRUE
3224 ),
3225 "plus2_unfulfilled_count" = (
3226 SELECT coalesce(sum("snapshot"."weight"), 0)
3227 FROM "issue" CROSS JOIN "opinion"
3228 JOIN "direct_interest_snapshot" AS "snapshot"
3229 ON "snapshot"."issue_id" = "issue"."id"
3230 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3231 AND "snapshot"."member_id" = "opinion"."member_id"
3232 WHERE "issue"."id" = "issue_id_p"
3233 AND "opinion"."suggestion_id" = "suggestion_id_v"
3234 AND "opinion"."degree" = 2
3235 AND "opinion"."fulfilled" = FALSE
3236 ),
3237 "plus2_fulfilled_count" = (
3238 SELECT coalesce(sum("snapshot"."weight"), 0)
3239 FROM "issue" CROSS JOIN "opinion"
3240 JOIN "direct_interest_snapshot" AS "snapshot"
3241 ON "snapshot"."issue_id" = "issue"."id"
3242 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3243 AND "snapshot"."member_id" = "opinion"."member_id"
3244 WHERE "issue"."id" = "issue_id_p"
3245 AND "opinion"."suggestion_id" = "suggestion_id_v"
3246 AND "opinion"."degree" = 2
3247 AND "opinion"."fulfilled" = TRUE
3249 WHERE "suggestion"."id" = "suggestion_id_v";
3250 END LOOP;
3251 END LOOP;
3252 RETURN;
3253 END;
3254 $$;
3256 COMMENT ON FUNCTION "create_snapshot"
3257 ( "issue"."id"%TYPE )
3258 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.';
3261 CREATE FUNCTION "set_snapshot_event"
3262 ( "issue_id_p" "issue"."id"%TYPE,
3263 "event_p" "snapshot_event" )
3264 RETURNS VOID
3265 LANGUAGE 'plpgsql' VOLATILE AS $$
3266 DECLARE
3267 "event_v" "issue"."latest_snapshot_event"%TYPE;
3268 BEGIN
3269 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3270 WHERE "id" = "issue_id_p" FOR UPDATE;
3271 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3272 WHERE "id" = "issue_id_p";
3273 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3274 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3275 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3276 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3277 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3278 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3279 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3280 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3281 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3282 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3283 RETURN;
3284 END;
3285 $$;
3287 COMMENT ON FUNCTION "set_snapshot_event"
3288 ( "issue"."id"%TYPE,
3289 "snapshot_event" )
3290 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3294 ---------------------
3295 -- Freezing issues --
3296 ---------------------
3298 CREATE FUNCTION "freeze_after_snapshot"
3299 ( "issue_id_p" "issue"."id"%TYPE )
3300 RETURNS VOID
3301 LANGUAGE 'plpgsql' VOLATILE AS $$
3302 DECLARE
3303 "issue_row" "issue"%ROWTYPE;
3304 "policy_row" "policy"%ROWTYPE;
3305 "initiative_row" "initiative"%ROWTYPE;
3306 BEGIN
3307 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3308 SELECT * INTO "policy_row"
3309 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3310 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3311 FOR "initiative_row" IN
3312 SELECT * FROM "initiative"
3313 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3314 LOOP
3315 IF
3316 "initiative_row"."satisfied_supporter_count" > 0 AND
3317 "initiative_row"."satisfied_supporter_count" *
3318 "policy_row"."initiative_quorum_den" >=
3319 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3320 THEN
3321 UPDATE "initiative" SET "admitted" = TRUE
3322 WHERE "id" = "initiative_row"."id";
3323 ELSE
3324 UPDATE "initiative" SET "admitted" = FALSE
3325 WHERE "id" = "initiative_row"."id";
3326 END IF;
3327 END LOOP;
3328 IF EXISTS (
3329 SELECT NULL FROM "initiative"
3330 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3331 ) THEN
3332 UPDATE "issue" SET
3333 "state" = 'voting',
3334 "accepted" = coalesce("accepted", now()),
3335 "half_frozen" = coalesce("half_frozen", now()),
3336 "fully_frozen" = now()
3337 WHERE "id" = "issue_id_p";
3338 ELSE
3339 UPDATE "issue" SET
3340 "state" = 'canceled_no_initiative_admitted',
3341 "accepted" = coalesce("accepted", now()),
3342 "half_frozen" = coalesce("half_frozen", now()),
3343 "fully_frozen" = now(),
3344 "closed" = now(),
3345 "ranks_available" = TRUE
3346 WHERE "id" = "issue_id_p";
3347 -- NOTE: The following DELETE statements have effect only when
3348 -- issue state has been manipulated
3349 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3350 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3351 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3352 END IF;
3353 RETURN;
3354 END;
3355 $$;
3357 COMMENT ON FUNCTION "freeze_after_snapshot"
3358 ( "issue"."id"%TYPE )
3359 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3362 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3363 RETURNS VOID
3364 LANGUAGE 'plpgsql' VOLATILE AS $$
3365 DECLARE
3366 "issue_row" "issue"%ROWTYPE;
3367 BEGIN
3368 PERFORM "create_snapshot"("issue_id_p");
3369 PERFORM "freeze_after_snapshot"("issue_id_p");
3370 RETURN;
3371 END;
3372 $$;
3374 COMMENT ON FUNCTION "manual_freeze"
3375 ( "issue"."id"%TYPE )
3376 IS 'Freeze an issue manually (fully) and start voting';
3380 -----------------------
3381 -- Counting of votes --
3382 -----------------------
3385 CREATE FUNCTION "weight_of_added_vote_delegations"
3386 ( "issue_id_p" "issue"."id"%TYPE,
3387 "member_id_p" "member"."id"%TYPE,
3388 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3389 RETURNS "direct_voter"."weight"%TYPE
3390 LANGUAGE 'plpgsql' VOLATILE AS $$
3391 DECLARE
3392 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3393 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3394 "weight_v" INT4;
3395 "sub_weight_v" INT4;
3396 BEGIN
3397 "weight_v" := 0;
3398 FOR "issue_delegation_row" IN
3399 SELECT * FROM "issue_delegation"
3400 WHERE "trustee_id" = "member_id_p"
3401 AND "issue_id" = "issue_id_p"
3402 LOOP
3403 IF NOT EXISTS (
3404 SELECT NULL FROM "direct_voter"
3405 WHERE "member_id" = "issue_delegation_row"."truster_id"
3406 AND "issue_id" = "issue_id_p"
3407 ) AND NOT EXISTS (
3408 SELECT NULL FROM "delegating_voter"
3409 WHERE "member_id" = "issue_delegation_row"."truster_id"
3410 AND "issue_id" = "issue_id_p"
3411 ) THEN
3412 "delegate_member_ids_v" :=
3413 "member_id_p" || "delegate_member_ids_p";
3414 INSERT INTO "delegating_voter" (
3415 "issue_id",
3416 "member_id",
3417 "scope",
3418 "delegate_member_ids"
3419 ) VALUES (
3420 "issue_id_p",
3421 "issue_delegation_row"."truster_id",
3422 "issue_delegation_row"."scope",
3423 "delegate_member_ids_v"
3424 );
3425 "sub_weight_v" := 1 +
3426 "weight_of_added_vote_delegations"(
3427 "issue_id_p",
3428 "issue_delegation_row"."truster_id",
3429 "delegate_member_ids_v"
3430 );
3431 UPDATE "delegating_voter"
3432 SET "weight" = "sub_weight_v"
3433 WHERE "issue_id" = "issue_id_p"
3434 AND "member_id" = "issue_delegation_row"."truster_id";
3435 "weight_v" := "weight_v" + "sub_weight_v";
3436 END IF;
3437 END LOOP;
3438 RETURN "weight_v";
3439 END;
3440 $$;
3442 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3443 ( "issue"."id"%TYPE,
3444 "member"."id"%TYPE,
3445 "delegating_voter"."delegate_member_ids"%TYPE )
3446 IS 'Helper function for "add_vote_delegations" function';
3449 CREATE FUNCTION "add_vote_delegations"
3450 ( "issue_id_p" "issue"."id"%TYPE )
3451 RETURNS VOID
3452 LANGUAGE 'plpgsql' VOLATILE AS $$
3453 DECLARE
3454 "member_id_v" "member"."id"%TYPE;
3455 BEGIN
3456 FOR "member_id_v" IN
3457 SELECT "member_id" FROM "direct_voter"
3458 WHERE "issue_id" = "issue_id_p"
3459 LOOP
3460 UPDATE "direct_voter" SET
3461 "weight" = "weight" + "weight_of_added_vote_delegations"(
3462 "issue_id_p",
3463 "member_id_v",
3464 '{}'
3466 WHERE "member_id" = "member_id_v"
3467 AND "issue_id" = "issue_id_p";
3468 END LOOP;
3469 RETURN;
3470 END;
3471 $$;
3473 COMMENT ON FUNCTION "add_vote_delegations"
3474 ( "issue_id_p" "issue"."id"%TYPE )
3475 IS 'Helper function for "close_voting" function';
3478 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3479 RETURNS VOID
3480 LANGUAGE 'plpgsql' VOLATILE AS $$
3481 DECLARE
3482 "area_id_v" "area"."id"%TYPE;
3483 "unit_id_v" "unit"."id"%TYPE;
3484 "member_id_v" "member"."id"%TYPE;
3485 BEGIN
3486 PERFORM "lock_issue"("issue_id_p");
3487 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3488 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3489 -- delete delegating votes (in cases of manual reset of issue state):
3490 DELETE FROM "delegating_voter"
3491 WHERE "issue_id" = "issue_id_p";
3492 -- delete votes from non-privileged voters:
3493 DELETE FROM "direct_voter"
3494 USING (
3495 SELECT
3496 "direct_voter"."member_id"
3497 FROM "direct_voter"
3498 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3499 LEFT JOIN "privilege"
3500 ON "privilege"."unit_id" = "unit_id_v"
3501 AND "privilege"."member_id" = "direct_voter"."member_id"
3502 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3503 "member"."active" = FALSE OR
3504 "privilege"."voting_right" ISNULL OR
3505 "privilege"."voting_right" = FALSE
3507 ) AS "subquery"
3508 WHERE "direct_voter"."issue_id" = "issue_id_p"
3509 AND "direct_voter"."member_id" = "subquery"."member_id";
3510 -- consider delegations:
3511 UPDATE "direct_voter" SET "weight" = 1
3512 WHERE "issue_id" = "issue_id_p";
3513 PERFORM "add_vote_delegations"("issue_id_p");
3514 -- set voter count and mark issue as being calculated:
3515 UPDATE "issue" SET
3516 "state" = 'calculation',
3517 "closed" = now(),
3518 "voter_count" = (
3519 SELECT coalesce(sum("weight"), 0)
3520 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3522 WHERE "id" = "issue_id_p";
3523 -- materialize battle_view:
3524 -- NOTE: "closed" column of issue must be set at this point
3525 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3526 INSERT INTO "battle" (
3527 "issue_id",
3528 "winning_initiative_id", "losing_initiative_id",
3529 "count"
3530 ) SELECT
3531 "issue_id",
3532 "winning_initiative_id", "losing_initiative_id",
3533 "count"
3534 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3535 -- copy "positive_votes" and "negative_votes" from "battle" table:
3536 UPDATE "initiative" SET
3537 "positive_votes" = "battle_win"."count",
3538 "negative_votes" = "battle_lose"."count"
3539 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3540 WHERE
3541 "battle_win"."issue_id" = "issue_id_p" AND
3542 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3543 "battle_win"."losing_initiative_id" ISNULL AND
3544 "battle_lose"."issue_id" = "issue_id_p" AND
3545 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3546 "battle_lose"."winning_initiative_id" ISNULL;
3547 END;
3548 $$;
3550 COMMENT ON FUNCTION "close_voting"
3551 ( "issue"."id"%TYPE )
3552 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.';
3555 CREATE FUNCTION "defeat_strength"
3556 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3557 RETURNS INT8
3558 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3559 BEGIN
3560 IF "positive_votes_p" > "negative_votes_p" THEN
3561 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3562 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3563 RETURN 0;
3564 ELSE
3565 RETURN -1;
3566 END IF;
3567 END;
3568 $$;
3570 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';
3573 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3574 RETURNS VOID
3575 LANGUAGE 'plpgsql' VOLATILE AS $$
3576 DECLARE
3577 "issue_row" "issue"%ROWTYPE;
3578 "policy_row" "policy"%ROWTYPE;
3579 "dimension_v" INTEGER;
3580 "vote_matrix" INT4[][]; -- absolute votes
3581 "matrix" INT8[][]; -- defeat strength / best paths
3582 "i" INTEGER;
3583 "j" INTEGER;
3584 "k" INTEGER;
3585 "battle_row" "battle"%ROWTYPE;
3586 "rank_ary" INT4[];
3587 "rank_v" INT4;
3588 "done_v" INTEGER;
3589 "winners_ary" INTEGER[];
3590 "initiative_id_v" "initiative"."id"%TYPE;
3591 BEGIN
3592 SELECT * INTO "issue_row"
3593 FROM "issue" WHERE "id" = "issue_id_p"
3594 FOR UPDATE;
3595 SELECT * INTO "policy_row"
3596 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3597 SELECT count(1) INTO "dimension_v"
3598 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3599 -- Create "vote_matrix" with absolute number of votes in pairwise
3600 -- comparison:
3601 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3602 "i" := 1;
3603 "j" := 2;
3604 FOR "battle_row" IN
3605 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3606 ORDER BY
3607 "winning_initiative_id" NULLS LAST,
3608 "losing_initiative_id" NULLS LAST
3609 LOOP
3610 "vote_matrix"["i"]["j"] := "battle_row"."count";
3611 IF "j" = "dimension_v" THEN
3612 "i" := "i" + 1;
3613 "j" := 1;
3614 ELSE
3615 "j" := "j" + 1;
3616 IF "j" = "i" THEN
3617 "j" := "j" + 1;
3618 END IF;
3619 END IF;
3620 END LOOP;
3621 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3622 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3623 END IF;
3624 -- Store defeat strengths in "matrix" using "defeat_strength"
3625 -- function:
3626 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3627 "i" := 1;
3628 LOOP
3629 "j" := 1;
3630 LOOP
3631 IF "i" != "j" THEN
3632 "matrix"["i"]["j"] := "defeat_strength"(
3633 "vote_matrix"["i"]["j"],
3634 "vote_matrix"["j"]["i"]
3635 );
3636 END IF;
3637 EXIT WHEN "j" = "dimension_v";
3638 "j" := "j" + 1;
3639 END LOOP;
3640 EXIT WHEN "i" = "dimension_v";
3641 "i" := "i" + 1;
3642 END LOOP;
3643 -- Find best paths:
3644 "i" := 1;
3645 LOOP
3646 "j" := 1;
3647 LOOP
3648 IF "i" != "j" THEN
3649 "k" := 1;
3650 LOOP
3651 IF "i" != "k" AND "j" != "k" THEN
3652 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3653 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3654 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3655 END IF;
3656 ELSE
3657 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3658 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3659 END IF;
3660 END IF;
3661 END IF;
3662 EXIT WHEN "k" = "dimension_v";
3663 "k" := "k" + 1;
3664 END LOOP;
3665 END IF;
3666 EXIT WHEN "j" = "dimension_v";
3667 "j" := "j" + 1;
3668 END LOOP;
3669 EXIT WHEN "i" = "dimension_v";
3670 "i" := "i" + 1;
3671 END LOOP;
3672 -- Determine order of winners:
3673 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3674 "rank_v" := 1;
3675 "done_v" := 0;
3676 LOOP
3677 "winners_ary" := '{}';
3678 "i" := 1;
3679 LOOP
3680 IF "rank_ary"["i"] ISNULL THEN
3681 "j" := 1;
3682 LOOP
3683 IF
3684 "i" != "j" AND
3685 "rank_ary"["j"] ISNULL AND
3686 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3687 THEN
3688 -- someone else is better
3689 EXIT;
3690 END IF;
3691 IF "j" = "dimension_v" THEN
3692 -- noone is better
3693 "winners_ary" := "winners_ary" || "i";
3694 EXIT;
3695 END IF;
3696 "j" := "j" + 1;
3697 END LOOP;
3698 END IF;
3699 EXIT WHEN "i" = "dimension_v";
3700 "i" := "i" + 1;
3701 END LOOP;
3702 "i" := 1;
3703 LOOP
3704 "rank_ary"["winners_ary"["i"]] := "rank_v";
3705 "done_v" := "done_v" + 1;
3706 EXIT WHEN "i" = array_upper("winners_ary", 1);
3707 "i" := "i" + 1;
3708 END LOOP;
3709 EXIT WHEN "done_v" = "dimension_v";
3710 "rank_v" := "rank_v" + 1;
3711 END LOOP;
3712 -- write preliminary results:
3713 "i" := 1;
3714 FOR "initiative_id_v" IN
3715 SELECT "id" FROM "initiative"
3716 WHERE "issue_id" = "issue_id_p" AND "admitted"
3717 ORDER BY "id"
3718 LOOP
3719 UPDATE "initiative" SET
3720 "direct_majority" =
3721 CASE WHEN "policy_row"."direct_majority_strict" THEN
3722 "positive_votes" * "policy_row"."direct_majority_den" >
3723 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3724 ELSE
3725 "positive_votes" * "policy_row"."direct_majority_den" >=
3726 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3727 END
3728 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3729 AND "issue_row"."voter_count"-"negative_votes" >=
3730 "policy_row"."direct_majority_non_negative",
3731 "indirect_majority" =
3732 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3733 "positive_votes" * "policy_row"."indirect_majority_den" >
3734 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3735 ELSE
3736 "positive_votes" * "policy_row"."indirect_majority_den" >=
3737 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3738 END
3739 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3740 AND "issue_row"."voter_count"-"negative_votes" >=
3741 "policy_row"."indirect_majority_non_negative",
3742 "schulze_rank" = "rank_ary"["i"],
3743 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3744 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3745 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3746 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3747 "eligible" = FALSE,
3748 "winner" = FALSE
3749 WHERE "id" = "initiative_id_v";
3750 "i" := "i" + 1;
3751 END LOOP;
3752 IF "i" != "dimension_v" THEN
3753 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3754 END IF;
3755 -- take indirect majorities into account:
3756 LOOP
3757 UPDATE "initiative" SET "indirect_majority" = TRUE
3758 FROM (
3759 SELECT "new_initiative"."id" AS "initiative_id"
3760 FROM "initiative" "old_initiative"
3761 JOIN "initiative" "new_initiative"
3762 ON "new_initiative"."issue_id" = "issue_id_p"
3763 AND "new_initiative"."indirect_majority" = FALSE
3764 JOIN "battle" "battle_win"
3765 ON "battle_win"."issue_id" = "issue_id_p"
3766 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3767 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3768 JOIN "battle" "battle_lose"
3769 ON "battle_lose"."issue_id" = "issue_id_p"
3770 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3771 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3772 WHERE "old_initiative"."issue_id" = "issue_id_p"
3773 AND "old_initiative"."indirect_majority" = TRUE
3774 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3775 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3776 "policy_row"."indirect_majority_num" *
3777 ("battle_win"."count"+"battle_lose"."count")
3778 ELSE
3779 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3780 "policy_row"."indirect_majority_num" *
3781 ("battle_win"."count"+"battle_lose"."count")
3782 END
3783 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3784 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3785 "policy_row"."indirect_majority_non_negative"
3786 ) AS "subquery"
3787 WHERE "id" = "subquery"."initiative_id";
3788 EXIT WHEN NOT FOUND;
3789 END LOOP;
3790 -- set "multistage_majority" for remaining matching initiatives:
3791 UPDATE "initiative" SET "multistage_majority" = TRUE
3792 FROM (
3793 SELECT "losing_initiative"."id" AS "initiative_id"
3794 FROM "initiative" "losing_initiative"
3795 JOIN "initiative" "winning_initiative"
3796 ON "winning_initiative"."issue_id" = "issue_id_p"
3797 AND "winning_initiative"."admitted"
3798 JOIN "battle" "battle_win"
3799 ON "battle_win"."issue_id" = "issue_id_p"
3800 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3801 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3802 JOIN "battle" "battle_lose"
3803 ON "battle_lose"."issue_id" = "issue_id_p"
3804 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3805 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3806 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3807 AND "losing_initiative"."admitted"
3808 AND "winning_initiative"."schulze_rank" <
3809 "losing_initiative"."schulze_rank"
3810 AND "battle_win"."count" > "battle_lose"."count"
3811 AND (
3812 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3813 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3814 ) AS "subquery"
3815 WHERE "id" = "subquery"."initiative_id";
3816 -- mark eligible initiatives:
3817 UPDATE "initiative" SET "eligible" = TRUE
3818 WHERE "issue_id" = "issue_id_p"
3819 AND "initiative"."direct_majority"
3820 AND "initiative"."indirect_majority"
3821 AND "initiative"."better_than_status_quo"
3822 AND (
3823 "policy_row"."no_multistage_majority" = FALSE OR
3824 "initiative"."multistage_majority" = FALSE )
3825 AND (
3826 "policy_row"."no_reverse_beat_path" = FALSE OR
3827 "initiative"."reverse_beat_path" = FALSE );
3828 -- mark final winner:
3829 UPDATE "initiative" SET "winner" = TRUE
3830 FROM (
3831 SELECT "id" AS "initiative_id"
3832 FROM "initiative"
3833 WHERE "issue_id" = "issue_id_p" AND "eligible"
3834 ORDER BY
3835 "schulze_rank",
3836 "vote_ratio"("positive_votes", "negative_votes"),
3837 "id"
3838 LIMIT 1
3839 ) AS "subquery"
3840 WHERE "id" = "subquery"."initiative_id";
3841 -- write (final) ranks:
3842 "rank_v" := 1;
3843 FOR "initiative_id_v" IN
3844 SELECT "id"
3845 FROM "initiative"
3846 WHERE "issue_id" = "issue_id_p" AND "admitted"
3847 ORDER BY
3848 "winner" DESC,
3849 "eligible" DESC,
3850 "schulze_rank",
3851 "vote_ratio"("positive_votes", "negative_votes"),
3852 "id"
3853 LOOP
3854 UPDATE "initiative" SET "rank" = "rank_v"
3855 WHERE "id" = "initiative_id_v";
3856 "rank_v" := "rank_v" + 1;
3857 END LOOP;
3858 -- set schulze rank of status quo and mark issue as finished:
3859 UPDATE "issue" SET
3860 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
3861 "state" =
3862 CASE WHEN EXISTS (
3863 SELECT NULL FROM "initiative"
3864 WHERE "issue_id" = "issue_id_p" AND "winner"
3865 ) THEN
3866 'finished_with_winner'::"issue_state"
3867 ELSE
3868 'finished_without_winner'::"issue_state"
3869 END,
3870 "ranks_available" = TRUE
3871 WHERE "id" = "issue_id_p";
3872 RETURN;
3873 END;
3874 $$;
3876 COMMENT ON FUNCTION "calculate_ranks"
3877 ( "issue"."id"%TYPE )
3878 IS 'Determine ranking (Votes have to be counted first)';
3882 -----------------------------
3883 -- Automatic state changes --
3884 -----------------------------
3887 CREATE FUNCTION "check_issue"
3888 ( "issue_id_p" "issue"."id"%TYPE )
3889 RETURNS VOID
3890 LANGUAGE 'plpgsql' VOLATILE AS $$
3891 DECLARE
3892 "issue_row" "issue"%ROWTYPE;
3893 "policy_row" "policy"%ROWTYPE;
3894 BEGIN
3895 PERFORM "lock_issue"("issue_id_p");
3896 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3897 -- only process open issues:
3898 IF "issue_row"."closed" ISNULL THEN
3899 SELECT * INTO "policy_row" FROM "policy"
3900 WHERE "id" = "issue_row"."policy_id";
3901 -- create a snapshot, unless issue is already fully frozen:
3902 IF "issue_row"."fully_frozen" ISNULL THEN
3903 PERFORM "create_snapshot"("issue_id_p");
3904 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3905 END IF;
3906 -- eventually close or accept issues, which have not been accepted:
3907 IF "issue_row"."accepted" ISNULL THEN
3908 IF EXISTS (
3909 SELECT NULL FROM "initiative"
3910 WHERE "issue_id" = "issue_id_p"
3911 AND "supporter_count" > 0
3912 AND "supporter_count" * "policy_row"."issue_quorum_den"
3913 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3914 ) THEN
3915 -- accept issues, if supporter count is high enough
3916 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3917 -- NOTE: "issue_row" used later
3918 "issue_row"."state" := 'discussion';
3919 "issue_row"."accepted" := now();
3920 UPDATE "issue" SET
3921 "state" = "issue_row"."state",
3922 "accepted" = "issue_row"."accepted"
3923 WHERE "id" = "issue_row"."id";
3924 ELSIF
3925 now() >= "issue_row"."created" + "issue_row"."admission_time"
3926 THEN
3927 -- close issues, if admission time has expired
3928 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3929 UPDATE "issue" SET
3930 "state" = 'canceled_issue_not_accepted',
3931 "closed" = now()
3932 WHERE "id" = "issue_row"."id";
3933 END IF;
3934 END IF;
3935 -- eventually half freeze issues:
3936 IF
3937 -- NOTE: issue can't be closed at this point, if it has been accepted
3938 "issue_row"."accepted" NOTNULL AND
3939 "issue_row"."half_frozen" ISNULL
3940 THEN
3941 IF
3942 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3943 THEN
3944 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3945 -- NOTE: "issue_row" used later
3946 "issue_row"."state" := 'verification';
3947 "issue_row"."half_frozen" := now();
3948 UPDATE "issue" SET
3949 "state" = "issue_row"."state",
3950 "half_frozen" = "issue_row"."half_frozen"
3951 WHERE "id" = "issue_row"."id";
3952 END IF;
3953 END IF;
3954 -- close issues after some time, if all initiatives have been revoked:
3955 IF
3956 "issue_row"."closed" ISNULL AND
3957 NOT EXISTS (
3958 -- all initiatives are revoked
3959 SELECT NULL FROM "initiative"
3960 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3961 ) AND (
3962 -- and issue has not been accepted yet
3963 "issue_row"."accepted" ISNULL OR
3964 NOT EXISTS (
3965 -- or no initiatives have been revoked lately
3966 SELECT NULL FROM "initiative"
3967 WHERE "issue_id" = "issue_id_p"
3968 AND now() < "revoked" + "issue_row"."verification_time"
3969 ) OR (
3970 -- or verification time has elapsed
3971 "issue_row"."half_frozen" NOTNULL AND
3972 "issue_row"."fully_frozen" ISNULL AND
3973 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3976 THEN
3977 -- NOTE: "issue_row" used later
3978 IF "issue_row"."accepted" ISNULL THEN
3979 "issue_row"."state" := 'canceled_revoked_before_accepted';
3980 ELSIF "issue_row"."half_frozen" ISNULL THEN
3981 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
3982 ELSE
3983 "issue_row"."state" := 'canceled_after_revocation_during_verification';
3984 END IF;
3985 "issue_row"."closed" := now();
3986 UPDATE "issue" SET
3987 "state" = "issue_row"."state",
3988 "closed" = "issue_row"."closed"
3989 WHERE "id" = "issue_row"."id";
3990 END IF;
3991 -- fully freeze issue after verification time:
3992 IF
3993 "issue_row"."half_frozen" NOTNULL AND
3994 "issue_row"."fully_frozen" ISNULL AND
3995 "issue_row"."closed" ISNULL AND
3996 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3997 THEN
3998 PERFORM "freeze_after_snapshot"("issue_id_p");
3999 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4000 END IF;
4001 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4002 -- close issue by calling close_voting(...) after voting time:
4003 IF
4004 "issue_row"."closed" ISNULL AND
4005 "issue_row"."fully_frozen" NOTNULL AND
4006 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4007 THEN
4008 PERFORM "close_voting"("issue_id_p");
4009 -- calculate ranks will not consume much time and can be done now
4010 PERFORM "calculate_ranks"("issue_id_p");
4011 END IF;
4012 END IF;
4013 RETURN;
4014 END;
4015 $$;
4017 COMMENT ON FUNCTION "check_issue"
4018 ( "issue"."id"%TYPE )
4019 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.';
4022 CREATE FUNCTION "check_everything"()
4023 RETURNS VOID
4024 LANGUAGE 'plpgsql' VOLATILE AS $$
4025 DECLARE
4026 "issue_id_v" "issue"."id"%TYPE;
4027 BEGIN
4028 PERFORM "check_activity"();
4029 PERFORM "calculate_member_counts"();
4030 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4031 PERFORM "check_issue"("issue_id_v");
4032 END LOOP;
4033 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4034 PERFORM "calculate_ranks"("issue_id_v");
4035 END LOOP;
4036 RETURN;
4037 END;
4038 $$;
4040 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.';
4044 ----------------------
4045 -- Deletion of data --
4046 ----------------------
4049 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4050 RETURNS VOID
4051 LANGUAGE 'plpgsql' VOLATILE AS $$
4052 DECLARE
4053 "issue_row" "issue"%ROWTYPE;
4054 BEGIN
4055 SELECT * INTO "issue_row"
4056 FROM "issue" WHERE "id" = "issue_id_p"
4057 FOR UPDATE;
4058 IF "issue_row"."cleaned" ISNULL THEN
4059 UPDATE "issue" SET
4060 "state" = 'voting',
4061 "closed" = NULL,
4062 "ranks_available" = FALSE
4063 WHERE "id" = "issue_id_p";
4064 DELETE FROM "issue_comment"
4065 WHERE "issue_id" = "issue_id_p";
4066 DELETE FROM "voting_comment"
4067 WHERE "issue_id" = "issue_id_p";
4068 DELETE FROM "delegating_voter"
4069 WHERE "issue_id" = "issue_id_p";
4070 DELETE FROM "direct_voter"
4071 WHERE "issue_id" = "issue_id_p";
4072 DELETE FROM "delegating_interest_snapshot"
4073 WHERE "issue_id" = "issue_id_p";
4074 DELETE FROM "direct_interest_snapshot"
4075 WHERE "issue_id" = "issue_id_p";
4076 DELETE FROM "delegating_population_snapshot"
4077 WHERE "issue_id" = "issue_id_p";
4078 DELETE FROM "direct_population_snapshot"
4079 WHERE "issue_id" = "issue_id_p";
4080 DELETE FROM "non_voter"
4081 WHERE "issue_id" = "issue_id_p";
4082 DELETE FROM "delegation"
4083 WHERE "issue_id" = "issue_id_p";
4084 DELETE FROM "supporter"
4085 WHERE "issue_id" = "issue_id_p";
4086 UPDATE "issue" SET
4087 "state" = "issue_row"."state",
4088 "closed" = "issue_row"."closed",
4089 "ranks_available" = "issue_row"."ranks_available",
4090 "cleaned" = now()
4091 WHERE "id" = "issue_id_p";
4092 END IF;
4093 RETURN;
4094 END;
4095 $$;
4097 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4100 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4101 RETURNS VOID
4102 LANGUAGE 'plpgsql' VOLATILE AS $$
4103 BEGIN
4104 UPDATE "member" SET
4105 "last_login" = NULL,
4106 "login" = NULL,
4107 "password" = NULL,
4108 "locked" = TRUE,
4109 "active" = FALSE,
4110 "notify_email" = NULL,
4111 "notify_email_unconfirmed" = NULL,
4112 "notify_email_secret" = NULL,
4113 "notify_email_secret_expiry" = NULL,
4114 "notify_email_lock_expiry" = NULL,
4115 "password_reset_secret" = NULL,
4116 "password_reset_secret_expiry" = NULL,
4117 "organizational_unit" = NULL,
4118 "internal_posts" = NULL,
4119 "realname" = NULL,
4120 "birthday" = NULL,
4121 "address" = NULL,
4122 "email" = NULL,
4123 "xmpp_address" = NULL,
4124 "website" = NULL,
4125 "phone" = NULL,
4126 "mobile_phone" = NULL,
4127 "profession" = NULL,
4128 "external_memberships" = NULL,
4129 "external_posts" = NULL,
4130 "statement" = NULL
4131 WHERE "id" = "member_id_p";
4132 -- "text_search_data" is updated by triggers
4133 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4134 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4135 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4136 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4137 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4138 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4139 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4140 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4141 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4142 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4143 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4144 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4145 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4146 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4147 DELETE FROM "direct_voter" USING "issue"
4148 WHERE "direct_voter"."issue_id" = "issue"."id"
4149 AND "issue"."closed" ISNULL
4150 AND "member_id" = "member_id_p";
4151 RETURN;
4152 END;
4153 $$;
4155 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)';
4158 CREATE FUNCTION "delete_private_data"()
4159 RETURNS VOID
4160 LANGUAGE 'plpgsql' VOLATILE AS $$
4161 BEGIN
4162 UPDATE "member" SET
4163 "invite_code" = NULL,
4164 "last_login" = NULL,
4165 "login" = NULL,
4166 "password" = NULL,
4167 "notify_email" = NULL,
4168 "notify_email_unconfirmed" = NULL,
4169 "notify_email_secret" = NULL,
4170 "notify_email_secret_expiry" = NULL,
4171 "notify_email_lock_expiry" = NULL,
4172 "password_reset_secret" = NULL,
4173 "password_reset_secret_expiry" = NULL,
4174 "organizational_unit" = NULL,
4175 "internal_posts" = NULL,
4176 "realname" = NULL,
4177 "birthday" = NULL,
4178 "address" = NULL,
4179 "email" = NULL,
4180 "xmpp_address" = NULL,
4181 "website" = NULL,
4182 "phone" = NULL,
4183 "mobile_phone" = NULL,
4184 "profession" = NULL,
4185 "external_memberships" = NULL,
4186 "external_posts" = NULL,
4187 "statement" = NULL;
4188 -- "text_search_data" is updated by triggers
4189 DELETE FROM "setting";
4190 DELETE FROM "setting_map";
4191 DELETE FROM "member_relation_setting";
4192 DELETE FROM "member_image";
4193 DELETE FROM "contact";
4194 DELETE FROM "ignored_member";
4195 DELETE FROM "area_setting";
4196 DELETE FROM "issue_setting";
4197 DELETE FROM "ignored_initiative";
4198 DELETE FROM "initiative_setting";
4199 DELETE FROM "suggestion_setting";
4200 DELETE FROM "non_voter";
4201 DELETE FROM "direct_voter" USING "issue"
4202 WHERE "direct_voter"."issue_id" = "issue"."id"
4203 AND "issue"."closed" ISNULL;
4204 RETURN;
4205 END;
4206 $$;
4208 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.';
4212 COMMIT;

Impressum / About Us