liquid_feedback_core

view core.sql @ 137:8766ddbd9b40

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

Impressum / About Us