liquid_feedback_core

view core.sql @ 204:b8fa47ee5d82

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

Impressum / About Us