liquid_feedback_core

view core.sql @ 162:7c8b812740ac

Delete entries from "issue_comment" and "voting_comment" tables in function "clean_issue"
author jbe
date Sat Jun 04 22:52:50 2011 +0200 (2011-06-04)
parents b49f1a37f8cf
children 7f2011c7b95e
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 ('1.5.0_devel', 1, 5, -1))
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 login anymore.';
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 "last_login" TIMESTAMPTZ,
88 "last_login_public" DATE,
89 "login" TEXT UNIQUE,
90 "password" TEXT,
91 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
92 "active" BOOLEAN NOT NULL DEFAULT TRUE,
93 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
94 "notify_email" TEXT,
95 "notify_email_unconfirmed" TEXT,
96 "notify_email_secret" TEXT UNIQUE,
97 "notify_email_secret_expiry" TIMESTAMPTZ,
98 "notify_email_lock_expiry" TIMESTAMPTZ,
99 "notify_level" "notify_level" NOT NULL DEFAULT 'none',
100 "notify_event_id" INT8,
101 "password_reset_secret" TEXT UNIQUE,
102 "password_reset_secret_expiry" TIMESTAMPTZ,
103 "name" TEXT NOT NULL UNIQUE,
104 "identification" TEXT UNIQUE,
105 "organizational_unit" TEXT,
106 "internal_posts" TEXT,
107 "realname" TEXT,
108 "birthday" DATE,
109 "address" TEXT,
110 "email" TEXT,
111 "xmpp_address" TEXT,
112 "website" TEXT,
113 "phone" TEXT,
114 "mobile_phone" TEXT,
115 "profession" TEXT,
116 "external_memberships" TEXT,
117 "external_posts" TEXT,
118 "formatting_engine" TEXT,
119 "statement" TEXT,
120 "text_search_data" TSVECTOR );
121 CREATE INDEX "member_active_idx" ON "member" ("active");
122 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
123 CREATE TRIGGER "update_text_search_data"
124 BEFORE INSERT OR UPDATE ON "member"
125 FOR EACH ROW EXECUTE PROCEDURE
126 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
127 "name", "identification", "organizational_unit", "internal_posts",
128 "realname", "external_memberships", "external_posts", "statement" );
130 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
132 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
133 COMMENT ON COLUMN "member"."last_login_public" IS 'Date of last login (time stripped for privacy reasons, updated only after day change)';
134 COMMENT ON COLUMN "member"."login" IS 'Login name';
135 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
136 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
137 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. When the user does not log in for an extended period of time, this flag may be set to FALSE. If the user is not locked, he/she may reset the active flag by logging in.';
138 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
139 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
140 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
141 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
142 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
143 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
144 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
145 COMMENT ON COLUMN "member"."notify_event_id" IS 'Latest "id" of an "event" the member was notified about';
146 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
147 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
148 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
149 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
150 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
151 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
152 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
153 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
154 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
155 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his homepage within the system';
158 CREATE TABLE "member_history" (
159 "id" SERIAL8 PRIMARY KEY,
160 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
161 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
162 "active" BOOLEAN NOT NULL,
163 "name" TEXT NOT NULL );
164 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
166 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
168 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
169 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
172 CREATE TABLE "rendered_member_statement" (
173 PRIMARY KEY ("member_id", "format"),
174 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
175 "format" TEXT,
176 "content" TEXT NOT NULL );
178 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)';
181 CREATE TABLE "invite_code" (
182 "id" SERIAL8 PRIMARY KEY,
183 "code" TEXT NOT NULL UNIQUE,
184 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
185 "used" TIMESTAMPTZ,
186 "member_id" INT4 UNIQUE REFERENCES "member" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
187 "comment" TEXT,
188 CONSTRAINT "only_used_codes_may_refer_to_member" CHECK ("used" NOTNULL OR "member_id" ISNULL) );
190 COMMENT ON TABLE "invite_code" IS 'Invite codes can be used once to create a new member account.';
192 COMMENT ON COLUMN "invite_code"."code" IS 'Secret code';
193 COMMENT ON COLUMN "invite_code"."created" IS 'Time of creation of the secret code';
194 COMMENT ON COLUMN "invite_code"."used" IS 'NULL, if not used yet, otherwise tells when this code was used to create a member account';
195 COMMENT ON COLUMN "invite_code"."member_id" IS 'References the member whose account was created with this code';
196 COMMENT ON COLUMN "invite_code"."comment" IS 'Comment on the code, which is to be used for administrative reasons only';
199 CREATE TABLE "setting" (
200 PRIMARY KEY ("member_id", "key"),
201 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
202 "key" TEXT NOT NULL,
203 "value" TEXT NOT NULL );
204 CREATE INDEX "setting_key_idx" ON "setting" ("key");
206 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
208 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
211 CREATE TABLE "setting_map" (
212 PRIMARY KEY ("member_id", "key", "subkey"),
213 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
214 "key" TEXT NOT NULL,
215 "subkey" TEXT NOT NULL,
216 "value" TEXT NOT NULL );
217 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
219 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
221 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
222 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
223 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
226 CREATE TABLE "member_relation_setting" (
227 PRIMARY KEY ("member_id", "key", "other_member_id"),
228 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
229 "key" TEXT NOT NULL,
230 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
231 "value" TEXT NOT NULL );
233 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
236 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
238 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
241 CREATE TABLE "member_image" (
242 PRIMARY KEY ("member_id", "image_type", "scaled"),
243 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
244 "image_type" "member_image_type",
245 "scaled" BOOLEAN,
246 "content_type" TEXT,
247 "data" BYTEA NOT NULL );
249 COMMENT ON TABLE "member_image" IS 'Images of members';
251 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
254 CREATE TABLE "member_count" (
255 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
256 "total_count" INT4 NOT NULL );
258 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';
260 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
261 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
264 CREATE TABLE "contact" (
265 PRIMARY KEY ("member_id", "other_member_id"),
266 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
267 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
268 "public" BOOLEAN NOT NULL DEFAULT FALSE,
269 CONSTRAINT "cant_save_yourself_as_contact"
270 CHECK ("member_id" != "other_member_id") );
271 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
273 COMMENT ON TABLE "contact" IS 'Contact lists';
275 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
276 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
277 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
280 CREATE TABLE "ignored_member" (
281 PRIMARY KEY ("member_id", "other_member_id"),
282 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
283 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
284 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
286 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
288 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
289 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
292 CREATE TABLE "session" (
293 "ident" TEXT PRIMARY KEY,
294 "additional_secret" TEXT,
295 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
296 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
297 "lang" TEXT );
298 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
300 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend';
302 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
303 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
304 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
305 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
308 CREATE TABLE "policy" (
309 "id" SERIAL4 PRIMARY KEY,
310 "index" INT4 NOT NULL,
311 "active" BOOLEAN NOT NULL DEFAULT TRUE,
312 "name" TEXT NOT NULL UNIQUE,
313 "description" TEXT NOT NULL DEFAULT '',
314 "admission_time" INTERVAL NOT NULL,
315 "discussion_time" INTERVAL NOT NULL,
316 "verification_time" INTERVAL NOT NULL,
317 "voting_time" INTERVAL NOT NULL,
318 "issue_quorum_num" INT4 NOT NULL,
319 "issue_quorum_den" INT4 NOT NULL,
320 "initiative_quorum_num" INT4 NOT NULL,
321 "initiative_quorum_den" INT4 NOT NULL,
322 "majority_num" INT4 NOT NULL DEFAULT 1,
323 "majority_den" INT4 NOT NULL DEFAULT 2,
324 "majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
325 "majority_positive" INT4 NOT NULL DEFAULT 0,
326 "majority_non_negative" INT4 NOT NULL DEFAULT 0,
327 "majority_indirect" BOOLEAN NOT NULL DEFAULT TRUE,
328 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
329 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE );
330 CREATE INDEX "policy_active_idx" ON "policy" ("active");
332 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
334 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
335 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
336 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
337 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
338 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
339 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
340 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"';
341 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"';
342 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
343 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
344 COMMENT ON COLUMN "policy"."majority_num" IS 'Numerator of fraction of majority to be reached during voting by an initiative to be an "attainable" winner';
345 COMMENT ON COLUMN "policy"."majority_den" IS 'Denominator of fraction of majority to be reached during voting by an initiative to be an "attainable" winner';
346 COMMENT ON COLUMN "policy"."majority_strict" IS 'If TRUE, then the majority must be strictly greater than "majority_num"/"majority_den", otherwise it may also be equal.';
347 COMMENT ON COLUMN "policy"."majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be an "attainable" winner.';
348 COMMENT ON COLUMN "policy"."majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be an "attainable" winner.';
349 COMMENT ON COLUMN "policy"."majority_indirect" IS 'If TRUE, then the majority specified by "majority_num", "majority_den", "majority_strict", "majority_positive" and "majority_non_negative" may be indirect through a beat path; if FALSE, then the status quo must be beaten directly with that majority';
350 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.';
351 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 (a) "majority_indirect" is TRUE, or (b) "no_reverse_beat_path" is TRUE and "majority_num"/"majority_den" is only a simple majority, or (c) "majority_num" is zero, 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").';
354 CREATE TABLE "unit" (
355 "id" SERIAL4 PRIMARY KEY,
356 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
357 "active" BOOLEAN NOT NULL DEFAULT TRUE,
358 "name" TEXT NOT NULL,
359 "description" TEXT NOT NULL DEFAULT '',
360 "member_count" INT4,
361 "text_search_data" TSVECTOR );
362 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
363 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
364 CREATE INDEX "unit_active_idx" ON "unit" ("active");
365 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
366 CREATE TRIGGER "update_text_search_data"
367 BEFORE INSERT OR UPDATE ON "unit"
368 FOR EACH ROW EXECUTE PROCEDURE
369 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
370 "name", "description" );
372 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
374 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
375 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in units of this area';
376 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
379 CREATE TABLE "area" (
380 "id" SERIAL4 PRIMARY KEY,
381 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
382 "active" BOOLEAN NOT NULL DEFAULT TRUE,
383 "name" TEXT NOT NULL,
384 "description" TEXT NOT NULL DEFAULT '',
385 "direct_member_count" INT4,
386 "member_weight" INT4,
387 "autoreject_weight" INT4,
388 "text_search_data" TSVECTOR );
389 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
390 CREATE INDEX "area_active_idx" ON "area" ("active");
391 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
392 CREATE TRIGGER "update_text_search_data"
393 BEFORE INSERT OR UPDATE ON "area"
394 FOR EACH ROW EXECUTE PROCEDURE
395 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
396 "name", "description" );
398 COMMENT ON TABLE "area" IS 'Subject areas';
400 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
401 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"';
402 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
403 COMMENT ON COLUMN "area"."autoreject_weight" IS 'Sum of weight of members using the autoreject feature';
406 CREATE TABLE "area_setting" (
407 PRIMARY KEY ("member_id", "key", "area_id"),
408 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
409 "key" TEXT NOT NULL,
410 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
411 "value" TEXT NOT NULL );
413 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
416 CREATE TABLE "allowed_policy" (
417 PRIMARY KEY ("area_id", "policy_id"),
418 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
419 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
420 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
421 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
423 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
425 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
428 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
430 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';
433 CREATE TYPE "issue_state" AS ENUM (
434 'admission', 'discussion', 'verification', 'voting',
435 'canceled_revoked_before_accepted',
436 'canceled_issue_not_accepted',
437 'canceled_after_revocation_during_discussion',
438 'canceled_after_revocation_during_verification',
439 'calculation',
440 'canceled_no_initiative_admitted',
441 'finished_without_winner', 'finished_with_winner');
443 COMMENT ON TYPE "issue_state" IS 'State of issues';
446 CREATE TABLE "issue" (
447 "id" SERIAL4 PRIMARY KEY,
448 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
449 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
450 "state" "issue_state" NOT NULL DEFAULT 'admission',
451 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
452 "accepted" TIMESTAMPTZ,
453 "half_frozen" TIMESTAMPTZ,
454 "fully_frozen" TIMESTAMPTZ,
455 "closed" TIMESTAMPTZ,
456 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
457 "cleaned" TIMESTAMPTZ,
458 "admission_time" INTERVAL NOT NULL,
459 "discussion_time" INTERVAL NOT NULL,
460 "verification_time" INTERVAL NOT NULL,
461 "voting_time" INTERVAL NOT NULL,
462 "snapshot" TIMESTAMPTZ,
463 "latest_snapshot_event" "snapshot_event",
464 "population" INT4,
465 "voter_count" INT4,
466 CONSTRAINT "valid_state" CHECK ((
467 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
468 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
469 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
470 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
471 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
472 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
473 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
474 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
475 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
476 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
477 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
478 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
479 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
480 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
481 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
482 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
483 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
484 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
485 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
486 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
487 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
488 )),
489 CONSTRAINT "state_change_order" CHECK (
490 "created" <= "accepted" AND
491 "accepted" <= "half_frozen" AND
492 "half_frozen" <= "fully_frozen" AND
493 "fully_frozen" <= "closed" ),
494 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
495 "cleaned" ISNULL OR "closed" NOTNULL ),
496 CONSTRAINT "last_snapshot_on_full_freeze"
497 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
498 CONSTRAINT "freeze_requires_snapshot"
499 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
500 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
501 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
502 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
503 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
504 CREATE INDEX "issue_created_idx" ON "issue" ("created");
505 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
506 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
507 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
508 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
509 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
510 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
512 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
514 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
515 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed, or members voted for voting; 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.';
516 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.';
517 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.';
518 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
519 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
520 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
521 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
522 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
523 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
524 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
525 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';
526 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
527 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';
530 CREATE TABLE "issue_setting" (
531 PRIMARY KEY ("member_id", "key", "issue_id"),
532 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
533 "key" TEXT NOT NULL,
534 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
535 "value" TEXT NOT NULL );
537 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
540 CREATE TABLE "initiative" (
541 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
542 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
543 "id" SERIAL4 PRIMARY KEY,
544 "name" TEXT NOT NULL,
545 "discussion_url" TEXT,
546 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
547 "revoked" TIMESTAMPTZ,
548 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
549 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
550 "admitted" BOOLEAN,
551 "supporter_count" INT4,
552 "informed_supporter_count" INT4,
553 "satisfied_supporter_count" INT4,
554 "satisfied_informed_supporter_count" INT4,
555 "positive_votes" INT4,
556 "negative_votes" INT4,
557 "attainable" BOOLEAN,
558 "favored_to_status_quo" BOOLEAN,
559 "unfavored_to_status_quo" BOOLEAN,
560 "schulze_rank" INT4,
561 "reverse_beat_path" BOOLEAN,
562 "multistage_majority" BOOLEAN,
563 "eligible" BOOLEAN,
564 "winner" BOOLEAN,
565 "text_search_data" TSVECTOR,
566 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
567 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
568 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
569 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
570 CONSTRAINT "revoked_initiatives_cant_be_admitted"
571 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
572 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
573 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
574 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND "attainable" ISNULL AND
575 "favored_to_status_quo" ISNULL AND "unfavored_to_status_quo" ISNULL AND
576 "schulze_rank" ISNULL AND
577 "multistage_majority" ISNULL AND "reverse_beat_path" ISNULL AND
578 "winner" ISNULL ) ),
579 CONSTRAINT "favored_excludes_unfavored" CHECK (NOT ("favored_to_status_quo" AND "unfavored_to_status_quo")) );
580 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
581 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
582 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
583 CREATE TRIGGER "update_text_search_data"
584 BEFORE INSERT OR UPDATE ON "initiative"
585 FOR EACH ROW EXECUTE PROCEDURE
586 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
587 "name", "discussion_url");
589 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.';
591 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
592 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
593 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
594 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
595 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
596 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
597 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
598 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
599 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
600 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
601 COMMENT ON COLUMN "initiative"."attainable" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "majority_num"/"majority_den", and "positive_votes" is greater-equal than "majority_positive", and ("positive_votes"+abstentions) is greater-equal than "majority_non_negative"';
602 COMMENT ON COLUMN "initiative"."favored_to_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
603 COMMENT ON COLUMN "initiative"."unfavored_to_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
604 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
605 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';
606 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';
607 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
608 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
611 CREATE TABLE "battle" (
612 "issue_id" INT4 NOT NULL,
613 "winning_initiative_id" INT4,
614 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
615 "losing_initiative_id" INT4,
616 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
617 "count" INT4 NOT NULL,
618 CONSTRAINT "initiative_ids_not_equal" CHECK (
619 "winning_initiative_id" != "losing_initiative_id" OR
620 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
621 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
622 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
623 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
624 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
626 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';
629 CREATE TABLE "ignored_initiative" (
630 PRIMARY KEY ("initiative_id", "member_id"),
631 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
632 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
633 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
635 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
638 CREATE TABLE "initiative_setting" (
639 PRIMARY KEY ("member_id", "key", "initiative_id"),
640 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
641 "key" TEXT NOT NULL,
642 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
643 "value" TEXT NOT NULL );
645 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
648 CREATE TABLE "draft" (
649 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
650 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
651 "id" SERIAL8 PRIMARY KEY,
652 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
653 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
654 "formatting_engine" TEXT,
655 "content" TEXT NOT NULL,
656 "text_search_data" TSVECTOR );
657 CREATE INDEX "draft_created_idx" ON "draft" ("created");
658 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
659 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
660 CREATE TRIGGER "update_text_search_data"
661 BEFORE INSERT OR UPDATE ON "draft"
662 FOR EACH ROW EXECUTE PROCEDURE
663 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
665 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.';
667 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
668 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
671 CREATE TABLE "rendered_draft" (
672 PRIMARY KEY ("draft_id", "format"),
673 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
674 "format" TEXT,
675 "content" TEXT NOT NULL );
677 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)';
680 CREATE TABLE "suggestion" (
681 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
682 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
683 "id" SERIAL8 PRIMARY KEY,
684 "draft_id" INT8 NOT NULL,
685 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
686 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
687 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
688 "name" TEXT NOT NULL,
689 "formatting_engine" TEXT,
690 "content" TEXT NOT NULL DEFAULT '',
691 "text_search_data" TSVECTOR,
692 "minus2_unfulfilled_count" INT4,
693 "minus2_fulfilled_count" INT4,
694 "minus1_unfulfilled_count" INT4,
695 "minus1_fulfilled_count" INT4,
696 "plus1_unfulfilled_count" INT4,
697 "plus1_fulfilled_count" INT4,
698 "plus2_unfulfilled_count" INT4,
699 "plus2_fulfilled_count" INT4 );
700 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
701 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
702 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
703 CREATE TRIGGER "update_text_search_data"
704 BEFORE INSERT OR UPDATE ON "suggestion"
705 FOR EACH ROW EXECUTE PROCEDURE
706 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
707 "name", "content");
709 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';
711 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")';
712 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
713 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
714 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
715 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
716 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
717 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
718 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
719 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
722 CREATE TABLE "rendered_suggestion" (
723 PRIMARY KEY ("suggestion_id", "format"),
724 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
725 "format" TEXT,
726 "content" TEXT NOT NULL );
728 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)';
731 CREATE TABLE "suggestion_setting" (
732 PRIMARY KEY ("member_id", "key", "suggestion_id"),
733 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
734 "key" TEXT NOT NULL,
735 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
736 "value" TEXT NOT NULL );
738 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
741 CREATE TABLE "invite_code_unit" (
742 PRIMARY KEY ("invite_code_id", "unit_id"),
743 "invite_code_id" INT8 REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
744 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
746 COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
749 CREATE TABLE "privilege" (
750 PRIMARY KEY ("unit_id", "member_id"),
751 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
752 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
753 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
754 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
755 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
756 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
757 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
759 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
761 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
762 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
763 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
764 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
765 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
768 CREATE TABLE "membership" (
769 PRIMARY KEY ("area_id", "member_id"),
770 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
771 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
772 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
773 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
775 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
777 COMMENT ON COLUMN "membership"."autoreject" IS 'TRUE = member votes against all initiatives, if he/she is neither direct_ or delegating_voter; Entries in the "issue_autoreject" table can override this setting.';
780 CREATE TABLE "interest" (
781 PRIMARY KEY ("issue_id", "member_id"),
782 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
783 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
784 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
786 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.';
789 CREATE TABLE "issue_autoreject" (
790 PRIMARY KEY ("issue_id", "member_id"),
791 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
792 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
793 "autoreject" BOOLEAN NOT NULL );
794 CREATE INDEX "issue_autoreject_member_id_idx" ON "issue_autoreject" ("member_id");
796 COMMENT ON TABLE "issue_autoreject" IS 'If autoreject=TRUE, then member votes against all initiatives, if he/she is neither direct_ or delegating_voter; Values of either TRUE or FALSE override settings in "membership" table.';
799 CREATE TABLE "initiator" (
800 PRIMARY KEY ("initiative_id", "member_id"),
801 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
802 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
803 "accepted" BOOLEAN );
804 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
806 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.';
808 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.';
811 CREATE TABLE "supporter" (
812 "issue_id" INT4 NOT NULL,
813 PRIMARY KEY ("initiative_id", "member_id"),
814 "initiative_id" INT4,
815 "member_id" INT4,
816 "draft_id" INT8 NOT NULL,
817 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
818 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
819 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
821 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.';
823 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")';
826 CREATE TABLE "opinion" (
827 "initiative_id" INT4 NOT NULL,
828 PRIMARY KEY ("suggestion_id", "member_id"),
829 "suggestion_id" INT8,
830 "member_id" INT4,
831 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
832 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
833 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
834 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
835 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
837 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.';
839 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
842 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
844 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
847 CREATE TABLE "delegation" (
848 "id" SERIAL8 PRIMARY KEY,
849 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
850 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
851 "scope" "delegation_scope" NOT NULL,
852 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
853 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
854 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
855 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
856 CONSTRAINT "no_unit_delegation_to_null"
857 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
858 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
859 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
860 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
861 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
862 UNIQUE ("unit_id", "truster_id"),
863 UNIQUE ("area_id", "truster_id"),
864 UNIQUE ("issue_id", "truster_id") );
865 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
866 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
868 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
870 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
871 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
872 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
875 CREATE TABLE "direct_population_snapshot" (
876 PRIMARY KEY ("issue_id", "event", "member_id"),
877 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
878 "event" "snapshot_event",
879 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
880 "weight" INT4 );
881 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
883 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area", an "interest" in the "issue", or "issue_autoreject"."autoreject" set to TRUE';
885 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
886 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
889 CREATE TABLE "delegating_population_snapshot" (
890 PRIMARY KEY ("issue_id", "event", "member_id"),
891 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
892 "event" "snapshot_event",
893 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
894 "weight" INT4,
895 "scope" "delegation_scope" NOT NULL,
896 "delegate_member_ids" INT4[] NOT NULL );
897 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
899 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
901 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
902 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
903 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
904 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"';
907 CREATE TABLE "direct_interest_snapshot" (
908 PRIMARY KEY ("issue_id", "event", "member_id"),
909 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
910 "event" "snapshot_event",
911 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
912 "weight" INT4 );
913 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
915 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
917 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
918 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
921 CREATE TABLE "delegating_interest_snapshot" (
922 PRIMARY KEY ("issue_id", "event", "member_id"),
923 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
924 "event" "snapshot_event",
925 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
926 "weight" INT4,
927 "scope" "delegation_scope" NOT NULL,
928 "delegate_member_ids" INT4[] NOT NULL );
929 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
931 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
933 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
934 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
935 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
936 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"';
939 CREATE TABLE "direct_supporter_snapshot" (
940 "issue_id" INT4 NOT NULL,
941 PRIMARY KEY ("initiative_id", "event", "member_id"),
942 "initiative_id" INT4,
943 "event" "snapshot_event",
944 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
945 "informed" BOOLEAN NOT NULL,
946 "satisfied" BOOLEAN NOT NULL,
947 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
948 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
949 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
951 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
953 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
954 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
955 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
958 CREATE TABLE "non_voter" (
959 PRIMARY KEY ("issue_id", "member_id"),
960 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
961 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
962 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
964 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
967 CREATE TABLE "direct_voter" (
968 PRIMARY KEY ("issue_id", "member_id"),
969 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
970 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
971 "weight" INT4,
972 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
973 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
975 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.';
977 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
978 COMMENT ON COLUMN "direct_voter"."autoreject" IS 'Votes were inserted due to "autoreject" feature';
981 CREATE TABLE "delegating_voter" (
982 PRIMARY KEY ("issue_id", "member_id"),
983 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
984 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
985 "weight" INT4,
986 "scope" "delegation_scope" NOT NULL,
987 "delegate_member_ids" INT4[] NOT NULL );
988 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
990 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
992 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
993 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
994 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"';
997 CREATE TABLE "vote" (
998 "issue_id" INT4 NOT NULL,
999 PRIMARY KEY ("initiative_id", "member_id"),
1000 "initiative_id" INT4,
1001 "member_id" INT4,
1002 "grade" INT4,
1003 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1004 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1005 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1007 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.';
1009 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.';
1012 CREATE TABLE "issue_comment" (
1013 PRIMARY KEY ("issue_id", "member_id"),
1014 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1015 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1016 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
1017 "formatting_engine" TEXT,
1018 "content" TEXT NOT NULL,
1019 "text_search_data" TSVECTOR );
1020 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
1021 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
1022 CREATE TRIGGER "update_text_search_data"
1023 BEFORE INSERT OR UPDATE ON "issue_comment"
1024 FOR EACH ROW EXECUTE PROCEDURE
1025 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1027 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
1029 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
1032 CREATE TABLE "rendered_issue_comment" (
1033 PRIMARY KEY ("issue_id", "member_id", "format"),
1034 FOREIGN KEY ("issue_id", "member_id")
1035 REFERENCES "issue_comment" ("issue_id", "member_id")
1036 ON DELETE CASCADE ON UPDATE CASCADE,
1037 "issue_id" INT4,
1038 "member_id" INT4,
1039 "format" TEXT,
1040 "content" TEXT NOT NULL );
1042 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)';
1045 CREATE TABLE "voting_comment" (
1046 PRIMARY KEY ("issue_id", "member_id"),
1047 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1048 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1049 "changed" TIMESTAMPTZ,
1050 "formatting_engine" TEXT,
1051 "content" TEXT NOT NULL,
1052 "text_search_data" TSVECTOR );
1053 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1054 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1055 CREATE TRIGGER "update_text_search_data"
1056 BEFORE INSERT OR UPDATE ON "voting_comment"
1057 FOR EACH ROW EXECUTE PROCEDURE
1058 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1060 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1062 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.';
1065 CREATE TABLE "rendered_voting_comment" (
1066 PRIMARY KEY ("issue_id", "member_id", "format"),
1067 FOREIGN KEY ("issue_id", "member_id")
1068 REFERENCES "voting_comment" ("issue_id", "member_id")
1069 ON DELETE CASCADE ON UPDATE CASCADE,
1070 "issue_id" INT4,
1071 "member_id" INT4,
1072 "format" TEXT,
1073 "content" TEXT NOT NULL );
1075 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)';
1078 CREATE TYPE "event_type" AS ENUM (
1079 'issue_state_changed',
1080 'initiative_created_in_new_issue',
1081 'initiative_created_in_existing_issue',
1082 'initiative_revoked',
1083 'new_draft_created',
1084 'suggestion_created');
1086 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1089 CREATE TABLE "event" (
1090 "id" SERIAL8 PRIMARY KEY,
1091 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1092 "event" "event_type" NOT NULL,
1093 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1094 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1095 "state" "issue_state" CHECK ("state" != 'calculation'),
1096 "initiative_id" INT4,
1097 "draft_id" INT8,
1098 "suggestion_id" INT8,
1099 FOREIGN KEY ("issue_id", "initiative_id")
1100 REFERENCES "initiative" ("issue_id", "id")
1101 ON DELETE CASCADE ON UPDATE CASCADE,
1102 FOREIGN KEY ("initiative_id", "draft_id")
1103 REFERENCES "draft" ("initiative_id", "id")
1104 ON DELETE CASCADE ON UPDATE CASCADE,
1105 FOREIGN KEY ("initiative_id", "suggestion_id")
1106 REFERENCES "suggestion" ("initiative_id", "id")
1107 ON DELETE CASCADE ON UPDATE CASCADE,
1108 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1109 "event" != 'issue_state_changed' OR (
1110 "member_id" ISNULL AND
1111 "issue_id" NOTNULL AND
1112 "state" NOTNULL AND
1113 "initiative_id" ISNULL AND
1114 "draft_id" ISNULL AND
1115 "suggestion_id" ISNULL )),
1116 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1117 "event" NOT IN (
1118 'initiative_created_in_new_issue',
1119 'initiative_created_in_existing_issue',
1120 'initiative_revoked',
1121 'new_draft_created'
1122 ) OR (
1123 "member_id" NOTNULL AND
1124 "issue_id" NOTNULL AND
1125 "state" NOTNULL AND
1126 "initiative_id" NOTNULL AND
1127 "draft_id" NOTNULL AND
1128 "suggestion_id" ISNULL )),
1129 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1130 "event" != 'suggestion_created' OR (
1131 "member_id" NOTNULL AND
1132 "issue_id" NOTNULL AND
1133 "state" NOTNULL AND
1134 "initiative_id" NOTNULL AND
1135 "draft_id" ISNULL AND
1136 "suggestion_id" NOTNULL )) );
1138 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1140 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1141 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1142 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1143 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1147 ----------------------------------------------
1148 -- Writing of history entries and event log --
1149 ----------------------------------------------
1151 CREATE FUNCTION "write_member_history_trigger"()
1152 RETURNS TRIGGER
1153 LANGUAGE 'plpgsql' VOLATILE AS $$
1154 BEGIN
1155 IF
1156 NEW."active" != OLD."active" OR
1157 NEW."name" != OLD."name"
1158 THEN
1159 INSERT INTO "member_history"
1160 ("member_id", "active", "name")
1161 VALUES (NEW."id", OLD."active", OLD."name");
1162 END IF;
1163 RETURN NULL;
1164 END;
1165 $$;
1167 CREATE TRIGGER "write_member_history"
1168 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1169 "write_member_history_trigger"();
1171 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1172 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1175 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1176 RETURNS TRIGGER
1177 LANGUAGE 'plpgsql' VOLATILE AS $$
1178 BEGIN
1179 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1180 INSERT INTO "event" ("event", "issue_id", "state")
1181 VALUES ('issue_state_changed', NEW."id", NEW."state");
1182 END IF;
1183 RETURN NULL;
1184 END;
1185 $$;
1187 CREATE TRIGGER "write_event_issue_state_changed"
1188 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1189 "write_event_issue_state_changed_trigger"();
1191 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1192 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1195 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1196 RETURNS TRIGGER
1197 LANGUAGE 'plpgsql' VOLATILE AS $$
1198 DECLARE
1199 "initiative_row" "initiative"%ROWTYPE;
1200 "issue_row" "issue"%ROWTYPE;
1201 "event_v" "event_type";
1202 BEGIN
1203 SELECT * INTO "initiative_row" FROM "initiative"
1204 WHERE "id" = NEW."initiative_id";
1205 SELECT * INTO "issue_row" FROM "issue"
1206 WHERE "id" = "initiative_row"."issue_id";
1207 IF EXISTS (
1208 SELECT NULL FROM "draft"
1209 WHERE "initiative_id" = NEW."initiative_id"
1210 AND "id" != NEW."id"
1211 ) THEN
1212 "event_v" := 'new_draft_created';
1213 ELSE
1214 IF EXISTS (
1215 SELECT NULL FROM "initiative"
1216 WHERE "issue_id" = "initiative_row"."issue_id"
1217 AND "id" != "initiative_row"."id"
1218 ) THEN
1219 "event_v" := 'initiative_created_in_existing_issue';
1220 ELSE
1221 "event_v" := 'initiative_created_in_new_issue';
1222 END IF;
1223 END IF;
1224 INSERT INTO "event" (
1225 "event", "member_id",
1226 "issue_id", "state", "initiative_id", "draft_id"
1227 ) VALUES (
1228 "event_v",
1229 NEW."author_id",
1230 "initiative_row"."issue_id",
1231 "issue_row"."state",
1232 "initiative_row"."id",
1233 NEW."id" );
1234 RETURN NULL;
1235 END;
1236 $$;
1238 CREATE TRIGGER "write_event_initiative_or_draft_created"
1239 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1240 "write_event_initiative_or_draft_created_trigger"();
1242 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1243 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1246 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1247 RETURNS TRIGGER
1248 LANGUAGE 'plpgsql' VOLATILE AS $$
1249 DECLARE
1250 "issue_row" "issue"%ROWTYPE;
1251 BEGIN
1252 SELECT * INTO "issue_row" FROM "issue"
1253 WHERE "id" = NEW."issue_id";
1254 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1255 INSERT INTO "event" (
1256 "event", "member_id", "issue_id", "state", "initiative_id"
1257 ) VALUES (
1258 'initiative_revoked',
1259 NEW."revoked_by_member_id",
1260 NEW."issue_id",
1261 "issue_row"."state",
1262 NEW."id" );
1263 END IF;
1264 RETURN NULL;
1265 END;
1266 $$;
1268 CREATE TRIGGER "write_event_initiative_revoked"
1269 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1270 "write_event_initiative_revoked_trigger"();
1272 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1273 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1276 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1277 RETURNS TRIGGER
1278 LANGUAGE 'plpgsql' VOLATILE AS $$
1279 DECLARE
1280 "initiative_row" "initiative"%ROWTYPE;
1281 "issue_row" "issue"%ROWTYPE;
1282 BEGIN
1283 SELECT * INTO "initiative_row" FROM "initiative"
1284 WHERE "id" = NEW."initiative_id";
1285 SELECT * INTO "issue_row" FROM "issue"
1286 WHERE "id" = "initiative_row"."issue_id";
1287 INSERT INTO "event" (
1288 "event", "member_id",
1289 "issue_id", "state", "initiative_id", "suggestion_id"
1290 ) VALUES (
1291 'suggestion_created',
1292 NEW."author_id",
1293 "initiative_row"."issue_id",
1294 "issue_row"."state",
1295 "initiative_row"."id",
1296 NEW."id" );
1297 RETURN NULL;
1298 END;
1299 $$;
1301 CREATE TRIGGER "write_event_suggestion_created"
1302 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1303 "write_event_suggestion_created_trigger"();
1305 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1306 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1310 ----------------------------
1311 -- Additional constraints --
1312 ----------------------------
1315 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1316 RETURNS TRIGGER
1317 LANGUAGE 'plpgsql' VOLATILE AS $$
1318 BEGIN
1319 IF NOT EXISTS (
1320 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1321 ) THEN
1322 --RAISE 'Cannot create issue without an initial initiative.' USING
1323 -- ERRCODE = 'integrity_constraint_violation',
1324 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1325 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1326 END IF;
1327 RETURN NULL;
1328 END;
1329 $$;
1331 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1332 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1333 FOR EACH ROW EXECUTE PROCEDURE
1334 "issue_requires_first_initiative_trigger"();
1336 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1337 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1340 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1341 RETURNS TRIGGER
1342 LANGUAGE 'plpgsql' VOLATILE AS $$
1343 DECLARE
1344 "reference_lost" BOOLEAN;
1345 BEGIN
1346 IF TG_OP = 'DELETE' THEN
1347 "reference_lost" := TRUE;
1348 ELSE
1349 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1350 END IF;
1351 IF
1352 "reference_lost" AND NOT EXISTS (
1353 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1355 THEN
1356 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1357 END IF;
1358 RETURN NULL;
1359 END;
1360 $$;
1362 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1363 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1364 FOR EACH ROW EXECUTE PROCEDURE
1365 "last_initiative_deletes_issue_trigger"();
1367 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1368 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1371 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1372 RETURNS TRIGGER
1373 LANGUAGE 'plpgsql' VOLATILE AS $$
1374 BEGIN
1375 IF NOT EXISTS (
1376 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1377 ) THEN
1378 --RAISE 'Cannot create initiative without an initial draft.' USING
1379 -- ERRCODE = 'integrity_constraint_violation',
1380 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1381 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1382 END IF;
1383 RETURN NULL;
1384 END;
1385 $$;
1387 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1388 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1389 FOR EACH ROW EXECUTE PROCEDURE
1390 "initiative_requires_first_draft_trigger"();
1392 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1393 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1396 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1397 RETURNS TRIGGER
1398 LANGUAGE 'plpgsql' VOLATILE AS $$
1399 DECLARE
1400 "reference_lost" BOOLEAN;
1401 BEGIN
1402 IF TG_OP = 'DELETE' THEN
1403 "reference_lost" := TRUE;
1404 ELSE
1405 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1406 END IF;
1407 IF
1408 "reference_lost" AND NOT EXISTS (
1409 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1411 THEN
1412 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1413 END IF;
1414 RETURN NULL;
1415 END;
1416 $$;
1418 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1419 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1420 FOR EACH ROW EXECUTE PROCEDURE
1421 "last_draft_deletes_initiative_trigger"();
1423 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1424 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1427 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1428 RETURNS TRIGGER
1429 LANGUAGE 'plpgsql' VOLATILE AS $$
1430 BEGIN
1431 IF NOT EXISTS (
1432 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1433 ) THEN
1434 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1435 END IF;
1436 RETURN NULL;
1437 END;
1438 $$;
1440 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1441 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1442 FOR EACH ROW EXECUTE PROCEDURE
1443 "suggestion_requires_first_opinion_trigger"();
1445 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1446 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1449 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1450 RETURNS TRIGGER
1451 LANGUAGE 'plpgsql' VOLATILE AS $$
1452 DECLARE
1453 "reference_lost" BOOLEAN;
1454 BEGIN
1455 IF TG_OP = 'DELETE' THEN
1456 "reference_lost" := TRUE;
1457 ELSE
1458 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1459 END IF;
1460 IF
1461 "reference_lost" AND NOT EXISTS (
1462 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1464 THEN
1465 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1466 END IF;
1467 RETURN NULL;
1468 END;
1469 $$;
1471 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1472 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1473 FOR EACH ROW EXECUTE PROCEDURE
1474 "last_opinion_deletes_suggestion_trigger"();
1476 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1477 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1481 ---------------------------------------------------------------
1482 -- Ensure that votes are not modified when issues are frozen --
1483 ---------------------------------------------------------------
1485 -- NOTE: Frontends should ensure this anyway, but in case of programming
1486 -- errors the following triggers ensure data integrity.
1489 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1490 RETURNS TRIGGER
1491 LANGUAGE 'plpgsql' VOLATILE AS $$
1492 DECLARE
1493 "issue_id_v" "issue"."id"%TYPE;
1494 "issue_row" "issue"%ROWTYPE;
1495 BEGIN
1496 IF TG_OP = 'DELETE' THEN
1497 "issue_id_v" := OLD."issue_id";
1498 ELSE
1499 "issue_id_v" := NEW."issue_id";
1500 END IF;
1501 SELECT INTO "issue_row" * FROM "issue"
1502 WHERE "id" = "issue_id_v" FOR SHARE;
1503 IF "issue_row"."closed" NOTNULL THEN
1504 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1505 END IF;
1506 RETURN NULL;
1507 END;
1508 $$;
1510 CREATE TRIGGER "forbid_changes_on_closed_issue"
1511 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1512 FOR EACH ROW EXECUTE PROCEDURE
1513 "forbid_changes_on_closed_issue_trigger"();
1515 CREATE TRIGGER "forbid_changes_on_closed_issue"
1516 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1517 FOR EACH ROW EXECUTE PROCEDURE
1518 "forbid_changes_on_closed_issue_trigger"();
1520 CREATE TRIGGER "forbid_changes_on_closed_issue"
1521 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1522 FOR EACH ROW EXECUTE PROCEDURE
1523 "forbid_changes_on_closed_issue_trigger"();
1525 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"';
1526 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';
1527 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';
1528 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';
1532 --------------------------------------------------------------------
1533 -- Auto-retrieval of fields only needed for referential integrity --
1534 --------------------------------------------------------------------
1537 CREATE FUNCTION "autofill_issue_id_trigger"()
1538 RETURNS TRIGGER
1539 LANGUAGE 'plpgsql' VOLATILE AS $$
1540 BEGIN
1541 IF NEW."issue_id" ISNULL THEN
1542 SELECT "issue_id" INTO NEW."issue_id"
1543 FROM "initiative" WHERE "id" = NEW."initiative_id";
1544 END IF;
1545 RETURN NEW;
1546 END;
1547 $$;
1549 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1550 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1552 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1553 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1555 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1556 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1557 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1560 CREATE FUNCTION "autofill_initiative_id_trigger"()
1561 RETURNS TRIGGER
1562 LANGUAGE 'plpgsql' VOLATILE AS $$
1563 BEGIN
1564 IF NEW."initiative_id" ISNULL THEN
1565 SELECT "initiative_id" INTO NEW."initiative_id"
1566 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1567 END IF;
1568 RETURN NEW;
1569 END;
1570 $$;
1572 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1573 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1575 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1576 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1580 -----------------------------------------------------
1581 -- Automatic calculation of certain default values --
1582 -----------------------------------------------------
1585 CREATE FUNCTION "copy_timings_trigger"()
1586 RETURNS TRIGGER
1587 LANGUAGE 'plpgsql' VOLATILE AS $$
1588 DECLARE
1589 "policy_row" "policy"%ROWTYPE;
1590 BEGIN
1591 SELECT * INTO "policy_row" FROM "policy"
1592 WHERE "id" = NEW."policy_id";
1593 IF NEW."admission_time" ISNULL THEN
1594 NEW."admission_time" := "policy_row"."admission_time";
1595 END IF;
1596 IF NEW."discussion_time" ISNULL THEN
1597 NEW."discussion_time" := "policy_row"."discussion_time";
1598 END IF;
1599 IF NEW."verification_time" ISNULL THEN
1600 NEW."verification_time" := "policy_row"."verification_time";
1601 END IF;
1602 IF NEW."voting_time" ISNULL THEN
1603 NEW."voting_time" := "policy_row"."voting_time";
1604 END IF;
1605 RETURN NEW;
1606 END;
1607 $$;
1609 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1610 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1612 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1613 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1616 CREATE FUNCTION "default_for_draft_id_trigger"()
1617 RETURNS TRIGGER
1618 LANGUAGE 'plpgsql' VOLATILE AS $$
1619 BEGIN
1620 IF NEW."draft_id" ISNULL THEN
1621 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1622 WHERE "initiative_id" = NEW."initiative_id";
1623 END IF;
1624 RETURN NEW;
1625 END;
1626 $$;
1628 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1629 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1630 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1631 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1633 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1634 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';
1635 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';
1639 ----------------------------------------
1640 -- Automatic creation of dependencies --
1641 ----------------------------------------
1644 CREATE FUNCTION "autocreate_interest_trigger"()
1645 RETURNS TRIGGER
1646 LANGUAGE 'plpgsql' VOLATILE AS $$
1647 BEGIN
1648 IF NOT EXISTS (
1649 SELECT NULL FROM "initiative" JOIN "interest"
1650 ON "initiative"."issue_id" = "interest"."issue_id"
1651 WHERE "initiative"."id" = NEW."initiative_id"
1652 AND "interest"."member_id" = NEW."member_id"
1653 ) THEN
1654 BEGIN
1655 INSERT INTO "interest" ("issue_id", "member_id")
1656 SELECT "issue_id", NEW."member_id"
1657 FROM "initiative" WHERE "id" = NEW."initiative_id";
1658 EXCEPTION WHEN unique_violation THEN END;
1659 END IF;
1660 RETURN NEW;
1661 END;
1662 $$;
1664 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1665 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1667 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1668 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';
1671 CREATE FUNCTION "autocreate_supporter_trigger"()
1672 RETURNS TRIGGER
1673 LANGUAGE 'plpgsql' VOLATILE AS $$
1674 BEGIN
1675 IF NOT EXISTS (
1676 SELECT NULL FROM "suggestion" JOIN "supporter"
1677 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1678 WHERE "suggestion"."id" = NEW."suggestion_id"
1679 AND "supporter"."member_id" = NEW."member_id"
1680 ) THEN
1681 BEGIN
1682 INSERT INTO "supporter" ("initiative_id", "member_id")
1683 SELECT "initiative_id", NEW."member_id"
1684 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1685 EXCEPTION WHEN unique_violation THEN END;
1686 END IF;
1687 RETURN NEW;
1688 END;
1689 $$;
1691 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1692 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1694 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1695 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.';
1699 ------------------------------------------
1700 -- Views and helper functions for views --
1701 ------------------------------------------
1704 CREATE VIEW "unit_delegation" AS
1705 SELECT
1706 "unit"."id" AS "unit_id",
1707 "delegation"."id",
1708 "delegation"."truster_id",
1709 "delegation"."trustee_id",
1710 "delegation"."scope"
1711 FROM "unit"
1712 JOIN "delegation"
1713 ON "delegation"."unit_id" = "unit"."id"
1714 JOIN "member"
1715 ON "delegation"."truster_id" = "member"."id"
1716 JOIN "privilege"
1717 ON "delegation"."unit_id" = "privilege"."unit_id"
1718 AND "delegation"."truster_id" = "privilege"."member_id"
1719 WHERE "member"."active" AND "privilege"."voting_right";
1721 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1724 CREATE VIEW "area_delegation" AS
1725 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1726 "area"."id" AS "area_id",
1727 "delegation"."id",
1728 "delegation"."truster_id",
1729 "delegation"."trustee_id",
1730 "delegation"."scope"
1731 FROM "area"
1732 JOIN "delegation"
1733 ON "delegation"."unit_id" = "area"."unit_id"
1734 OR "delegation"."area_id" = "area"."id"
1735 JOIN "member"
1736 ON "delegation"."truster_id" = "member"."id"
1737 JOIN "privilege"
1738 ON "area"."unit_id" = "privilege"."unit_id"
1739 AND "delegation"."truster_id" = "privilege"."member_id"
1740 WHERE "member"."active" AND "privilege"."voting_right"
1741 ORDER BY
1742 "area"."id",
1743 "delegation"."truster_id",
1744 "delegation"."scope" DESC;
1746 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1749 CREATE VIEW "issue_delegation" AS
1750 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1751 "issue"."id" AS "issue_id",
1752 "delegation"."id",
1753 "delegation"."truster_id",
1754 "delegation"."trustee_id",
1755 "delegation"."scope"
1756 FROM "issue"
1757 JOIN "area"
1758 ON "area"."id" = "issue"."area_id"
1759 JOIN "delegation"
1760 ON "delegation"."unit_id" = "area"."unit_id"
1761 OR "delegation"."area_id" = "area"."id"
1762 OR "delegation"."issue_id" = "issue"."id"
1763 JOIN "member"
1764 ON "delegation"."truster_id" = "member"."id"
1765 JOIN "privilege"
1766 ON "area"."unit_id" = "privilege"."unit_id"
1767 AND "delegation"."truster_id" = "privilege"."member_id"
1768 WHERE "member"."active" AND "privilege"."voting_right"
1769 ORDER BY
1770 "issue"."id",
1771 "delegation"."truster_id",
1772 "delegation"."scope" DESC;
1774 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1777 CREATE FUNCTION "membership_weight_with_skipping"
1778 ( "area_id_p" "area"."id"%TYPE,
1779 "member_id_p" "member"."id"%TYPE,
1780 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1781 RETURNS INT4
1782 LANGUAGE 'plpgsql' STABLE AS $$
1783 DECLARE
1784 "sum_v" INT4;
1785 "delegation_row" "area_delegation"%ROWTYPE;
1786 BEGIN
1787 "sum_v" := 1;
1788 FOR "delegation_row" IN
1789 SELECT "area_delegation".*
1790 FROM "area_delegation" LEFT JOIN "membership"
1791 ON "membership"."area_id" = "area_id_p"
1792 AND "membership"."member_id" = "area_delegation"."truster_id"
1793 WHERE "area_delegation"."area_id" = "area_id_p"
1794 AND "area_delegation"."trustee_id" = "member_id_p"
1795 AND "membership"."member_id" ISNULL
1796 LOOP
1797 IF NOT
1798 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1799 THEN
1800 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1801 "area_id_p",
1802 "delegation_row"."truster_id",
1803 "skip_member_ids_p" || "delegation_row"."truster_id"
1804 );
1805 END IF;
1806 END LOOP;
1807 RETURN "sum_v";
1808 END;
1809 $$;
1811 COMMENT ON FUNCTION "membership_weight_with_skipping"
1812 ( "area"."id"%TYPE,
1813 "member"."id"%TYPE,
1814 INT4[] )
1815 IS 'Helper function for "membership_weight" function';
1818 CREATE FUNCTION "membership_weight"
1819 ( "area_id_p" "area"."id"%TYPE,
1820 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1821 RETURNS INT4
1822 LANGUAGE 'plpgsql' STABLE AS $$
1823 BEGIN
1824 RETURN "membership_weight_with_skipping"(
1825 "area_id_p",
1826 "member_id_p",
1827 ARRAY["member_id_p"]
1828 );
1829 END;
1830 $$;
1832 COMMENT ON FUNCTION "membership_weight"
1833 ( "area"."id"%TYPE,
1834 "member"."id"%TYPE )
1835 IS 'Calculates the potential voting weight of a member in a given area';
1838 CREATE VIEW "member_count_view" AS
1839 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1841 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1844 CREATE VIEW "unit_member_count" AS
1845 SELECT
1846 "unit"."id" AS "unit_id",
1847 sum("member"."id") AS "member_count"
1848 FROM "unit"
1849 LEFT JOIN "privilege"
1850 ON "privilege"."unit_id" = "unit"."id"
1851 AND "privilege"."voting_right"
1852 LEFT JOIN "member"
1853 ON "member"."id" = "privilege"."member_id"
1854 AND "member"."active"
1855 GROUP BY "unit"."id";
1857 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1860 CREATE VIEW "area_member_count" AS
1861 SELECT
1862 "area"."id" AS "area_id",
1863 count("member"."id") AS "direct_member_count",
1864 coalesce(
1865 sum(
1866 CASE WHEN "member"."id" NOTNULL THEN
1867 "membership_weight"("area"."id", "member"."id")
1868 ELSE 0 END
1870 ) AS "member_weight",
1871 coalesce(
1872 sum(
1873 CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
1874 "membership_weight"("area"."id", "member"."id")
1875 ELSE 0 END
1877 ) AS "autoreject_weight"
1878 FROM "area"
1879 LEFT JOIN "membership"
1880 ON "area"."id" = "membership"."area_id"
1881 LEFT JOIN "privilege"
1882 ON "privilege"."unit_id" = "area"."unit_id"
1883 AND "privilege"."member_id" = "membership"."member_id"
1884 AND "privilege"."voting_right"
1885 LEFT JOIN "member"
1886 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1887 AND "member"."active"
1888 GROUP BY "area"."id";
1890 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count", "member_weight" and "autoreject_weight" columns of table "area"';
1893 CREATE VIEW "opening_draft" AS
1894 SELECT "draft".* FROM (
1895 SELECT
1896 "initiative"."id" AS "initiative_id",
1897 min("draft"."id") AS "draft_id"
1898 FROM "initiative" JOIN "draft"
1899 ON "initiative"."id" = "draft"."initiative_id"
1900 GROUP BY "initiative"."id"
1901 ) AS "subquery"
1902 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1904 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1907 CREATE VIEW "current_draft" AS
1908 SELECT "draft".* FROM (
1909 SELECT
1910 "initiative"."id" AS "initiative_id",
1911 max("draft"."id") AS "draft_id"
1912 FROM "initiative" JOIN "draft"
1913 ON "initiative"."id" = "draft"."initiative_id"
1914 GROUP BY "initiative"."id"
1915 ) AS "subquery"
1916 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1918 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1921 CREATE VIEW "critical_opinion" AS
1922 SELECT * FROM "opinion"
1923 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1924 OR ("degree" = -2 AND "fulfilled" = TRUE);
1926 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1929 CREATE VIEW "battle_participant" AS
1930 SELECT "initiative"."id", "initiative"."issue_id"
1931 FROM "issue" JOIN "initiative"
1932 ON "issue"."id" = "initiative"."issue_id"
1933 WHERE "initiative"."admitted"
1934 UNION ALL
1935 SELECT NULL, "id" AS "issue_id"
1936 FROM "issue";
1938 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1941 CREATE VIEW "battle_view" AS
1942 SELECT
1943 "issue"."id" AS "issue_id",
1944 "winning_initiative"."id" AS "winning_initiative_id",
1945 "losing_initiative"."id" AS "losing_initiative_id",
1946 sum(
1947 CASE WHEN
1948 coalesce("better_vote"."grade", 0) >
1949 coalesce("worse_vote"."grade", 0)
1950 THEN "direct_voter"."weight" ELSE 0 END
1951 ) AS "count"
1952 FROM "issue"
1953 LEFT JOIN "direct_voter"
1954 ON "issue"."id" = "direct_voter"."issue_id"
1955 JOIN "battle_participant" AS "winning_initiative"
1956 ON "issue"."id" = "winning_initiative"."issue_id"
1957 JOIN "battle_participant" AS "losing_initiative"
1958 ON "issue"."id" = "losing_initiative"."issue_id"
1959 LEFT JOIN "vote" AS "better_vote"
1960 ON "direct_voter"."member_id" = "better_vote"."member_id"
1961 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1962 LEFT JOIN "vote" AS "worse_vote"
1963 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1964 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1965 WHERE "issue"."closed" NOTNULL
1966 AND "issue"."cleaned" ISNULL
1967 AND (
1968 "winning_initiative"."id" != "losing_initiative"."id" OR
1969 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1970 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1971 GROUP BY
1972 "issue"."id",
1973 "winning_initiative"."id",
1974 "losing_initiative"."id";
1976 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';
1979 CREATE VIEW "expired_session" AS
1980 SELECT * FROM "session" WHERE now() > "expiry";
1982 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
1983 DELETE FROM "session" WHERE "ident" = OLD."ident";
1985 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
1986 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
1989 CREATE VIEW "open_issue" AS
1990 SELECT * FROM "issue" WHERE "closed" ISNULL;
1992 COMMENT ON VIEW "open_issue" IS 'All open issues';
1995 CREATE VIEW "issue_with_ranks_missing" AS
1996 SELECT * FROM "issue"
1997 WHERE "fully_frozen" NOTNULL
1998 AND "closed" NOTNULL
1999 AND "ranks_available" = FALSE;
2001 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2004 CREATE VIEW "member_contingent" AS
2005 SELECT
2006 "member"."id" AS "member_id",
2007 "contingent"."time_frame",
2008 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2010 SELECT count(1) FROM "draft"
2011 WHERE "draft"."author_id" = "member"."id"
2012 AND "draft"."created" > now() - "contingent"."time_frame"
2013 ) + (
2014 SELECT count(1) FROM "suggestion"
2015 WHERE "suggestion"."author_id" = "member"."id"
2016 AND "suggestion"."created" > now() - "contingent"."time_frame"
2018 ELSE NULL END AS "text_entry_count",
2019 "contingent"."text_entry_limit",
2020 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2021 SELECT count(1) FROM "opening_draft"
2022 WHERE "opening_draft"."author_id" = "member"."id"
2023 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2024 ) ELSE NULL END AS "initiative_count",
2025 "contingent"."initiative_limit"
2026 FROM "member" CROSS JOIN "contingent";
2028 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2030 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2031 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2034 CREATE VIEW "member_contingent_left" AS
2035 SELECT
2036 "member_id",
2037 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2038 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2039 FROM "member_contingent" GROUP BY "member_id";
2041 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.';
2044 CREATE VIEW "event_seen_by_member" AS
2045 SELECT
2046 "member"."id" AS "seen_by_member_id",
2047 CASE WHEN "event"."state" IN (
2048 'voting',
2049 'finished_without_winner',
2050 'finished_with_winner'
2051 ) THEN
2052 'voting'::"notify_level"
2053 ELSE
2054 CASE WHEN "event"."state" IN (
2055 'verification',
2056 'canceled_after_revocation_during_verification',
2057 'canceled_no_initiative_admitted'
2058 ) THEN
2059 'verification'::"notify_level"
2060 ELSE
2061 CASE WHEN "event"."state" IN (
2062 'discussion',
2063 'canceled_after_revocation_during_discussion'
2064 ) THEN
2065 'discussion'::"notify_level"
2066 ELSE
2067 'all'::"notify_level"
2068 END
2069 END
2070 END AS "notify_level",
2071 "event".*
2072 FROM "member" CROSS JOIN "event"
2073 LEFT JOIN "issue"
2074 ON "event"."issue_id" = "issue"."id"
2075 LEFT JOIN "membership"
2076 ON "member"."id" = "membership"."member_id"
2077 AND "issue"."area_id" = "membership"."area_id"
2078 LEFT JOIN "interest"
2079 ON "member"."id" = "interest"."member_id"
2080 AND "event"."issue_id" = "interest"."issue_id"
2081 LEFT JOIN "supporter"
2082 ON "member"."id" = "supporter"."member_id"
2083 AND "event"."initiative_id" = "supporter"."initiative_id"
2084 LEFT JOIN "ignored_member"
2085 ON "member"."id" = "ignored_member"."member_id"
2086 AND "event"."member_id" = "ignored_member"."other_member_id"
2087 LEFT JOIN "ignored_initiative"
2088 ON "member"."id" = "ignored_initiative"."member_id"
2089 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2090 WHERE (
2091 "supporter"."member_id" NOTNULL OR
2092 "interest"."member_id" NOTNULL OR
2093 ( "membership"."member_id" NOTNULL AND
2094 "event"."event" IN (
2095 'issue_state_changed',
2096 'initiative_created_in_new_issue',
2097 'initiative_created_in_existing_issue',
2098 'initiative_revoked' ) ) )
2099 AND "ignored_member"."member_id" ISNULL
2100 AND "ignored_initiative"."member_id" ISNULL;
2102 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
2105 CREATE VIEW "pending_notification" AS
2106 SELECT
2107 "member"."id" AS "seen_by_member_id",
2108 "event".*
2109 FROM "member" CROSS JOIN "event"
2110 LEFT JOIN "issue"
2111 ON "event"."issue_id" = "issue"."id"
2112 LEFT JOIN "membership"
2113 ON "member"."id" = "membership"."member_id"
2114 AND "issue"."area_id" = "membership"."area_id"
2115 LEFT JOIN "interest"
2116 ON "member"."id" = "interest"."member_id"
2117 AND "event"."issue_id" = "interest"."issue_id"
2118 LEFT JOIN "supporter"
2119 ON "member"."id" = "supporter"."member_id"
2120 AND "event"."initiative_id" = "supporter"."initiative_id"
2121 LEFT JOIN "ignored_member"
2122 ON "member"."id" = "ignored_member"."member_id"
2123 AND "event"."member_id" = "ignored_member"."other_member_id"
2124 LEFT JOIN "ignored_initiative"
2125 ON "member"."id" = "ignored_initiative"."member_id"
2126 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2127 WHERE (
2128 "member"."notify_event_id" ISNULL OR
2129 ( "member"."notify_event_id" NOTNULL AND
2130 "member"."notify_event_id" < "event"."id" ) )
2131 AND (
2132 ( "member"."notify_level" >= 'all' ) OR
2133 ( "member"."notify_level" >= 'voting' AND
2134 "event"."state" IN (
2135 'voting',
2136 'finished_without_winner',
2137 'finished_with_winner' ) ) OR
2138 ( "member"."notify_level" >= 'verification' AND
2139 "event"."state" IN (
2140 'verification',
2141 'canceled_after_revocation_during_verification',
2142 'canceled_no_initiative_admitted' ) ) OR
2143 ( "member"."notify_level" >= 'discussion' AND
2144 "event"."state" IN (
2145 'discussion',
2146 'canceled_after_revocation_during_discussion' ) ) )
2147 AND (
2148 "supporter"."member_id" NOTNULL OR
2149 "interest"."member_id" NOTNULL OR
2150 ( "membership"."member_id" NOTNULL AND
2151 "event"."event" IN (
2152 'issue_state_changed',
2153 'initiative_created_in_new_issue',
2154 'initiative_created_in_existing_issue',
2155 'initiative_revoked' ) ) )
2156 AND "ignored_member"."member_id" ISNULL
2157 AND "ignored_initiative"."member_id" ISNULL;
2159 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
2162 CREATE TYPE "timeline_event" AS ENUM (
2163 'issue_created',
2164 'issue_canceled',
2165 'issue_accepted',
2166 'issue_half_frozen',
2167 'issue_finished_without_voting',
2168 'issue_voting_started',
2169 'issue_finished_after_voting',
2170 'initiative_created',
2171 'initiative_revoked',
2172 'draft_created',
2173 'suggestion_created');
2175 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2178 CREATE VIEW "timeline_issue" AS
2179 SELECT
2180 "created" AS "occurrence",
2181 'issue_created'::"timeline_event" AS "event",
2182 "id" AS "issue_id"
2183 FROM "issue"
2184 UNION ALL
2185 SELECT
2186 "closed" AS "occurrence",
2187 'issue_canceled'::"timeline_event" AS "event",
2188 "id" AS "issue_id"
2189 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2190 UNION ALL
2191 SELECT
2192 "accepted" AS "occurrence",
2193 'issue_accepted'::"timeline_event" AS "event",
2194 "id" AS "issue_id"
2195 FROM "issue" WHERE "accepted" NOTNULL
2196 UNION ALL
2197 SELECT
2198 "half_frozen" AS "occurrence",
2199 'issue_half_frozen'::"timeline_event" AS "event",
2200 "id" AS "issue_id"
2201 FROM "issue" WHERE "half_frozen" NOTNULL
2202 UNION ALL
2203 SELECT
2204 "fully_frozen" AS "occurrence",
2205 'issue_voting_started'::"timeline_event" AS "event",
2206 "id" AS "issue_id"
2207 FROM "issue"
2208 WHERE "fully_frozen" NOTNULL
2209 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2210 UNION ALL
2211 SELECT
2212 "closed" AS "occurrence",
2213 CASE WHEN "fully_frozen" = "closed" THEN
2214 'issue_finished_without_voting'::"timeline_event"
2215 ELSE
2216 'issue_finished_after_voting'::"timeline_event"
2217 END AS "event",
2218 "id" AS "issue_id"
2219 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2221 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2224 CREATE VIEW "timeline_initiative" AS
2225 SELECT
2226 "created" AS "occurrence",
2227 'initiative_created'::"timeline_event" AS "event",
2228 "id" AS "initiative_id"
2229 FROM "initiative"
2230 UNION ALL
2231 SELECT
2232 "revoked" AS "occurrence",
2233 'initiative_revoked'::"timeline_event" AS "event",
2234 "id" AS "initiative_id"
2235 FROM "initiative" WHERE "revoked" NOTNULL;
2237 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2240 CREATE VIEW "timeline_draft" AS
2241 SELECT
2242 "created" AS "occurrence",
2243 'draft_created'::"timeline_event" AS "event",
2244 "id" AS "draft_id"
2245 FROM "draft";
2247 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2250 CREATE VIEW "timeline_suggestion" AS
2251 SELECT
2252 "created" AS "occurrence",
2253 'suggestion_created'::"timeline_event" AS "event",
2254 "id" AS "suggestion_id"
2255 FROM "suggestion";
2257 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2260 CREATE VIEW "timeline" AS
2261 SELECT
2262 "occurrence",
2263 "event",
2264 "issue_id",
2265 NULL AS "initiative_id",
2266 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2267 NULL::INT8 AS "suggestion_id"
2268 FROM "timeline_issue"
2269 UNION ALL
2270 SELECT
2271 "occurrence",
2272 "event",
2273 NULL AS "issue_id",
2274 "initiative_id",
2275 NULL AS "draft_id",
2276 NULL AS "suggestion_id"
2277 FROM "timeline_initiative"
2278 UNION ALL
2279 SELECT
2280 "occurrence",
2281 "event",
2282 NULL AS "issue_id",
2283 NULL AS "initiative_id",
2284 "draft_id",
2285 NULL AS "suggestion_id"
2286 FROM "timeline_draft"
2287 UNION ALL
2288 SELECT
2289 "occurrence",
2290 "event",
2291 NULL AS "issue_id",
2292 NULL AS "initiative_id",
2293 NULL AS "draft_id",
2294 "suggestion_id"
2295 FROM "timeline_suggestion";
2297 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2301 --------------------------------------------------
2302 -- Set returning function for delegation chains --
2303 --------------------------------------------------
2306 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2307 ('first', 'intermediate', 'last', 'repetition');
2309 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2312 CREATE TYPE "delegation_chain_row" AS (
2313 "index" INT4,
2314 "member_id" INT4,
2315 "member_valid" BOOLEAN,
2316 "participation" BOOLEAN,
2317 "overridden" BOOLEAN,
2318 "scope_in" "delegation_scope",
2319 "scope_out" "delegation_scope",
2320 "disabled_out" BOOLEAN,
2321 "loop" "delegation_chain_loop_tag" );
2323 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2325 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2326 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';
2327 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2328 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2329 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2330 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2331 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2334 CREATE FUNCTION "delegation_chain"
2335 ( "member_id_p" "member"."id"%TYPE,
2336 "unit_id_p" "unit"."id"%TYPE,
2337 "area_id_p" "area"."id"%TYPE,
2338 "issue_id_p" "issue"."id"%TYPE,
2339 "simulate_trustee_id_p" "member"."id"%TYPE )
2340 RETURNS SETOF "delegation_chain_row"
2341 LANGUAGE 'plpgsql' STABLE AS $$
2342 DECLARE
2343 "scope_v" "delegation_scope";
2344 "unit_id_v" "unit"."id"%TYPE;
2345 "area_id_v" "area"."id"%TYPE;
2346 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2347 "loop_member_id_v" "member"."id"%TYPE;
2348 "output_row" "delegation_chain_row";
2349 "output_rows" "delegation_chain_row"[];
2350 "delegation_row" "delegation"%ROWTYPE;
2351 "row_count" INT4;
2352 "i" INT4;
2353 "loop_v" BOOLEAN;
2354 BEGIN
2355 IF
2356 "unit_id_p" NOTNULL AND
2357 "area_id_p" ISNULL AND
2358 "issue_id_p" ISNULL
2359 THEN
2360 "scope_v" := 'unit';
2361 "unit_id_v" := "unit_id_p";
2362 ELSIF
2363 "unit_id_p" ISNULL AND
2364 "area_id_p" NOTNULL AND
2365 "issue_id_p" ISNULL
2366 THEN
2367 "scope_v" := 'area';
2368 "area_id_v" := "area_id_p";
2369 SELECT "unit_id" INTO "unit_id_v"
2370 FROM "area" WHERE "id" = "area_id_v";
2371 ELSIF
2372 "unit_id_p" ISNULL AND
2373 "area_id_p" ISNULL AND
2374 "issue_id_p" NOTNULL
2375 THEN
2376 "scope_v" := 'issue';
2377 SELECT "area_id" INTO "area_id_v"
2378 FROM "issue" WHERE "id" = "issue_id_p";
2379 SELECT "unit_id" INTO "unit_id_v"
2380 FROM "area" WHERE "id" = "area_id_v";
2381 ELSE
2382 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2383 END IF;
2384 "visited_member_ids" := '{}';
2385 "loop_member_id_v" := NULL;
2386 "output_rows" := '{}';
2387 "output_row"."index" := 0;
2388 "output_row"."member_id" := "member_id_p";
2389 "output_row"."member_valid" := TRUE;
2390 "output_row"."participation" := FALSE;
2391 "output_row"."overridden" := FALSE;
2392 "output_row"."disabled_out" := FALSE;
2393 "output_row"."scope_out" := NULL;
2394 LOOP
2395 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2396 "loop_member_id_v" := "output_row"."member_id";
2397 ELSE
2398 "visited_member_ids" :=
2399 "visited_member_ids" || "output_row"."member_id";
2400 END IF;
2401 IF "output_row"."participation" THEN
2402 "output_row"."overridden" := TRUE;
2403 END IF;
2404 "output_row"."scope_in" := "output_row"."scope_out";
2405 IF EXISTS (
2406 SELECT NULL FROM "member" JOIN "privilege"
2407 ON "privilege"."member_id" = "member"."id"
2408 AND "privilege"."unit_id" = "unit_id_v"
2409 WHERE "id" = "output_row"."member_id"
2410 AND "member"."active" AND "privilege"."voting_right"
2411 ) THEN
2412 IF "scope_v" = 'unit' THEN
2413 SELECT * INTO "delegation_row" FROM "delegation"
2414 WHERE "truster_id" = "output_row"."member_id"
2415 AND "unit_id" = "unit_id_v";
2416 ELSIF "scope_v" = 'area' THEN
2417 "output_row"."participation" := EXISTS (
2418 SELECT NULL FROM "membership"
2419 WHERE "area_id" = "area_id_p"
2420 AND "member_id" = "output_row"."member_id"
2421 );
2422 SELECT * INTO "delegation_row" FROM "delegation"
2423 WHERE "truster_id" = "output_row"."member_id"
2424 AND (
2425 "unit_id" = "unit_id_v" OR
2426 "area_id" = "area_id_v"
2428 ORDER BY "scope" DESC;
2429 ELSIF "scope_v" = 'issue' THEN
2430 "output_row"."participation" := EXISTS (
2431 SELECT NULL FROM "interest"
2432 WHERE "issue_id" = "issue_id_p"
2433 AND "member_id" = "output_row"."member_id"
2434 );
2435 SELECT * INTO "delegation_row" FROM "delegation"
2436 WHERE "truster_id" = "output_row"."member_id"
2437 AND (
2438 "unit_id" = "unit_id_v" OR
2439 "area_id" = "area_id_v" OR
2440 "issue_id" = "issue_id_p"
2442 ORDER BY "scope" DESC;
2443 END IF;
2444 ELSE
2445 "output_row"."member_valid" := FALSE;
2446 "output_row"."participation" := FALSE;
2447 "output_row"."scope_out" := NULL;
2448 "delegation_row" := ROW(NULL);
2449 END IF;
2450 IF
2451 "output_row"."member_id" = "member_id_p" AND
2452 "simulate_trustee_id_p" NOTNULL
2453 THEN
2454 "output_row"."scope_out" := "scope_v";
2455 "output_rows" := "output_rows" || "output_row";
2456 "output_row"."member_id" := "simulate_trustee_id_p";
2457 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2458 "output_row"."scope_out" := "delegation_row"."scope";
2459 "output_rows" := "output_rows" || "output_row";
2460 "output_row"."member_id" := "delegation_row"."trustee_id";
2461 ELSIF "delegation_row"."scope" NOTNULL THEN
2462 "output_row"."scope_out" := "delegation_row"."scope";
2463 "output_row"."disabled_out" := TRUE;
2464 "output_rows" := "output_rows" || "output_row";
2465 EXIT;
2466 ELSE
2467 "output_row"."scope_out" := NULL;
2468 "output_rows" := "output_rows" || "output_row";
2469 EXIT;
2470 END IF;
2471 EXIT WHEN "loop_member_id_v" NOTNULL;
2472 "output_row"."index" := "output_row"."index" + 1;
2473 END LOOP;
2474 "row_count" := array_upper("output_rows", 1);
2475 "i" := 1;
2476 "loop_v" := FALSE;
2477 LOOP
2478 "output_row" := "output_rows"["i"];
2479 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2480 IF "loop_v" THEN
2481 IF "i" + 1 = "row_count" THEN
2482 "output_row"."loop" := 'last';
2483 ELSIF "i" = "row_count" THEN
2484 "output_row"."loop" := 'repetition';
2485 ELSE
2486 "output_row"."loop" := 'intermediate';
2487 END IF;
2488 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2489 "output_row"."loop" := 'first';
2490 "loop_v" := TRUE;
2491 END IF;
2492 IF "scope_v" = 'unit' THEN
2493 "output_row"."participation" := NULL;
2494 END IF;
2495 RETURN NEXT "output_row";
2496 "i" := "i" + 1;
2497 END LOOP;
2498 RETURN;
2499 END;
2500 $$;
2502 COMMENT ON FUNCTION "delegation_chain"
2503 ( "member"."id"%TYPE,
2504 "unit"."id"%TYPE,
2505 "area"."id"%TYPE,
2506 "issue"."id"%TYPE,
2507 "member"."id"%TYPE )
2508 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2511 CREATE FUNCTION "delegation_chain"
2512 ( "member_id_p" "member"."id"%TYPE,
2513 "unit_id_p" "unit"."id"%TYPE,
2514 "area_id_p" "area"."id"%TYPE,
2515 "issue_id_p" "issue"."id"%TYPE )
2516 RETURNS SETOF "delegation_chain_row"
2517 LANGUAGE 'plpgsql' STABLE AS $$
2518 DECLARE
2519 "result_row" "delegation_chain_row";
2520 BEGIN
2521 FOR "result_row" IN
2522 SELECT * FROM "delegation_chain"(
2523 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2525 LOOP
2526 RETURN NEXT "result_row";
2527 END LOOP;
2528 RETURN;
2529 END;
2530 $$;
2532 COMMENT ON FUNCTION "delegation_chain"
2533 ( "member"."id"%TYPE,
2534 "unit"."id"%TYPE,
2535 "area"."id"%TYPE,
2536 "issue"."id"%TYPE )
2537 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2541 ------------------------------
2542 -- Comparison by vote count --
2543 ------------------------------
2545 CREATE FUNCTION "vote_ratio"
2546 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2547 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2548 RETURNS FLOAT8
2549 LANGUAGE 'plpgsql' STABLE AS $$
2550 BEGIN
2551 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2552 RETURN
2553 "positive_votes_p"::FLOAT8 /
2554 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2555 ELSIF "positive_votes_p" > 0 THEN
2556 RETURN "positive_votes_p";
2557 ELSIF "negative_votes_p" > 0 THEN
2558 RETURN 1 - "negative_votes_p";
2559 ELSE
2560 RETURN 0.5;
2561 END IF;
2562 END;
2563 $$;
2565 COMMENT ON FUNCTION "vote_ratio"
2566 ( "initiative"."positive_votes"%TYPE,
2567 "initiative"."negative_votes"%TYPE )
2568 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.';
2572 ------------------------------------------------
2573 -- Locking for snapshots and voting procedure --
2574 ------------------------------------------------
2577 CREATE FUNCTION "share_row_lock_issue_trigger"()
2578 RETURNS TRIGGER
2579 LANGUAGE 'plpgsql' VOLATILE AS $$
2580 BEGIN
2581 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2582 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2583 END IF;
2584 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2585 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2586 RETURN NEW;
2587 ELSE
2588 RETURN OLD;
2589 END IF;
2590 END;
2591 $$;
2593 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2596 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2597 RETURNS TRIGGER
2598 LANGUAGE 'plpgsql' VOLATILE AS $$
2599 BEGIN
2600 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2601 PERFORM NULL FROM "issue"
2602 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2603 WHERE "initiative"."id" = OLD."initiative_id"
2604 FOR SHARE OF "issue";
2605 END IF;
2606 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2607 PERFORM NULL FROM "issue"
2608 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2609 WHERE "initiative"."id" = NEW."initiative_id"
2610 FOR SHARE OF "issue";
2611 RETURN NEW;
2612 ELSE
2613 RETURN OLD;
2614 END IF;
2615 END;
2616 $$;
2618 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2621 CREATE TRIGGER "share_row_lock_issue"
2622 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2623 FOR EACH ROW EXECUTE PROCEDURE
2624 "share_row_lock_issue_trigger"();
2626 CREATE TRIGGER "share_row_lock_issue"
2627 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2628 FOR EACH ROW EXECUTE PROCEDURE
2629 "share_row_lock_issue_trigger"();
2631 CREATE TRIGGER "share_row_lock_issue"
2632 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2633 FOR EACH ROW EXECUTE PROCEDURE
2634 "share_row_lock_issue_trigger"();
2636 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2637 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2638 FOR EACH ROW EXECUTE PROCEDURE
2639 "share_row_lock_issue_via_initiative_trigger"();
2641 CREATE TRIGGER "share_row_lock_issue"
2642 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2643 FOR EACH ROW EXECUTE PROCEDURE
2644 "share_row_lock_issue_trigger"();
2646 CREATE TRIGGER "share_row_lock_issue"
2647 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2648 FOR EACH ROW EXECUTE PROCEDURE
2649 "share_row_lock_issue_trigger"();
2651 CREATE TRIGGER "share_row_lock_issue"
2652 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2653 FOR EACH ROW EXECUTE PROCEDURE
2654 "share_row_lock_issue_trigger"();
2656 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2657 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2658 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2659 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2660 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2661 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2662 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2665 CREATE FUNCTION "lock_issue"
2666 ( "issue_id_p" "issue"."id"%TYPE )
2667 RETURNS VOID
2668 LANGUAGE 'plpgsql' VOLATILE AS $$
2669 BEGIN
2670 LOCK TABLE "member" IN SHARE MODE;
2671 LOCK TABLE "privilege" IN SHARE MODE;
2672 LOCK TABLE "membership" IN SHARE MODE;
2673 LOCK TABLE "policy" IN SHARE MODE;
2674 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2675 -- NOTE: The row-level exclusive lock in combination with the
2676 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2677 -- acquire a row-level share lock on the issue) ensure that no data
2678 -- is changed, which could affect calculation of snapshots or
2679 -- counting of votes. Table "delegation" must be table-level-locked,
2680 -- as it also contains issue- and global-scope delegations.
2681 LOCK TABLE "delegation" IN SHARE MODE;
2682 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2683 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2684 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2685 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2686 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2687 RETURN;
2688 END;
2689 $$;
2691 COMMENT ON FUNCTION "lock_issue"
2692 ( "issue"."id"%TYPE )
2693 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2697 ------------------------------------------------------------------------
2698 -- Regular tasks, except calculcation of snapshots and voting results --
2699 ------------------------------------------------------------------------
2701 CREATE FUNCTION "check_last_login"()
2702 RETURNS VOID
2703 LANGUAGE 'plpgsql' VOLATILE AS $$
2704 DECLARE
2705 "system_setting_row" "system_setting"%ROWTYPE;
2706 BEGIN
2707 SELECT * INTO "system_setting_row" FROM "system_setting";
2708 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2709 UPDATE "member" SET "last_login_public" = "last_login"::date
2710 FROM (
2711 SELECT DISTINCT "member"."id"
2712 FROM "member" LEFT JOIN "member_history"
2713 ON "member"."id" = "member_history"."member_id"
2714 WHERE "member"."last_login"::date < 'today' OR (
2715 "member_history"."until"::date >= 'today' AND
2716 "member_history"."active" = FALSE AND "member"."active" = TRUE
2718 ) AS "subquery"
2719 WHERE "member"."id" = "subquery"."id";
2720 IF "system_setting_row"."member_ttl" NOTNULL THEN
2721 UPDATE "member" SET "active" = FALSE
2722 WHERE "active" = TRUE
2723 AND "last_login"::date < 'today'
2724 AND "last_login_public" <
2725 (now() - "system_setting_row"."member_ttl")::date;
2726 END IF;
2727 RETURN;
2728 END;
2729 $$;
2731 COMMENT ON FUNCTION "check_last_login"() IS 'Updates "last_login_public" field, which contains the date but not the time of the last login, and deactivates members who do not login for the time specified in "system_setting"."member_ttl". For privacy reasons this function does not update "last_login_public", if the last login of a member has been today (except when member was reactivated today).';
2734 CREATE FUNCTION "calculate_member_counts"()
2735 RETURNS VOID
2736 LANGUAGE 'plpgsql' VOLATILE AS $$
2737 BEGIN
2738 LOCK TABLE "member" IN SHARE MODE;
2739 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2740 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2741 LOCK TABLE "area" IN EXCLUSIVE MODE;
2742 LOCK TABLE "privilege" IN SHARE MODE;
2743 LOCK TABLE "membership" IN SHARE MODE;
2744 DELETE FROM "member_count";
2745 INSERT INTO "member_count" ("total_count")
2746 SELECT "total_count" FROM "member_count_view";
2747 UPDATE "unit" SET "member_count" = "view"."member_count"
2748 FROM "unit_member_count" AS "view"
2749 WHERE "view"."unit_id" = "unit"."id";
2750 UPDATE "area" SET
2751 "direct_member_count" = "view"."direct_member_count",
2752 "member_weight" = "view"."member_weight",
2753 "autoreject_weight" = "view"."autoreject_weight"
2754 FROM "area_member_count" AS "view"
2755 WHERE "view"."area_id" = "area"."id";
2756 RETURN;
2757 END;
2758 $$;
2760 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"';
2764 ------------------------------
2765 -- Calculation of snapshots --
2766 ------------------------------
2768 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2769 ( "issue_id_p" "issue"."id"%TYPE,
2770 "member_id_p" "member"."id"%TYPE,
2771 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2772 RETURNS "direct_population_snapshot"."weight"%TYPE
2773 LANGUAGE 'plpgsql' VOLATILE AS $$
2774 DECLARE
2775 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2776 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2777 "weight_v" INT4;
2778 "sub_weight_v" INT4;
2779 BEGIN
2780 "weight_v" := 0;
2781 FOR "issue_delegation_row" IN
2782 SELECT * FROM "issue_delegation"
2783 WHERE "trustee_id" = "member_id_p"
2784 AND "issue_id" = "issue_id_p"
2785 LOOP
2786 IF NOT EXISTS (
2787 SELECT NULL FROM "direct_population_snapshot"
2788 WHERE "issue_id" = "issue_id_p"
2789 AND "event" = 'periodic'
2790 AND "member_id" = "issue_delegation_row"."truster_id"
2791 ) AND NOT EXISTS (
2792 SELECT NULL FROM "delegating_population_snapshot"
2793 WHERE "issue_id" = "issue_id_p"
2794 AND "event" = 'periodic'
2795 AND "member_id" = "issue_delegation_row"."truster_id"
2796 ) THEN
2797 "delegate_member_ids_v" :=
2798 "member_id_p" || "delegate_member_ids_p";
2799 INSERT INTO "delegating_population_snapshot" (
2800 "issue_id",
2801 "event",
2802 "member_id",
2803 "scope",
2804 "delegate_member_ids"
2805 ) VALUES (
2806 "issue_id_p",
2807 'periodic',
2808 "issue_delegation_row"."truster_id",
2809 "issue_delegation_row"."scope",
2810 "delegate_member_ids_v"
2811 );
2812 "sub_weight_v" := 1 +
2813 "weight_of_added_delegations_for_population_snapshot"(
2814 "issue_id_p",
2815 "issue_delegation_row"."truster_id",
2816 "delegate_member_ids_v"
2817 );
2818 UPDATE "delegating_population_snapshot"
2819 SET "weight" = "sub_weight_v"
2820 WHERE "issue_id" = "issue_id_p"
2821 AND "event" = 'periodic'
2822 AND "member_id" = "issue_delegation_row"."truster_id";
2823 "weight_v" := "weight_v" + "sub_weight_v";
2824 END IF;
2825 END LOOP;
2826 RETURN "weight_v";
2827 END;
2828 $$;
2830 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2831 ( "issue"."id"%TYPE,
2832 "member"."id"%TYPE,
2833 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2834 IS 'Helper function for "create_population_snapshot" function';
2837 CREATE FUNCTION "create_population_snapshot"
2838 ( "issue_id_p" "issue"."id"%TYPE )
2839 RETURNS VOID
2840 LANGUAGE 'plpgsql' VOLATILE AS $$
2841 DECLARE
2842 "member_id_v" "member"."id"%TYPE;
2843 BEGIN
2844 DELETE FROM "direct_population_snapshot"
2845 WHERE "issue_id" = "issue_id_p"
2846 AND "event" = 'periodic';
2847 DELETE FROM "delegating_population_snapshot"
2848 WHERE "issue_id" = "issue_id_p"
2849 AND "event" = 'periodic';
2850 INSERT INTO "direct_population_snapshot"
2851 ("issue_id", "event", "member_id")
2852 SELECT
2853 "issue_id_p" AS "issue_id",
2854 'periodic'::"snapshot_event" AS "event",
2855 "member"."id" AS "member_id"
2856 FROM "issue"
2857 JOIN "area" ON "issue"."area_id" = "area"."id"
2858 JOIN "membership" ON "area"."id" = "membership"."area_id"
2859 JOIN "member" ON "membership"."member_id" = "member"."id"
2860 JOIN "privilege"
2861 ON "privilege"."unit_id" = "area"."unit_id"
2862 AND "privilege"."member_id" = "member"."id"
2863 WHERE "issue"."id" = "issue_id_p"
2864 AND "member"."active" AND "privilege"."voting_right"
2865 UNION
2866 SELECT
2867 "issue_id_p" AS "issue_id",
2868 'periodic'::"snapshot_event" AS "event",
2869 "member"."id" AS "member_id"
2870 FROM "issue"
2871 JOIN "area" ON "issue"."area_id" = "area"."id"
2872 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2873 JOIN "member" ON "interest"."member_id" = "member"."id"
2874 JOIN "privilege"
2875 ON "privilege"."unit_id" = "area"."unit_id"
2876 AND "privilege"."member_id" = "member"."id"
2877 WHERE "issue"."id" = "issue_id_p"
2878 AND "member"."active" AND "privilege"."voting_right"
2879 UNION
2880 SELECT
2881 "issue_id_p" AS "issue_id",
2882 'periodic'::"snapshot_event" AS "event",
2883 "member"."id" AS "member_id"
2884 FROM "issue"
2885 JOIN "area" ON "issue"."area_id" = "area"."id"
2886 JOIN "issue_autoreject" ON "issue"."id" = "issue_autoreject"."issue_id"
2887 JOIN "member" ON "issue_autoreject"."member_id" = "member"."id"
2888 JOIN "privilege"
2889 ON "privilege"."unit_id" = "area"."unit_id"
2890 AND "privilege"."member_id" = "member"."id"
2891 WHERE "issue"."id" = "issue_id_p"
2892 AND "member"."active" AND "privilege"."voting_right";
2893 FOR "member_id_v" IN
2894 SELECT "member_id" FROM "direct_population_snapshot"
2895 WHERE "issue_id" = "issue_id_p"
2896 AND "event" = 'periodic'
2897 LOOP
2898 UPDATE "direct_population_snapshot" SET
2899 "weight" = 1 +
2900 "weight_of_added_delegations_for_population_snapshot"(
2901 "issue_id_p",
2902 "member_id_v",
2903 '{}'
2905 WHERE "issue_id" = "issue_id_p"
2906 AND "event" = 'periodic'
2907 AND "member_id" = "member_id_v";
2908 END LOOP;
2909 RETURN;
2910 END;
2911 $$;
2913 COMMENT ON FUNCTION "create_population_snapshot"
2914 ( "issue"."id"%TYPE )
2915 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.';
2918 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2919 ( "issue_id_p" "issue"."id"%TYPE,
2920 "member_id_p" "member"."id"%TYPE,
2921 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2922 RETURNS "direct_interest_snapshot"."weight"%TYPE
2923 LANGUAGE 'plpgsql' VOLATILE AS $$
2924 DECLARE
2925 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2926 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2927 "weight_v" INT4;
2928 "sub_weight_v" INT4;
2929 BEGIN
2930 "weight_v" := 0;
2931 FOR "issue_delegation_row" IN
2932 SELECT * FROM "issue_delegation"
2933 WHERE "trustee_id" = "member_id_p"
2934 AND "issue_id" = "issue_id_p"
2935 LOOP
2936 IF NOT EXISTS (
2937 SELECT NULL FROM "direct_interest_snapshot"
2938 WHERE "issue_id" = "issue_id_p"
2939 AND "event" = 'periodic'
2940 AND "member_id" = "issue_delegation_row"."truster_id"
2941 ) AND NOT EXISTS (
2942 SELECT NULL FROM "delegating_interest_snapshot"
2943 WHERE "issue_id" = "issue_id_p"
2944 AND "event" = 'periodic'
2945 AND "member_id" = "issue_delegation_row"."truster_id"
2946 ) THEN
2947 "delegate_member_ids_v" :=
2948 "member_id_p" || "delegate_member_ids_p";
2949 INSERT INTO "delegating_interest_snapshot" (
2950 "issue_id",
2951 "event",
2952 "member_id",
2953 "scope",
2954 "delegate_member_ids"
2955 ) VALUES (
2956 "issue_id_p",
2957 'periodic',
2958 "issue_delegation_row"."truster_id",
2959 "issue_delegation_row"."scope",
2960 "delegate_member_ids_v"
2961 );
2962 "sub_weight_v" := 1 +
2963 "weight_of_added_delegations_for_interest_snapshot"(
2964 "issue_id_p",
2965 "issue_delegation_row"."truster_id",
2966 "delegate_member_ids_v"
2967 );
2968 UPDATE "delegating_interest_snapshot"
2969 SET "weight" = "sub_weight_v"
2970 WHERE "issue_id" = "issue_id_p"
2971 AND "event" = 'periodic'
2972 AND "member_id" = "issue_delegation_row"."truster_id";
2973 "weight_v" := "weight_v" + "sub_weight_v";
2974 END IF;
2975 END LOOP;
2976 RETURN "weight_v";
2977 END;
2978 $$;
2980 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2981 ( "issue"."id"%TYPE,
2982 "member"."id"%TYPE,
2983 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2984 IS 'Helper function for "create_interest_snapshot" function';
2987 CREATE FUNCTION "create_interest_snapshot"
2988 ( "issue_id_p" "issue"."id"%TYPE )
2989 RETURNS VOID
2990 LANGUAGE 'plpgsql' VOLATILE AS $$
2991 DECLARE
2992 "member_id_v" "member"."id"%TYPE;
2993 BEGIN
2994 DELETE FROM "direct_interest_snapshot"
2995 WHERE "issue_id" = "issue_id_p"
2996 AND "event" = 'periodic';
2997 DELETE FROM "delegating_interest_snapshot"
2998 WHERE "issue_id" = "issue_id_p"
2999 AND "event" = 'periodic';
3000 DELETE FROM "direct_supporter_snapshot"
3001 WHERE "issue_id" = "issue_id_p"
3002 AND "event" = 'periodic';
3003 INSERT INTO "direct_interest_snapshot"
3004 ("issue_id", "event", "member_id")
3005 SELECT
3006 "issue_id_p" AS "issue_id",
3007 'periodic' AS "event",
3008 "member"."id" AS "member_id"
3009 FROM "issue"
3010 JOIN "area" ON "issue"."area_id" = "area"."id"
3011 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3012 JOIN "member" ON "interest"."member_id" = "member"."id"
3013 JOIN "privilege"
3014 ON "privilege"."unit_id" = "area"."unit_id"
3015 AND "privilege"."member_id" = "member"."id"
3016 WHERE "issue"."id" = "issue_id_p"
3017 AND "member"."active" AND "privilege"."voting_right";
3018 FOR "member_id_v" IN
3019 SELECT "member_id" FROM "direct_interest_snapshot"
3020 WHERE "issue_id" = "issue_id_p"
3021 AND "event" = 'periodic'
3022 LOOP
3023 UPDATE "direct_interest_snapshot" SET
3024 "weight" = 1 +
3025 "weight_of_added_delegations_for_interest_snapshot"(
3026 "issue_id_p",
3027 "member_id_v",
3028 '{}'
3030 WHERE "issue_id" = "issue_id_p"
3031 AND "event" = 'periodic'
3032 AND "member_id" = "member_id_v";
3033 END LOOP;
3034 INSERT INTO "direct_supporter_snapshot"
3035 ( "issue_id", "initiative_id", "event", "member_id",
3036 "informed", "satisfied" )
3037 SELECT
3038 "issue_id_p" AS "issue_id",
3039 "initiative"."id" AS "initiative_id",
3040 'periodic' AS "event",
3041 "supporter"."member_id" AS "member_id",
3042 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3043 NOT EXISTS (
3044 SELECT NULL FROM "critical_opinion"
3045 WHERE "initiative_id" = "initiative"."id"
3046 AND "member_id" = "supporter"."member_id"
3047 ) AS "satisfied"
3048 FROM "initiative"
3049 JOIN "supporter"
3050 ON "supporter"."initiative_id" = "initiative"."id"
3051 JOIN "current_draft"
3052 ON "initiative"."id" = "current_draft"."initiative_id"
3053 JOIN "direct_interest_snapshot"
3054 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3055 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3056 AND "event" = 'periodic'
3057 WHERE "initiative"."issue_id" = "issue_id_p";
3058 RETURN;
3059 END;
3060 $$;
3062 COMMENT ON FUNCTION "create_interest_snapshot"
3063 ( "issue"."id"%TYPE )
3064 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.';
3067 CREATE FUNCTION "create_snapshot"
3068 ( "issue_id_p" "issue"."id"%TYPE )
3069 RETURNS VOID
3070 LANGUAGE 'plpgsql' VOLATILE AS $$
3071 DECLARE
3072 "initiative_id_v" "initiative"."id"%TYPE;
3073 "suggestion_id_v" "suggestion"."id"%TYPE;
3074 BEGIN
3075 PERFORM "lock_issue"("issue_id_p");
3076 PERFORM "create_population_snapshot"("issue_id_p");
3077 PERFORM "create_interest_snapshot"("issue_id_p");
3078 UPDATE "issue" SET
3079 "snapshot" = now(),
3080 "latest_snapshot_event" = 'periodic',
3081 "population" = (
3082 SELECT coalesce(sum("weight"), 0)
3083 FROM "direct_population_snapshot"
3084 WHERE "issue_id" = "issue_id_p"
3085 AND "event" = 'periodic'
3087 WHERE "id" = "issue_id_p";
3088 FOR "initiative_id_v" IN
3089 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3090 LOOP
3091 UPDATE "initiative" SET
3092 "supporter_count" = (
3093 SELECT coalesce(sum("di"."weight"), 0)
3094 FROM "direct_interest_snapshot" AS "di"
3095 JOIN "direct_supporter_snapshot" AS "ds"
3096 ON "di"."member_id" = "ds"."member_id"
3097 WHERE "di"."issue_id" = "issue_id_p"
3098 AND "di"."event" = 'periodic'
3099 AND "ds"."initiative_id" = "initiative_id_v"
3100 AND "ds"."event" = 'periodic'
3101 ),
3102 "informed_supporter_count" = (
3103 SELECT coalesce(sum("di"."weight"), 0)
3104 FROM "direct_interest_snapshot" AS "di"
3105 JOIN "direct_supporter_snapshot" AS "ds"
3106 ON "di"."member_id" = "ds"."member_id"
3107 WHERE "di"."issue_id" = "issue_id_p"
3108 AND "di"."event" = 'periodic'
3109 AND "ds"."initiative_id" = "initiative_id_v"
3110 AND "ds"."event" = 'periodic'
3111 AND "ds"."informed"
3112 ),
3113 "satisfied_supporter_count" = (
3114 SELECT coalesce(sum("di"."weight"), 0)
3115 FROM "direct_interest_snapshot" AS "di"
3116 JOIN "direct_supporter_snapshot" AS "ds"
3117 ON "di"."member_id" = "ds"."member_id"
3118 WHERE "di"."issue_id" = "issue_id_p"
3119 AND "di"."event" = 'periodic'
3120 AND "ds"."initiative_id" = "initiative_id_v"
3121 AND "ds"."event" = 'periodic'
3122 AND "ds"."satisfied"
3123 ),
3124 "satisfied_informed_supporter_count" = (
3125 SELECT coalesce(sum("di"."weight"), 0)
3126 FROM "direct_interest_snapshot" AS "di"
3127 JOIN "direct_supporter_snapshot" AS "ds"
3128 ON "di"."member_id" = "ds"."member_id"
3129 WHERE "di"."issue_id" = "issue_id_p"
3130 AND "di"."event" = 'periodic'
3131 AND "ds"."initiative_id" = "initiative_id_v"
3132 AND "ds"."event" = 'periodic'
3133 AND "ds"."informed"
3134 AND "ds"."satisfied"
3136 WHERE "id" = "initiative_id_v";
3137 FOR "suggestion_id_v" IN
3138 SELECT "id" FROM "suggestion"
3139 WHERE "initiative_id" = "initiative_id_v"
3140 LOOP
3141 UPDATE "suggestion" SET
3142 "minus2_unfulfilled_count" = (
3143 SELECT coalesce(sum("snapshot"."weight"), 0)
3144 FROM "issue" CROSS JOIN "opinion"
3145 JOIN "direct_interest_snapshot" AS "snapshot"
3146 ON "snapshot"."issue_id" = "issue"."id"
3147 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3148 AND "snapshot"."member_id" = "opinion"."member_id"
3149 WHERE "issue"."id" = "issue_id_p"
3150 AND "opinion"."suggestion_id" = "suggestion_id_v"
3151 AND "opinion"."degree" = -2
3152 AND "opinion"."fulfilled" = FALSE
3153 ),
3154 "minus2_fulfilled_count" = (
3155 SELECT coalesce(sum("snapshot"."weight"), 0)
3156 FROM "issue" CROSS JOIN "opinion"
3157 JOIN "direct_interest_snapshot" AS "snapshot"
3158 ON "snapshot"."issue_id" = "issue"."id"
3159 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3160 AND "snapshot"."member_id" = "opinion"."member_id"
3161 WHERE "issue"."id" = "issue_id_p"
3162 AND "opinion"."suggestion_id" = "suggestion_id_v"
3163 AND "opinion"."degree" = -2
3164 AND "opinion"."fulfilled" = TRUE
3165 ),
3166 "minus1_unfulfilled_count" = (
3167 SELECT coalesce(sum("snapshot"."weight"), 0)
3168 FROM "issue" CROSS JOIN "opinion"
3169 JOIN "direct_interest_snapshot" AS "snapshot"
3170 ON "snapshot"."issue_id" = "issue"."id"
3171 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3172 AND "snapshot"."member_id" = "opinion"."member_id"
3173 WHERE "issue"."id" = "issue_id_p"
3174 AND "opinion"."suggestion_id" = "suggestion_id_v"
3175 AND "opinion"."degree" = -1
3176 AND "opinion"."fulfilled" = FALSE
3177 ),
3178 "minus1_fulfilled_count" = (
3179 SELECT coalesce(sum("snapshot"."weight"), 0)
3180 FROM "issue" CROSS JOIN "opinion"
3181 JOIN "direct_interest_snapshot" AS "snapshot"
3182 ON "snapshot"."issue_id" = "issue"."id"
3183 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3184 AND "snapshot"."member_id" = "opinion"."member_id"
3185 WHERE "issue"."id" = "issue_id_p"
3186 AND "opinion"."suggestion_id" = "suggestion_id_v"
3187 AND "opinion"."degree" = -1
3188 AND "opinion"."fulfilled" = TRUE
3189 ),
3190 "plus1_unfulfilled_count" = (
3191 SELECT coalesce(sum("snapshot"."weight"), 0)
3192 FROM "issue" CROSS JOIN "opinion"
3193 JOIN "direct_interest_snapshot" AS "snapshot"
3194 ON "snapshot"."issue_id" = "issue"."id"
3195 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3196 AND "snapshot"."member_id" = "opinion"."member_id"
3197 WHERE "issue"."id" = "issue_id_p"
3198 AND "opinion"."suggestion_id" = "suggestion_id_v"
3199 AND "opinion"."degree" = 1
3200 AND "opinion"."fulfilled" = FALSE
3201 ),
3202 "plus1_fulfilled_count" = (
3203 SELECT coalesce(sum("snapshot"."weight"), 0)
3204 FROM "issue" CROSS JOIN "opinion"
3205 JOIN "direct_interest_snapshot" AS "snapshot"
3206 ON "snapshot"."issue_id" = "issue"."id"
3207 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3208 AND "snapshot"."member_id" = "opinion"."member_id"
3209 WHERE "issue"."id" = "issue_id_p"
3210 AND "opinion"."suggestion_id" = "suggestion_id_v"
3211 AND "opinion"."degree" = 1
3212 AND "opinion"."fulfilled" = TRUE
3213 ),
3214 "plus2_unfulfilled_count" = (
3215 SELECT coalesce(sum("snapshot"."weight"), 0)
3216 FROM "issue" CROSS JOIN "opinion"
3217 JOIN "direct_interest_snapshot" AS "snapshot"
3218 ON "snapshot"."issue_id" = "issue"."id"
3219 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3220 AND "snapshot"."member_id" = "opinion"."member_id"
3221 WHERE "issue"."id" = "issue_id_p"
3222 AND "opinion"."suggestion_id" = "suggestion_id_v"
3223 AND "opinion"."degree" = 2
3224 AND "opinion"."fulfilled" = FALSE
3225 ),
3226 "plus2_fulfilled_count" = (
3227 SELECT coalesce(sum("snapshot"."weight"), 0)
3228 FROM "issue" CROSS JOIN "opinion"
3229 JOIN "direct_interest_snapshot" AS "snapshot"
3230 ON "snapshot"."issue_id" = "issue"."id"
3231 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3232 AND "snapshot"."member_id" = "opinion"."member_id"
3233 WHERE "issue"."id" = "issue_id_p"
3234 AND "opinion"."suggestion_id" = "suggestion_id_v"
3235 AND "opinion"."degree" = 2
3236 AND "opinion"."fulfilled" = TRUE
3238 WHERE "suggestion"."id" = "suggestion_id_v";
3239 END LOOP;
3240 END LOOP;
3241 RETURN;
3242 END;
3243 $$;
3245 COMMENT ON FUNCTION "create_snapshot"
3246 ( "issue"."id"%TYPE )
3247 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.';
3250 CREATE FUNCTION "set_snapshot_event"
3251 ( "issue_id_p" "issue"."id"%TYPE,
3252 "event_p" "snapshot_event" )
3253 RETURNS VOID
3254 LANGUAGE 'plpgsql' VOLATILE AS $$
3255 DECLARE
3256 "event_v" "issue"."latest_snapshot_event"%TYPE;
3257 BEGIN
3258 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3259 WHERE "id" = "issue_id_p" FOR UPDATE;
3260 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3261 WHERE "id" = "issue_id_p";
3262 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3263 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3264 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3265 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3266 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3267 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3268 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3269 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3270 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3271 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3272 RETURN;
3273 END;
3274 $$;
3276 COMMENT ON FUNCTION "set_snapshot_event"
3277 ( "issue"."id"%TYPE,
3278 "snapshot_event" )
3279 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3283 ---------------------
3284 -- Freezing issues --
3285 ---------------------
3287 CREATE FUNCTION "freeze_after_snapshot"
3288 ( "issue_id_p" "issue"."id"%TYPE )
3289 RETURNS VOID
3290 LANGUAGE 'plpgsql' VOLATILE AS $$
3291 DECLARE
3292 "issue_row" "issue"%ROWTYPE;
3293 "policy_row" "policy"%ROWTYPE;
3294 "initiative_row" "initiative"%ROWTYPE;
3295 BEGIN
3296 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3297 SELECT * INTO "policy_row"
3298 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3299 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3300 FOR "initiative_row" IN
3301 SELECT * FROM "initiative"
3302 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3303 LOOP
3304 IF
3305 "initiative_row"."satisfied_supporter_count" > 0 AND
3306 "initiative_row"."satisfied_supporter_count" *
3307 "policy_row"."initiative_quorum_den" >=
3308 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3309 THEN
3310 UPDATE "initiative" SET "admitted" = TRUE
3311 WHERE "id" = "initiative_row"."id";
3312 ELSE
3313 UPDATE "initiative" SET "admitted" = FALSE
3314 WHERE "id" = "initiative_row"."id";
3315 END IF;
3316 END LOOP;
3317 IF EXISTS (
3318 SELECT NULL FROM "initiative"
3319 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3320 ) THEN
3321 UPDATE "issue" SET
3322 "state" = 'voting',
3323 "accepted" = coalesce("accepted", now()),
3324 "half_frozen" = coalesce("half_frozen", now()),
3325 "fully_frozen" = now()
3326 WHERE "id" = "issue_id_p";
3327 ELSE
3328 UPDATE "issue" SET
3329 "state" = 'canceled_no_initiative_admitted',
3330 "accepted" = coalesce("accepted", now()),
3331 "half_frozen" = coalesce("half_frozen", now()),
3332 "fully_frozen" = now(),
3333 "closed" = now(),
3334 "ranks_available" = TRUE
3335 WHERE "id" = "issue_id_p";
3336 -- NOTE: The following DELETE statements have effect only when
3337 -- issue state has been manipulated
3338 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3339 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3340 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3341 END IF;
3342 RETURN;
3343 END;
3344 $$;
3346 COMMENT ON FUNCTION "freeze_after_snapshot"
3347 ( "issue"."id"%TYPE )
3348 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3351 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3352 RETURNS VOID
3353 LANGUAGE 'plpgsql' VOLATILE AS $$
3354 DECLARE
3355 "issue_row" "issue"%ROWTYPE;
3356 BEGIN
3357 PERFORM "create_snapshot"("issue_id_p");
3358 PERFORM "freeze_after_snapshot"("issue_id_p");
3359 RETURN;
3360 END;
3361 $$;
3363 COMMENT ON FUNCTION "manual_freeze"
3364 ( "issue"."id"%TYPE )
3365 IS 'Freeze an issue manually (fully) and start voting';
3369 -----------------------
3370 -- Counting of votes --
3371 -----------------------
3374 CREATE FUNCTION "weight_of_added_vote_delegations"
3375 ( "issue_id_p" "issue"."id"%TYPE,
3376 "member_id_p" "member"."id"%TYPE,
3377 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3378 RETURNS "direct_voter"."weight"%TYPE
3379 LANGUAGE 'plpgsql' VOLATILE AS $$
3380 DECLARE
3381 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3382 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3383 "weight_v" INT4;
3384 "sub_weight_v" INT4;
3385 BEGIN
3386 "weight_v" := 0;
3387 FOR "issue_delegation_row" IN
3388 SELECT * FROM "issue_delegation"
3389 WHERE "trustee_id" = "member_id_p"
3390 AND "issue_id" = "issue_id_p"
3391 LOOP
3392 IF NOT EXISTS (
3393 SELECT NULL FROM "direct_voter"
3394 WHERE "member_id" = "issue_delegation_row"."truster_id"
3395 AND "issue_id" = "issue_id_p"
3396 ) AND NOT EXISTS (
3397 SELECT NULL FROM "delegating_voter"
3398 WHERE "member_id" = "issue_delegation_row"."truster_id"
3399 AND "issue_id" = "issue_id_p"
3400 ) THEN
3401 "delegate_member_ids_v" :=
3402 "member_id_p" || "delegate_member_ids_p";
3403 INSERT INTO "delegating_voter" (
3404 "issue_id",
3405 "member_id",
3406 "scope",
3407 "delegate_member_ids"
3408 ) VALUES (
3409 "issue_id_p",
3410 "issue_delegation_row"."truster_id",
3411 "issue_delegation_row"."scope",
3412 "delegate_member_ids_v"
3413 );
3414 "sub_weight_v" := 1 +
3415 "weight_of_added_vote_delegations"(
3416 "issue_id_p",
3417 "issue_delegation_row"."truster_id",
3418 "delegate_member_ids_v"
3419 );
3420 UPDATE "delegating_voter"
3421 SET "weight" = "sub_weight_v"
3422 WHERE "issue_id" = "issue_id_p"
3423 AND "member_id" = "issue_delegation_row"."truster_id";
3424 "weight_v" := "weight_v" + "sub_weight_v";
3425 END IF;
3426 END LOOP;
3427 RETURN "weight_v";
3428 END;
3429 $$;
3431 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3432 ( "issue"."id"%TYPE,
3433 "member"."id"%TYPE,
3434 "delegating_voter"."delegate_member_ids"%TYPE )
3435 IS 'Helper function for "add_vote_delegations" function';
3438 CREATE FUNCTION "add_vote_delegations"
3439 ( "issue_id_p" "issue"."id"%TYPE )
3440 RETURNS VOID
3441 LANGUAGE 'plpgsql' VOLATILE AS $$
3442 DECLARE
3443 "member_id_v" "member"."id"%TYPE;
3444 BEGIN
3445 FOR "member_id_v" IN
3446 SELECT "member_id" FROM "direct_voter"
3447 WHERE "issue_id" = "issue_id_p"
3448 LOOP
3449 UPDATE "direct_voter" SET
3450 "weight" = "weight" + "weight_of_added_vote_delegations"(
3451 "issue_id_p",
3452 "member_id_v",
3453 '{}'
3455 WHERE "member_id" = "member_id_v"
3456 AND "issue_id" = "issue_id_p";
3457 END LOOP;
3458 RETURN;
3459 END;
3460 $$;
3462 COMMENT ON FUNCTION "add_vote_delegations"
3463 ( "issue_id_p" "issue"."id"%TYPE )
3464 IS 'Helper function for "close_voting" function';
3467 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3468 RETURNS VOID
3469 LANGUAGE 'plpgsql' VOLATILE AS $$
3470 DECLARE
3471 "area_id_v" "area"."id"%TYPE;
3472 "unit_id_v" "unit"."id"%TYPE;
3473 "member_id_v" "member"."id"%TYPE;
3474 BEGIN
3475 PERFORM "lock_issue"("issue_id_p");
3476 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3477 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3478 -- consider delegations and auto-reject:
3479 DELETE FROM "delegating_voter"
3480 WHERE "issue_id" = "issue_id_p";
3481 DELETE FROM "direct_voter"
3482 WHERE "issue_id" = "issue_id_p"
3483 AND "autoreject" = TRUE;
3484 DELETE FROM "direct_voter"
3485 USING (
3486 SELECT
3487 "direct_voter"."member_id"
3488 FROM "direct_voter"
3489 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3490 LEFT JOIN "privilege"
3491 ON "privilege"."unit_id" = "unit_id_v"
3492 AND "privilege"."member_id" = "direct_voter"."member_id"
3493 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3494 "member"."active" = FALSE OR
3495 "privilege"."voting_right" ISNULL OR
3496 "privilege"."voting_right" = FALSE
3498 ) AS "subquery"
3499 WHERE "direct_voter"."issue_id" = "issue_id_p"
3500 AND "direct_voter"."member_id" = "subquery"."member_id";
3501 UPDATE "direct_voter" SET "weight" = 1
3502 WHERE "issue_id" = "issue_id_p";
3503 PERFORM "add_vote_delegations"("issue_id_p");
3504 FOR "member_id_v" IN
3505 SELECT "issue_autoreject"."member_id"
3506 FROM "issue_autoreject"
3507 JOIN "member"
3508 ON "issue_autoreject"."member_id" = "member"."id"
3509 JOIN "privilege"
3510 ON "privilege"."unit_id" = "unit_id_v"
3511 AND "privilege"."member_id" = "member"."id"
3512 LEFT JOIN "direct_voter"
3513 ON "issue_autoreject"."member_id" = "direct_voter"."member_id"
3514 AND "issue_autoreject"."issue_id" = "direct_voter"."issue_id"
3515 LEFT JOIN "delegating_voter"
3516 ON "issue_autoreject"."member_id" = "delegating_voter"."member_id"
3517 AND "issue_autoreject"."issue_id" = "delegating_voter"."issue_id"
3518 WHERE "issue_autoreject"."issue_id" = "issue_id_p"
3519 AND "issue_autoreject"."autoreject" = TRUE
3520 AND "member"."active"
3521 AND "privilege"."voting_right"
3522 AND "direct_voter"."member_id" ISNULL
3523 AND "delegating_voter"."member_id" ISNULL
3524 UNION
3525 SELECT "membership"."member_id"
3526 FROM "membership"
3527 JOIN "member"
3528 ON "membership"."member_id" = "member"."id"
3529 JOIN "privilege"
3530 ON "privilege"."unit_id" = "unit_id_v"
3531 AND "privilege"."member_id" = "member"."id"
3532 LEFT JOIN "issue_autoreject"
3533 ON "membership"."member_id" = "issue_autoreject"."member_id"
3534 AND "issue_autoreject"."issue_id" = "issue_id_p"
3535 LEFT JOIN "direct_voter"
3536 ON "membership"."member_id" = "direct_voter"."member_id"
3537 AND "direct_voter"."issue_id" = "issue_id_p"
3538 LEFT JOIN "delegating_voter"
3539 ON "membership"."member_id" = "delegating_voter"."member_id"
3540 AND "delegating_voter"."issue_id" = "issue_id_p"
3541 WHERE "membership"."area_id" = "area_id_v"
3542 AND "membership"."autoreject" = TRUE
3543 AND "member"."active"
3544 AND "privilege"."voting_right"
3545 AND "issue_autoreject"."autoreject" ISNULL
3546 AND "direct_voter"."member_id" ISNULL
3547 AND "delegating_voter"."member_id" ISNULL
3548 LOOP
3549 INSERT INTO "direct_voter"
3550 ("member_id", "issue_id", "weight", "autoreject") VALUES
3551 ("member_id_v", "issue_id_p", 1, TRUE);
3552 INSERT INTO "vote" (
3553 "member_id",
3554 "issue_id",
3555 "initiative_id",
3556 "grade"
3557 ) SELECT
3558 "member_id_v" AS "member_id",
3559 "issue_id_p" AS "issue_id",
3560 "id" AS "initiative_id",
3561 -1 AS "grade"
3562 FROM "initiative"
3563 WHERE "issue_id" = "issue_id_p" AND "admitted";
3564 END LOOP;
3565 PERFORM "add_vote_delegations"("issue_id_p");
3566 -- set voter count and mark issue as being calculated:
3567 UPDATE "issue" SET
3568 "state" = 'calculation',
3569 "closed" = now(),
3570 "voter_count" = (
3571 SELECT coalesce(sum("weight"), 0)
3572 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3574 WHERE "id" = "issue_id_p";
3575 -- materialize battle_view:
3576 -- NOTE: "closed" column of issue must be set at this point
3577 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3578 INSERT INTO "battle" (
3579 "issue_id",
3580 "winning_initiative_id", "losing_initiative_id",
3581 "count"
3582 ) SELECT
3583 "issue_id",
3584 "winning_initiative_id", "losing_initiative_id",
3585 "count"
3586 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3587 -- copy "positive_votes" and "negative_votes" from "battle" table:
3588 UPDATE "initiative" SET
3589 "positive_votes" = "battle_win"."count",
3590 "negative_votes" = "battle_lose"."count"
3591 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3592 WHERE
3593 "battle_win"."issue_id" = "issue_id_p" AND
3594 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3595 "battle_win"."losing_initiative_id" ISNULL AND
3596 "battle_lose"."issue_id" = "issue_id_p" AND
3597 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3598 "battle_lose"."winning_initiative_id" ISNULL;
3599 END;
3600 $$;
3602 COMMENT ON FUNCTION "close_voting"
3603 ( "issue"."id"%TYPE )
3604 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.';
3607 CREATE FUNCTION "defeat_strength"
3608 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3609 RETURNS INT8
3610 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3611 BEGIN
3612 IF "positive_votes_p" > "negative_votes_p" THEN
3613 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3614 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3615 RETURN 0;
3616 ELSE
3617 RETURN -1;
3618 END IF;
3619 END;
3620 $$;
3622 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';
3625 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3626 RETURNS VOID
3627 LANGUAGE 'plpgsql' VOLATILE AS $$
3628 DECLARE
3629 "issue_row" "issue"%ROWTYPE;
3630 "policy_row" "policy"%ROWTYPE;
3631 "dimension_v" INTEGER;
3632 "vote_matrix" INT4[][]; -- absolute votes
3633 "matrix" INT8[][]; -- defeat strength / best paths
3634 "i" INTEGER;
3635 "j" INTEGER;
3636 "k" INTEGER;
3637 "battle_row" "battle"%ROWTYPE;
3638 "rank_ary" INT4[];
3639 "rank_v" INT4;
3640 "done_v" INTEGER;
3641 "winners_ary" INTEGER[];
3642 "initiative_id_v" "initiative"."id"%TYPE;
3643 BEGIN
3644 SELECT * INTO "issue_row"
3645 FROM "issue" WHERE "id" = "issue_id_p"
3646 FOR UPDATE;
3647 SELECT * INTO "policy_row"
3648 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3649 SELECT count(1) INTO "dimension_v"
3650 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3651 IF "dimension_v" > 1 THEN
3652 -- Create "vote_matrix" with absolute number of votes in pairwise
3653 -- comparison:
3654 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3655 "i" := 1;
3656 "j" := 2;
3657 FOR "battle_row" IN
3658 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3659 ORDER BY
3660 "winning_initiative_id" NULLS LAST,
3661 "losing_initiative_id" NULLS LAST
3662 LOOP
3663 "vote_matrix"["i"]["j"] := "battle_row"."count";
3664 IF "j" = "dimension_v" THEN
3665 "i" := "i" + 1;
3666 "j" := 1;
3667 ELSE
3668 "j" := "j" + 1;
3669 IF "j" = "i" THEN
3670 "j" := "j" + 1;
3671 END IF;
3672 END IF;
3673 END LOOP;
3674 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3675 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3676 END IF;
3677 -- Store defeat strengths in "matrix" using "defeat_strength"
3678 -- function:
3679 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3680 "i" := 1;
3681 LOOP
3682 "j" := 1;
3683 LOOP
3684 IF "i" != "j" THEN
3685 "matrix"["i"]["j"] := "defeat_strength"(
3686 "vote_matrix"["i"]["j"],
3687 "vote_matrix"["j"]["i"]
3688 );
3689 END IF;
3690 EXIT WHEN "j" = "dimension_v";
3691 "j" := "j" + 1;
3692 END LOOP;
3693 EXIT WHEN "i" = "dimension_v";
3694 "i" := "i" + 1;
3695 END LOOP;
3696 -- Find best paths:
3697 "i" := 1;
3698 LOOP
3699 "j" := 1;
3700 LOOP
3701 IF "i" != "j" THEN
3702 "k" := 1;
3703 LOOP
3704 IF "i" != "k" AND "j" != "k" THEN
3705 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3706 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3707 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3708 END IF;
3709 ELSE
3710 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3711 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3712 END IF;
3713 END IF;
3714 END IF;
3715 EXIT WHEN "k" = "dimension_v";
3716 "k" := "k" + 1;
3717 END LOOP;
3718 END IF;
3719 EXIT WHEN "j" = "dimension_v";
3720 "j" := "j" + 1;
3721 END LOOP;
3722 EXIT WHEN "i" = "dimension_v";
3723 "i" := "i" + 1;
3724 END LOOP;
3725 -- Determine order of winners:
3726 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3727 "rank_v" := 1;
3728 "done_v" := 0;
3729 LOOP
3730 "winners_ary" := '{}';
3731 "i" := 1;
3732 LOOP
3733 IF "rank_ary"["i"] ISNULL THEN
3734 "j" := 1;
3735 LOOP
3736 IF
3737 "i" != "j" AND
3738 "rank_ary"["j"] ISNULL AND
3739 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3740 THEN
3741 -- someone else is better
3742 EXIT;
3743 END IF;
3744 IF "j" = "dimension_v" THEN
3745 -- noone is better
3746 "winners_ary" := "winners_ary" || "i";
3747 EXIT;
3748 END IF;
3749 "j" := "j" + 1;
3750 END LOOP;
3751 END IF;
3752 EXIT WHEN "i" = "dimension_v";
3753 "i" := "i" + 1;
3754 END LOOP;
3755 "i" := 1;
3756 LOOP
3757 "rank_ary"["winners_ary"["i"]] := "rank_v";
3758 "done_v" := "done_v" + 1;
3759 EXIT WHEN "i" = array_upper("winners_ary", 1);
3760 "i" := "i" + 1;
3761 END LOOP;
3762 EXIT WHEN "done_v" = "dimension_v";
3763 "rank_v" := "rank_v" + 1;
3764 END LOOP;
3765 -- write preliminary results:
3766 "i" := 1;
3767 FOR "initiative_id_v" IN
3768 SELECT "id" FROM "initiative"
3769 WHERE "issue_id" = "issue_id_p" AND "admitted"
3770 ORDER BY "id"
3771 LOOP
3772 UPDATE "initiative" SET
3773 "attainable" =
3774 CASE WHEN "policy_row"."majority_strict" THEN
3775 "positive_votes" * "policy_row"."majority_den" >
3776 "policy_row"."majority_num" * ("positive_votes"+"negative_votes")
3777 ELSE
3778 "positive_votes" * "policy_row"."majority_den" >=
3779 "policy_row"."majority_num" * ("positive_votes"+"negative_votes")
3780 END
3781 AND "positive_votes" >= "policy_row"."majority_positive"
3782 AND "issue_row"."voter_count"-"negative_votes" >=
3783 "policy_row"."majority_non_negative",
3784 "favored_to_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3785 "unfavored_to_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3786 "schulze_rank" = "rank_ary"["i"],
3787 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3788 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0
3789 WHERE "id" = "initiative_id_v";
3790 "i" := "i" + 1;
3791 END LOOP;
3792 IF "i" != "dimension_v" THEN
3793 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3794 END IF;
3795 if "policy_row"."majority_indirect" THEN
3796 -- take indirect majorities into account:
3797 LOOP
3798 UPDATE "initiative" SET "attainable" = TRUE
3799 FROM (
3800 SELECT "new_initiative"."id" AS "initiative_id"
3801 FROM "initiative" "old_initiative"
3802 JOIN "initiative" "new_initiative"
3803 ON "new_initiative"."issue_id" = "issue_id_p"
3804 AND "new_initiative"."attainable" = FALSE
3805 JOIN "battle" "battle_win"
3806 ON "battle_win"."issue_id" = "issue_id_p"
3807 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3808 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3809 JOIN "battle" "battle_lose"
3810 ON "battle_lose"."issue_id" = "issue_id_p"
3811 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3812 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3813 WHERE "old_initiative"."issue_id" = "issue_id_p"
3814 AND "old_initiative"."attainable" = TRUE
3815 AND CASE WHEN "policy_row"."majority_strict" THEN
3816 "battle_win"."count" * "policy_row"."majority_den" >
3817 "policy_row"."majority_num" *
3818 ("battle_win"."count"+"battle_lose"."count")
3819 ELSE
3820 "battle_win"."count" * "policy_row"."majority_den" >=
3821 "policy_row"."majority_num" *
3822 ("battle_win"."count"+"battle_lose"."count")
3823 END
3824 AND "battle_win"."count" >= "policy_row"."majority_positive"
3825 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3826 "policy_row"."majority_non_negative"
3827 ) AS "subquery"
3828 WHERE "id" = "subquery"."initiative_id";
3829 EXIT WHEN NOT FOUND;
3830 END LOOP;
3831 END IF;
3832 -- set "multistage_majority" for remaining matching initiatives:
3833 UPDATE "initiative" SET "multistage_majority" = TRUE
3834 FROM (
3835 SELECT "losing_initiative"."id" AS "initiative_id"
3836 FROM "initiative" "losing_initiative"
3837 JOIN "initiative" "winning_initiative"
3838 ON "winning_initiative"."issue_id" = "issue_id_p"
3839 AND "winning_initiative"."admitted"
3840 JOIN "battle" "battle_win"
3841 ON "battle_win"."issue_id" = "issue_id_p"
3842 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3843 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3844 JOIN "battle" "battle_lose"
3845 ON "battle_lose"."issue_id" = "issue_id_p"
3846 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3847 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3848 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3849 AND "losing_initiative"."admitted"
3850 AND "winning_initiative"."schulze_rank" <
3851 "losing_initiative"."schulze_rank"
3852 AND "battle_win"."count" > "battle_lose"."count"
3853 AND (
3854 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3855 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3856 ) AS "subquery"
3857 WHERE "id" = "subquery"."initiative_id";
3858 -- mark eligible initiatives:
3859 "rank_v" := 1;
3860 UPDATE "initiative" SET "eligible" = TRUE
3861 FROM (
3862 SELECT "initiative"."id" AS "initiative_id"
3863 FROM "issue"
3864 JOIN "policy"
3865 ON "issue"."policy_id" = "policy"."id"
3866 JOIN "initiative"
3867 ON "issue"."id" = "initiative"."issue_id"
3868 WHERE "issue_id" = "issue_id_p"
3869 AND "initiative"."attainable"
3870 AND "initiative"."favored_to_status_quo"
3871 AND (
3872 "policy"."no_multistage_majority" = FALSE OR
3873 "initiative"."multistage_majority" = FALSE )
3874 AND (
3875 "policy"."no_reverse_beat_path" = FALSE OR
3876 "initiative"."reverse_beat_path" = FALSE )
3877 ) AS "subquery"
3878 WHERE "id" = "subquery"."initiative_id";
3879 -- mark final winner:
3880 UPDATE "initiative" SET "winner" = TRUE
3881 FROM (
3882 SELECT "id" AS "initiative_id"
3883 FROM "initiative"
3884 WHERE "issue_id" = "issue_id_p" AND "eligible"
3885 ORDER BY "schulze_rank", "id"
3886 LIMIT 1
3887 ) AS "subquery"
3888 WHERE "id" = "subquery"."initiative_id";
3889 END IF;
3890 -- mark issue as finished:
3891 UPDATE "issue" SET
3892 "state" =
3893 CASE WHEN EXISTS (
3894 SELECT NULL FROM "initiative"
3895 WHERE "issue_id" = "issue_id_p" AND "winner"
3896 ) THEN
3897 'finished_with_winner'::"issue_state"
3898 ELSE
3899 'finished_without_winner'::"issue_state"
3900 END,
3901 "ranks_available" = TRUE
3902 WHERE "id" = "issue_id_p";
3903 RETURN;
3904 END;
3905 $$;
3907 COMMENT ON FUNCTION "calculate_ranks"
3908 ( "issue"."id"%TYPE )
3909 IS 'Determine ranking (Votes have to be counted first)';
3913 -----------------------------
3914 -- Automatic state changes --
3915 -----------------------------
3918 CREATE FUNCTION "check_issue"
3919 ( "issue_id_p" "issue"."id"%TYPE )
3920 RETURNS VOID
3921 LANGUAGE 'plpgsql' VOLATILE AS $$
3922 DECLARE
3923 "issue_row" "issue"%ROWTYPE;
3924 "policy_row" "policy"%ROWTYPE;
3925 BEGIN
3926 PERFORM "lock_issue"("issue_id_p");
3927 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3928 -- only process open issues:
3929 IF "issue_row"."closed" ISNULL THEN
3930 SELECT * INTO "policy_row" FROM "policy"
3931 WHERE "id" = "issue_row"."policy_id";
3932 -- create a snapshot, unless issue is already fully frozen:
3933 IF "issue_row"."fully_frozen" ISNULL THEN
3934 PERFORM "create_snapshot"("issue_id_p");
3935 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3936 END IF;
3937 -- eventually close or accept issues, which have not been accepted:
3938 IF "issue_row"."accepted" ISNULL THEN
3939 IF EXISTS (
3940 SELECT NULL FROM "initiative"
3941 WHERE "issue_id" = "issue_id_p"
3942 AND "supporter_count" > 0
3943 AND "supporter_count" * "policy_row"."issue_quorum_den"
3944 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3945 ) THEN
3946 -- accept issues, if supporter count is high enough
3947 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3948 -- NOTE: "issue_row" used later
3949 "issue_row"."state" := 'discussion';
3950 "issue_row"."accepted" := now();
3951 UPDATE "issue" SET
3952 "state" = "issue_row"."state",
3953 "accepted" = "issue_row"."accepted"
3954 WHERE "id" = "issue_row"."id";
3955 ELSIF
3956 now() >= "issue_row"."created" + "issue_row"."admission_time"
3957 THEN
3958 -- close issues, if admission time has expired
3959 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3960 UPDATE "issue" SET
3961 "state" = 'canceled_issue_not_accepted',
3962 "closed" = now()
3963 WHERE "id" = "issue_row"."id";
3964 END IF;
3965 END IF;
3966 -- eventually half freeze issues:
3967 IF
3968 -- NOTE: issue can't be closed at this point, if it has been accepted
3969 "issue_row"."accepted" NOTNULL AND
3970 "issue_row"."half_frozen" ISNULL
3971 THEN
3972 IF
3973 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3974 THEN
3975 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3976 -- NOTE: "issue_row" used later
3977 "issue_row"."state" := 'verification';
3978 "issue_row"."half_frozen" := now();
3979 UPDATE "issue" SET
3980 "state" = "issue_row"."state",
3981 "half_frozen" = "issue_row"."half_frozen"
3982 WHERE "id" = "issue_row"."id";
3983 END IF;
3984 END IF;
3985 -- close issues after some time, if all initiatives have been revoked:
3986 IF
3987 "issue_row"."closed" ISNULL AND
3988 NOT EXISTS (
3989 -- all initiatives are revoked
3990 SELECT NULL FROM "initiative"
3991 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3992 ) AND (
3993 -- and issue has not been accepted yet
3994 "issue_row"."accepted" ISNULL OR
3995 NOT EXISTS (
3996 -- or no initiatives have been revoked lately
3997 SELECT NULL FROM "initiative"
3998 WHERE "issue_id" = "issue_id_p"
3999 AND now() < "revoked" + "issue_row"."verification_time"
4000 ) OR (
4001 -- or verification time has elapsed
4002 "issue_row"."half_frozen" NOTNULL AND
4003 "issue_row"."fully_frozen" ISNULL AND
4004 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4007 THEN
4008 -- NOTE: "issue_row" used later
4009 IF "issue_row"."accepted" ISNULL THEN
4010 "issue_row"."state" := 'canceled_revoked_before_accepted';
4011 ELSIF "issue_row"."half_frozen" ISNULL THEN
4012 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4013 ELSE
4014 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4015 END IF;
4016 "issue_row"."closed" := now();
4017 UPDATE "issue" SET
4018 "state" = "issue_row"."state",
4019 "closed" = "issue_row"."closed"
4020 WHERE "id" = "issue_row"."id";
4021 END IF;
4022 -- fully freeze issue after verification time:
4023 IF
4024 "issue_row"."half_frozen" NOTNULL AND
4025 "issue_row"."fully_frozen" ISNULL AND
4026 "issue_row"."closed" ISNULL AND
4027 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4028 THEN
4029 PERFORM "freeze_after_snapshot"("issue_id_p");
4030 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4031 END IF;
4032 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4033 -- close issue by calling close_voting(...) after voting time:
4034 IF
4035 "issue_row"."closed" ISNULL AND
4036 "issue_row"."fully_frozen" NOTNULL AND
4037 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4038 THEN
4039 PERFORM "close_voting"("issue_id_p");
4040 -- calculate ranks will not consume much time and can be done now
4041 PERFORM "calculate_ranks"("issue_id_p");
4042 END IF;
4043 END IF;
4044 RETURN;
4045 END;
4046 $$;
4048 COMMENT ON FUNCTION "check_issue"
4049 ( "issue"."id"%TYPE )
4050 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.';
4053 CREATE FUNCTION "check_everything"()
4054 RETURNS VOID
4055 LANGUAGE 'plpgsql' VOLATILE AS $$
4056 DECLARE
4057 "issue_id_v" "issue"."id"%TYPE;
4058 BEGIN
4059 DELETE FROM "expired_session";
4060 PERFORM "check_last_login"();
4061 PERFORM "calculate_member_counts"();
4062 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4063 PERFORM "check_issue"("issue_id_v");
4064 END LOOP;
4065 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4066 PERFORM "calculate_ranks"("issue_id_v");
4067 END LOOP;
4068 RETURN;
4069 END;
4070 $$;
4072 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.';
4076 ----------------------
4077 -- Deletion of data --
4078 ----------------------
4081 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4082 RETURNS VOID
4083 LANGUAGE 'plpgsql' VOLATILE AS $$
4084 DECLARE
4085 "issue_row" "issue"%ROWTYPE;
4086 BEGIN
4087 SELECT * INTO "issue_row"
4088 FROM "issue" WHERE "id" = "issue_id_p"
4089 FOR UPDATE;
4090 IF "issue_row"."cleaned" ISNULL THEN
4091 UPDATE "issue" SET
4092 "state" = 'voting',
4093 "closed" = NULL,
4094 "ranks_available" = FALSE
4095 WHERE "id" = "issue_id_p";
4096 DELETE FROM "issue_comment"
4097 WHERE "issue_id" = "issue_id_p";
4098 DELETE FROM "voting_comment"
4099 WHERE "issue_id" = "issue_id_p";
4100 DELETE FROM "delegating_voter"
4101 WHERE "issue_id" = "issue_id_p";
4102 DELETE FROM "direct_voter"
4103 WHERE "issue_id" = "issue_id_p";
4104 DELETE FROM "delegating_interest_snapshot"
4105 WHERE "issue_id" = "issue_id_p";
4106 DELETE FROM "direct_interest_snapshot"
4107 WHERE "issue_id" = "issue_id_p";
4108 DELETE FROM "delegating_population_snapshot"
4109 WHERE "issue_id" = "issue_id_p";
4110 DELETE FROM "direct_population_snapshot"
4111 WHERE "issue_id" = "issue_id_p";
4112 DELETE FROM "non_voter"
4113 WHERE "issue_id" = "issue_id_p";
4114 DELETE FROM "delegation"
4115 WHERE "issue_id" = "issue_id_p";
4116 DELETE FROM "supporter"
4117 WHERE "issue_id" = "issue_id_p";
4118 DELETE FROM "issue_autoreject"
4119 WHERE "issue_id" = "issue_id_p";
4120 UPDATE "issue" SET
4121 "state" = "issue_row"."state",
4122 "closed" = "issue_row"."closed",
4123 "ranks_available" = "issue_row"."ranks_available",
4124 "cleaned" = now()
4125 WHERE "id" = "issue_id_p";
4126 END IF;
4127 RETURN;
4128 END;
4129 $$;
4131 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4134 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4135 RETURNS VOID
4136 LANGUAGE 'plpgsql' VOLATILE AS $$
4137 BEGIN
4138 UPDATE "member" SET
4139 "last_login" = NULL,
4140 "last_login_public" = NULL,
4141 "login" = NULL,
4142 "password" = NULL,
4143 "locked" = TRUE,
4144 "active" = FALSE,
4145 "notify_email" = NULL,
4146 "notify_email_unconfirmed" = NULL,
4147 "notify_email_secret" = NULL,
4148 "notify_email_secret_expiry" = NULL,
4149 "notify_email_lock_expiry" = NULL,
4150 "password_reset_secret" = NULL,
4151 "password_reset_secret_expiry" = NULL,
4152 "organizational_unit" = NULL,
4153 "internal_posts" = NULL,
4154 "realname" = NULL,
4155 "birthday" = NULL,
4156 "address" = NULL,
4157 "email" = NULL,
4158 "xmpp_address" = NULL,
4159 "website" = NULL,
4160 "phone" = NULL,
4161 "mobile_phone" = NULL,
4162 "profession" = NULL,
4163 "external_memberships" = NULL,
4164 "external_posts" = NULL,
4165 "statement" = NULL
4166 WHERE "id" = "member_id_p";
4167 -- "text_search_data" is updated by triggers
4168 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4169 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4170 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4171 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4172 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4173 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4174 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4175 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4176 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4177 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4178 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4179 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4180 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4181 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4182 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4183 DELETE FROM "direct_voter" USING "issue"
4184 WHERE "direct_voter"."issue_id" = "issue"."id"
4185 AND "issue"."closed" ISNULL
4186 AND "member_id" = "member_id_p";
4187 RETURN;
4188 END;
4189 $$;
4191 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)';
4194 CREATE FUNCTION "delete_private_data"()
4195 RETURNS VOID
4196 LANGUAGE 'plpgsql' VOLATILE AS $$
4197 BEGIN
4198 UPDATE "member" SET
4199 "last_login" = NULL,
4200 "login" = NULL,
4201 "password" = NULL,
4202 "notify_email" = NULL,
4203 "notify_email_unconfirmed" = NULL,
4204 "notify_email_secret" = NULL,
4205 "notify_email_secret_expiry" = NULL,
4206 "notify_email_lock_expiry" = NULL,
4207 "password_reset_secret" = NULL,
4208 "password_reset_secret_expiry" = NULL,
4209 "organizational_unit" = NULL,
4210 "internal_posts" = NULL,
4211 "realname" = NULL,
4212 "birthday" = NULL,
4213 "address" = NULL,
4214 "email" = NULL,
4215 "xmpp_address" = NULL,
4216 "website" = NULL,
4217 "phone" = NULL,
4218 "mobile_phone" = NULL,
4219 "profession" = NULL,
4220 "external_memberships" = NULL,
4221 "external_posts" = NULL,
4222 "statement" = NULL;
4223 -- "text_search_data" is updated by triggers
4224 DELETE FROM "invite_code";
4225 DELETE FROM "setting";
4226 DELETE FROM "setting_map";
4227 DELETE FROM "member_relation_setting";
4228 DELETE FROM "member_image";
4229 DELETE FROM "contact";
4230 DELETE FROM "ignored_member";
4231 DELETE FROM "session";
4232 DELETE FROM "area_setting";
4233 DELETE FROM "issue_setting";
4234 DELETE FROM "ignored_initiative";
4235 DELETE FROM "initiative_setting";
4236 DELETE FROM "suggestion_setting";
4237 DELETE FROM "non_voter";
4238 DELETE FROM "direct_voter" USING "issue"
4239 WHERE "direct_voter"."issue_id" = "issue"."id"
4240 AND "issue"."closed" ISNULL;
4241 RETURN;
4242 END;
4243 $$;
4245 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.';
4249 COMMIT;

Impressum / About Us