liquid_feedback_core

view core.sql @ 203:976e7dafe641

Added table "unit_setting"
author jbe
date Sat Oct 08 20:48:30 2011 +0200 (2011-10-08)
parents e8c6035b03f3
children b8fa47ee5d82
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 "informed" BOOLEAN NOT NULL,
950 "satisfied" BOOLEAN NOT NULL,
951 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
952 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
953 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
955 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
957 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
958 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
959 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
962 CREATE TABLE "non_voter" (
963 PRIMARY KEY ("issue_id", "member_id"),
964 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
965 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
966 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
968 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
971 CREATE TABLE "direct_voter" (
972 PRIMARY KEY ("issue_id", "member_id"),
973 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
974 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
975 "weight" INT4 );
976 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
978 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.';
980 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
983 CREATE TABLE "delegating_voter" (
984 PRIMARY KEY ("issue_id", "member_id"),
985 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
986 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
987 "weight" INT4,
988 "scope" "delegation_scope" NOT NULL,
989 "delegate_member_ids" INT4[] NOT NULL );
990 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
992 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
994 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
995 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
996 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"';
999 CREATE TABLE "vote" (
1000 "issue_id" INT4 NOT NULL,
1001 PRIMARY KEY ("initiative_id", "member_id"),
1002 "initiative_id" INT4,
1003 "member_id" INT4,
1004 "grade" INT4,
1005 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1006 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1007 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1009 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.';
1011 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.';
1014 CREATE TABLE "issue_comment" (
1015 PRIMARY KEY ("issue_id", "member_id"),
1016 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1017 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1018 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
1019 "formatting_engine" TEXT,
1020 "content" TEXT NOT NULL,
1021 "text_search_data" TSVECTOR );
1022 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
1023 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
1024 CREATE TRIGGER "update_text_search_data"
1025 BEFORE INSERT OR UPDATE ON "issue_comment"
1026 FOR EACH ROW EXECUTE PROCEDURE
1027 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1029 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
1031 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
1034 CREATE TABLE "rendered_issue_comment" (
1035 PRIMARY KEY ("issue_id", "member_id", "format"),
1036 FOREIGN KEY ("issue_id", "member_id")
1037 REFERENCES "issue_comment" ("issue_id", "member_id")
1038 ON DELETE CASCADE ON UPDATE CASCADE,
1039 "issue_id" INT4,
1040 "member_id" INT4,
1041 "format" TEXT,
1042 "content" TEXT NOT NULL );
1044 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)';
1047 CREATE TABLE "voting_comment" (
1048 PRIMARY KEY ("issue_id", "member_id"),
1049 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1050 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1051 "changed" TIMESTAMPTZ,
1052 "formatting_engine" TEXT,
1053 "content" TEXT NOT NULL,
1054 "text_search_data" TSVECTOR );
1055 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1056 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1057 CREATE TRIGGER "update_text_search_data"
1058 BEFORE INSERT OR UPDATE ON "voting_comment"
1059 FOR EACH ROW EXECUTE PROCEDURE
1060 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1062 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1064 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.';
1067 CREATE TABLE "rendered_voting_comment" (
1068 PRIMARY KEY ("issue_id", "member_id", "format"),
1069 FOREIGN KEY ("issue_id", "member_id")
1070 REFERENCES "voting_comment" ("issue_id", "member_id")
1071 ON DELETE CASCADE ON UPDATE CASCADE,
1072 "issue_id" INT4,
1073 "member_id" INT4,
1074 "format" TEXT,
1075 "content" TEXT NOT NULL );
1077 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)';
1080 CREATE TYPE "event_type" AS ENUM (
1081 'issue_state_changed',
1082 'initiative_created_in_new_issue',
1083 'initiative_created_in_existing_issue',
1084 'initiative_revoked',
1085 'new_draft_created',
1086 'suggestion_created');
1088 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1091 CREATE TABLE "event" (
1092 "id" SERIAL8 PRIMARY KEY,
1093 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1094 "event" "event_type" NOT NULL,
1095 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1096 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1097 "state" "issue_state" CHECK ("state" != 'calculation'),
1098 "initiative_id" INT4,
1099 "draft_id" INT8,
1100 "suggestion_id" INT8,
1101 FOREIGN KEY ("issue_id", "initiative_id")
1102 REFERENCES "initiative" ("issue_id", "id")
1103 ON DELETE CASCADE ON UPDATE CASCADE,
1104 FOREIGN KEY ("initiative_id", "draft_id")
1105 REFERENCES "draft" ("initiative_id", "id")
1106 ON DELETE CASCADE ON UPDATE CASCADE,
1107 FOREIGN KEY ("initiative_id", "suggestion_id")
1108 REFERENCES "suggestion" ("initiative_id", "id")
1109 ON DELETE CASCADE ON UPDATE CASCADE,
1110 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1111 "event" != 'issue_state_changed' OR (
1112 "member_id" ISNULL AND
1113 "issue_id" NOTNULL AND
1114 "state" NOTNULL AND
1115 "initiative_id" ISNULL AND
1116 "draft_id" ISNULL AND
1117 "suggestion_id" ISNULL )),
1118 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1119 "event" NOT IN (
1120 'initiative_created_in_new_issue',
1121 'initiative_created_in_existing_issue',
1122 'initiative_revoked',
1123 'new_draft_created'
1124 ) OR (
1125 "member_id" NOTNULL AND
1126 "issue_id" NOTNULL AND
1127 "state" NOTNULL AND
1128 "initiative_id" NOTNULL AND
1129 "draft_id" NOTNULL AND
1130 "suggestion_id" ISNULL )),
1131 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1132 "event" != 'suggestion_created' OR (
1133 "member_id" NOTNULL AND
1134 "issue_id" NOTNULL AND
1135 "state" NOTNULL AND
1136 "initiative_id" NOTNULL AND
1137 "draft_id" ISNULL AND
1138 "suggestion_id" NOTNULL )) );
1140 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1142 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1143 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1144 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1145 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1149 ----------------------------------------------
1150 -- Writing of history entries and event log --
1151 ----------------------------------------------
1154 CREATE FUNCTION "write_member_history_trigger"()
1155 RETURNS TRIGGER
1156 LANGUAGE 'plpgsql' VOLATILE AS $$
1157 BEGIN
1158 IF
1159 NEW."active" != OLD."active" OR
1160 NEW."name" != OLD."name"
1161 THEN
1162 INSERT INTO "member_history"
1163 ("member_id", "active", "name")
1164 VALUES (NEW."id", OLD."active", OLD."name");
1165 END IF;
1166 RETURN NULL;
1167 END;
1168 $$;
1170 CREATE TRIGGER "write_member_history"
1171 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1172 "write_member_history_trigger"();
1174 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1175 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1178 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1179 RETURNS TRIGGER
1180 LANGUAGE 'plpgsql' VOLATILE AS $$
1181 BEGIN
1182 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1183 INSERT INTO "event" ("event", "issue_id", "state")
1184 VALUES ('issue_state_changed', NEW."id", NEW."state");
1185 END IF;
1186 RETURN NULL;
1187 END;
1188 $$;
1190 CREATE TRIGGER "write_event_issue_state_changed"
1191 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1192 "write_event_issue_state_changed_trigger"();
1194 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1195 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1198 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1199 RETURNS TRIGGER
1200 LANGUAGE 'plpgsql' VOLATILE AS $$
1201 DECLARE
1202 "initiative_row" "initiative"%ROWTYPE;
1203 "issue_row" "issue"%ROWTYPE;
1204 "event_v" "event_type";
1205 BEGIN
1206 SELECT * INTO "initiative_row" FROM "initiative"
1207 WHERE "id" = NEW."initiative_id";
1208 SELECT * INTO "issue_row" FROM "issue"
1209 WHERE "id" = "initiative_row"."issue_id";
1210 IF EXISTS (
1211 SELECT NULL FROM "draft"
1212 WHERE "initiative_id" = NEW."initiative_id"
1213 AND "id" != NEW."id"
1214 ) THEN
1215 "event_v" := 'new_draft_created';
1216 ELSE
1217 IF EXISTS (
1218 SELECT NULL FROM "initiative"
1219 WHERE "issue_id" = "initiative_row"."issue_id"
1220 AND "id" != "initiative_row"."id"
1221 ) THEN
1222 "event_v" := 'initiative_created_in_existing_issue';
1223 ELSE
1224 "event_v" := 'initiative_created_in_new_issue';
1225 END IF;
1226 END IF;
1227 INSERT INTO "event" (
1228 "event", "member_id",
1229 "issue_id", "state", "initiative_id", "draft_id"
1230 ) VALUES (
1231 "event_v",
1232 NEW."author_id",
1233 "initiative_row"."issue_id",
1234 "issue_row"."state",
1235 "initiative_row"."id",
1236 NEW."id" );
1237 RETURN NULL;
1238 END;
1239 $$;
1241 CREATE TRIGGER "write_event_initiative_or_draft_created"
1242 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1243 "write_event_initiative_or_draft_created_trigger"();
1245 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1246 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1249 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1250 RETURNS TRIGGER
1251 LANGUAGE 'plpgsql' VOLATILE AS $$
1252 DECLARE
1253 "issue_row" "issue"%ROWTYPE;
1254 BEGIN
1255 SELECT * INTO "issue_row" FROM "issue"
1256 WHERE "id" = NEW."issue_id";
1257 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1258 INSERT INTO "event" (
1259 "event", "member_id", "issue_id", "state", "initiative_id"
1260 ) VALUES (
1261 'initiative_revoked',
1262 NEW."revoked_by_member_id",
1263 NEW."issue_id",
1264 "issue_row"."state",
1265 NEW."id" );
1266 END IF;
1267 RETURN NULL;
1268 END;
1269 $$;
1271 CREATE TRIGGER "write_event_initiative_revoked"
1272 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1273 "write_event_initiative_revoked_trigger"();
1275 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1276 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1279 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1280 RETURNS TRIGGER
1281 LANGUAGE 'plpgsql' VOLATILE AS $$
1282 DECLARE
1283 "initiative_row" "initiative"%ROWTYPE;
1284 "issue_row" "issue"%ROWTYPE;
1285 BEGIN
1286 SELECT * INTO "initiative_row" FROM "initiative"
1287 WHERE "id" = NEW."initiative_id";
1288 SELECT * INTO "issue_row" FROM "issue"
1289 WHERE "id" = "initiative_row"."issue_id";
1290 INSERT INTO "event" (
1291 "event", "member_id",
1292 "issue_id", "state", "initiative_id", "suggestion_id"
1293 ) VALUES (
1294 'suggestion_created',
1295 NEW."author_id",
1296 "initiative_row"."issue_id",
1297 "issue_row"."state",
1298 "initiative_row"."id",
1299 NEW."id" );
1300 RETURN NULL;
1301 END;
1302 $$;
1304 CREATE TRIGGER "write_event_suggestion_created"
1305 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1306 "write_event_suggestion_created_trigger"();
1308 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1309 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1313 ----------------------------
1314 -- Additional constraints --
1315 ----------------------------
1318 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1319 RETURNS TRIGGER
1320 LANGUAGE 'plpgsql' VOLATILE AS $$
1321 BEGIN
1322 IF NOT EXISTS (
1323 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1324 ) THEN
1325 --RAISE 'Cannot create issue without an initial initiative.' USING
1326 -- ERRCODE = 'integrity_constraint_violation',
1327 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1328 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1329 END IF;
1330 RETURN NULL;
1331 END;
1332 $$;
1334 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1335 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1336 FOR EACH ROW EXECUTE PROCEDURE
1337 "issue_requires_first_initiative_trigger"();
1339 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1340 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1343 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1344 RETURNS TRIGGER
1345 LANGUAGE 'plpgsql' VOLATILE AS $$
1346 DECLARE
1347 "reference_lost" BOOLEAN;
1348 BEGIN
1349 IF TG_OP = 'DELETE' THEN
1350 "reference_lost" := TRUE;
1351 ELSE
1352 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1353 END IF;
1354 IF
1355 "reference_lost" AND NOT EXISTS (
1356 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1358 THEN
1359 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1360 END IF;
1361 RETURN NULL;
1362 END;
1363 $$;
1365 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1366 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1367 FOR EACH ROW EXECUTE PROCEDURE
1368 "last_initiative_deletes_issue_trigger"();
1370 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1371 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1374 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1375 RETURNS TRIGGER
1376 LANGUAGE 'plpgsql' VOLATILE AS $$
1377 BEGIN
1378 IF NOT EXISTS (
1379 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1380 ) THEN
1381 --RAISE 'Cannot create initiative without an initial draft.' USING
1382 -- ERRCODE = 'integrity_constraint_violation',
1383 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1384 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1385 END IF;
1386 RETURN NULL;
1387 END;
1388 $$;
1390 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1391 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1392 FOR EACH ROW EXECUTE PROCEDURE
1393 "initiative_requires_first_draft_trigger"();
1395 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1396 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1399 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1400 RETURNS TRIGGER
1401 LANGUAGE 'plpgsql' VOLATILE AS $$
1402 DECLARE
1403 "reference_lost" BOOLEAN;
1404 BEGIN
1405 IF TG_OP = 'DELETE' THEN
1406 "reference_lost" := TRUE;
1407 ELSE
1408 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1409 END IF;
1410 IF
1411 "reference_lost" AND NOT EXISTS (
1412 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1414 THEN
1415 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1416 END IF;
1417 RETURN NULL;
1418 END;
1419 $$;
1421 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1422 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1423 FOR EACH ROW EXECUTE PROCEDURE
1424 "last_draft_deletes_initiative_trigger"();
1426 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1427 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1430 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1431 RETURNS TRIGGER
1432 LANGUAGE 'plpgsql' VOLATILE AS $$
1433 BEGIN
1434 IF NOT EXISTS (
1435 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1436 ) THEN
1437 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1438 END IF;
1439 RETURN NULL;
1440 END;
1441 $$;
1443 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1444 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1445 FOR EACH ROW EXECUTE PROCEDURE
1446 "suggestion_requires_first_opinion_trigger"();
1448 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1449 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1452 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1453 RETURNS TRIGGER
1454 LANGUAGE 'plpgsql' VOLATILE AS $$
1455 DECLARE
1456 "reference_lost" BOOLEAN;
1457 BEGIN
1458 IF TG_OP = 'DELETE' THEN
1459 "reference_lost" := TRUE;
1460 ELSE
1461 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1462 END IF;
1463 IF
1464 "reference_lost" AND NOT EXISTS (
1465 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1467 THEN
1468 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1469 END IF;
1470 RETURN NULL;
1471 END;
1472 $$;
1474 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1475 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1476 FOR EACH ROW EXECUTE PROCEDURE
1477 "last_opinion_deletes_suggestion_trigger"();
1479 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1480 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1484 ---------------------------------------------------------------
1485 -- Ensure that votes are not modified when issues are frozen --
1486 ---------------------------------------------------------------
1488 -- NOTE: Frontends should ensure this anyway, but in case of programming
1489 -- errors the following triggers ensure data integrity.
1492 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1493 RETURNS TRIGGER
1494 LANGUAGE 'plpgsql' VOLATILE AS $$
1495 DECLARE
1496 "issue_id_v" "issue"."id"%TYPE;
1497 "issue_row" "issue"%ROWTYPE;
1498 BEGIN
1499 IF TG_OP = 'DELETE' THEN
1500 "issue_id_v" := OLD."issue_id";
1501 ELSE
1502 "issue_id_v" := NEW."issue_id";
1503 END IF;
1504 SELECT INTO "issue_row" * FROM "issue"
1505 WHERE "id" = "issue_id_v" FOR SHARE;
1506 IF "issue_row"."closed" NOTNULL THEN
1507 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1508 END IF;
1509 RETURN NULL;
1510 END;
1511 $$;
1513 CREATE TRIGGER "forbid_changes_on_closed_issue"
1514 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1515 FOR EACH ROW EXECUTE PROCEDURE
1516 "forbid_changes_on_closed_issue_trigger"();
1518 CREATE TRIGGER "forbid_changes_on_closed_issue"
1519 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1520 FOR EACH ROW EXECUTE PROCEDURE
1521 "forbid_changes_on_closed_issue_trigger"();
1523 CREATE TRIGGER "forbid_changes_on_closed_issue"
1524 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1525 FOR EACH ROW EXECUTE PROCEDURE
1526 "forbid_changes_on_closed_issue_trigger"();
1528 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"';
1529 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';
1530 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';
1531 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';
1535 --------------------------------------------------------------------
1536 -- Auto-retrieval of fields only needed for referential integrity --
1537 --------------------------------------------------------------------
1540 CREATE FUNCTION "autofill_issue_id_trigger"()
1541 RETURNS TRIGGER
1542 LANGUAGE 'plpgsql' VOLATILE AS $$
1543 BEGIN
1544 IF NEW."issue_id" ISNULL THEN
1545 SELECT "issue_id" INTO NEW."issue_id"
1546 FROM "initiative" WHERE "id" = NEW."initiative_id";
1547 END IF;
1548 RETURN NEW;
1549 END;
1550 $$;
1552 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1553 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1555 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1556 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1558 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1559 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1560 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1563 CREATE FUNCTION "autofill_initiative_id_trigger"()
1564 RETURNS TRIGGER
1565 LANGUAGE 'plpgsql' VOLATILE AS $$
1566 BEGIN
1567 IF NEW."initiative_id" ISNULL THEN
1568 SELECT "initiative_id" INTO NEW."initiative_id"
1569 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1570 END IF;
1571 RETURN NEW;
1572 END;
1573 $$;
1575 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1576 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1578 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1579 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1583 -----------------------------------------------------
1584 -- Automatic calculation of certain default values --
1585 -----------------------------------------------------
1588 CREATE FUNCTION "copy_timings_trigger"()
1589 RETURNS TRIGGER
1590 LANGUAGE 'plpgsql' VOLATILE AS $$
1591 DECLARE
1592 "policy_row" "policy"%ROWTYPE;
1593 BEGIN
1594 SELECT * INTO "policy_row" FROM "policy"
1595 WHERE "id" = NEW."policy_id";
1596 IF NEW."admission_time" ISNULL THEN
1597 NEW."admission_time" := "policy_row"."admission_time";
1598 END IF;
1599 IF NEW."discussion_time" ISNULL THEN
1600 NEW."discussion_time" := "policy_row"."discussion_time";
1601 END IF;
1602 IF NEW."verification_time" ISNULL THEN
1603 NEW."verification_time" := "policy_row"."verification_time";
1604 END IF;
1605 IF NEW."voting_time" ISNULL THEN
1606 NEW."voting_time" := "policy_row"."voting_time";
1607 END IF;
1608 RETURN NEW;
1609 END;
1610 $$;
1612 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1613 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1615 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1616 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1619 CREATE FUNCTION "default_for_draft_id_trigger"()
1620 RETURNS TRIGGER
1621 LANGUAGE 'plpgsql' VOLATILE AS $$
1622 BEGIN
1623 IF NEW."draft_id" ISNULL THEN
1624 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1625 WHERE "initiative_id" = NEW."initiative_id";
1626 END IF;
1627 RETURN NEW;
1628 END;
1629 $$;
1631 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1632 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1633 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1634 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1636 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1637 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';
1638 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';
1642 ----------------------------------------
1643 -- Automatic creation of dependencies --
1644 ----------------------------------------
1647 CREATE FUNCTION "autocreate_interest_trigger"()
1648 RETURNS TRIGGER
1649 LANGUAGE 'plpgsql' VOLATILE AS $$
1650 BEGIN
1651 IF NOT EXISTS (
1652 SELECT NULL FROM "initiative" JOIN "interest"
1653 ON "initiative"."issue_id" = "interest"."issue_id"
1654 WHERE "initiative"."id" = NEW."initiative_id"
1655 AND "interest"."member_id" = NEW."member_id"
1656 ) THEN
1657 BEGIN
1658 INSERT INTO "interest" ("issue_id", "member_id")
1659 SELECT "issue_id", NEW."member_id"
1660 FROM "initiative" WHERE "id" = NEW."initiative_id";
1661 EXCEPTION WHEN unique_violation THEN END;
1662 END IF;
1663 RETURN NEW;
1664 END;
1665 $$;
1667 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1668 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1670 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1671 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';
1674 CREATE FUNCTION "autocreate_supporter_trigger"()
1675 RETURNS TRIGGER
1676 LANGUAGE 'plpgsql' VOLATILE AS $$
1677 BEGIN
1678 IF NOT EXISTS (
1679 SELECT NULL FROM "suggestion" JOIN "supporter"
1680 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1681 WHERE "suggestion"."id" = NEW."suggestion_id"
1682 AND "supporter"."member_id" = NEW."member_id"
1683 ) THEN
1684 BEGIN
1685 INSERT INTO "supporter" ("initiative_id", "member_id")
1686 SELECT "initiative_id", NEW."member_id"
1687 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1688 EXCEPTION WHEN unique_violation THEN END;
1689 END IF;
1690 RETURN NEW;
1691 END;
1692 $$;
1694 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1695 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1697 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1698 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.';
1702 ------------------------------------------
1703 -- Views and helper functions for views --
1704 ------------------------------------------
1707 CREATE VIEW "unit_delegation" AS
1708 SELECT
1709 "unit"."id" AS "unit_id",
1710 "delegation"."id",
1711 "delegation"."truster_id",
1712 "delegation"."trustee_id",
1713 "delegation"."scope"
1714 FROM "unit"
1715 JOIN "delegation"
1716 ON "delegation"."unit_id" = "unit"."id"
1717 JOIN "member"
1718 ON "delegation"."truster_id" = "member"."id"
1719 JOIN "privilege"
1720 ON "delegation"."unit_id" = "privilege"."unit_id"
1721 AND "delegation"."truster_id" = "privilege"."member_id"
1722 WHERE "member"."active" AND "privilege"."voting_right";
1724 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1727 CREATE VIEW "area_delegation" AS
1728 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1729 "area"."id" AS "area_id",
1730 "delegation"."id",
1731 "delegation"."truster_id",
1732 "delegation"."trustee_id",
1733 "delegation"."scope"
1734 FROM "area"
1735 JOIN "delegation"
1736 ON "delegation"."unit_id" = "area"."unit_id"
1737 OR "delegation"."area_id" = "area"."id"
1738 JOIN "member"
1739 ON "delegation"."truster_id" = "member"."id"
1740 JOIN "privilege"
1741 ON "area"."unit_id" = "privilege"."unit_id"
1742 AND "delegation"."truster_id" = "privilege"."member_id"
1743 WHERE "member"."active" AND "privilege"."voting_right"
1744 ORDER BY
1745 "area"."id",
1746 "delegation"."truster_id",
1747 "delegation"."scope" DESC;
1749 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1752 CREATE VIEW "issue_delegation" AS
1753 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1754 "issue"."id" AS "issue_id",
1755 "delegation"."id",
1756 "delegation"."truster_id",
1757 "delegation"."trustee_id",
1758 "delegation"."scope"
1759 FROM "issue"
1760 JOIN "area"
1761 ON "area"."id" = "issue"."area_id"
1762 JOIN "delegation"
1763 ON "delegation"."unit_id" = "area"."unit_id"
1764 OR "delegation"."area_id" = "area"."id"
1765 OR "delegation"."issue_id" = "issue"."id"
1766 JOIN "member"
1767 ON "delegation"."truster_id" = "member"."id"
1768 JOIN "privilege"
1769 ON "area"."unit_id" = "privilege"."unit_id"
1770 AND "delegation"."truster_id" = "privilege"."member_id"
1771 WHERE "member"."active" AND "privilege"."voting_right"
1772 ORDER BY
1773 "issue"."id",
1774 "delegation"."truster_id",
1775 "delegation"."scope" DESC;
1777 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1780 CREATE FUNCTION "membership_weight_with_skipping"
1781 ( "area_id_p" "area"."id"%TYPE,
1782 "member_id_p" "member"."id"%TYPE,
1783 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1784 RETURNS INT4
1785 LANGUAGE 'plpgsql' STABLE AS $$
1786 DECLARE
1787 "sum_v" INT4;
1788 "delegation_row" "area_delegation"%ROWTYPE;
1789 BEGIN
1790 "sum_v" := 1;
1791 FOR "delegation_row" IN
1792 SELECT "area_delegation".*
1793 FROM "area_delegation" LEFT JOIN "membership"
1794 ON "membership"."area_id" = "area_id_p"
1795 AND "membership"."member_id" = "area_delegation"."truster_id"
1796 WHERE "area_delegation"."area_id" = "area_id_p"
1797 AND "area_delegation"."trustee_id" = "member_id_p"
1798 AND "membership"."member_id" ISNULL
1799 LOOP
1800 IF NOT
1801 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1802 THEN
1803 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1804 "area_id_p",
1805 "delegation_row"."truster_id",
1806 "skip_member_ids_p" || "delegation_row"."truster_id"
1807 );
1808 END IF;
1809 END LOOP;
1810 RETURN "sum_v";
1811 END;
1812 $$;
1814 COMMENT ON FUNCTION "membership_weight_with_skipping"
1815 ( "area"."id"%TYPE,
1816 "member"."id"%TYPE,
1817 INT4[] )
1818 IS 'Helper function for "membership_weight" function';
1821 CREATE FUNCTION "membership_weight"
1822 ( "area_id_p" "area"."id"%TYPE,
1823 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1824 RETURNS INT4
1825 LANGUAGE 'plpgsql' STABLE AS $$
1826 BEGIN
1827 RETURN "membership_weight_with_skipping"(
1828 "area_id_p",
1829 "member_id_p",
1830 ARRAY["member_id_p"]
1831 );
1832 END;
1833 $$;
1835 COMMENT ON FUNCTION "membership_weight"
1836 ( "area"."id"%TYPE,
1837 "member"."id"%TYPE )
1838 IS 'Calculates the potential voting weight of a member in a given area';
1841 CREATE VIEW "member_count_view" AS
1842 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1844 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1847 CREATE VIEW "unit_member_count" AS
1848 SELECT
1849 "unit"."id" AS "unit_id",
1850 sum("member"."id") AS "member_count"
1851 FROM "unit"
1852 LEFT JOIN "privilege"
1853 ON "privilege"."unit_id" = "unit"."id"
1854 AND "privilege"."voting_right"
1855 LEFT JOIN "member"
1856 ON "member"."id" = "privilege"."member_id"
1857 AND "member"."active"
1858 GROUP BY "unit"."id";
1860 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1863 CREATE VIEW "area_member_count" AS
1864 SELECT
1865 "area"."id" AS "area_id",
1866 count("member"."id") AS "direct_member_count",
1867 coalesce(
1868 sum(
1869 CASE WHEN "member"."id" NOTNULL THEN
1870 "membership_weight"("area"."id", "member"."id")
1871 ELSE 0 END
1873 ) AS "member_weight"
1874 FROM "area"
1875 LEFT JOIN "membership"
1876 ON "area"."id" = "membership"."area_id"
1877 LEFT JOIN "privilege"
1878 ON "privilege"."unit_id" = "area"."unit_id"
1879 AND "privilege"."member_id" = "membership"."member_id"
1880 AND "privilege"."voting_right"
1881 LEFT JOIN "member"
1882 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1883 AND "member"."active"
1884 GROUP BY "area"."id";
1886 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1889 CREATE VIEW "opening_draft" AS
1890 SELECT "draft".* FROM (
1891 SELECT
1892 "initiative"."id" AS "initiative_id",
1893 min("draft"."id") AS "draft_id"
1894 FROM "initiative" JOIN "draft"
1895 ON "initiative"."id" = "draft"."initiative_id"
1896 GROUP BY "initiative"."id"
1897 ) AS "subquery"
1898 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1900 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1903 CREATE VIEW "current_draft" AS
1904 SELECT "draft".* FROM (
1905 SELECT
1906 "initiative"."id" AS "initiative_id",
1907 max("draft"."id") AS "draft_id"
1908 FROM "initiative" JOIN "draft"
1909 ON "initiative"."id" = "draft"."initiative_id"
1910 GROUP BY "initiative"."id"
1911 ) AS "subquery"
1912 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1914 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1917 CREATE VIEW "critical_opinion" AS
1918 SELECT * FROM "opinion"
1919 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1920 OR ("degree" = -2 AND "fulfilled" = TRUE);
1922 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1925 CREATE VIEW "battle_participant" AS
1926 SELECT "initiative"."id", "initiative"."issue_id"
1927 FROM "issue" JOIN "initiative"
1928 ON "issue"."id" = "initiative"."issue_id"
1929 WHERE "initiative"."admitted"
1930 UNION ALL
1931 SELECT NULL, "id" AS "issue_id"
1932 FROM "issue";
1934 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1937 CREATE VIEW "battle_view" AS
1938 SELECT
1939 "issue"."id" AS "issue_id",
1940 "winning_initiative"."id" AS "winning_initiative_id",
1941 "losing_initiative"."id" AS "losing_initiative_id",
1942 sum(
1943 CASE WHEN
1944 coalesce("better_vote"."grade", 0) >
1945 coalesce("worse_vote"."grade", 0)
1946 THEN "direct_voter"."weight" ELSE 0 END
1947 ) AS "count"
1948 FROM "issue"
1949 LEFT JOIN "direct_voter"
1950 ON "issue"."id" = "direct_voter"."issue_id"
1951 JOIN "battle_participant" AS "winning_initiative"
1952 ON "issue"."id" = "winning_initiative"."issue_id"
1953 JOIN "battle_participant" AS "losing_initiative"
1954 ON "issue"."id" = "losing_initiative"."issue_id"
1955 LEFT JOIN "vote" AS "better_vote"
1956 ON "direct_voter"."member_id" = "better_vote"."member_id"
1957 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1958 LEFT JOIN "vote" AS "worse_vote"
1959 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1960 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1961 WHERE "issue"."closed" NOTNULL
1962 AND "issue"."cleaned" ISNULL
1963 AND (
1964 "winning_initiative"."id" != "losing_initiative"."id" OR
1965 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1966 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1967 GROUP BY
1968 "issue"."id",
1969 "winning_initiative"."id",
1970 "losing_initiative"."id";
1972 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';
1975 CREATE VIEW "open_issue" AS
1976 SELECT * FROM "issue" WHERE "closed" ISNULL;
1978 COMMENT ON VIEW "open_issue" IS 'All open issues';
1981 CREATE VIEW "issue_with_ranks_missing" AS
1982 SELECT * FROM "issue"
1983 WHERE "fully_frozen" NOTNULL
1984 AND "closed" NOTNULL
1985 AND "ranks_available" = FALSE;
1987 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
1990 CREATE VIEW "member_contingent" AS
1991 SELECT
1992 "member"."id" AS "member_id",
1993 "contingent"."time_frame",
1994 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
1996 SELECT count(1) FROM "draft"
1997 WHERE "draft"."author_id" = "member"."id"
1998 AND "draft"."created" > now() - "contingent"."time_frame"
1999 ) + (
2000 SELECT count(1) FROM "suggestion"
2001 WHERE "suggestion"."author_id" = "member"."id"
2002 AND "suggestion"."created" > now() - "contingent"."time_frame"
2004 ELSE NULL END AS "text_entry_count",
2005 "contingent"."text_entry_limit",
2006 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2007 SELECT count(1) FROM "opening_draft"
2008 WHERE "opening_draft"."author_id" = "member"."id"
2009 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2010 ) ELSE NULL END AS "initiative_count",
2011 "contingent"."initiative_limit"
2012 FROM "member" CROSS JOIN "contingent";
2014 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2016 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2017 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2020 CREATE VIEW "member_contingent_left" AS
2021 SELECT
2022 "member_id",
2023 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2024 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2025 FROM "member_contingent" GROUP BY "member_id";
2027 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.';
2030 CREATE VIEW "event_seen_by_member" AS
2031 SELECT
2032 "member"."id" AS "seen_by_member_id",
2033 CASE WHEN "event"."state" IN (
2034 'voting',
2035 'finished_without_winner',
2036 'finished_with_winner'
2037 ) THEN
2038 'voting'::"notify_level"
2039 ELSE
2040 CASE WHEN "event"."state" IN (
2041 'verification',
2042 'canceled_after_revocation_during_verification',
2043 'canceled_no_initiative_admitted'
2044 ) THEN
2045 'verification'::"notify_level"
2046 ELSE
2047 CASE WHEN "event"."state" IN (
2048 'discussion',
2049 'canceled_after_revocation_during_discussion'
2050 ) THEN
2051 'discussion'::"notify_level"
2052 ELSE
2053 'all'::"notify_level"
2054 END
2055 END
2056 END AS "notify_level",
2057 "event".*
2058 FROM "member" CROSS JOIN "event"
2059 LEFT JOIN "issue"
2060 ON "event"."issue_id" = "issue"."id"
2061 LEFT JOIN "membership"
2062 ON "member"."id" = "membership"."member_id"
2063 AND "issue"."area_id" = "membership"."area_id"
2064 LEFT JOIN "interest"
2065 ON "member"."id" = "interest"."member_id"
2066 AND "event"."issue_id" = "interest"."issue_id"
2067 LEFT JOIN "supporter"
2068 ON "member"."id" = "supporter"."member_id"
2069 AND "event"."initiative_id" = "supporter"."initiative_id"
2070 LEFT JOIN "ignored_member"
2071 ON "member"."id" = "ignored_member"."member_id"
2072 AND "event"."member_id" = "ignored_member"."other_member_id"
2073 LEFT JOIN "ignored_initiative"
2074 ON "member"."id" = "ignored_initiative"."member_id"
2075 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2076 WHERE (
2077 "supporter"."member_id" NOTNULL OR
2078 "interest"."member_id" NOTNULL OR
2079 ( "membership"."member_id" NOTNULL AND
2080 "event"."event" IN (
2081 'issue_state_changed',
2082 'initiative_created_in_new_issue',
2083 'initiative_created_in_existing_issue',
2084 'initiative_revoked' ) ) )
2085 AND "ignored_member"."member_id" ISNULL
2086 AND "ignored_initiative"."member_id" ISNULL;
2088 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
2091 CREATE VIEW "pending_notification" AS
2092 SELECT
2093 "member"."id" AS "seen_by_member_id",
2094 "event".*
2095 FROM "member" CROSS JOIN "event"
2096 LEFT JOIN "issue"
2097 ON "event"."issue_id" = "issue"."id"
2098 LEFT JOIN "membership"
2099 ON "member"."id" = "membership"."member_id"
2100 AND "issue"."area_id" = "membership"."area_id"
2101 LEFT JOIN "interest"
2102 ON "member"."id" = "interest"."member_id"
2103 AND "event"."issue_id" = "interest"."issue_id"
2104 LEFT JOIN "supporter"
2105 ON "member"."id" = "supporter"."member_id"
2106 AND "event"."initiative_id" = "supporter"."initiative_id"
2107 LEFT JOIN "ignored_member"
2108 ON "member"."id" = "ignored_member"."member_id"
2109 AND "event"."member_id" = "ignored_member"."other_member_id"
2110 LEFT JOIN "ignored_initiative"
2111 ON "member"."id" = "ignored_initiative"."member_id"
2112 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2113 WHERE (
2114 "member"."notify_event_id" ISNULL OR
2115 ( "member"."notify_event_id" NOTNULL AND
2116 "member"."notify_event_id" < "event"."id" ) )
2117 AND (
2118 ( "member"."notify_level" >= 'all' ) OR
2119 ( "member"."notify_level" >= 'voting' AND
2120 "event"."state" IN (
2121 'voting',
2122 'finished_without_winner',
2123 'finished_with_winner' ) ) OR
2124 ( "member"."notify_level" >= 'verification' AND
2125 "event"."state" IN (
2126 'verification',
2127 'canceled_after_revocation_during_verification',
2128 'canceled_no_initiative_admitted' ) ) OR
2129 ( "member"."notify_level" >= 'discussion' AND
2130 "event"."state" IN (
2131 'discussion',
2132 'canceled_after_revocation_during_discussion' ) ) )
2133 AND (
2134 "supporter"."member_id" NOTNULL OR
2135 "interest"."member_id" NOTNULL OR
2136 ( "membership"."member_id" NOTNULL AND
2137 "event"."event" IN (
2138 'issue_state_changed',
2139 'initiative_created_in_new_issue',
2140 'initiative_created_in_existing_issue',
2141 'initiative_revoked' ) ) )
2142 AND "ignored_member"."member_id" ISNULL
2143 AND "ignored_initiative"."member_id" ISNULL;
2145 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
2148 CREATE TYPE "timeline_event" AS ENUM (
2149 'issue_created',
2150 'issue_canceled',
2151 'issue_accepted',
2152 'issue_half_frozen',
2153 'issue_finished_without_voting',
2154 'issue_voting_started',
2155 'issue_finished_after_voting',
2156 'initiative_created',
2157 'initiative_revoked',
2158 'draft_created',
2159 'suggestion_created');
2161 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2164 CREATE VIEW "timeline_issue" AS
2165 SELECT
2166 "created" AS "occurrence",
2167 'issue_created'::"timeline_event" AS "event",
2168 "id" AS "issue_id"
2169 FROM "issue"
2170 UNION ALL
2171 SELECT
2172 "closed" AS "occurrence",
2173 'issue_canceled'::"timeline_event" AS "event",
2174 "id" AS "issue_id"
2175 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2176 UNION ALL
2177 SELECT
2178 "accepted" AS "occurrence",
2179 'issue_accepted'::"timeline_event" AS "event",
2180 "id" AS "issue_id"
2181 FROM "issue" WHERE "accepted" NOTNULL
2182 UNION ALL
2183 SELECT
2184 "half_frozen" AS "occurrence",
2185 'issue_half_frozen'::"timeline_event" AS "event",
2186 "id" AS "issue_id"
2187 FROM "issue" WHERE "half_frozen" NOTNULL
2188 UNION ALL
2189 SELECT
2190 "fully_frozen" AS "occurrence",
2191 'issue_voting_started'::"timeline_event" AS "event",
2192 "id" AS "issue_id"
2193 FROM "issue"
2194 WHERE "fully_frozen" NOTNULL
2195 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2196 UNION ALL
2197 SELECT
2198 "closed" AS "occurrence",
2199 CASE WHEN "fully_frozen" = "closed" THEN
2200 'issue_finished_without_voting'::"timeline_event"
2201 ELSE
2202 'issue_finished_after_voting'::"timeline_event"
2203 END AS "event",
2204 "id" AS "issue_id"
2205 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2207 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2210 CREATE VIEW "timeline_initiative" AS
2211 SELECT
2212 "created" AS "occurrence",
2213 'initiative_created'::"timeline_event" AS "event",
2214 "id" AS "initiative_id"
2215 FROM "initiative"
2216 UNION ALL
2217 SELECT
2218 "revoked" AS "occurrence",
2219 'initiative_revoked'::"timeline_event" AS "event",
2220 "id" AS "initiative_id"
2221 FROM "initiative" WHERE "revoked" NOTNULL;
2223 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2226 CREATE VIEW "timeline_draft" AS
2227 SELECT
2228 "created" AS "occurrence",
2229 'draft_created'::"timeline_event" AS "event",
2230 "id" AS "draft_id"
2231 FROM "draft";
2233 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2236 CREATE VIEW "timeline_suggestion" AS
2237 SELECT
2238 "created" AS "occurrence",
2239 'suggestion_created'::"timeline_event" AS "event",
2240 "id" AS "suggestion_id"
2241 FROM "suggestion";
2243 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2246 CREATE VIEW "timeline" AS
2247 SELECT
2248 "occurrence",
2249 "event",
2250 "issue_id",
2251 NULL AS "initiative_id",
2252 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2253 NULL::INT8 AS "suggestion_id"
2254 FROM "timeline_issue"
2255 UNION ALL
2256 SELECT
2257 "occurrence",
2258 "event",
2259 NULL AS "issue_id",
2260 "initiative_id",
2261 NULL AS "draft_id",
2262 NULL AS "suggestion_id"
2263 FROM "timeline_initiative"
2264 UNION ALL
2265 SELECT
2266 "occurrence",
2267 "event",
2268 NULL AS "issue_id",
2269 NULL AS "initiative_id",
2270 "draft_id",
2271 NULL AS "suggestion_id"
2272 FROM "timeline_draft"
2273 UNION ALL
2274 SELECT
2275 "occurrence",
2276 "event",
2277 NULL AS "issue_id",
2278 NULL AS "initiative_id",
2279 NULL AS "draft_id",
2280 "suggestion_id"
2281 FROM "timeline_suggestion";
2283 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2287 --------------------------------------------------
2288 -- Set returning function for delegation chains --
2289 --------------------------------------------------
2292 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2293 ('first', 'intermediate', 'last', 'repetition');
2295 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2298 CREATE TYPE "delegation_chain_row" AS (
2299 "index" INT4,
2300 "member_id" INT4,
2301 "member_valid" BOOLEAN,
2302 "participation" BOOLEAN,
2303 "overridden" BOOLEAN,
2304 "scope_in" "delegation_scope",
2305 "scope_out" "delegation_scope",
2306 "disabled_out" BOOLEAN,
2307 "loop" "delegation_chain_loop_tag" );
2309 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2311 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2312 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';
2313 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2314 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2315 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2316 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2317 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2320 CREATE FUNCTION "delegation_chain"
2321 ( "member_id_p" "member"."id"%TYPE,
2322 "unit_id_p" "unit"."id"%TYPE,
2323 "area_id_p" "area"."id"%TYPE,
2324 "issue_id_p" "issue"."id"%TYPE,
2325 "simulate_trustee_id_p" "member"."id"%TYPE )
2326 RETURNS SETOF "delegation_chain_row"
2327 LANGUAGE 'plpgsql' STABLE AS $$
2328 DECLARE
2329 "scope_v" "delegation_scope";
2330 "unit_id_v" "unit"."id"%TYPE;
2331 "area_id_v" "area"."id"%TYPE;
2332 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2333 "loop_member_id_v" "member"."id"%TYPE;
2334 "output_row" "delegation_chain_row";
2335 "output_rows" "delegation_chain_row"[];
2336 "delegation_row" "delegation"%ROWTYPE;
2337 "row_count" INT4;
2338 "i" INT4;
2339 "loop_v" BOOLEAN;
2340 BEGIN
2341 IF
2342 "unit_id_p" NOTNULL AND
2343 "area_id_p" ISNULL AND
2344 "issue_id_p" ISNULL
2345 THEN
2346 "scope_v" := 'unit';
2347 "unit_id_v" := "unit_id_p";
2348 ELSIF
2349 "unit_id_p" ISNULL AND
2350 "area_id_p" NOTNULL AND
2351 "issue_id_p" ISNULL
2352 THEN
2353 "scope_v" := 'area';
2354 "area_id_v" := "area_id_p";
2355 SELECT "unit_id" INTO "unit_id_v"
2356 FROM "area" WHERE "id" = "area_id_v";
2357 ELSIF
2358 "unit_id_p" ISNULL AND
2359 "area_id_p" ISNULL AND
2360 "issue_id_p" NOTNULL
2361 THEN
2362 "scope_v" := 'issue';
2363 SELECT "area_id" INTO "area_id_v"
2364 FROM "issue" WHERE "id" = "issue_id_p";
2365 SELECT "unit_id" INTO "unit_id_v"
2366 FROM "area" WHERE "id" = "area_id_v";
2367 ELSE
2368 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2369 END IF;
2370 "visited_member_ids" := '{}';
2371 "loop_member_id_v" := NULL;
2372 "output_rows" := '{}';
2373 "output_row"."index" := 0;
2374 "output_row"."member_id" := "member_id_p";
2375 "output_row"."member_valid" := TRUE;
2376 "output_row"."participation" := FALSE;
2377 "output_row"."overridden" := FALSE;
2378 "output_row"."disabled_out" := FALSE;
2379 "output_row"."scope_out" := NULL;
2380 LOOP
2381 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2382 "loop_member_id_v" := "output_row"."member_id";
2383 ELSE
2384 "visited_member_ids" :=
2385 "visited_member_ids" || "output_row"."member_id";
2386 END IF;
2387 IF "output_row"."participation" THEN
2388 "output_row"."overridden" := TRUE;
2389 END IF;
2390 "output_row"."scope_in" := "output_row"."scope_out";
2391 IF EXISTS (
2392 SELECT NULL FROM "member" JOIN "privilege"
2393 ON "privilege"."member_id" = "member"."id"
2394 AND "privilege"."unit_id" = "unit_id_v"
2395 WHERE "id" = "output_row"."member_id"
2396 AND "member"."active" AND "privilege"."voting_right"
2397 ) THEN
2398 IF "scope_v" = 'unit' THEN
2399 SELECT * INTO "delegation_row" FROM "delegation"
2400 WHERE "truster_id" = "output_row"."member_id"
2401 AND "unit_id" = "unit_id_v";
2402 ELSIF "scope_v" = 'area' THEN
2403 "output_row"."participation" := EXISTS (
2404 SELECT NULL FROM "membership"
2405 WHERE "area_id" = "area_id_p"
2406 AND "member_id" = "output_row"."member_id"
2407 );
2408 SELECT * INTO "delegation_row" FROM "delegation"
2409 WHERE "truster_id" = "output_row"."member_id"
2410 AND (
2411 "unit_id" = "unit_id_v" OR
2412 "area_id" = "area_id_v"
2414 ORDER BY "scope" DESC;
2415 ELSIF "scope_v" = 'issue' THEN
2416 "output_row"."participation" := EXISTS (
2417 SELECT NULL FROM "interest"
2418 WHERE "issue_id" = "issue_id_p"
2419 AND "member_id" = "output_row"."member_id"
2420 );
2421 SELECT * INTO "delegation_row" FROM "delegation"
2422 WHERE "truster_id" = "output_row"."member_id"
2423 AND (
2424 "unit_id" = "unit_id_v" OR
2425 "area_id" = "area_id_v" OR
2426 "issue_id" = "issue_id_p"
2428 ORDER BY "scope" DESC;
2429 END IF;
2430 ELSE
2431 "output_row"."member_valid" := FALSE;
2432 "output_row"."participation" := FALSE;
2433 "output_row"."scope_out" := NULL;
2434 "delegation_row" := ROW(NULL);
2435 END IF;
2436 IF
2437 "output_row"."member_id" = "member_id_p" AND
2438 "simulate_trustee_id_p" NOTNULL
2439 THEN
2440 "output_row"."scope_out" := "scope_v";
2441 "output_rows" := "output_rows" || "output_row";
2442 "output_row"."member_id" := "simulate_trustee_id_p";
2443 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2444 "output_row"."scope_out" := "delegation_row"."scope";
2445 "output_rows" := "output_rows" || "output_row";
2446 "output_row"."member_id" := "delegation_row"."trustee_id";
2447 ELSIF "delegation_row"."scope" NOTNULL THEN
2448 "output_row"."scope_out" := "delegation_row"."scope";
2449 "output_row"."disabled_out" := TRUE;
2450 "output_rows" := "output_rows" || "output_row";
2451 EXIT;
2452 ELSE
2453 "output_row"."scope_out" := NULL;
2454 "output_rows" := "output_rows" || "output_row";
2455 EXIT;
2456 END IF;
2457 EXIT WHEN "loop_member_id_v" NOTNULL;
2458 "output_row"."index" := "output_row"."index" + 1;
2459 END LOOP;
2460 "row_count" := array_upper("output_rows", 1);
2461 "i" := 1;
2462 "loop_v" := FALSE;
2463 LOOP
2464 "output_row" := "output_rows"["i"];
2465 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2466 IF "loop_v" THEN
2467 IF "i" + 1 = "row_count" THEN
2468 "output_row"."loop" := 'last';
2469 ELSIF "i" = "row_count" THEN
2470 "output_row"."loop" := 'repetition';
2471 ELSE
2472 "output_row"."loop" := 'intermediate';
2473 END IF;
2474 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2475 "output_row"."loop" := 'first';
2476 "loop_v" := TRUE;
2477 END IF;
2478 IF "scope_v" = 'unit' THEN
2479 "output_row"."participation" := NULL;
2480 END IF;
2481 RETURN NEXT "output_row";
2482 "i" := "i" + 1;
2483 END LOOP;
2484 RETURN;
2485 END;
2486 $$;
2488 COMMENT ON FUNCTION "delegation_chain"
2489 ( "member"."id"%TYPE,
2490 "unit"."id"%TYPE,
2491 "area"."id"%TYPE,
2492 "issue"."id"%TYPE,
2493 "member"."id"%TYPE )
2494 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2497 CREATE FUNCTION "delegation_chain"
2498 ( "member_id_p" "member"."id"%TYPE,
2499 "unit_id_p" "unit"."id"%TYPE,
2500 "area_id_p" "area"."id"%TYPE,
2501 "issue_id_p" "issue"."id"%TYPE )
2502 RETURNS SETOF "delegation_chain_row"
2503 LANGUAGE 'plpgsql' STABLE AS $$
2504 DECLARE
2505 "result_row" "delegation_chain_row";
2506 BEGIN
2507 FOR "result_row" IN
2508 SELECT * FROM "delegation_chain"(
2509 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2511 LOOP
2512 RETURN NEXT "result_row";
2513 END LOOP;
2514 RETURN;
2515 END;
2516 $$;
2518 COMMENT ON FUNCTION "delegation_chain"
2519 ( "member"."id"%TYPE,
2520 "unit"."id"%TYPE,
2521 "area"."id"%TYPE,
2522 "issue"."id"%TYPE )
2523 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2527 ------------------------------
2528 -- Comparison by vote count --
2529 ------------------------------
2531 CREATE FUNCTION "vote_ratio"
2532 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2533 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2534 RETURNS FLOAT8
2535 LANGUAGE 'plpgsql' STABLE AS $$
2536 BEGIN
2537 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2538 RETURN
2539 "positive_votes_p"::FLOAT8 /
2540 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2541 ELSIF "positive_votes_p" > 0 THEN
2542 RETURN "positive_votes_p";
2543 ELSIF "negative_votes_p" > 0 THEN
2544 RETURN 1 - "negative_votes_p";
2545 ELSE
2546 RETURN 0.5;
2547 END IF;
2548 END;
2549 $$;
2551 COMMENT ON FUNCTION "vote_ratio"
2552 ( "initiative"."positive_votes"%TYPE,
2553 "initiative"."negative_votes"%TYPE )
2554 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.';
2558 ------------------------------------------------
2559 -- Locking for snapshots and voting procedure --
2560 ------------------------------------------------
2563 CREATE FUNCTION "share_row_lock_issue_trigger"()
2564 RETURNS TRIGGER
2565 LANGUAGE 'plpgsql' VOLATILE AS $$
2566 BEGIN
2567 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2568 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2569 END IF;
2570 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2571 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2572 RETURN NEW;
2573 ELSE
2574 RETURN OLD;
2575 END IF;
2576 END;
2577 $$;
2579 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2582 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2583 RETURNS TRIGGER
2584 LANGUAGE 'plpgsql' VOLATILE AS $$
2585 BEGIN
2586 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2587 PERFORM NULL FROM "issue"
2588 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2589 WHERE "initiative"."id" = OLD."initiative_id"
2590 FOR SHARE OF "issue";
2591 END IF;
2592 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2593 PERFORM NULL FROM "issue"
2594 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2595 WHERE "initiative"."id" = NEW."initiative_id"
2596 FOR SHARE OF "issue";
2597 RETURN NEW;
2598 ELSE
2599 RETURN OLD;
2600 END IF;
2601 END;
2602 $$;
2604 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2607 CREATE TRIGGER "share_row_lock_issue"
2608 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2609 FOR EACH ROW EXECUTE PROCEDURE
2610 "share_row_lock_issue_trigger"();
2612 CREATE TRIGGER "share_row_lock_issue"
2613 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2614 FOR EACH ROW EXECUTE PROCEDURE
2615 "share_row_lock_issue_trigger"();
2617 CREATE TRIGGER "share_row_lock_issue"
2618 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2619 FOR EACH ROW EXECUTE PROCEDURE
2620 "share_row_lock_issue_trigger"();
2622 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2623 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2624 FOR EACH ROW EXECUTE PROCEDURE
2625 "share_row_lock_issue_via_initiative_trigger"();
2627 CREATE TRIGGER "share_row_lock_issue"
2628 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2629 FOR EACH ROW EXECUTE PROCEDURE
2630 "share_row_lock_issue_trigger"();
2632 CREATE TRIGGER "share_row_lock_issue"
2633 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2634 FOR EACH ROW EXECUTE PROCEDURE
2635 "share_row_lock_issue_trigger"();
2637 CREATE TRIGGER "share_row_lock_issue"
2638 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2639 FOR EACH ROW EXECUTE PROCEDURE
2640 "share_row_lock_issue_trigger"();
2642 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2643 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2644 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2645 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2646 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2647 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2648 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2651 CREATE FUNCTION "lock_issue"
2652 ( "issue_id_p" "issue"."id"%TYPE )
2653 RETURNS VOID
2654 LANGUAGE 'plpgsql' VOLATILE AS $$
2655 BEGIN
2656 LOCK TABLE "member" IN SHARE MODE;
2657 LOCK TABLE "privilege" IN SHARE MODE;
2658 LOCK TABLE "membership" IN SHARE MODE;
2659 LOCK TABLE "policy" IN SHARE MODE;
2660 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2661 -- NOTE: The row-level exclusive lock in combination with the
2662 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2663 -- acquire a row-level share lock on the issue) ensure that no data
2664 -- is changed, which could affect calculation of snapshots or
2665 -- counting of votes. Table "delegation" must be table-level-locked,
2666 -- as it also contains issue- and global-scope delegations.
2667 LOCK TABLE "delegation" IN SHARE MODE;
2668 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2669 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2670 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2671 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2672 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2673 RETURN;
2674 END;
2675 $$;
2677 COMMENT ON FUNCTION "lock_issue"
2678 ( "issue"."id"%TYPE )
2679 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2683 ------------------------------------------------------------------------
2684 -- Regular tasks, except calculcation of snapshots and voting results --
2685 ------------------------------------------------------------------------
2687 CREATE FUNCTION "check_activity"()
2688 RETURNS VOID
2689 LANGUAGE 'plpgsql' VOLATILE AS $$
2690 DECLARE
2691 "system_setting_row" "system_setting"%ROWTYPE;
2692 BEGIN
2693 SELECT * INTO "system_setting_row" FROM "system_setting";
2694 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2695 IF "system_setting_row"."member_ttl" NOTNULL THEN
2696 UPDATE "member" SET "active" = FALSE
2697 WHERE "active" = TRUE
2698 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2699 END IF;
2700 RETURN;
2701 END;
2702 $$;
2704 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2707 CREATE FUNCTION "calculate_member_counts"()
2708 RETURNS VOID
2709 LANGUAGE 'plpgsql' VOLATILE AS $$
2710 BEGIN
2711 LOCK TABLE "member" IN SHARE MODE;
2712 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2713 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2714 LOCK TABLE "area" IN EXCLUSIVE MODE;
2715 LOCK TABLE "privilege" IN SHARE MODE;
2716 LOCK TABLE "membership" IN SHARE MODE;
2717 DELETE FROM "member_count";
2718 INSERT INTO "member_count" ("total_count")
2719 SELECT "total_count" FROM "member_count_view";
2720 UPDATE "unit" SET "member_count" = "view"."member_count"
2721 FROM "unit_member_count" AS "view"
2722 WHERE "view"."unit_id" = "unit"."id";
2723 UPDATE "area" SET
2724 "direct_member_count" = "view"."direct_member_count",
2725 "member_weight" = "view"."member_weight"
2726 FROM "area_member_count" AS "view"
2727 WHERE "view"."area_id" = "area"."id";
2728 RETURN;
2729 END;
2730 $$;
2732 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"';
2736 ------------------------------
2737 -- Calculation of snapshots --
2738 ------------------------------
2740 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2741 ( "issue_id_p" "issue"."id"%TYPE,
2742 "member_id_p" "member"."id"%TYPE,
2743 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2744 RETURNS "direct_population_snapshot"."weight"%TYPE
2745 LANGUAGE 'plpgsql' VOLATILE AS $$
2746 DECLARE
2747 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2748 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2749 "weight_v" INT4;
2750 "sub_weight_v" INT4;
2751 BEGIN
2752 "weight_v" := 0;
2753 FOR "issue_delegation_row" IN
2754 SELECT * FROM "issue_delegation"
2755 WHERE "trustee_id" = "member_id_p"
2756 AND "issue_id" = "issue_id_p"
2757 LOOP
2758 IF NOT EXISTS (
2759 SELECT NULL FROM "direct_population_snapshot"
2760 WHERE "issue_id" = "issue_id_p"
2761 AND "event" = 'periodic'
2762 AND "member_id" = "issue_delegation_row"."truster_id"
2763 ) AND NOT EXISTS (
2764 SELECT NULL FROM "delegating_population_snapshot"
2765 WHERE "issue_id" = "issue_id_p"
2766 AND "event" = 'periodic'
2767 AND "member_id" = "issue_delegation_row"."truster_id"
2768 ) THEN
2769 "delegate_member_ids_v" :=
2770 "member_id_p" || "delegate_member_ids_p";
2771 INSERT INTO "delegating_population_snapshot" (
2772 "issue_id",
2773 "event",
2774 "member_id",
2775 "scope",
2776 "delegate_member_ids"
2777 ) VALUES (
2778 "issue_id_p",
2779 'periodic',
2780 "issue_delegation_row"."truster_id",
2781 "issue_delegation_row"."scope",
2782 "delegate_member_ids_v"
2783 );
2784 "sub_weight_v" := 1 +
2785 "weight_of_added_delegations_for_population_snapshot"(
2786 "issue_id_p",
2787 "issue_delegation_row"."truster_id",
2788 "delegate_member_ids_v"
2789 );
2790 UPDATE "delegating_population_snapshot"
2791 SET "weight" = "sub_weight_v"
2792 WHERE "issue_id" = "issue_id_p"
2793 AND "event" = 'periodic'
2794 AND "member_id" = "issue_delegation_row"."truster_id";
2795 "weight_v" := "weight_v" + "sub_weight_v";
2796 END IF;
2797 END LOOP;
2798 RETURN "weight_v";
2799 END;
2800 $$;
2802 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2803 ( "issue"."id"%TYPE,
2804 "member"."id"%TYPE,
2805 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2806 IS 'Helper function for "create_population_snapshot" function';
2809 CREATE FUNCTION "create_population_snapshot"
2810 ( "issue_id_p" "issue"."id"%TYPE )
2811 RETURNS VOID
2812 LANGUAGE 'plpgsql' VOLATILE AS $$
2813 DECLARE
2814 "member_id_v" "member"."id"%TYPE;
2815 BEGIN
2816 DELETE FROM "direct_population_snapshot"
2817 WHERE "issue_id" = "issue_id_p"
2818 AND "event" = 'periodic';
2819 DELETE FROM "delegating_population_snapshot"
2820 WHERE "issue_id" = "issue_id_p"
2821 AND "event" = 'periodic';
2822 INSERT INTO "direct_population_snapshot"
2823 ("issue_id", "event", "member_id")
2824 SELECT
2825 "issue_id_p" AS "issue_id",
2826 'periodic'::"snapshot_event" AS "event",
2827 "member"."id" AS "member_id"
2828 FROM "issue"
2829 JOIN "area" ON "issue"."area_id" = "area"."id"
2830 JOIN "membership" ON "area"."id" = "membership"."area_id"
2831 JOIN "member" ON "membership"."member_id" = "member"."id"
2832 JOIN "privilege"
2833 ON "privilege"."unit_id" = "area"."unit_id"
2834 AND "privilege"."member_id" = "member"."id"
2835 WHERE "issue"."id" = "issue_id_p"
2836 AND "member"."active" AND "privilege"."voting_right"
2837 UNION
2838 SELECT
2839 "issue_id_p" AS "issue_id",
2840 'periodic'::"snapshot_event" AS "event",
2841 "member"."id" AS "member_id"
2842 FROM "issue"
2843 JOIN "area" ON "issue"."area_id" = "area"."id"
2844 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2845 JOIN "member" ON "interest"."member_id" = "member"."id"
2846 JOIN "privilege"
2847 ON "privilege"."unit_id" = "area"."unit_id"
2848 AND "privilege"."member_id" = "member"."id"
2849 WHERE "issue"."id" = "issue_id_p"
2850 AND "member"."active" AND "privilege"."voting_right";
2851 FOR "member_id_v" IN
2852 SELECT "member_id" FROM "direct_population_snapshot"
2853 WHERE "issue_id" = "issue_id_p"
2854 AND "event" = 'periodic'
2855 LOOP
2856 UPDATE "direct_population_snapshot" SET
2857 "weight" = 1 +
2858 "weight_of_added_delegations_for_population_snapshot"(
2859 "issue_id_p",
2860 "member_id_v",
2861 '{}'
2863 WHERE "issue_id" = "issue_id_p"
2864 AND "event" = 'periodic'
2865 AND "member_id" = "member_id_v";
2866 END LOOP;
2867 RETURN;
2868 END;
2869 $$;
2871 COMMENT ON FUNCTION "create_population_snapshot"
2872 ( "issue"."id"%TYPE )
2873 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.';
2876 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2877 ( "issue_id_p" "issue"."id"%TYPE,
2878 "member_id_p" "member"."id"%TYPE,
2879 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2880 RETURNS "direct_interest_snapshot"."weight"%TYPE
2881 LANGUAGE 'plpgsql' VOLATILE AS $$
2882 DECLARE
2883 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2884 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2885 "weight_v" INT4;
2886 "sub_weight_v" INT4;
2887 BEGIN
2888 "weight_v" := 0;
2889 FOR "issue_delegation_row" IN
2890 SELECT * FROM "issue_delegation"
2891 WHERE "trustee_id" = "member_id_p"
2892 AND "issue_id" = "issue_id_p"
2893 LOOP
2894 IF NOT EXISTS (
2895 SELECT NULL FROM "direct_interest_snapshot"
2896 WHERE "issue_id" = "issue_id_p"
2897 AND "event" = 'periodic'
2898 AND "member_id" = "issue_delegation_row"."truster_id"
2899 ) AND NOT EXISTS (
2900 SELECT NULL FROM "delegating_interest_snapshot"
2901 WHERE "issue_id" = "issue_id_p"
2902 AND "event" = 'periodic'
2903 AND "member_id" = "issue_delegation_row"."truster_id"
2904 ) THEN
2905 "delegate_member_ids_v" :=
2906 "member_id_p" || "delegate_member_ids_p";
2907 INSERT INTO "delegating_interest_snapshot" (
2908 "issue_id",
2909 "event",
2910 "member_id",
2911 "scope",
2912 "delegate_member_ids"
2913 ) VALUES (
2914 "issue_id_p",
2915 'periodic',
2916 "issue_delegation_row"."truster_id",
2917 "issue_delegation_row"."scope",
2918 "delegate_member_ids_v"
2919 );
2920 "sub_weight_v" := 1 +
2921 "weight_of_added_delegations_for_interest_snapshot"(
2922 "issue_id_p",
2923 "issue_delegation_row"."truster_id",
2924 "delegate_member_ids_v"
2925 );
2926 UPDATE "delegating_interest_snapshot"
2927 SET "weight" = "sub_weight_v"
2928 WHERE "issue_id" = "issue_id_p"
2929 AND "event" = 'periodic'
2930 AND "member_id" = "issue_delegation_row"."truster_id";
2931 "weight_v" := "weight_v" + "sub_weight_v";
2932 END IF;
2933 END LOOP;
2934 RETURN "weight_v";
2935 END;
2936 $$;
2938 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2939 ( "issue"."id"%TYPE,
2940 "member"."id"%TYPE,
2941 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2942 IS 'Helper function for "create_interest_snapshot" function';
2945 CREATE FUNCTION "create_interest_snapshot"
2946 ( "issue_id_p" "issue"."id"%TYPE )
2947 RETURNS VOID
2948 LANGUAGE 'plpgsql' VOLATILE AS $$
2949 DECLARE
2950 "member_id_v" "member"."id"%TYPE;
2951 BEGIN
2952 DELETE FROM "direct_interest_snapshot"
2953 WHERE "issue_id" = "issue_id_p"
2954 AND "event" = 'periodic';
2955 DELETE FROM "delegating_interest_snapshot"
2956 WHERE "issue_id" = "issue_id_p"
2957 AND "event" = 'periodic';
2958 DELETE FROM "direct_supporter_snapshot"
2959 WHERE "issue_id" = "issue_id_p"
2960 AND "event" = 'periodic';
2961 INSERT INTO "direct_interest_snapshot"
2962 ("issue_id", "event", "member_id")
2963 SELECT
2964 "issue_id_p" AS "issue_id",
2965 'periodic' AS "event",
2966 "member"."id" AS "member_id"
2967 FROM "issue"
2968 JOIN "area" ON "issue"."area_id" = "area"."id"
2969 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2970 JOIN "member" ON "interest"."member_id" = "member"."id"
2971 JOIN "privilege"
2972 ON "privilege"."unit_id" = "area"."unit_id"
2973 AND "privilege"."member_id" = "member"."id"
2974 WHERE "issue"."id" = "issue_id_p"
2975 AND "member"."active" AND "privilege"."voting_right";
2976 FOR "member_id_v" IN
2977 SELECT "member_id" FROM "direct_interest_snapshot"
2978 WHERE "issue_id" = "issue_id_p"
2979 AND "event" = 'periodic'
2980 LOOP
2981 UPDATE "direct_interest_snapshot" SET
2982 "weight" = 1 +
2983 "weight_of_added_delegations_for_interest_snapshot"(
2984 "issue_id_p",
2985 "member_id_v",
2986 '{}'
2988 WHERE "issue_id" = "issue_id_p"
2989 AND "event" = 'periodic'
2990 AND "member_id" = "member_id_v";
2991 END LOOP;
2992 INSERT INTO "direct_supporter_snapshot"
2993 ( "issue_id", "initiative_id", "event", "member_id",
2994 "informed", "satisfied" )
2995 SELECT
2996 "issue_id_p" AS "issue_id",
2997 "initiative"."id" AS "initiative_id",
2998 'periodic' AS "event",
2999 "supporter"."member_id" AS "member_id",
3000 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3001 NOT EXISTS (
3002 SELECT NULL FROM "critical_opinion"
3003 WHERE "initiative_id" = "initiative"."id"
3004 AND "member_id" = "supporter"."member_id"
3005 ) AS "satisfied"
3006 FROM "initiative"
3007 JOIN "supporter"
3008 ON "supporter"."initiative_id" = "initiative"."id"
3009 JOIN "current_draft"
3010 ON "initiative"."id" = "current_draft"."initiative_id"
3011 JOIN "direct_interest_snapshot"
3012 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3013 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3014 AND "event" = 'periodic'
3015 WHERE "initiative"."issue_id" = "issue_id_p";
3016 RETURN;
3017 END;
3018 $$;
3020 COMMENT ON FUNCTION "create_interest_snapshot"
3021 ( "issue"."id"%TYPE )
3022 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.';
3025 CREATE FUNCTION "create_snapshot"
3026 ( "issue_id_p" "issue"."id"%TYPE )
3027 RETURNS VOID
3028 LANGUAGE 'plpgsql' VOLATILE AS $$
3029 DECLARE
3030 "initiative_id_v" "initiative"."id"%TYPE;
3031 "suggestion_id_v" "suggestion"."id"%TYPE;
3032 BEGIN
3033 PERFORM "lock_issue"("issue_id_p");
3034 PERFORM "create_population_snapshot"("issue_id_p");
3035 PERFORM "create_interest_snapshot"("issue_id_p");
3036 UPDATE "issue" SET
3037 "snapshot" = now(),
3038 "latest_snapshot_event" = 'periodic',
3039 "population" = (
3040 SELECT coalesce(sum("weight"), 0)
3041 FROM "direct_population_snapshot"
3042 WHERE "issue_id" = "issue_id_p"
3043 AND "event" = 'periodic'
3045 WHERE "id" = "issue_id_p";
3046 FOR "initiative_id_v" IN
3047 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3048 LOOP
3049 UPDATE "initiative" SET
3050 "supporter_count" = (
3051 SELECT coalesce(sum("di"."weight"), 0)
3052 FROM "direct_interest_snapshot" AS "di"
3053 JOIN "direct_supporter_snapshot" AS "ds"
3054 ON "di"."member_id" = "ds"."member_id"
3055 WHERE "di"."issue_id" = "issue_id_p"
3056 AND "di"."event" = 'periodic'
3057 AND "ds"."initiative_id" = "initiative_id_v"
3058 AND "ds"."event" = 'periodic'
3059 ),
3060 "informed_supporter_count" = (
3061 SELECT coalesce(sum("di"."weight"), 0)
3062 FROM "direct_interest_snapshot" AS "di"
3063 JOIN "direct_supporter_snapshot" AS "ds"
3064 ON "di"."member_id" = "ds"."member_id"
3065 WHERE "di"."issue_id" = "issue_id_p"
3066 AND "di"."event" = 'periodic'
3067 AND "ds"."initiative_id" = "initiative_id_v"
3068 AND "ds"."event" = 'periodic'
3069 AND "ds"."informed"
3070 ),
3071 "satisfied_supporter_count" = (
3072 SELECT coalesce(sum("di"."weight"), 0)
3073 FROM "direct_interest_snapshot" AS "di"
3074 JOIN "direct_supporter_snapshot" AS "ds"
3075 ON "di"."member_id" = "ds"."member_id"
3076 WHERE "di"."issue_id" = "issue_id_p"
3077 AND "di"."event" = 'periodic'
3078 AND "ds"."initiative_id" = "initiative_id_v"
3079 AND "ds"."event" = 'periodic'
3080 AND "ds"."satisfied"
3081 ),
3082 "satisfied_informed_supporter_count" = (
3083 SELECT coalesce(sum("di"."weight"), 0)
3084 FROM "direct_interest_snapshot" AS "di"
3085 JOIN "direct_supporter_snapshot" AS "ds"
3086 ON "di"."member_id" = "ds"."member_id"
3087 WHERE "di"."issue_id" = "issue_id_p"
3088 AND "di"."event" = 'periodic'
3089 AND "ds"."initiative_id" = "initiative_id_v"
3090 AND "ds"."event" = 'periodic'
3091 AND "ds"."informed"
3092 AND "ds"."satisfied"
3094 WHERE "id" = "initiative_id_v";
3095 FOR "suggestion_id_v" IN
3096 SELECT "id" FROM "suggestion"
3097 WHERE "initiative_id" = "initiative_id_v"
3098 LOOP
3099 UPDATE "suggestion" SET
3100 "minus2_unfulfilled_count" = (
3101 SELECT coalesce(sum("snapshot"."weight"), 0)
3102 FROM "issue" CROSS JOIN "opinion"
3103 JOIN "direct_interest_snapshot" AS "snapshot"
3104 ON "snapshot"."issue_id" = "issue"."id"
3105 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3106 AND "snapshot"."member_id" = "opinion"."member_id"
3107 WHERE "issue"."id" = "issue_id_p"
3108 AND "opinion"."suggestion_id" = "suggestion_id_v"
3109 AND "opinion"."degree" = -2
3110 AND "opinion"."fulfilled" = FALSE
3111 ),
3112 "minus2_fulfilled_count" = (
3113 SELECT coalesce(sum("snapshot"."weight"), 0)
3114 FROM "issue" CROSS JOIN "opinion"
3115 JOIN "direct_interest_snapshot" AS "snapshot"
3116 ON "snapshot"."issue_id" = "issue"."id"
3117 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3118 AND "snapshot"."member_id" = "opinion"."member_id"
3119 WHERE "issue"."id" = "issue_id_p"
3120 AND "opinion"."suggestion_id" = "suggestion_id_v"
3121 AND "opinion"."degree" = -2
3122 AND "opinion"."fulfilled" = TRUE
3123 ),
3124 "minus1_unfulfilled_count" = (
3125 SELECT coalesce(sum("snapshot"."weight"), 0)
3126 FROM "issue" CROSS JOIN "opinion"
3127 JOIN "direct_interest_snapshot" AS "snapshot"
3128 ON "snapshot"."issue_id" = "issue"."id"
3129 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3130 AND "snapshot"."member_id" = "opinion"."member_id"
3131 WHERE "issue"."id" = "issue_id_p"
3132 AND "opinion"."suggestion_id" = "suggestion_id_v"
3133 AND "opinion"."degree" = -1
3134 AND "opinion"."fulfilled" = FALSE
3135 ),
3136 "minus1_fulfilled_count" = (
3137 SELECT coalesce(sum("snapshot"."weight"), 0)
3138 FROM "issue" CROSS JOIN "opinion"
3139 JOIN "direct_interest_snapshot" AS "snapshot"
3140 ON "snapshot"."issue_id" = "issue"."id"
3141 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3142 AND "snapshot"."member_id" = "opinion"."member_id"
3143 WHERE "issue"."id" = "issue_id_p"
3144 AND "opinion"."suggestion_id" = "suggestion_id_v"
3145 AND "opinion"."degree" = -1
3146 AND "opinion"."fulfilled" = TRUE
3147 ),
3148 "plus1_unfulfilled_count" = (
3149 SELECT coalesce(sum("snapshot"."weight"), 0)
3150 FROM "issue" CROSS JOIN "opinion"
3151 JOIN "direct_interest_snapshot" AS "snapshot"
3152 ON "snapshot"."issue_id" = "issue"."id"
3153 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3154 AND "snapshot"."member_id" = "opinion"."member_id"
3155 WHERE "issue"."id" = "issue_id_p"
3156 AND "opinion"."suggestion_id" = "suggestion_id_v"
3157 AND "opinion"."degree" = 1
3158 AND "opinion"."fulfilled" = FALSE
3159 ),
3160 "plus1_fulfilled_count" = (
3161 SELECT coalesce(sum("snapshot"."weight"), 0)
3162 FROM "issue" CROSS JOIN "opinion"
3163 JOIN "direct_interest_snapshot" AS "snapshot"
3164 ON "snapshot"."issue_id" = "issue"."id"
3165 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3166 AND "snapshot"."member_id" = "opinion"."member_id"
3167 WHERE "issue"."id" = "issue_id_p"
3168 AND "opinion"."suggestion_id" = "suggestion_id_v"
3169 AND "opinion"."degree" = 1
3170 AND "opinion"."fulfilled" = TRUE
3171 ),
3172 "plus2_unfulfilled_count" = (
3173 SELECT coalesce(sum("snapshot"."weight"), 0)
3174 FROM "issue" CROSS JOIN "opinion"
3175 JOIN "direct_interest_snapshot" AS "snapshot"
3176 ON "snapshot"."issue_id" = "issue"."id"
3177 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3178 AND "snapshot"."member_id" = "opinion"."member_id"
3179 WHERE "issue"."id" = "issue_id_p"
3180 AND "opinion"."suggestion_id" = "suggestion_id_v"
3181 AND "opinion"."degree" = 2
3182 AND "opinion"."fulfilled" = FALSE
3183 ),
3184 "plus2_fulfilled_count" = (
3185 SELECT coalesce(sum("snapshot"."weight"), 0)
3186 FROM "issue" CROSS JOIN "opinion"
3187 JOIN "direct_interest_snapshot" AS "snapshot"
3188 ON "snapshot"."issue_id" = "issue"."id"
3189 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3190 AND "snapshot"."member_id" = "opinion"."member_id"
3191 WHERE "issue"."id" = "issue_id_p"
3192 AND "opinion"."suggestion_id" = "suggestion_id_v"
3193 AND "opinion"."degree" = 2
3194 AND "opinion"."fulfilled" = TRUE
3196 WHERE "suggestion"."id" = "suggestion_id_v";
3197 END LOOP;
3198 END LOOP;
3199 RETURN;
3200 END;
3201 $$;
3203 COMMENT ON FUNCTION "create_snapshot"
3204 ( "issue"."id"%TYPE )
3205 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.';
3208 CREATE FUNCTION "set_snapshot_event"
3209 ( "issue_id_p" "issue"."id"%TYPE,
3210 "event_p" "snapshot_event" )
3211 RETURNS VOID
3212 LANGUAGE 'plpgsql' VOLATILE AS $$
3213 DECLARE
3214 "event_v" "issue"."latest_snapshot_event"%TYPE;
3215 BEGIN
3216 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3217 WHERE "id" = "issue_id_p" FOR UPDATE;
3218 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3219 WHERE "id" = "issue_id_p";
3220 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3221 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3222 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3223 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3224 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3225 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3226 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3227 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3228 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3229 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3230 RETURN;
3231 END;
3232 $$;
3234 COMMENT ON FUNCTION "set_snapshot_event"
3235 ( "issue"."id"%TYPE,
3236 "snapshot_event" )
3237 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3241 ---------------------
3242 -- Freezing issues --
3243 ---------------------
3245 CREATE FUNCTION "freeze_after_snapshot"
3246 ( "issue_id_p" "issue"."id"%TYPE )
3247 RETURNS VOID
3248 LANGUAGE 'plpgsql' VOLATILE AS $$
3249 DECLARE
3250 "issue_row" "issue"%ROWTYPE;
3251 "policy_row" "policy"%ROWTYPE;
3252 "initiative_row" "initiative"%ROWTYPE;
3253 BEGIN
3254 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3255 SELECT * INTO "policy_row"
3256 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3257 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3258 FOR "initiative_row" IN
3259 SELECT * FROM "initiative"
3260 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3261 LOOP
3262 IF
3263 "initiative_row"."satisfied_supporter_count" > 0 AND
3264 "initiative_row"."satisfied_supporter_count" *
3265 "policy_row"."initiative_quorum_den" >=
3266 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3267 THEN
3268 UPDATE "initiative" SET "admitted" = TRUE
3269 WHERE "id" = "initiative_row"."id";
3270 ELSE
3271 UPDATE "initiative" SET "admitted" = FALSE
3272 WHERE "id" = "initiative_row"."id";
3273 END IF;
3274 END LOOP;
3275 IF EXISTS (
3276 SELECT NULL FROM "initiative"
3277 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3278 ) THEN
3279 UPDATE "issue" SET
3280 "state" = 'voting',
3281 "accepted" = coalesce("accepted", now()),
3282 "half_frozen" = coalesce("half_frozen", now()),
3283 "fully_frozen" = now()
3284 WHERE "id" = "issue_id_p";
3285 ELSE
3286 UPDATE "issue" SET
3287 "state" = 'canceled_no_initiative_admitted',
3288 "accepted" = coalesce("accepted", now()),
3289 "half_frozen" = coalesce("half_frozen", now()),
3290 "fully_frozen" = now(),
3291 "closed" = now(),
3292 "ranks_available" = TRUE
3293 WHERE "id" = "issue_id_p";
3294 -- NOTE: The following DELETE statements have effect only when
3295 -- issue state has been manipulated
3296 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3297 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3298 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3299 END IF;
3300 RETURN;
3301 END;
3302 $$;
3304 COMMENT ON FUNCTION "freeze_after_snapshot"
3305 ( "issue"."id"%TYPE )
3306 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3309 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3310 RETURNS VOID
3311 LANGUAGE 'plpgsql' VOLATILE AS $$
3312 DECLARE
3313 "issue_row" "issue"%ROWTYPE;
3314 BEGIN
3315 PERFORM "create_snapshot"("issue_id_p");
3316 PERFORM "freeze_after_snapshot"("issue_id_p");
3317 RETURN;
3318 END;
3319 $$;
3321 COMMENT ON FUNCTION "manual_freeze"
3322 ( "issue"."id"%TYPE )
3323 IS 'Freeze an issue manually (fully) and start voting';
3327 -----------------------
3328 -- Counting of votes --
3329 -----------------------
3332 CREATE FUNCTION "weight_of_added_vote_delegations"
3333 ( "issue_id_p" "issue"."id"%TYPE,
3334 "member_id_p" "member"."id"%TYPE,
3335 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3336 RETURNS "direct_voter"."weight"%TYPE
3337 LANGUAGE 'plpgsql' VOLATILE AS $$
3338 DECLARE
3339 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3340 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3341 "weight_v" INT4;
3342 "sub_weight_v" INT4;
3343 BEGIN
3344 "weight_v" := 0;
3345 FOR "issue_delegation_row" IN
3346 SELECT * FROM "issue_delegation"
3347 WHERE "trustee_id" = "member_id_p"
3348 AND "issue_id" = "issue_id_p"
3349 LOOP
3350 IF NOT EXISTS (
3351 SELECT NULL FROM "direct_voter"
3352 WHERE "member_id" = "issue_delegation_row"."truster_id"
3353 AND "issue_id" = "issue_id_p"
3354 ) AND NOT EXISTS (
3355 SELECT NULL FROM "delegating_voter"
3356 WHERE "member_id" = "issue_delegation_row"."truster_id"
3357 AND "issue_id" = "issue_id_p"
3358 ) THEN
3359 "delegate_member_ids_v" :=
3360 "member_id_p" || "delegate_member_ids_p";
3361 INSERT INTO "delegating_voter" (
3362 "issue_id",
3363 "member_id",
3364 "scope",
3365 "delegate_member_ids"
3366 ) VALUES (
3367 "issue_id_p",
3368 "issue_delegation_row"."truster_id",
3369 "issue_delegation_row"."scope",
3370 "delegate_member_ids_v"
3371 );
3372 "sub_weight_v" := 1 +
3373 "weight_of_added_vote_delegations"(
3374 "issue_id_p",
3375 "issue_delegation_row"."truster_id",
3376 "delegate_member_ids_v"
3377 );
3378 UPDATE "delegating_voter"
3379 SET "weight" = "sub_weight_v"
3380 WHERE "issue_id" = "issue_id_p"
3381 AND "member_id" = "issue_delegation_row"."truster_id";
3382 "weight_v" := "weight_v" + "sub_weight_v";
3383 END IF;
3384 END LOOP;
3385 RETURN "weight_v";
3386 END;
3387 $$;
3389 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3390 ( "issue"."id"%TYPE,
3391 "member"."id"%TYPE,
3392 "delegating_voter"."delegate_member_ids"%TYPE )
3393 IS 'Helper function for "add_vote_delegations" function';
3396 CREATE FUNCTION "add_vote_delegations"
3397 ( "issue_id_p" "issue"."id"%TYPE )
3398 RETURNS VOID
3399 LANGUAGE 'plpgsql' VOLATILE AS $$
3400 DECLARE
3401 "member_id_v" "member"."id"%TYPE;
3402 BEGIN
3403 FOR "member_id_v" IN
3404 SELECT "member_id" FROM "direct_voter"
3405 WHERE "issue_id" = "issue_id_p"
3406 LOOP
3407 UPDATE "direct_voter" SET
3408 "weight" = "weight" + "weight_of_added_vote_delegations"(
3409 "issue_id_p",
3410 "member_id_v",
3411 '{}'
3413 WHERE "member_id" = "member_id_v"
3414 AND "issue_id" = "issue_id_p";
3415 END LOOP;
3416 RETURN;
3417 END;
3418 $$;
3420 COMMENT ON FUNCTION "add_vote_delegations"
3421 ( "issue_id_p" "issue"."id"%TYPE )
3422 IS 'Helper function for "close_voting" function';
3425 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3426 RETURNS VOID
3427 LANGUAGE 'plpgsql' VOLATILE AS $$
3428 DECLARE
3429 "area_id_v" "area"."id"%TYPE;
3430 "unit_id_v" "unit"."id"%TYPE;
3431 "member_id_v" "member"."id"%TYPE;
3432 BEGIN
3433 PERFORM "lock_issue"("issue_id_p");
3434 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3435 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3436 -- delete delegating votes (in cases of manual reset of issue state):
3437 DELETE FROM "delegating_voter"
3438 WHERE "issue_id" = "issue_id_p";
3439 -- delete votes from non-privileged voters:
3440 DELETE FROM "direct_voter"
3441 USING (
3442 SELECT
3443 "direct_voter"."member_id"
3444 FROM "direct_voter"
3445 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3446 LEFT JOIN "privilege"
3447 ON "privilege"."unit_id" = "unit_id_v"
3448 AND "privilege"."member_id" = "direct_voter"."member_id"
3449 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3450 "member"."active" = FALSE OR
3451 "privilege"."voting_right" ISNULL OR
3452 "privilege"."voting_right" = FALSE
3454 ) AS "subquery"
3455 WHERE "direct_voter"."issue_id" = "issue_id_p"
3456 AND "direct_voter"."member_id" = "subquery"."member_id";
3457 -- consider delegations:
3458 UPDATE "direct_voter" SET "weight" = 1
3459 WHERE "issue_id" = "issue_id_p";
3460 PERFORM "add_vote_delegations"("issue_id_p");
3461 -- set voter count and mark issue as being calculated:
3462 UPDATE "issue" SET
3463 "state" = 'calculation',
3464 "closed" = now(),
3465 "voter_count" = (
3466 SELECT coalesce(sum("weight"), 0)
3467 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3469 WHERE "id" = "issue_id_p";
3470 -- materialize battle_view:
3471 -- NOTE: "closed" column of issue must be set at this point
3472 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3473 INSERT INTO "battle" (
3474 "issue_id",
3475 "winning_initiative_id", "losing_initiative_id",
3476 "count"
3477 ) SELECT
3478 "issue_id",
3479 "winning_initiative_id", "losing_initiative_id",
3480 "count"
3481 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3482 -- copy "positive_votes" and "negative_votes" from "battle" table:
3483 UPDATE "initiative" SET
3484 "positive_votes" = "battle_win"."count",
3485 "negative_votes" = "battle_lose"."count"
3486 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3487 WHERE
3488 "battle_win"."issue_id" = "issue_id_p" AND
3489 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3490 "battle_win"."losing_initiative_id" ISNULL AND
3491 "battle_lose"."issue_id" = "issue_id_p" AND
3492 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3493 "battle_lose"."winning_initiative_id" ISNULL;
3494 END;
3495 $$;
3497 COMMENT ON FUNCTION "close_voting"
3498 ( "issue"."id"%TYPE )
3499 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.';
3502 CREATE FUNCTION "defeat_strength"
3503 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3504 RETURNS INT8
3505 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3506 BEGIN
3507 IF "positive_votes_p" > "negative_votes_p" THEN
3508 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3509 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3510 RETURN 0;
3511 ELSE
3512 RETURN -1;
3513 END IF;
3514 END;
3515 $$;
3517 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';
3520 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3521 RETURNS VOID
3522 LANGUAGE 'plpgsql' VOLATILE AS $$
3523 DECLARE
3524 "issue_row" "issue"%ROWTYPE;
3525 "policy_row" "policy"%ROWTYPE;
3526 "dimension_v" INTEGER;
3527 "vote_matrix" INT4[][]; -- absolute votes
3528 "matrix" INT8[][]; -- defeat strength / best paths
3529 "i" INTEGER;
3530 "j" INTEGER;
3531 "k" INTEGER;
3532 "battle_row" "battle"%ROWTYPE;
3533 "rank_ary" INT4[];
3534 "rank_v" INT4;
3535 "done_v" INTEGER;
3536 "winners_ary" INTEGER[];
3537 "initiative_id_v" "initiative"."id"%TYPE;
3538 BEGIN
3539 SELECT * INTO "issue_row"
3540 FROM "issue" WHERE "id" = "issue_id_p"
3541 FOR UPDATE;
3542 SELECT * INTO "policy_row"
3543 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3544 SELECT count(1) INTO "dimension_v"
3545 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3546 -- Create "vote_matrix" with absolute number of votes in pairwise
3547 -- comparison:
3548 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3549 "i" := 1;
3550 "j" := 2;
3551 FOR "battle_row" IN
3552 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3553 ORDER BY
3554 "winning_initiative_id" NULLS LAST,
3555 "losing_initiative_id" NULLS LAST
3556 LOOP
3557 "vote_matrix"["i"]["j"] := "battle_row"."count";
3558 IF "j" = "dimension_v" THEN
3559 "i" := "i" + 1;
3560 "j" := 1;
3561 ELSE
3562 "j" := "j" + 1;
3563 IF "j" = "i" THEN
3564 "j" := "j" + 1;
3565 END IF;
3566 END IF;
3567 END LOOP;
3568 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3569 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3570 END IF;
3571 -- Store defeat strengths in "matrix" using "defeat_strength"
3572 -- function:
3573 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3574 "i" := 1;
3575 LOOP
3576 "j" := 1;
3577 LOOP
3578 IF "i" != "j" THEN
3579 "matrix"["i"]["j"] := "defeat_strength"(
3580 "vote_matrix"["i"]["j"],
3581 "vote_matrix"["j"]["i"]
3582 );
3583 END IF;
3584 EXIT WHEN "j" = "dimension_v";
3585 "j" := "j" + 1;
3586 END LOOP;
3587 EXIT WHEN "i" = "dimension_v";
3588 "i" := "i" + 1;
3589 END LOOP;
3590 -- Find best paths:
3591 "i" := 1;
3592 LOOP
3593 "j" := 1;
3594 LOOP
3595 IF "i" != "j" THEN
3596 "k" := 1;
3597 LOOP
3598 IF "i" != "k" AND "j" != "k" THEN
3599 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3600 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3601 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3602 END IF;
3603 ELSE
3604 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3605 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3606 END IF;
3607 END IF;
3608 END IF;
3609 EXIT WHEN "k" = "dimension_v";
3610 "k" := "k" + 1;
3611 END LOOP;
3612 END IF;
3613 EXIT WHEN "j" = "dimension_v";
3614 "j" := "j" + 1;
3615 END LOOP;
3616 EXIT WHEN "i" = "dimension_v";
3617 "i" := "i" + 1;
3618 END LOOP;
3619 -- Determine order of winners:
3620 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3621 "rank_v" := 1;
3622 "done_v" := 0;
3623 LOOP
3624 "winners_ary" := '{}';
3625 "i" := 1;
3626 LOOP
3627 IF "rank_ary"["i"] ISNULL THEN
3628 "j" := 1;
3629 LOOP
3630 IF
3631 "i" != "j" AND
3632 "rank_ary"["j"] ISNULL AND
3633 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3634 THEN
3635 -- someone else is better
3636 EXIT;
3637 END IF;
3638 IF "j" = "dimension_v" THEN
3639 -- noone is better
3640 "winners_ary" := "winners_ary" || "i";
3641 EXIT;
3642 END IF;
3643 "j" := "j" + 1;
3644 END LOOP;
3645 END IF;
3646 EXIT WHEN "i" = "dimension_v";
3647 "i" := "i" + 1;
3648 END LOOP;
3649 "i" := 1;
3650 LOOP
3651 "rank_ary"["winners_ary"["i"]] := "rank_v";
3652 "done_v" := "done_v" + 1;
3653 EXIT WHEN "i" = array_upper("winners_ary", 1);
3654 "i" := "i" + 1;
3655 END LOOP;
3656 EXIT WHEN "done_v" = "dimension_v";
3657 "rank_v" := "rank_v" + 1;
3658 END LOOP;
3659 -- write preliminary results:
3660 "i" := 1;
3661 FOR "initiative_id_v" IN
3662 SELECT "id" FROM "initiative"
3663 WHERE "issue_id" = "issue_id_p" AND "admitted"
3664 ORDER BY "id"
3665 LOOP
3666 UPDATE "initiative" SET
3667 "direct_majority" =
3668 CASE WHEN "policy_row"."direct_majority_strict" THEN
3669 "positive_votes" * "policy_row"."direct_majority_den" >
3670 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3671 ELSE
3672 "positive_votes" * "policy_row"."direct_majority_den" >=
3673 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3674 END
3675 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3676 AND "issue_row"."voter_count"-"negative_votes" >=
3677 "policy_row"."direct_majority_non_negative",
3678 "indirect_majority" =
3679 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3680 "positive_votes" * "policy_row"."indirect_majority_den" >
3681 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3682 ELSE
3683 "positive_votes" * "policy_row"."indirect_majority_den" >=
3684 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3685 END
3686 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3687 AND "issue_row"."voter_count"-"negative_votes" >=
3688 "policy_row"."indirect_majority_non_negative",
3689 "schulze_rank" = "rank_ary"["i"],
3690 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3691 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3692 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3693 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3694 "winner" = FALSE
3695 WHERE "id" = "initiative_id_v";
3696 "i" := "i" + 1;
3697 END LOOP;
3698 IF "i" != "dimension_v" THEN
3699 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3700 END IF;
3701 -- take indirect majorities into account:
3702 LOOP
3703 UPDATE "initiative" SET "indirect_majority" = TRUE
3704 FROM (
3705 SELECT "new_initiative"."id" AS "initiative_id"
3706 FROM "initiative" "old_initiative"
3707 JOIN "initiative" "new_initiative"
3708 ON "new_initiative"."issue_id" = "issue_id_p"
3709 AND "new_initiative"."indirect_majority" = FALSE
3710 JOIN "battle" "battle_win"
3711 ON "battle_win"."issue_id" = "issue_id_p"
3712 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3713 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3714 JOIN "battle" "battle_lose"
3715 ON "battle_lose"."issue_id" = "issue_id_p"
3716 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3717 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3718 WHERE "old_initiative"."issue_id" = "issue_id_p"
3719 AND "old_initiative"."indirect_majority" = TRUE
3720 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3721 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3722 "policy_row"."indirect_majority_num" *
3723 ("battle_win"."count"+"battle_lose"."count")
3724 ELSE
3725 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3726 "policy_row"."indirect_majority_num" *
3727 ("battle_win"."count"+"battle_lose"."count")
3728 END
3729 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3730 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3731 "policy_row"."indirect_majority_non_negative"
3732 ) AS "subquery"
3733 WHERE "id" = "subquery"."initiative_id";
3734 EXIT WHEN NOT FOUND;
3735 END LOOP;
3736 -- set "multistage_majority" for remaining matching initiatives:
3737 UPDATE "initiative" SET "multistage_majority" = TRUE
3738 FROM (
3739 SELECT "losing_initiative"."id" AS "initiative_id"
3740 FROM "initiative" "losing_initiative"
3741 JOIN "initiative" "winning_initiative"
3742 ON "winning_initiative"."issue_id" = "issue_id_p"
3743 AND "winning_initiative"."admitted"
3744 JOIN "battle" "battle_win"
3745 ON "battle_win"."issue_id" = "issue_id_p"
3746 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3747 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3748 JOIN "battle" "battle_lose"
3749 ON "battle_lose"."issue_id" = "issue_id_p"
3750 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3751 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3752 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3753 AND "losing_initiative"."admitted"
3754 AND "winning_initiative"."schulze_rank" <
3755 "losing_initiative"."schulze_rank"
3756 AND "battle_win"."count" > "battle_lose"."count"
3757 AND (
3758 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3759 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3760 ) AS "subquery"
3761 WHERE "id" = "subquery"."initiative_id";
3762 -- mark eligible initiatives:
3763 UPDATE "initiative" SET "eligible" = TRUE
3764 WHERE "issue_id" = "issue_id_p"
3765 AND "initiative"."direct_majority"
3766 AND "initiative"."indirect_majority"
3767 AND "initiative"."better_than_status_quo"
3768 AND (
3769 "policy_row"."no_multistage_majority" = FALSE OR
3770 "initiative"."multistage_majority" = FALSE )
3771 AND (
3772 "policy_row"."no_reverse_beat_path" = FALSE OR
3773 "initiative"."reverse_beat_path" = FALSE );
3774 -- mark final winner:
3775 UPDATE "initiative" SET "winner" = TRUE
3776 FROM (
3777 SELECT "id" AS "initiative_id"
3778 FROM "initiative"
3779 WHERE "issue_id" = "issue_id_p" AND "eligible"
3780 ORDER BY "schulze_rank", "id"
3781 LIMIT 1
3782 ) AS "subquery"
3783 WHERE "id" = "subquery"."initiative_id";
3784 -- write (final) ranks:
3785 "rank_v" := 1;
3786 FOR "initiative_id_v" IN
3787 SELECT "id"
3788 FROM "initiative"
3789 WHERE "issue_id" = "issue_id_p" AND "admitted"
3790 ORDER BY
3791 "winner" DESC,
3792 ("direct_majority" AND "indirect_majority") DESC,
3793 "schulze_rank",
3794 "id"
3795 LOOP
3796 UPDATE "initiative" SET "rank" = "rank_v"
3797 WHERE "id" = "initiative_id_v";
3798 "rank_v" := "rank_v" + 1;
3799 END LOOP;
3800 -- set schulze rank of status quo and mark issue as finished:
3801 UPDATE "issue" SET
3802 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
3803 "state" =
3804 CASE WHEN EXISTS (
3805 SELECT NULL FROM "initiative"
3806 WHERE "issue_id" = "issue_id_p" AND "winner"
3807 ) THEN
3808 'finished_with_winner'::"issue_state"
3809 ELSE
3810 'finished_without_winner'::"issue_state"
3811 END,
3812 "ranks_available" = TRUE
3813 WHERE "id" = "issue_id_p";
3814 RETURN;
3815 END;
3816 $$;
3818 COMMENT ON FUNCTION "calculate_ranks"
3819 ( "issue"."id"%TYPE )
3820 IS 'Determine ranking (Votes have to be counted first)';
3824 -----------------------------
3825 -- Automatic state changes --
3826 -----------------------------
3829 CREATE FUNCTION "check_issue"
3830 ( "issue_id_p" "issue"."id"%TYPE )
3831 RETURNS VOID
3832 LANGUAGE 'plpgsql' VOLATILE AS $$
3833 DECLARE
3834 "issue_row" "issue"%ROWTYPE;
3835 "policy_row" "policy"%ROWTYPE;
3836 BEGIN
3837 PERFORM "lock_issue"("issue_id_p");
3838 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3839 -- only process open issues:
3840 IF "issue_row"."closed" ISNULL THEN
3841 SELECT * INTO "policy_row" FROM "policy"
3842 WHERE "id" = "issue_row"."policy_id";
3843 -- create a snapshot, unless issue is already fully frozen:
3844 IF "issue_row"."fully_frozen" ISNULL THEN
3845 PERFORM "create_snapshot"("issue_id_p");
3846 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3847 END IF;
3848 -- eventually close or accept issues, which have not been accepted:
3849 IF "issue_row"."accepted" ISNULL THEN
3850 IF EXISTS (
3851 SELECT NULL FROM "initiative"
3852 WHERE "issue_id" = "issue_id_p"
3853 AND "supporter_count" > 0
3854 AND "supporter_count" * "policy_row"."issue_quorum_den"
3855 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3856 ) THEN
3857 -- accept issues, if supporter count is high enough
3858 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3859 -- NOTE: "issue_row" used later
3860 "issue_row"."state" := 'discussion';
3861 "issue_row"."accepted" := now();
3862 UPDATE "issue" SET
3863 "state" = "issue_row"."state",
3864 "accepted" = "issue_row"."accepted"
3865 WHERE "id" = "issue_row"."id";
3866 ELSIF
3867 now() >= "issue_row"."created" + "issue_row"."admission_time"
3868 THEN
3869 -- close issues, if admission time has expired
3870 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3871 UPDATE "issue" SET
3872 "state" = 'canceled_issue_not_accepted',
3873 "closed" = now()
3874 WHERE "id" = "issue_row"."id";
3875 END IF;
3876 END IF;
3877 -- eventually half freeze issues:
3878 IF
3879 -- NOTE: issue can't be closed at this point, if it has been accepted
3880 "issue_row"."accepted" NOTNULL AND
3881 "issue_row"."half_frozen" ISNULL
3882 THEN
3883 IF
3884 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3885 THEN
3886 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3887 -- NOTE: "issue_row" used later
3888 "issue_row"."state" := 'verification';
3889 "issue_row"."half_frozen" := now();
3890 UPDATE "issue" SET
3891 "state" = "issue_row"."state",
3892 "half_frozen" = "issue_row"."half_frozen"
3893 WHERE "id" = "issue_row"."id";
3894 END IF;
3895 END IF;
3896 -- close issues after some time, if all initiatives have been revoked:
3897 IF
3898 "issue_row"."closed" ISNULL AND
3899 NOT EXISTS (
3900 -- all initiatives are revoked
3901 SELECT NULL FROM "initiative"
3902 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3903 ) AND (
3904 -- and issue has not been accepted yet
3905 "issue_row"."accepted" ISNULL OR
3906 NOT EXISTS (
3907 -- or no initiatives have been revoked lately
3908 SELECT NULL FROM "initiative"
3909 WHERE "issue_id" = "issue_id_p"
3910 AND now() < "revoked" + "issue_row"."verification_time"
3911 ) OR (
3912 -- or verification time has elapsed
3913 "issue_row"."half_frozen" NOTNULL AND
3914 "issue_row"."fully_frozen" ISNULL AND
3915 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3918 THEN
3919 -- NOTE: "issue_row" used later
3920 IF "issue_row"."accepted" ISNULL THEN
3921 "issue_row"."state" := 'canceled_revoked_before_accepted';
3922 ELSIF "issue_row"."half_frozen" ISNULL THEN
3923 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
3924 ELSE
3925 "issue_row"."state" := 'canceled_after_revocation_during_verification';
3926 END IF;
3927 "issue_row"."closed" := now();
3928 UPDATE "issue" SET
3929 "state" = "issue_row"."state",
3930 "closed" = "issue_row"."closed"
3931 WHERE "id" = "issue_row"."id";
3932 END IF;
3933 -- fully freeze issue after verification time:
3934 IF
3935 "issue_row"."half_frozen" NOTNULL AND
3936 "issue_row"."fully_frozen" ISNULL AND
3937 "issue_row"."closed" ISNULL AND
3938 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3939 THEN
3940 PERFORM "freeze_after_snapshot"("issue_id_p");
3941 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
3942 END IF;
3943 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3944 -- close issue by calling close_voting(...) after voting time:
3945 IF
3946 "issue_row"."closed" ISNULL AND
3947 "issue_row"."fully_frozen" NOTNULL AND
3948 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
3949 THEN
3950 PERFORM "close_voting"("issue_id_p");
3951 -- calculate ranks will not consume much time and can be done now
3952 PERFORM "calculate_ranks"("issue_id_p");
3953 END IF;
3954 END IF;
3955 RETURN;
3956 END;
3957 $$;
3959 COMMENT ON FUNCTION "check_issue"
3960 ( "issue"."id"%TYPE )
3961 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.';
3964 CREATE FUNCTION "check_everything"()
3965 RETURNS VOID
3966 LANGUAGE 'plpgsql' VOLATILE AS $$
3967 DECLARE
3968 "issue_id_v" "issue"."id"%TYPE;
3969 BEGIN
3970 PERFORM "check_activity"();
3971 PERFORM "calculate_member_counts"();
3972 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
3973 PERFORM "check_issue"("issue_id_v");
3974 END LOOP;
3975 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
3976 PERFORM "calculate_ranks"("issue_id_v");
3977 END LOOP;
3978 RETURN;
3979 END;
3980 $$;
3982 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.';
3986 ----------------------
3987 -- Deletion of data --
3988 ----------------------
3991 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
3992 RETURNS VOID
3993 LANGUAGE 'plpgsql' VOLATILE AS $$
3994 DECLARE
3995 "issue_row" "issue"%ROWTYPE;
3996 BEGIN
3997 SELECT * INTO "issue_row"
3998 FROM "issue" WHERE "id" = "issue_id_p"
3999 FOR UPDATE;
4000 IF "issue_row"."cleaned" ISNULL THEN
4001 UPDATE "issue" SET
4002 "state" = 'voting',
4003 "closed" = NULL,
4004 "ranks_available" = FALSE
4005 WHERE "id" = "issue_id_p";
4006 DELETE FROM "issue_comment"
4007 WHERE "issue_id" = "issue_id_p";
4008 DELETE FROM "voting_comment"
4009 WHERE "issue_id" = "issue_id_p";
4010 DELETE FROM "delegating_voter"
4011 WHERE "issue_id" = "issue_id_p";
4012 DELETE FROM "direct_voter"
4013 WHERE "issue_id" = "issue_id_p";
4014 DELETE FROM "delegating_interest_snapshot"
4015 WHERE "issue_id" = "issue_id_p";
4016 DELETE FROM "direct_interest_snapshot"
4017 WHERE "issue_id" = "issue_id_p";
4018 DELETE FROM "delegating_population_snapshot"
4019 WHERE "issue_id" = "issue_id_p";
4020 DELETE FROM "direct_population_snapshot"
4021 WHERE "issue_id" = "issue_id_p";
4022 DELETE FROM "non_voter"
4023 WHERE "issue_id" = "issue_id_p";
4024 DELETE FROM "delegation"
4025 WHERE "issue_id" = "issue_id_p";
4026 DELETE FROM "supporter"
4027 WHERE "issue_id" = "issue_id_p";
4028 UPDATE "issue" SET
4029 "state" = "issue_row"."state",
4030 "closed" = "issue_row"."closed",
4031 "ranks_available" = "issue_row"."ranks_available",
4032 "cleaned" = now()
4033 WHERE "id" = "issue_id_p";
4034 END IF;
4035 RETURN;
4036 END;
4037 $$;
4039 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4042 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4043 RETURNS VOID
4044 LANGUAGE 'plpgsql' VOLATILE AS $$
4045 BEGIN
4046 UPDATE "member" SET
4047 "last_login" = NULL,
4048 "login" = NULL,
4049 "password" = NULL,
4050 "locked" = TRUE,
4051 "active" = FALSE,
4052 "notify_email" = NULL,
4053 "notify_email_unconfirmed" = NULL,
4054 "notify_email_secret" = NULL,
4055 "notify_email_secret_expiry" = NULL,
4056 "notify_email_lock_expiry" = NULL,
4057 "password_reset_secret" = NULL,
4058 "password_reset_secret_expiry" = NULL,
4059 "organizational_unit" = NULL,
4060 "internal_posts" = NULL,
4061 "realname" = NULL,
4062 "birthday" = NULL,
4063 "address" = NULL,
4064 "email" = NULL,
4065 "xmpp_address" = NULL,
4066 "website" = NULL,
4067 "phone" = NULL,
4068 "mobile_phone" = NULL,
4069 "profession" = NULL,
4070 "external_memberships" = NULL,
4071 "external_posts" = NULL,
4072 "statement" = NULL
4073 WHERE "id" = "member_id_p";
4074 -- "text_search_data" is updated by triggers
4075 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4076 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4077 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4078 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4079 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4080 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4081 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4082 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4083 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4084 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4085 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4086 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4087 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4088 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4089 DELETE FROM "direct_voter" USING "issue"
4090 WHERE "direct_voter"."issue_id" = "issue"."id"
4091 AND "issue"."closed" ISNULL
4092 AND "member_id" = "member_id_p";
4093 RETURN;
4094 END;
4095 $$;
4097 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)';
4100 CREATE FUNCTION "delete_private_data"()
4101 RETURNS VOID
4102 LANGUAGE 'plpgsql' VOLATILE AS $$
4103 BEGIN
4104 UPDATE "member" SET
4105 "last_login" = NULL,
4106 "login" = NULL,
4107 "password" = NULL,
4108 "notify_email" = NULL,
4109 "notify_email_unconfirmed" = NULL,
4110 "notify_email_secret" = NULL,
4111 "notify_email_secret_expiry" = NULL,
4112 "notify_email_lock_expiry" = NULL,
4113 "password_reset_secret" = NULL,
4114 "password_reset_secret_expiry" = NULL,
4115 "organizational_unit" = NULL,
4116 "internal_posts" = NULL,
4117 "realname" = NULL,
4118 "birthday" = NULL,
4119 "address" = NULL,
4120 "email" = NULL,
4121 "xmpp_address" = NULL,
4122 "website" = NULL,
4123 "phone" = NULL,
4124 "mobile_phone" = NULL,
4125 "profession" = NULL,
4126 "external_memberships" = NULL,
4127 "external_posts" = NULL,
4128 "statement" = NULL;
4129 -- "text_search_data" is updated by triggers
4130 DELETE FROM "invite_code";
4131 DELETE FROM "setting";
4132 DELETE FROM "setting_map";
4133 DELETE FROM "member_relation_setting";
4134 DELETE FROM "member_image";
4135 DELETE FROM "contact";
4136 DELETE FROM "ignored_member";
4137 DELETE FROM "area_setting";
4138 DELETE FROM "issue_setting";
4139 DELETE FROM "ignored_initiative";
4140 DELETE FROM "initiative_setting";
4141 DELETE FROM "suggestion_setting";
4142 DELETE FROM "non_voter";
4143 DELETE FROM "direct_voter" USING "issue"
4144 WHERE "direct_voter"."issue_id" = "issue"."id"
4145 AND "issue"."closed" ISNULL;
4146 RETURN;
4147 END;
4148 $$;
4150 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.';
4154 COMMIT;

Impressum / About Us