liquid_feedback_core

view core.sql @ 127:bbadd6b2634d

Bugfix in calculation of minimal rank of initiatives having a majority in function "calculate_ranks"
author jbe
date Tue May 24 03:12:20 2011 +0200 (2011-05-24)
parents 5edfb00d840a
children 5ea2f9c5ba9a
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 CREATE INDEX "policy_active_idx" ON "policy" ("active");
316 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
318 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
319 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
320 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
321 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
322 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
323 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
324 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"';
325 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"';
326 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
327 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
328 COMMENT ON COLUMN "policy"."majority_num" IS 'Numerator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
329 COMMENT ON COLUMN "policy"."majority_den" IS 'Denominator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
330 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.';
333 CREATE TABLE "unit" (
334 "id" SERIAL4 PRIMARY KEY,
335 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
336 "active" BOOLEAN NOT NULL DEFAULT TRUE,
337 "name" TEXT NOT NULL,
338 "description" TEXT NOT NULL DEFAULT '',
339 "member_count" INT4,
340 "text_search_data" TSVECTOR );
341 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
342 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
343 CREATE INDEX "unit_active_idx" ON "unit" ("active");
344 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
345 CREATE TRIGGER "update_text_search_data"
346 BEFORE INSERT OR UPDATE ON "unit"
347 FOR EACH ROW EXECUTE PROCEDURE
348 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
349 "name", "description" );
351 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
353 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
354 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in units of this area';
355 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
358 CREATE TABLE "area" (
359 "id" SERIAL4 PRIMARY KEY,
360 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
361 "active" BOOLEAN NOT NULL DEFAULT TRUE,
362 "name" TEXT NOT NULL,
363 "description" TEXT NOT NULL DEFAULT '',
364 "direct_member_count" INT4,
365 "member_weight" INT4,
366 "autoreject_weight" INT4,
367 "text_search_data" TSVECTOR );
368 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
369 CREATE INDEX "area_active_idx" ON "area" ("active");
370 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
371 CREATE TRIGGER "update_text_search_data"
372 BEFORE INSERT OR UPDATE ON "area"
373 FOR EACH ROW EXECUTE PROCEDURE
374 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
375 "name", "description" );
377 COMMENT ON TABLE "area" IS 'Subject areas';
379 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
380 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"';
381 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
382 COMMENT ON COLUMN "area"."autoreject_weight" IS 'Sum of weight of members using the autoreject feature';
385 CREATE TABLE "area_setting" (
386 PRIMARY KEY ("member_id", "key", "area_id"),
387 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
388 "key" TEXT NOT NULL,
389 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
390 "value" TEXT NOT NULL );
392 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
395 CREATE TABLE "allowed_policy" (
396 PRIMARY KEY ("area_id", "policy_id"),
397 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
398 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
399 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
400 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
402 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
404 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
407 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
409 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';
412 CREATE TYPE "issue_state" AS ENUM (
413 'admission', 'discussion', 'verification', 'voting',
414 'canceled_revoked_before_accepted',
415 'canceled_issue_not_accepted',
416 'canceled_after_revocation_during_discussion',
417 'canceled_after_revocation_during_verification',
418 'calculation',
419 'canceled_no_initiative_admitted',
420 'finished_without_winner', 'finished_with_winner');
422 COMMENT ON TYPE "issue_state" IS 'State of issues';
425 CREATE TABLE "issue" (
426 "id" SERIAL4 PRIMARY KEY,
427 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
428 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
429 "state" "issue_state" NOT NULL DEFAULT 'admission',
430 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
431 "accepted" TIMESTAMPTZ,
432 "half_frozen" TIMESTAMPTZ,
433 "fully_frozen" TIMESTAMPTZ,
434 "closed" TIMESTAMPTZ,
435 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
436 "cleaned" TIMESTAMPTZ,
437 "admission_time" INTERVAL NOT NULL,
438 "discussion_time" INTERVAL NOT NULL,
439 "verification_time" INTERVAL NOT NULL,
440 "voting_time" INTERVAL NOT NULL,
441 "snapshot" TIMESTAMPTZ,
442 "latest_snapshot_event" "snapshot_event",
443 "population" INT4,
444 "vote_now" INT4,
445 "vote_later" INT4,
446 "voter_count" INT4,
447 CONSTRAINT "valid_state" CHECK ((
448 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
449 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
450 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
451 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
452 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
453 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
454 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
455 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
456 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
457 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
458 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
459 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
460 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
461 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
462 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
463 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
464 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
465 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
466 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
467 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
468 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
469 )),
470 CONSTRAINT "state_change_order" CHECK (
471 "created" <= "accepted" AND
472 "accepted" <= "half_frozen" AND
473 "half_frozen" <= "fully_frozen" AND
474 "fully_frozen" <= "closed" ),
475 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
476 "cleaned" ISNULL OR "closed" NOTNULL ),
477 CONSTRAINT "last_snapshot_on_full_freeze"
478 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
479 CONSTRAINT "freeze_requires_snapshot"
480 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
481 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
482 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
483 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
484 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
485 CREATE INDEX "issue_created_idx" ON "issue" ("created");
486 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
487 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
488 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
489 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
490 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
491 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
493 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
495 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
496 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.';
497 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.';
498 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.';
499 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
500 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
501 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
502 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
503 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
504 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
505 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';
506 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';
507 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
508 COMMENT ON COLUMN "issue"."vote_now" IS 'Number of votes in favor of voting now, as calculated from table "direct_interest_snapshot"';
509 COMMENT ON COLUMN "issue"."vote_later" IS 'Number of votes against voting now, as calculated from table "direct_interest_snapshot"';
510 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';
513 CREATE TABLE "issue_setting" (
514 PRIMARY KEY ("member_id", "key", "issue_id"),
515 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
516 "key" TEXT NOT NULL,
517 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
518 "value" TEXT NOT NULL );
520 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
523 CREATE TABLE "initiative" (
524 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
525 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
526 "id" SERIAL4 PRIMARY KEY,
527 "name" TEXT NOT NULL,
528 "discussion_url" TEXT,
529 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
530 "revoked" TIMESTAMPTZ,
531 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
532 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
533 "admitted" BOOLEAN,
534 "supporter_count" INT4,
535 "informed_supporter_count" INT4,
536 "satisfied_supporter_count" INT4,
537 "satisfied_informed_supporter_count" INT4,
538 "positive_votes" INT4,
539 "negative_votes" INT4,
540 "majority" BOOLEAN,
541 "rank" INT4,
542 "winner" BOOLEAN,
543 "text_search_data" TSVECTOR,
544 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
545 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
546 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
547 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
548 CONSTRAINT "revoked_initiatives_cant_be_admitted"
549 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
550 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results"
551 CHECK (("admitted" NOTNULL AND "admitted" = TRUE) OR ("positive_votes" ISNULL AND "negative_votes" ISNULL AND "majority" ISNULL AND "rank" ISNULL AND "winner" ISNULL)),
552 CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_majority_must_be_null"
553 CHECK ("positive_votes" NOTNULL = "negative_votes" NOTNULL AND "positive_votes" NOTNULL = "majority" NOTNULL) );
554 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
555 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
556 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
557 CREATE TRIGGER "update_text_search_data"
558 BEFORE INSERT OR UPDATE ON "initiative"
559 FOR EACH ROW EXECUTE PROCEDURE
560 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
561 "name", "discussion_url");
563 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.';
565 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
566 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
567 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
568 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
569 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
570 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
571 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
572 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
573 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
574 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
575 COMMENT ON COLUMN "initiative"."majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "majority_num"/"majority_den"';
576 COMMENT ON COLUMN "initiative"."rank" IS 'Rank of initiatives, which are ranked better than the "status-quo"; set to NULL for initiatives ranked worse than status-quo or being non-admitted';
577 COMMENT ON COLUMN "initiative"."winner" IS 'TRUE, if initiative is final winner (having "majority"=TRUE and the smallest rank among other initiatives with "majority"=TRUE); set to NULL for non-admitted initiatives';
580 CREATE TABLE "battle" (
581 "issue_id" INT4 NOT NULL,
582 "winning_initiative_id" INT4,
583 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
584 "losing_initiative_id" INT4,
585 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
586 "count" INT4 NOT NULL,
587 CONSTRAINT "initiative_ids_not_equal" CHECK (
588 "winning_initiative_id" != "losing_initiative_id" OR
589 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
590 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
591 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
592 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
593 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
595 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';
598 CREATE TABLE "ignored_initiative" (
599 PRIMARY KEY ("initiative_id", "member_id"),
600 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
601 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
602 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
604 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
607 CREATE TABLE "initiative_setting" (
608 PRIMARY KEY ("member_id", "key", "initiative_id"),
609 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
610 "key" TEXT NOT NULL,
611 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
612 "value" TEXT NOT NULL );
614 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
617 CREATE TABLE "draft" (
618 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
619 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
620 "id" SERIAL8 PRIMARY KEY,
621 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
622 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
623 "formatting_engine" TEXT,
624 "content" TEXT NOT NULL,
625 "text_search_data" TSVECTOR );
626 CREATE INDEX "draft_created_idx" ON "draft" ("created");
627 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
628 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
629 CREATE TRIGGER "update_text_search_data"
630 BEFORE INSERT OR UPDATE ON "draft"
631 FOR EACH ROW EXECUTE PROCEDURE
632 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
634 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.';
636 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
637 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
640 CREATE TABLE "rendered_draft" (
641 PRIMARY KEY ("draft_id", "format"),
642 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
643 "format" TEXT,
644 "content" TEXT NOT NULL );
646 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)';
649 CREATE TABLE "suggestion" (
650 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
651 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
652 "id" SERIAL8 PRIMARY KEY,
653 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
654 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
655 "name" TEXT NOT NULL,
656 "description" TEXT NOT NULL DEFAULT '',
657 "text_search_data" TSVECTOR,
658 "minus2_unfulfilled_count" INT4,
659 "minus2_fulfilled_count" INT4,
660 "minus1_unfulfilled_count" INT4,
661 "minus1_fulfilled_count" INT4,
662 "plus1_unfulfilled_count" INT4,
663 "plus1_fulfilled_count" INT4,
664 "plus2_unfulfilled_count" INT4,
665 "plus2_fulfilled_count" INT4 );
666 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
667 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
668 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
669 CREATE TRIGGER "update_text_search_data"
670 BEFORE INSERT OR UPDATE ON "suggestion"
671 FOR EACH ROW EXECUTE PROCEDURE
672 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
673 "name", "description");
675 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';
677 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
678 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
679 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
680 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
681 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
682 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
683 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
684 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
687 CREATE TABLE "suggestion_setting" (
688 PRIMARY KEY ("member_id", "key", "suggestion_id"),
689 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
690 "key" TEXT NOT NULL,
691 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
692 "value" TEXT NOT NULL );
694 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
697 CREATE TABLE "invite_code_unit" (
698 PRIMARY KEY ("invite_code_id", "unit_id"),
699 "invite_code_id" INT8 REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
700 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
702 COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
705 CREATE TABLE "privilege" (
706 PRIMARY KEY ("unit_id", "member_id"),
707 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
708 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
709 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
710 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
711 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
712 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
713 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
715 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
717 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
718 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
719 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
720 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
721 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
724 CREATE TABLE "membership" (
725 PRIMARY KEY ("area_id", "member_id"),
726 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
727 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
728 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
729 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
731 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
733 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.';
736 CREATE TABLE "interest" (
737 PRIMARY KEY ("issue_id", "member_id"),
738 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
739 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
740 "autoreject" BOOLEAN,
741 "voting_requested" BOOLEAN );
742 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
744 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.';
746 COMMENT ON COLUMN "interest"."autoreject" IS 'TRUE = member votes against all initiatives in case of not explicitly taking part in the voting procedure';
747 COMMENT ON COLUMN "interest"."voting_requested" IS 'TRUE = member wants to vote now, FALSE = member wants to vote later, NULL = policy rules should apply';
750 CREATE TABLE "initiator" (
751 PRIMARY KEY ("initiative_id", "member_id"),
752 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
753 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
754 "accepted" BOOLEAN );
755 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
757 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.';
759 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.';
762 CREATE TABLE "supporter" (
763 "issue_id" INT4 NOT NULL,
764 PRIMARY KEY ("initiative_id", "member_id"),
765 "initiative_id" INT4,
766 "member_id" INT4,
767 "draft_id" INT8 NOT NULL,
768 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
769 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE );
770 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
772 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.';
774 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft, defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
777 CREATE TABLE "opinion" (
778 "initiative_id" INT4 NOT NULL,
779 PRIMARY KEY ("suggestion_id", "member_id"),
780 "suggestion_id" INT8,
781 "member_id" INT4,
782 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
783 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
784 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
785 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
786 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
788 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.';
790 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
793 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
795 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
798 CREATE TABLE "delegation" (
799 "id" SERIAL8 PRIMARY KEY,
800 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
802 "scope" "delegation_scope" NOT NULL,
803 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
804 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
805 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
806 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
807 CONSTRAINT "no_unit_delegation_to_null"
808 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
809 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
810 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
811 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
812 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
813 UNIQUE ("unit_id", "truster_id"),
814 UNIQUE ("area_id", "truster_id"),
815 UNIQUE ("issue_id", "truster_id") );
816 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
817 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
819 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
821 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
822 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
823 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
826 CREATE TABLE "direct_population_snapshot" (
827 PRIMARY KEY ("issue_id", "event", "member_id"),
828 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
829 "event" "snapshot_event",
830 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
831 "weight" INT4 );
832 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
834 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
836 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
837 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
840 CREATE TABLE "delegating_population_snapshot" (
841 PRIMARY KEY ("issue_id", "event", "member_id"),
842 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
843 "event" "snapshot_event",
844 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
845 "weight" INT4,
846 "scope" "delegation_scope" NOT NULL,
847 "delegate_member_ids" INT4[] NOT NULL );
848 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
850 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
852 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
853 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
854 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
855 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"';
858 CREATE TABLE "direct_interest_snapshot" (
859 PRIMARY KEY ("issue_id", "event", "member_id"),
860 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
861 "event" "snapshot_event",
862 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
863 "weight" INT4,
864 "voting_requested" BOOLEAN );
865 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
867 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
869 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
870 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
871 COMMENT ON COLUMN "direct_interest_snapshot"."voting_requested" IS 'Copied from column "voting_requested" of table "interest"';
874 CREATE TABLE "delegating_interest_snapshot" (
875 PRIMARY KEY ("issue_id", "event", "member_id"),
876 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
877 "event" "snapshot_event",
878 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
879 "weight" INT4,
880 "scope" "delegation_scope" NOT NULL,
881 "delegate_member_ids" INT4[] NOT NULL );
882 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
884 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
886 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
887 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
888 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
889 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"';
892 CREATE TABLE "direct_supporter_snapshot" (
893 "issue_id" INT4 NOT NULL,
894 PRIMARY KEY ("initiative_id", "event", "member_id"),
895 "initiative_id" INT4,
896 "event" "snapshot_event",
897 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
898 "informed" BOOLEAN NOT NULL,
899 "satisfied" BOOLEAN NOT NULL,
900 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
901 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
902 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
904 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
906 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
907 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
908 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
911 CREATE TABLE "non_voter" (
912 PRIMARY KEY ("issue_id", "member_id"),
913 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
914 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
915 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
917 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
920 CREATE TABLE "direct_voter" (
921 PRIMARY KEY ("issue_id", "member_id"),
922 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
923 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
924 "weight" INT4,
925 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
926 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
928 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.';
930 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
931 COMMENT ON COLUMN "direct_voter"."autoreject" IS 'Votes were inserted due to "autoreject" feature';
934 CREATE TABLE "delegating_voter" (
935 PRIMARY KEY ("issue_id", "member_id"),
936 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
937 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
938 "weight" INT4,
939 "scope" "delegation_scope" NOT NULL,
940 "delegate_member_ids" INT4[] NOT NULL );
941 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
943 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
945 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
946 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
947 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"';
950 CREATE TABLE "vote" (
951 "issue_id" INT4 NOT NULL,
952 PRIMARY KEY ("initiative_id", "member_id"),
953 "initiative_id" INT4,
954 "member_id" INT4,
955 "grade" INT4,
956 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
957 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
958 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
960 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.';
962 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.';
965 CREATE TABLE "issue_comment" (
966 PRIMARY KEY ("issue_id", "member_id"),
967 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
968 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
969 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
970 "formatting_engine" TEXT,
971 "content" TEXT NOT NULL,
972 "text_search_data" TSVECTOR );
973 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
974 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
975 CREATE TRIGGER "update_text_search_data"
976 BEFORE INSERT OR UPDATE ON "issue_comment"
977 FOR EACH ROW EXECUTE PROCEDURE
978 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
980 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
982 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
985 CREATE TABLE "rendered_issue_comment" (
986 PRIMARY KEY ("issue_id", "member_id", "format"),
987 FOREIGN KEY ("issue_id", "member_id")
988 REFERENCES "issue_comment" ("issue_id", "member_id")
989 ON DELETE CASCADE ON UPDATE CASCADE,
990 "issue_id" INT4,
991 "member_id" INT4,
992 "format" TEXT,
993 "content" TEXT NOT NULL );
995 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)';
998 CREATE TABLE "voting_comment" (
999 PRIMARY KEY ("issue_id", "member_id"),
1000 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1001 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1002 "changed" TIMESTAMPTZ,
1003 "formatting_engine" TEXT,
1004 "content" TEXT NOT NULL,
1005 "text_search_data" TSVECTOR );
1006 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1007 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1008 CREATE TRIGGER "update_text_search_data"
1009 BEFORE INSERT OR UPDATE ON "voting_comment"
1010 FOR EACH ROW EXECUTE PROCEDURE
1011 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1013 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1015 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.';
1018 CREATE TABLE "rendered_voting_comment" (
1019 PRIMARY KEY ("issue_id", "member_id", "format"),
1020 FOREIGN KEY ("issue_id", "member_id")
1021 REFERENCES "voting_comment" ("issue_id", "member_id")
1022 ON DELETE CASCADE ON UPDATE CASCADE,
1023 "issue_id" INT4,
1024 "member_id" INT4,
1025 "format" TEXT,
1026 "content" TEXT NOT NULL );
1028 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)';
1031 CREATE TYPE "event_type" AS ENUM (
1032 'issue_state_changed',
1033 'initiative_created_in_new_issue',
1034 'initiative_created_in_existing_issue',
1035 'initiative_revoked',
1036 'new_draft_created',
1037 'suggestion_created');
1039 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1042 CREATE TABLE "event" (
1043 "id" SERIAL8 PRIMARY KEY,
1044 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1045 "event" "event_type" NOT NULL,
1046 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1047 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1048 "state" "issue_state" CHECK ("state" != 'calculation'),
1049 "initiative_id" INT4,
1050 "draft_id" INT8,
1051 "suggestion_id" INT8,
1052 FOREIGN KEY ("issue_id", "initiative_id")
1053 REFERENCES "initiative" ("issue_id", "id")
1054 ON DELETE CASCADE ON UPDATE CASCADE,
1055 FOREIGN KEY ("initiative_id", "draft_id")
1056 REFERENCES "draft" ("initiative_id", "id")
1057 ON DELETE CASCADE ON UPDATE CASCADE,
1058 FOREIGN KEY ("initiative_id", "suggestion_id")
1059 REFERENCES "suggestion" ("initiative_id", "id")
1060 ON DELETE CASCADE ON UPDATE CASCADE,
1061 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1062 "event" != 'issue_state_changed' OR (
1063 "member_id" ISNULL AND
1064 "issue_id" NOTNULL AND
1065 "state" NOTNULL AND
1066 "initiative_id" ISNULL AND
1067 "draft_id" ISNULL AND
1068 "suggestion_id" ISNULL )),
1069 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1070 "event" NOT IN (
1071 'initiative_created_in_new_issue',
1072 'initiative_created_in_existing_issue',
1073 'initiative_revoked',
1074 'new_draft_created'
1075 ) OR (
1076 "member_id" NOTNULL AND
1077 "issue_id" NOTNULL AND
1078 "state" NOTNULL AND
1079 "initiative_id" NOTNULL AND
1080 "draft_id" NOTNULL AND
1081 "suggestion_id" ISNULL )),
1082 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1083 "event" != 'suggestion_created' OR (
1084 "member_id" NOTNULL AND
1085 "issue_id" NOTNULL AND
1086 "state" NOTNULL AND
1087 "initiative_id" NOTNULL AND
1088 "draft_id" ISNULL AND
1089 "suggestion_id" NOTNULL )) );
1091 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1093 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1094 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1095 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1096 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1100 ----------------------------------------------
1101 -- Writing of history entries and event log --
1102 ----------------------------------------------
1104 CREATE FUNCTION "write_member_history_trigger"()
1105 RETURNS TRIGGER
1106 LANGUAGE 'plpgsql' VOLATILE AS $$
1107 BEGIN
1108 IF
1109 NEW."active" != OLD."active" OR
1110 NEW."name" != OLD."name"
1111 THEN
1112 INSERT INTO "member_history"
1113 ("member_id", "active", "name")
1114 VALUES (NEW."id", OLD."active", OLD."name");
1115 END IF;
1116 RETURN NULL;
1117 END;
1118 $$;
1120 CREATE TRIGGER "write_member_history"
1121 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1122 "write_member_history_trigger"();
1124 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1125 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1128 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1129 RETURNS TRIGGER
1130 LANGUAGE 'plpgsql' VOLATILE AS $$
1131 BEGIN
1132 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1133 INSERT INTO "event" ("event", "issue_id", "state")
1134 VALUES ('issue_state_changed', NEW."id", NEW."state");
1135 END IF;
1136 RETURN NULL;
1137 END;
1138 $$;
1140 CREATE TRIGGER "write_event_issue_state_changed"
1141 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1142 "write_event_issue_state_changed_trigger"();
1144 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1145 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1148 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1149 RETURNS TRIGGER
1150 LANGUAGE 'plpgsql' VOLATILE AS $$
1151 DECLARE
1152 "initiative_row" "initiative"%ROWTYPE;
1153 "issue_row" "issue"%ROWTYPE;
1154 "event_v" "event_type";
1155 BEGIN
1156 SELECT * INTO "initiative_row" FROM "initiative"
1157 WHERE "id" = NEW."initiative_id";
1158 SELECT * INTO "issue_row" FROM "issue"
1159 WHERE "id" = "initiative_row"."issue_id";
1160 IF EXISTS (
1161 SELECT NULL FROM "draft"
1162 WHERE "initiative_id" = NEW."initiative_id"
1163 AND "id" != NEW."id"
1164 ) THEN
1165 "event_v" := 'new_draft_created';
1166 ELSE
1167 IF EXISTS (
1168 SELECT NULL FROM "initiative"
1169 WHERE "issue_id" = "initiative_row"."issue_id"
1170 AND "id" != "initiative_row"."id"
1171 ) THEN
1172 "event_v" := 'initiative_created_in_existing_issue';
1173 ELSE
1174 "event_v" := 'initiative_created_in_new_issue';
1175 END IF;
1176 END IF;
1177 INSERT INTO "event" (
1178 "event", "member_id",
1179 "issue_id", "state", "initiative_id", "draft_id"
1180 ) VALUES (
1181 "event_v",
1182 NEW."author_id",
1183 "initiative_row"."issue_id",
1184 "issue_row"."state",
1185 "initiative_row"."id",
1186 NEW."id" );
1187 RETURN NULL;
1188 END;
1189 $$;
1191 CREATE TRIGGER "write_event_initiative_or_draft_created"
1192 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1193 "write_event_initiative_or_draft_created_trigger"();
1195 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1196 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1199 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1200 RETURNS TRIGGER
1201 LANGUAGE 'plpgsql' VOLATILE AS $$
1202 DECLARE
1203 "issue_row" "issue"%ROWTYPE;
1204 BEGIN
1205 SELECT * INTO "issue_row" FROM "issue"
1206 WHERE "id" = NEW."issue_id";
1207 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1208 INSERT INTO "event" (
1209 "event", "member_id", "issue_id", "state", "initiative_id"
1210 ) VALUES (
1211 'initiative_revoked',
1212 NEW."revoked_by_member_id",
1213 NEW."issue_id",
1214 "issue_row"."state",
1215 NEW."id" );
1216 END IF;
1217 RETURN NULL;
1218 END;
1219 $$;
1221 CREATE TRIGGER "write_event_initiative_revoked"
1222 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1223 "write_event_initiative_revoked_trigger"();
1225 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1226 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1229 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1230 RETURNS TRIGGER
1231 LANGUAGE 'plpgsql' VOLATILE AS $$
1232 DECLARE
1233 "initiative_row" "initiative"%ROWTYPE;
1234 "issue_row" "issue"%ROWTYPE;
1235 BEGIN
1236 SELECT * INTO "initiative_row" FROM "initiative"
1237 WHERE "id" = NEW."initiative_id";
1238 SELECT * INTO "issue_row" FROM "issue"
1239 WHERE "id" = "initiative_row"."issue_id";
1240 INSERT INTO "event" (
1241 "event", "member_id",
1242 "issue_id", "state", "initiative_id", "suggestion_id"
1243 ) VALUES (
1244 'suggestion_created',
1245 NEW."author_id",
1246 "initiative_row"."issue_id",
1247 "issue_row"."state",
1248 "initiative_row"."id",
1249 NEW."id" );
1250 RETURN NULL;
1251 END;
1252 $$;
1254 CREATE TRIGGER "write_event_suggestion_created"
1255 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1256 "write_event_suggestion_created_trigger"();
1258 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1259 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1263 ----------------------------
1264 -- Additional constraints --
1265 ----------------------------
1268 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1269 RETURNS TRIGGER
1270 LANGUAGE 'plpgsql' VOLATILE AS $$
1271 BEGIN
1272 IF NOT EXISTS (
1273 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1274 ) THEN
1275 --RAISE 'Cannot create issue without an initial initiative.' USING
1276 -- ERRCODE = 'integrity_constraint_violation',
1277 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1278 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1279 END IF;
1280 RETURN NULL;
1281 END;
1282 $$;
1284 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1285 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1286 FOR EACH ROW EXECUTE PROCEDURE
1287 "issue_requires_first_initiative_trigger"();
1289 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1290 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1293 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1294 RETURNS TRIGGER
1295 LANGUAGE 'plpgsql' VOLATILE AS $$
1296 DECLARE
1297 "reference_lost" BOOLEAN;
1298 BEGIN
1299 IF TG_OP = 'DELETE' THEN
1300 "reference_lost" := TRUE;
1301 ELSE
1302 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1303 END IF;
1304 IF
1305 "reference_lost" AND NOT EXISTS (
1306 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1308 THEN
1309 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1310 END IF;
1311 RETURN NULL;
1312 END;
1313 $$;
1315 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1316 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1317 FOR EACH ROW EXECUTE PROCEDURE
1318 "last_initiative_deletes_issue_trigger"();
1320 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1321 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1324 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1325 RETURNS TRIGGER
1326 LANGUAGE 'plpgsql' VOLATILE AS $$
1327 BEGIN
1328 IF NOT EXISTS (
1329 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1330 ) THEN
1331 --RAISE 'Cannot create initiative without an initial draft.' USING
1332 -- ERRCODE = 'integrity_constraint_violation',
1333 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1334 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1335 END IF;
1336 RETURN NULL;
1337 END;
1338 $$;
1340 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1341 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1342 FOR EACH ROW EXECUTE PROCEDURE
1343 "initiative_requires_first_draft_trigger"();
1345 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1346 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1349 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1350 RETURNS TRIGGER
1351 LANGUAGE 'plpgsql' VOLATILE AS $$
1352 DECLARE
1353 "reference_lost" BOOLEAN;
1354 BEGIN
1355 IF TG_OP = 'DELETE' THEN
1356 "reference_lost" := TRUE;
1357 ELSE
1358 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1359 END IF;
1360 IF
1361 "reference_lost" AND NOT EXISTS (
1362 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1364 THEN
1365 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1366 END IF;
1367 RETURN NULL;
1368 END;
1369 $$;
1371 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1372 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1373 FOR EACH ROW EXECUTE PROCEDURE
1374 "last_draft_deletes_initiative_trigger"();
1376 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1377 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1380 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1381 RETURNS TRIGGER
1382 LANGUAGE 'plpgsql' VOLATILE AS $$
1383 BEGIN
1384 IF NOT EXISTS (
1385 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1386 ) THEN
1387 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1388 END IF;
1389 RETURN NULL;
1390 END;
1391 $$;
1393 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1394 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1395 FOR EACH ROW EXECUTE PROCEDURE
1396 "suggestion_requires_first_opinion_trigger"();
1398 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1399 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1402 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1403 RETURNS TRIGGER
1404 LANGUAGE 'plpgsql' VOLATILE AS $$
1405 DECLARE
1406 "reference_lost" BOOLEAN;
1407 BEGIN
1408 IF TG_OP = 'DELETE' THEN
1409 "reference_lost" := TRUE;
1410 ELSE
1411 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1412 END IF;
1413 IF
1414 "reference_lost" AND NOT EXISTS (
1415 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1417 THEN
1418 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1419 END IF;
1420 RETURN NULL;
1421 END;
1422 $$;
1424 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1425 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1426 FOR EACH ROW EXECUTE PROCEDURE
1427 "last_opinion_deletes_suggestion_trigger"();
1429 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1430 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1434 ---------------------------------------------------------------
1435 -- Ensure that votes are not modified when issues are frozen --
1436 ---------------------------------------------------------------
1438 -- NOTE: Frontends should ensure this anyway, but in case of programming
1439 -- errors the following triggers ensure data integrity.
1442 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1443 RETURNS TRIGGER
1444 LANGUAGE 'plpgsql' VOLATILE AS $$
1445 DECLARE
1446 "issue_id_v" "issue"."id"%TYPE;
1447 "issue_row" "issue"%ROWTYPE;
1448 BEGIN
1449 IF TG_OP = 'DELETE' THEN
1450 "issue_id_v" := OLD."issue_id";
1451 ELSE
1452 "issue_id_v" := NEW."issue_id";
1453 END IF;
1454 SELECT INTO "issue_row" * FROM "issue"
1455 WHERE "id" = "issue_id_v" FOR SHARE;
1456 IF "issue_row"."closed" NOTNULL THEN
1457 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1458 END IF;
1459 RETURN NULL;
1460 END;
1461 $$;
1463 CREATE TRIGGER "forbid_changes_on_closed_issue"
1464 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1465 FOR EACH ROW EXECUTE PROCEDURE
1466 "forbid_changes_on_closed_issue_trigger"();
1468 CREATE TRIGGER "forbid_changes_on_closed_issue"
1469 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1470 FOR EACH ROW EXECUTE PROCEDURE
1471 "forbid_changes_on_closed_issue_trigger"();
1473 CREATE TRIGGER "forbid_changes_on_closed_issue"
1474 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1475 FOR EACH ROW EXECUTE PROCEDURE
1476 "forbid_changes_on_closed_issue_trigger"();
1478 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"';
1479 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';
1480 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';
1481 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';
1485 --------------------------------------------------------------------
1486 -- Auto-retrieval of fields only needed for referential integrity --
1487 --------------------------------------------------------------------
1490 CREATE FUNCTION "autofill_issue_id_trigger"()
1491 RETURNS TRIGGER
1492 LANGUAGE 'plpgsql' VOLATILE AS $$
1493 BEGIN
1494 IF NEW."issue_id" ISNULL THEN
1495 SELECT "issue_id" INTO NEW."issue_id"
1496 FROM "initiative" WHERE "id" = NEW."initiative_id";
1497 END IF;
1498 RETURN NEW;
1499 END;
1500 $$;
1502 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1503 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1505 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1506 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1508 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1509 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1510 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1513 CREATE FUNCTION "autofill_initiative_id_trigger"()
1514 RETURNS TRIGGER
1515 LANGUAGE 'plpgsql' VOLATILE AS $$
1516 BEGIN
1517 IF NEW."initiative_id" ISNULL THEN
1518 SELECT "initiative_id" INTO NEW."initiative_id"
1519 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1520 END IF;
1521 RETURN NEW;
1522 END;
1523 $$;
1525 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1526 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1528 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1529 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1533 -----------------------------------------------------
1534 -- Automatic calculation of certain default values --
1535 -----------------------------------------------------
1538 CREATE FUNCTION "copy_timings_trigger"()
1539 RETURNS TRIGGER
1540 LANGUAGE 'plpgsql' VOLATILE AS $$
1541 DECLARE
1542 "policy_row" "policy"%ROWTYPE;
1543 BEGIN
1544 SELECT * INTO "policy_row" FROM "policy"
1545 WHERE "id" = NEW."policy_id";
1546 IF NEW."admission_time" ISNULL THEN
1547 NEW."admission_time" := "policy_row"."admission_time";
1548 END IF;
1549 IF NEW."discussion_time" ISNULL THEN
1550 NEW."discussion_time" := "policy_row"."discussion_time";
1551 END IF;
1552 IF NEW."verification_time" ISNULL THEN
1553 NEW."verification_time" := "policy_row"."verification_time";
1554 END IF;
1555 IF NEW."voting_time" ISNULL THEN
1556 NEW."voting_time" := "policy_row"."voting_time";
1557 END IF;
1558 RETURN NEW;
1559 END;
1560 $$;
1562 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1563 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1565 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1566 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1569 CREATE FUNCTION "supporter_default_for_draft_id_trigger"()
1570 RETURNS TRIGGER
1571 LANGUAGE 'plpgsql' VOLATILE AS $$
1572 BEGIN
1573 IF NEW."draft_id" ISNULL THEN
1574 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1575 WHERE "initiative_id" = NEW."initiative_id";
1576 END IF;
1577 RETURN NEW;
1578 END;
1579 $$;
1581 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1582 FOR EACH ROW EXECUTE PROCEDURE "supporter_default_for_draft_id_trigger"();
1584 COMMENT ON FUNCTION "supporter_default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on table "supporter"';
1585 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';
1589 ----------------------------------------
1590 -- Automatic creation of dependencies --
1591 ----------------------------------------
1594 CREATE FUNCTION "autocreate_interest_trigger"()
1595 RETURNS TRIGGER
1596 LANGUAGE 'plpgsql' VOLATILE AS $$
1597 BEGIN
1598 IF NOT EXISTS (
1599 SELECT NULL FROM "initiative" JOIN "interest"
1600 ON "initiative"."issue_id" = "interest"."issue_id"
1601 WHERE "initiative"."id" = NEW."initiative_id"
1602 AND "interest"."member_id" = NEW."member_id"
1603 ) THEN
1604 BEGIN
1605 INSERT INTO "interest" ("issue_id", "member_id")
1606 SELECT "issue_id", NEW."member_id"
1607 FROM "initiative" WHERE "id" = NEW."initiative_id";
1608 EXCEPTION WHEN unique_violation THEN END;
1609 END IF;
1610 RETURN NEW;
1611 END;
1612 $$;
1614 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1615 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1617 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1618 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';
1621 CREATE FUNCTION "autocreate_supporter_trigger"()
1622 RETURNS TRIGGER
1623 LANGUAGE 'plpgsql' VOLATILE AS $$
1624 BEGIN
1625 IF NOT EXISTS (
1626 SELECT NULL FROM "suggestion" JOIN "supporter"
1627 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1628 WHERE "suggestion"."id" = NEW."suggestion_id"
1629 AND "supporter"."member_id" = NEW."member_id"
1630 ) THEN
1631 BEGIN
1632 INSERT INTO "supporter" ("initiative_id", "member_id")
1633 SELECT "initiative_id", NEW."member_id"
1634 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1635 EXCEPTION WHEN unique_violation THEN END;
1636 END IF;
1637 RETURN NEW;
1638 END;
1639 $$;
1641 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1642 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1644 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1645 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.';
1649 ------------------------------------------
1650 -- Views and helper functions for views --
1651 ------------------------------------------
1654 CREATE VIEW "unit_delegation" AS
1655 SELECT
1656 "unit"."id" AS "unit_id",
1657 "delegation"."id",
1658 "delegation"."truster_id",
1659 "delegation"."trustee_id",
1660 "delegation"."scope"
1661 FROM "unit"
1662 JOIN "delegation"
1663 ON "delegation"."unit_id" = "unit"."id"
1664 JOIN "member"
1665 ON "delegation"."truster_id" = "member"."id"
1666 JOIN "privilege"
1667 ON "delegation"."unit_id" = "privilege"."unit_id"
1668 AND "delegation"."truster_id" = "privilege"."member_id"
1669 WHERE "member"."active" AND "privilege"."voting_right";
1671 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1674 CREATE VIEW "area_delegation" AS
1675 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1676 "area"."id" AS "area_id",
1677 "delegation"."id",
1678 "delegation"."truster_id",
1679 "delegation"."trustee_id",
1680 "delegation"."scope"
1681 FROM "area"
1682 JOIN "delegation"
1683 ON "delegation"."unit_id" = "area"."unit_id"
1684 OR "delegation"."area_id" = "area"."id"
1685 JOIN "member"
1686 ON "delegation"."truster_id" = "member"."id"
1687 JOIN "privilege"
1688 ON "area"."unit_id" = "privilege"."unit_id"
1689 AND "delegation"."truster_id" = "privilege"."member_id"
1690 WHERE "member"."active" AND "privilege"."voting_right"
1691 ORDER BY
1692 "area"."id",
1693 "delegation"."truster_id",
1694 "delegation"."scope" DESC;
1696 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1699 CREATE VIEW "issue_delegation" AS
1700 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1701 "issue"."id" AS "issue_id",
1702 "delegation"."id",
1703 "delegation"."truster_id",
1704 "delegation"."trustee_id",
1705 "delegation"."scope"
1706 FROM "issue"
1707 JOIN "area"
1708 ON "area"."id" = "issue"."area_id"
1709 JOIN "delegation"
1710 ON "delegation"."unit_id" = "area"."unit_id"
1711 OR "delegation"."area_id" = "area"."id"
1712 OR "delegation"."issue_id" = "issue"."id"
1713 JOIN "member"
1714 ON "delegation"."truster_id" = "member"."id"
1715 JOIN "privilege"
1716 ON "area"."unit_id" = "privilege"."unit_id"
1717 AND "delegation"."truster_id" = "privilege"."member_id"
1718 WHERE "member"."active" AND "privilege"."voting_right"
1719 ORDER BY
1720 "issue"."id",
1721 "delegation"."truster_id",
1722 "delegation"."scope" DESC;
1724 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1727 CREATE FUNCTION "membership_weight_with_skipping"
1728 ( "area_id_p" "area"."id"%TYPE,
1729 "member_id_p" "member"."id"%TYPE,
1730 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1731 RETURNS INT4
1732 LANGUAGE 'plpgsql' STABLE AS $$
1733 DECLARE
1734 "sum_v" INT4;
1735 "delegation_row" "area_delegation"%ROWTYPE;
1736 BEGIN
1737 "sum_v" := 1;
1738 FOR "delegation_row" IN
1739 SELECT "area_delegation".*
1740 FROM "area_delegation" LEFT JOIN "membership"
1741 ON "membership"."area_id" = "area_id_p"
1742 AND "membership"."member_id" = "area_delegation"."truster_id"
1743 WHERE "area_delegation"."area_id" = "area_id_p"
1744 AND "area_delegation"."trustee_id" = "member_id_p"
1745 AND "membership"."member_id" ISNULL
1746 LOOP
1747 IF NOT
1748 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1749 THEN
1750 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1751 "area_id_p",
1752 "delegation_row"."truster_id",
1753 "skip_member_ids_p" || "delegation_row"."truster_id"
1754 );
1755 END IF;
1756 END LOOP;
1757 RETURN "sum_v";
1758 END;
1759 $$;
1761 COMMENT ON FUNCTION "membership_weight_with_skipping"
1762 ( "area"."id"%TYPE,
1763 "member"."id"%TYPE,
1764 INT4[] )
1765 IS 'Helper function for "membership_weight" function';
1768 CREATE FUNCTION "membership_weight"
1769 ( "area_id_p" "area"."id"%TYPE,
1770 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1771 RETURNS INT4
1772 LANGUAGE 'plpgsql' STABLE AS $$
1773 BEGIN
1774 RETURN "membership_weight_with_skipping"(
1775 "area_id_p",
1776 "member_id_p",
1777 ARRAY["member_id_p"]
1778 );
1779 END;
1780 $$;
1782 COMMENT ON FUNCTION "membership_weight"
1783 ( "area"."id"%TYPE,
1784 "member"."id"%TYPE )
1785 IS 'Calculates the potential voting weight of a member in a given area';
1788 CREATE VIEW "member_count_view" AS
1789 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1791 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1794 CREATE VIEW "unit_member_count" AS
1795 SELECT
1796 "unit"."id" AS "unit_id",
1797 sum("member"."id") AS "member_count"
1798 FROM "unit"
1799 LEFT JOIN "privilege"
1800 ON "privilege"."unit_id" = "unit"."id"
1801 AND "privilege"."voting_right"
1802 LEFT JOIN "member"
1803 ON "member"."id" = "privilege"."member_id"
1804 AND "member"."active"
1805 GROUP BY "unit"."id";
1807 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1810 CREATE VIEW "area_member_count" AS
1811 SELECT
1812 "area"."id" AS "area_id",
1813 count("member"."id") AS "direct_member_count",
1814 coalesce(
1815 sum(
1816 CASE WHEN "member"."id" NOTNULL THEN
1817 "membership_weight"("area"."id", "member"."id")
1818 ELSE 0 END
1820 ) AS "member_weight",
1821 coalesce(
1822 sum(
1823 CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
1824 "membership_weight"("area"."id", "member"."id")
1825 ELSE 0 END
1827 ) AS "autoreject_weight"
1828 FROM "area"
1829 LEFT JOIN "membership"
1830 ON "area"."id" = "membership"."area_id"
1831 LEFT JOIN "privilege"
1832 ON "privilege"."unit_id" = "area"."unit_id"
1833 AND "privilege"."member_id" = "membership"."member_id"
1834 AND "privilege"."voting_right"
1835 LEFT JOIN "member"
1836 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1837 AND "member"."active"
1838 GROUP BY "area"."id";
1840 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count", "member_weight" and "autoreject_weight" columns of table "area"';
1843 CREATE VIEW "opening_draft" AS
1844 SELECT "draft".* FROM (
1845 SELECT
1846 "initiative"."id" AS "initiative_id",
1847 min("draft"."id") AS "draft_id"
1848 FROM "initiative" JOIN "draft"
1849 ON "initiative"."id" = "draft"."initiative_id"
1850 GROUP BY "initiative"."id"
1851 ) AS "subquery"
1852 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1854 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1857 CREATE VIEW "current_draft" AS
1858 SELECT "draft".* FROM (
1859 SELECT
1860 "initiative"."id" AS "initiative_id",
1861 max("draft"."id") AS "draft_id"
1862 FROM "initiative" JOIN "draft"
1863 ON "initiative"."id" = "draft"."initiative_id"
1864 GROUP BY "initiative"."id"
1865 ) AS "subquery"
1866 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1868 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1871 CREATE VIEW "critical_opinion" AS
1872 SELECT * FROM "opinion"
1873 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1874 OR ("degree" = -2 AND "fulfilled" = TRUE);
1876 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1879 CREATE VIEW "battle_participant" AS
1880 SELECT "initiative"."id", "initiative"."issue_id"
1881 FROM "issue" JOIN "initiative"
1882 ON "issue"."id" = "initiative"."issue_id"
1883 WHERE "initiative"."admitted"
1884 UNION ALL
1885 SELECT NULL, "id" AS "issue_id"
1886 FROM "issue";
1888 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1891 CREATE VIEW "battle_view" AS
1892 SELECT
1893 "issue"."id" AS "issue_id",
1894 "winning_initiative"."id" AS "winning_initiative_id",
1895 "losing_initiative"."id" AS "losing_initiative_id",
1896 sum(
1897 CASE WHEN
1898 coalesce("better_vote"."grade", 0) >
1899 coalesce("worse_vote"."grade", 0)
1900 THEN "direct_voter"."weight" ELSE 0 END
1901 ) AS "count"
1902 FROM "issue"
1903 LEFT JOIN "direct_voter"
1904 ON "issue"."id" = "direct_voter"."issue_id"
1905 JOIN "battle_participant" AS "winning_initiative"
1906 ON "issue"."id" = "winning_initiative"."issue_id"
1907 JOIN "battle_participant" AS "losing_initiative"
1908 ON "issue"."id" = "losing_initiative"."issue_id"
1909 LEFT JOIN "vote" AS "better_vote"
1910 ON "direct_voter"."member_id" = "better_vote"."member_id"
1911 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1912 LEFT JOIN "vote" AS "worse_vote"
1913 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1914 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1915 WHERE "issue"."closed" NOTNULL
1916 AND "issue"."cleaned" ISNULL
1917 AND (
1918 "winning_initiative"."id" != "losing_initiative"."id" OR
1919 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1920 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1921 GROUP BY
1922 "issue"."id",
1923 "winning_initiative"."id",
1924 "losing_initiative"."id";
1926 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';
1929 CREATE VIEW "expired_session" AS
1930 SELECT * FROM "session" WHERE now() > "expiry";
1932 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
1933 DELETE FROM "session" WHERE "ident" = OLD."ident";
1935 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
1936 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
1939 CREATE VIEW "open_issue" AS
1940 SELECT * FROM "issue" WHERE "closed" ISNULL;
1942 COMMENT ON VIEW "open_issue" IS 'All open issues';
1945 CREATE VIEW "issue_with_ranks_missing" AS
1946 SELECT * FROM "issue"
1947 WHERE "fully_frozen" NOTNULL
1948 AND "closed" NOTNULL
1949 AND "ranks_available" = FALSE;
1951 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
1954 CREATE VIEW "member_contingent" AS
1955 SELECT
1956 "member"."id" AS "member_id",
1957 "contingent"."time_frame",
1958 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
1960 SELECT count(1) FROM "draft"
1961 WHERE "draft"."author_id" = "member"."id"
1962 AND "draft"."created" > now() - "contingent"."time_frame"
1963 ) + (
1964 SELECT count(1) FROM "suggestion"
1965 WHERE "suggestion"."author_id" = "member"."id"
1966 AND "suggestion"."created" > now() - "contingent"."time_frame"
1968 ELSE NULL END AS "text_entry_count",
1969 "contingent"."text_entry_limit",
1970 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
1971 SELECT count(1) FROM "opening_draft"
1972 WHERE "opening_draft"."author_id" = "member"."id"
1973 AND "opening_draft"."created" > now() - "contingent"."time_frame"
1974 ) ELSE NULL END AS "initiative_count",
1975 "contingent"."initiative_limit"
1976 FROM "member" CROSS JOIN "contingent";
1978 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
1980 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
1981 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
1984 CREATE VIEW "member_contingent_left" AS
1985 SELECT
1986 "member_id",
1987 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
1988 max("initiative_limit" - "initiative_count") AS "initiatives_left"
1989 FROM "member_contingent" GROUP BY "member_id";
1991 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.';
1994 CREATE VIEW "event_seen_by_member" AS
1995 SELECT
1996 "member"."id" AS "seen_by_member_id",
1997 CASE WHEN "event"."state" IN (
1998 'voting',
1999 'finished_without_winner',
2000 'finished_with_winner'
2001 ) THEN
2002 'voting'::"notify_level"
2003 ELSE
2004 CASE WHEN "event"."state" IN (
2005 'verification',
2006 'canceled_after_revocation_during_verification',
2007 'canceled_no_initiative_admitted'
2008 ) THEN
2009 'verification'::"notify_level"
2010 ELSE
2011 CASE WHEN "event"."state" IN (
2012 'discussion',
2013 'canceled_after_revocation_during_discussion'
2014 ) THEN
2015 'discussion'::"notify_level"
2016 ELSE
2017 'all'::"notify_level"
2018 END
2019 END
2020 END AS "notify_level",
2021 "event".*
2022 FROM "member" CROSS JOIN "event"
2023 LEFT JOIN "issue"
2024 ON "event"."issue_id" = "issue"."id"
2025 LEFT JOIN "membership"
2026 ON "member"."id" = "membership"."member_id"
2027 AND "issue"."area_id" = "membership"."area_id"
2028 LEFT JOIN "interest"
2029 ON "member"."id" = "interest"."member_id"
2030 AND "event"."issue_id" = "interest"."issue_id"
2031 LEFT JOIN "supporter"
2032 ON "member"."id" = "supporter"."member_id"
2033 AND "event"."initiative_id" = "supporter"."initiative_id"
2034 LEFT JOIN "ignored_member"
2035 ON "member"."id" = "ignored_member"."member_id"
2036 AND "event"."member_id" = "ignored_member"."other_member_id"
2037 LEFT JOIN "ignored_initiative"
2038 ON "member"."id" = "ignored_initiative"."member_id"
2039 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2040 WHERE (
2041 "supporter"."member_id" NOTNULL OR
2042 "interest"."member_id" NOTNULL OR
2043 ( "membership"."member_id" NOTNULL AND
2044 "event"."event" IN (
2045 'issue_state_changed',
2046 'initiative_created_in_new_issue',
2047 'initiative_created_in_existing_issue',
2048 'initiative_revoked' ) ) )
2049 AND "ignored_member"."member_id" ISNULL
2050 AND "ignored_initiative"."member_id" ISNULL;
2052 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
2055 CREATE VIEW "pending_notification" AS
2056 SELECT
2057 "member"."id" AS "seen_by_member_id",
2058 "event".*
2059 FROM "member" CROSS JOIN "event"
2060 LEFT JOIN "issue"
2061 ON "event"."issue_id" = "issue"."id"
2062 LEFT JOIN "membership"
2063 ON "member"."id" = "membership"."member_id"
2064 AND "issue"."area_id" = "membership"."area_id"
2065 LEFT JOIN "interest"
2066 ON "member"."id" = "interest"."member_id"
2067 AND "event"."issue_id" = "interest"."issue_id"
2068 LEFT JOIN "supporter"
2069 ON "member"."id" = "supporter"."member_id"
2070 AND "event"."initiative_id" = "supporter"."initiative_id"
2071 LEFT JOIN "ignored_member"
2072 ON "member"."id" = "ignored_member"."member_id"
2073 AND "event"."member_id" = "ignored_member"."other_member_id"
2074 LEFT JOIN "ignored_initiative"
2075 ON "member"."id" = "ignored_initiative"."member_id"
2076 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2077 WHERE (
2078 "member"."notify_event_id" ISNULL OR
2079 ( "member"."notify_event_id" NOTNULL AND
2080 "member"."notify_event_id" < "event"."id" ) )
2081 AND (
2082 ( "member"."notify_level" >= 'all' ) OR
2083 ( "member"."notify_level" >= 'voting' AND
2084 "event"."state" IN (
2085 'voting',
2086 'finished_without_winner',
2087 'finished_with_winner' ) ) OR
2088 ( "member"."notify_level" >= 'verification' AND
2089 "event"."state" IN (
2090 'verification',
2091 'canceled_after_revocation_during_verification',
2092 'canceled_no_initiative_admitted' ) ) OR
2093 ( "member"."notify_level" >= 'discussion' AND
2094 "event"."state" IN (
2095 'discussion',
2096 'canceled_after_revocation_during_discussion' ) ) )
2097 AND (
2098 "supporter"."member_id" NOTNULL OR
2099 "interest"."member_id" NOTNULL OR
2100 ( "membership"."member_id" NOTNULL AND
2101 "event"."event" IN (
2102 'issue_state_changed',
2103 'initiative_created_in_new_issue',
2104 'initiative_created_in_existing_issue',
2105 'initiative_revoked' ) ) )
2106 AND "ignored_member"."member_id" ISNULL
2107 AND "ignored_initiative"."member_id" ISNULL;
2109 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
2112 CREATE TYPE "timeline_event" AS ENUM (
2113 'issue_created',
2114 'issue_canceled',
2115 'issue_accepted',
2116 'issue_half_frozen',
2117 'issue_finished_without_voting',
2118 'issue_voting_started',
2119 'issue_finished_after_voting',
2120 'initiative_created',
2121 'initiative_revoked',
2122 'draft_created',
2123 'suggestion_created');
2125 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2128 CREATE VIEW "timeline_issue" AS
2129 SELECT
2130 "created" AS "occurrence",
2131 'issue_created'::"timeline_event" AS "event",
2132 "id" AS "issue_id"
2133 FROM "issue"
2134 UNION ALL
2135 SELECT
2136 "closed" AS "occurrence",
2137 'issue_canceled'::"timeline_event" AS "event",
2138 "id" AS "issue_id"
2139 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2140 UNION ALL
2141 SELECT
2142 "accepted" AS "occurrence",
2143 'issue_accepted'::"timeline_event" AS "event",
2144 "id" AS "issue_id"
2145 FROM "issue" WHERE "accepted" NOTNULL
2146 UNION ALL
2147 SELECT
2148 "half_frozen" AS "occurrence",
2149 'issue_half_frozen'::"timeline_event" AS "event",
2150 "id" AS "issue_id"
2151 FROM "issue" WHERE "half_frozen" NOTNULL
2152 UNION ALL
2153 SELECT
2154 "fully_frozen" AS "occurrence",
2155 'issue_voting_started'::"timeline_event" AS "event",
2156 "id" AS "issue_id"
2157 FROM "issue"
2158 WHERE "fully_frozen" NOTNULL
2159 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2160 UNION ALL
2161 SELECT
2162 "closed" AS "occurrence",
2163 CASE WHEN "fully_frozen" = "closed" THEN
2164 'issue_finished_without_voting'::"timeline_event"
2165 ELSE
2166 'issue_finished_after_voting'::"timeline_event"
2167 END AS "event",
2168 "id" AS "issue_id"
2169 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2171 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2174 CREATE VIEW "timeline_initiative" AS
2175 SELECT
2176 "created" AS "occurrence",
2177 'initiative_created'::"timeline_event" AS "event",
2178 "id" AS "initiative_id"
2179 FROM "initiative"
2180 UNION ALL
2181 SELECT
2182 "revoked" AS "occurrence",
2183 'initiative_revoked'::"timeline_event" AS "event",
2184 "id" AS "initiative_id"
2185 FROM "initiative" WHERE "revoked" NOTNULL;
2187 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2190 CREATE VIEW "timeline_draft" AS
2191 SELECT
2192 "created" AS "occurrence",
2193 'draft_created'::"timeline_event" AS "event",
2194 "id" AS "draft_id"
2195 FROM "draft";
2197 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2200 CREATE VIEW "timeline_suggestion" AS
2201 SELECT
2202 "created" AS "occurrence",
2203 'suggestion_created'::"timeline_event" AS "event",
2204 "id" AS "suggestion_id"
2205 FROM "suggestion";
2207 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2210 CREATE VIEW "timeline" AS
2211 SELECT
2212 "occurrence",
2213 "event",
2214 "issue_id",
2215 NULL AS "initiative_id",
2216 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2217 NULL::INT8 AS "suggestion_id"
2218 FROM "timeline_issue"
2219 UNION ALL
2220 SELECT
2221 "occurrence",
2222 "event",
2223 NULL AS "issue_id",
2224 "initiative_id",
2225 NULL AS "draft_id",
2226 NULL AS "suggestion_id"
2227 FROM "timeline_initiative"
2228 UNION ALL
2229 SELECT
2230 "occurrence",
2231 "event",
2232 NULL AS "issue_id",
2233 NULL AS "initiative_id",
2234 "draft_id",
2235 NULL AS "suggestion_id"
2236 FROM "timeline_draft"
2237 UNION ALL
2238 SELECT
2239 "occurrence",
2240 "event",
2241 NULL AS "issue_id",
2242 NULL AS "initiative_id",
2243 NULL AS "draft_id",
2244 "suggestion_id"
2245 FROM "timeline_suggestion";
2247 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2251 --------------------------------------------------
2252 -- Set returning function for delegation chains --
2253 --------------------------------------------------
2256 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2257 ('first', 'intermediate', 'last', 'repetition');
2259 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2262 CREATE TYPE "delegation_chain_row" AS (
2263 "index" INT4,
2264 "member_id" INT4,
2265 "member_valid" BOOLEAN,
2266 "participation" BOOLEAN,
2267 "overridden" BOOLEAN,
2268 "scope_in" "delegation_scope",
2269 "scope_out" "delegation_scope",
2270 "disabled_out" BOOLEAN,
2271 "loop" "delegation_chain_loop_tag" );
2273 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2275 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2276 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';
2277 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2278 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2279 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2280 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2281 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2284 CREATE FUNCTION "delegation_chain"
2285 ( "member_id_p" "member"."id"%TYPE,
2286 "unit_id_p" "unit"."id"%TYPE,
2287 "area_id_p" "area"."id"%TYPE,
2288 "issue_id_p" "issue"."id"%TYPE,
2289 "simulate_trustee_id_p" "member"."id"%TYPE )
2290 RETURNS SETOF "delegation_chain_row"
2291 LANGUAGE 'plpgsql' STABLE AS $$
2292 DECLARE
2293 "scope_v" "delegation_scope";
2294 "unit_id_v" "unit"."id"%TYPE;
2295 "area_id_v" "area"."id"%TYPE;
2296 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2297 "loop_member_id_v" "member"."id"%TYPE;
2298 "output_row" "delegation_chain_row";
2299 "output_rows" "delegation_chain_row"[];
2300 "delegation_row" "delegation"%ROWTYPE;
2301 "row_count" INT4;
2302 "i" INT4;
2303 "loop_v" BOOLEAN;
2304 BEGIN
2305 IF
2306 "unit_id_p" NOTNULL AND
2307 "area_id_p" ISNULL AND
2308 "issue_id_p" ISNULL
2309 THEN
2310 "scope_v" := 'unit';
2311 "unit_id_v" := "unit_id_p";
2312 ELSIF
2313 "unit_id_p" ISNULL AND
2314 "area_id_p" NOTNULL AND
2315 "issue_id_p" ISNULL
2316 THEN
2317 "scope_v" := 'area';
2318 "area_id_v" := "area_id_p";
2319 SELECT "unit_id" INTO "unit_id_v"
2320 FROM "area" WHERE "id" = "area_id_v";
2321 ELSIF
2322 "unit_id_p" ISNULL AND
2323 "area_id_p" ISNULL AND
2324 "issue_id_p" NOTNULL
2325 THEN
2326 "scope_v" := 'issue';
2327 SELECT "area_id" INTO "area_id_v"
2328 FROM "issue" WHERE "id" = "issue_id_p";
2329 SELECT "unit_id" INTO "unit_id_v"
2330 FROM "area" WHERE "id" = "area_id_v";
2331 ELSE
2332 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2333 END IF;
2334 "visited_member_ids" := '{}';
2335 "loop_member_id_v" := NULL;
2336 "output_rows" := '{}';
2337 "output_row"."index" := 0;
2338 "output_row"."member_id" := "member_id_p";
2339 "output_row"."member_valid" := TRUE;
2340 "output_row"."participation" := FALSE;
2341 "output_row"."overridden" := FALSE;
2342 "output_row"."disabled_out" := FALSE;
2343 "output_row"."scope_out" := NULL;
2344 LOOP
2345 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2346 "loop_member_id_v" := "output_row"."member_id";
2347 ELSE
2348 "visited_member_ids" :=
2349 "visited_member_ids" || "output_row"."member_id";
2350 END IF;
2351 IF "output_row"."participation" THEN
2352 "output_row"."overridden" := TRUE;
2353 END IF;
2354 "output_row"."scope_in" := "output_row"."scope_out";
2355 IF EXISTS (
2356 SELECT NULL FROM "member" JOIN "privilege"
2357 ON "privilege"."member_id" = "member"."id"
2358 AND "privilege"."unit_id" = "unit_id_v"
2359 WHERE "id" = "output_row"."member_id"
2360 AND "member"."active" AND "privilege"."voting_right"
2361 ) THEN
2362 IF "scope_v" = 'unit' THEN
2363 SELECT * INTO "delegation_row" FROM "delegation"
2364 WHERE "truster_id" = "output_row"."member_id"
2365 AND "unit_id" = "unit_id_v";
2366 ELSIF "scope_v" = 'area' THEN
2367 "output_row"."participation" := EXISTS (
2368 SELECT NULL FROM "membership"
2369 WHERE "area_id" = "area_id_p"
2370 AND "member_id" = "output_row"."member_id"
2371 );
2372 SELECT * INTO "delegation_row" FROM "delegation"
2373 WHERE "truster_id" = "output_row"."member_id"
2374 AND (
2375 "unit_id" = "unit_id_v" OR
2376 "area_id" = "area_id_v"
2378 ORDER BY "scope" DESC;
2379 ELSIF "scope_v" = 'issue' THEN
2380 "output_row"."participation" := EXISTS (
2381 SELECT NULL FROM "interest"
2382 WHERE "issue_id" = "issue_id_p"
2383 AND "member_id" = "output_row"."member_id"
2384 );
2385 SELECT * INTO "delegation_row" FROM "delegation"
2386 WHERE "truster_id" = "output_row"."member_id"
2387 AND (
2388 "unit_id" = "unit_id_v" OR
2389 "area_id" = "area_id_v" OR
2390 "issue_id" = "issue_id_p"
2392 ORDER BY "scope" DESC;
2393 END IF;
2394 ELSE
2395 "output_row"."member_valid" := FALSE;
2396 "output_row"."participation" := FALSE;
2397 "output_row"."scope_out" := NULL;
2398 "delegation_row" := ROW(NULL);
2399 END IF;
2400 IF
2401 "output_row"."member_id" = "member_id_p" AND
2402 "simulate_trustee_id_p" NOTNULL
2403 THEN
2404 "output_row"."scope_out" := "scope_v";
2405 "output_rows" := "output_rows" || "output_row";
2406 "output_row"."member_id" := "simulate_trustee_id_p";
2407 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2408 "output_row"."scope_out" := "delegation_row"."scope";
2409 "output_rows" := "output_rows" || "output_row";
2410 "output_row"."member_id" := "delegation_row"."trustee_id";
2411 ELSIF "delegation_row"."scope" NOTNULL THEN
2412 "output_row"."scope_out" := "delegation_row"."scope";
2413 "output_row"."disabled_out" := TRUE;
2414 "output_rows" := "output_rows" || "output_row";
2415 EXIT;
2416 ELSE
2417 "output_row"."scope_out" := NULL;
2418 "output_rows" := "output_rows" || "output_row";
2419 EXIT;
2420 END IF;
2421 EXIT WHEN "loop_member_id_v" NOTNULL;
2422 "output_row"."index" := "output_row"."index" + 1;
2423 END LOOP;
2424 "row_count" := array_upper("output_rows", 1);
2425 "i" := 1;
2426 "loop_v" := FALSE;
2427 LOOP
2428 "output_row" := "output_rows"["i"];
2429 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2430 IF "loop_v" THEN
2431 IF "i" + 1 = "row_count" THEN
2432 "output_row"."loop" := 'last';
2433 ELSIF "i" = "row_count" THEN
2434 "output_row"."loop" := 'repetition';
2435 ELSE
2436 "output_row"."loop" := 'intermediate';
2437 END IF;
2438 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2439 "output_row"."loop" := 'first';
2440 "loop_v" := TRUE;
2441 END IF;
2442 IF "scope_v" = 'unit' THEN
2443 "output_row"."participation" := NULL;
2444 END IF;
2445 RETURN NEXT "output_row";
2446 "i" := "i" + 1;
2447 END LOOP;
2448 RETURN;
2449 END;
2450 $$;
2452 COMMENT ON FUNCTION "delegation_chain"
2453 ( "member"."id"%TYPE,
2454 "unit"."id"%TYPE,
2455 "area"."id"%TYPE,
2456 "issue"."id"%TYPE,
2457 "member"."id"%TYPE )
2458 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2461 CREATE FUNCTION "delegation_chain"
2462 ( "member_id_p" "member"."id"%TYPE,
2463 "unit_id_p" "unit"."id"%TYPE,
2464 "area_id_p" "area"."id"%TYPE,
2465 "issue_id_p" "issue"."id"%TYPE )
2466 RETURNS SETOF "delegation_chain_row"
2467 LANGUAGE 'plpgsql' STABLE AS $$
2468 DECLARE
2469 "result_row" "delegation_chain_row";
2470 BEGIN
2471 FOR "result_row" IN
2472 SELECT * FROM "delegation_chain"(
2473 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2475 LOOP
2476 RETURN NEXT "result_row";
2477 END LOOP;
2478 RETURN;
2479 END;
2480 $$;
2482 COMMENT ON FUNCTION "delegation_chain"
2483 ( "member"."id"%TYPE,
2484 "unit"."id"%TYPE,
2485 "area"."id"%TYPE,
2486 "issue"."id"%TYPE )
2487 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2491 ------------------------------
2492 -- Comparison by vote count --
2493 ------------------------------
2495 CREATE FUNCTION "vote_ratio"
2496 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2497 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2498 RETURNS FLOAT8
2499 LANGUAGE 'plpgsql' STABLE AS $$
2500 BEGIN
2501 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2502 RETURN
2503 "positive_votes_p"::FLOAT8 /
2504 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2505 ELSIF "positive_votes_p" > 0 THEN
2506 RETURN "positive_votes_p";
2507 ELSIF "negative_votes_p" > 0 THEN
2508 RETURN 1 - "negative_votes_p";
2509 ELSE
2510 RETURN 0.5;
2511 END IF;
2512 END;
2513 $$;
2515 COMMENT ON FUNCTION "vote_ratio"
2516 ( "initiative"."positive_votes"%TYPE,
2517 "initiative"."negative_votes"%TYPE )
2518 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.';
2522 ------------------------------------------------
2523 -- Locking for snapshots and voting procedure --
2524 ------------------------------------------------
2527 CREATE FUNCTION "share_row_lock_issue_trigger"()
2528 RETURNS TRIGGER
2529 LANGUAGE 'plpgsql' VOLATILE AS $$
2530 BEGIN
2531 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2532 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2533 END IF;
2534 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2535 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2536 RETURN NEW;
2537 ELSE
2538 RETURN OLD;
2539 END IF;
2540 END;
2541 $$;
2543 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2546 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2547 RETURNS TRIGGER
2548 LANGUAGE 'plpgsql' VOLATILE AS $$
2549 BEGIN
2550 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2551 PERFORM NULL FROM "issue"
2552 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2553 WHERE "initiative"."id" = OLD."initiative_id"
2554 FOR SHARE OF "issue";
2555 END IF;
2556 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2557 PERFORM NULL FROM "issue"
2558 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2559 WHERE "initiative"."id" = NEW."initiative_id"
2560 FOR SHARE OF "issue";
2561 RETURN NEW;
2562 ELSE
2563 RETURN OLD;
2564 END IF;
2565 END;
2566 $$;
2568 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2571 CREATE TRIGGER "share_row_lock_issue"
2572 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2573 FOR EACH ROW EXECUTE PROCEDURE
2574 "share_row_lock_issue_trigger"();
2576 CREATE TRIGGER "share_row_lock_issue"
2577 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2578 FOR EACH ROW EXECUTE PROCEDURE
2579 "share_row_lock_issue_trigger"();
2581 CREATE TRIGGER "share_row_lock_issue"
2582 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2583 FOR EACH ROW EXECUTE PROCEDURE
2584 "share_row_lock_issue_trigger"();
2586 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2587 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2588 FOR EACH ROW EXECUTE PROCEDURE
2589 "share_row_lock_issue_via_initiative_trigger"();
2591 CREATE TRIGGER "share_row_lock_issue"
2592 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
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 "delegating_voter"
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 "vote"
2603 FOR EACH ROW EXECUTE PROCEDURE
2604 "share_row_lock_issue_trigger"();
2606 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2607 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2608 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2609 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2610 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2611 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2612 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2615 CREATE FUNCTION "lock_issue"
2616 ( "issue_id_p" "issue"."id"%TYPE )
2617 RETURNS VOID
2618 LANGUAGE 'plpgsql' VOLATILE AS $$
2619 BEGIN
2620 LOCK TABLE "member" IN SHARE MODE;
2621 LOCK TABLE "privilege" IN SHARE MODE;
2622 LOCK TABLE "membership" IN SHARE MODE;
2623 LOCK TABLE "policy" IN SHARE MODE;
2624 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2625 -- NOTE: The row-level exclusive lock in combination with the
2626 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2627 -- acquire a row-level share lock on the issue) ensure that no data
2628 -- is changed, which could affect calculation of snapshots or
2629 -- counting of votes. Table "delegation" must be table-level-locked,
2630 -- as it also contains issue- and global-scope delegations.
2631 LOCK TABLE "delegation" IN SHARE MODE;
2632 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2633 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2634 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2635 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2636 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2637 RETURN;
2638 END;
2639 $$;
2641 COMMENT ON FUNCTION "lock_issue"
2642 ( "issue"."id"%TYPE )
2643 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2647 ------------------------------------------------------------------------
2648 -- Regular tasks, except calculcation of snapshots and voting results --
2649 ------------------------------------------------------------------------
2651 CREATE FUNCTION "check_last_login"()
2652 RETURNS VOID
2653 LANGUAGE 'plpgsql' VOLATILE AS $$
2654 DECLARE
2655 "system_setting_row" "system_setting"%ROWTYPE;
2656 BEGIN
2657 SELECT * INTO "system_setting_row" FROM "system_setting";
2658 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2659 UPDATE "member" SET "last_login_public" = "last_login"::date
2660 FROM (
2661 SELECT DISTINCT "member"."id"
2662 FROM "member" LEFT JOIN "member_history"
2663 ON "member"."id" = "member_history"."member_id"
2664 WHERE "member"."last_login"::date < 'today' OR (
2665 "member_history"."until"::date >= 'today' AND
2666 "member_history"."active" = FALSE AND "member"."active" = TRUE
2668 ) AS "subquery"
2669 WHERE "member"."id" = "subquery"."id";
2670 IF "system_setting_row"."member_ttl" NOTNULL THEN
2671 UPDATE "member" SET "active" = FALSE
2672 WHERE "active" = TRUE
2673 AND "last_login"::date < 'today'
2674 AND "last_login_public" <
2675 (now() - "system_setting_row"."member_ttl")::date;
2676 END IF;
2677 RETURN;
2678 END;
2679 $$;
2681 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).';
2684 CREATE FUNCTION "calculate_member_counts"()
2685 RETURNS VOID
2686 LANGUAGE 'plpgsql' VOLATILE AS $$
2687 BEGIN
2688 LOCK TABLE "member" IN SHARE MODE;
2689 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2690 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2691 LOCK TABLE "area" IN EXCLUSIVE MODE;
2692 LOCK TABLE "privilege" IN SHARE MODE;
2693 LOCK TABLE "membership" IN SHARE MODE;
2694 DELETE FROM "member_count";
2695 INSERT INTO "member_count" ("total_count")
2696 SELECT "total_count" FROM "member_count_view";
2697 UPDATE "unit" SET "member_count" = "view"."member_count"
2698 FROM "unit_member_count" AS "view"
2699 WHERE "view"."unit_id" = "unit"."id";
2700 UPDATE "area" SET
2701 "direct_member_count" = "view"."direct_member_count",
2702 "member_weight" = "view"."member_weight",
2703 "autoreject_weight" = "view"."autoreject_weight"
2704 FROM "area_member_count" AS "view"
2705 WHERE "view"."area_id" = "area"."id";
2706 RETURN;
2707 END;
2708 $$;
2710 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"';
2714 ------------------------------
2715 -- Calculation of snapshots --
2716 ------------------------------
2718 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2719 ( "issue_id_p" "issue"."id"%TYPE,
2720 "member_id_p" "member"."id"%TYPE,
2721 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2722 RETURNS "direct_population_snapshot"."weight"%TYPE
2723 LANGUAGE 'plpgsql' VOLATILE AS $$
2724 DECLARE
2725 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2726 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2727 "weight_v" INT4;
2728 "sub_weight_v" INT4;
2729 BEGIN
2730 "weight_v" := 0;
2731 FOR "issue_delegation_row" IN
2732 SELECT * FROM "issue_delegation"
2733 WHERE "trustee_id" = "member_id_p"
2734 AND "issue_id" = "issue_id_p"
2735 LOOP
2736 IF NOT EXISTS (
2737 SELECT NULL FROM "direct_population_snapshot"
2738 WHERE "issue_id" = "issue_id_p"
2739 AND "event" = 'periodic'
2740 AND "member_id" = "issue_delegation_row"."truster_id"
2741 ) AND NOT EXISTS (
2742 SELECT NULL FROM "delegating_population_snapshot"
2743 WHERE "issue_id" = "issue_id_p"
2744 AND "event" = 'periodic'
2745 AND "member_id" = "issue_delegation_row"."truster_id"
2746 ) THEN
2747 "delegate_member_ids_v" :=
2748 "member_id_p" || "delegate_member_ids_p";
2749 INSERT INTO "delegating_population_snapshot" (
2750 "issue_id",
2751 "event",
2752 "member_id",
2753 "scope",
2754 "delegate_member_ids"
2755 ) VALUES (
2756 "issue_id_p",
2757 'periodic',
2758 "issue_delegation_row"."truster_id",
2759 "issue_delegation_row"."scope",
2760 "delegate_member_ids_v"
2761 );
2762 "sub_weight_v" := 1 +
2763 "weight_of_added_delegations_for_population_snapshot"(
2764 "issue_id_p",
2765 "issue_delegation_row"."truster_id",
2766 "delegate_member_ids_v"
2767 );
2768 UPDATE "delegating_population_snapshot"
2769 SET "weight" = "sub_weight_v"
2770 WHERE "issue_id" = "issue_id_p"
2771 AND "event" = 'periodic'
2772 AND "member_id" = "issue_delegation_row"."truster_id";
2773 "weight_v" := "weight_v" + "sub_weight_v";
2774 END IF;
2775 END LOOP;
2776 RETURN "weight_v";
2777 END;
2778 $$;
2780 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2781 ( "issue"."id"%TYPE,
2782 "member"."id"%TYPE,
2783 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2784 IS 'Helper function for "create_population_snapshot" function';
2787 CREATE FUNCTION "create_population_snapshot"
2788 ( "issue_id_p" "issue"."id"%TYPE )
2789 RETURNS VOID
2790 LANGUAGE 'plpgsql' VOLATILE AS $$
2791 DECLARE
2792 "member_id_v" "member"."id"%TYPE;
2793 BEGIN
2794 DELETE FROM "direct_population_snapshot"
2795 WHERE "issue_id" = "issue_id_p"
2796 AND "event" = 'periodic';
2797 DELETE FROM "delegating_population_snapshot"
2798 WHERE "issue_id" = "issue_id_p"
2799 AND "event" = 'periodic';
2800 INSERT INTO "direct_population_snapshot"
2801 ("issue_id", "event", "member_id")
2802 SELECT
2803 "issue_id_p" AS "issue_id",
2804 'periodic'::"snapshot_event" AS "event",
2805 "member"."id" AS "member_id"
2806 FROM "issue"
2807 JOIN "area" ON "issue"."area_id" = "area"."id"
2808 JOIN "membership" ON "area"."id" = "membership"."area_id"
2809 JOIN "member" ON "membership"."member_id" = "member"."id"
2810 JOIN "privilege"
2811 ON "privilege"."unit_id" = "area"."unit_id"
2812 AND "privilege"."member_id" = "member"."id"
2813 WHERE "issue"."id" = "issue_id_p"
2814 AND "member"."active" AND "privilege"."voting_right"
2815 UNION
2816 SELECT
2817 "issue_id_p" AS "issue_id",
2818 'periodic'::"snapshot_event" AS "event",
2819 "member"."id" AS "member_id"
2820 FROM "issue"
2821 JOIN "area" ON "issue"."area_id" = "area"."id"
2822 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2823 JOIN "member" ON "interest"."member_id" = "member"."id"
2824 JOIN "privilege"
2825 ON "privilege"."unit_id" = "area"."unit_id"
2826 AND "privilege"."member_id" = "member"."id"
2827 WHERE "issue"."id" = "issue_id_p"
2828 AND "member"."active" AND "privilege"."voting_right";
2829 FOR "member_id_v" IN
2830 SELECT "member_id" FROM "direct_population_snapshot"
2831 WHERE "issue_id" = "issue_id_p"
2832 AND "event" = 'periodic'
2833 LOOP
2834 UPDATE "direct_population_snapshot" SET
2835 "weight" = 1 +
2836 "weight_of_added_delegations_for_population_snapshot"(
2837 "issue_id_p",
2838 "member_id_v",
2839 '{}'
2841 WHERE "issue_id" = "issue_id_p"
2842 AND "event" = 'periodic'
2843 AND "member_id" = "member_id_v";
2844 END LOOP;
2845 RETURN;
2846 END;
2847 $$;
2849 COMMENT ON FUNCTION "create_population_snapshot"
2850 ( "issue"."id"%TYPE )
2851 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.';
2854 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2855 ( "issue_id_p" "issue"."id"%TYPE,
2856 "member_id_p" "member"."id"%TYPE,
2857 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2858 RETURNS "direct_interest_snapshot"."weight"%TYPE
2859 LANGUAGE 'plpgsql' VOLATILE AS $$
2860 DECLARE
2861 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2862 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2863 "weight_v" INT4;
2864 "sub_weight_v" INT4;
2865 BEGIN
2866 "weight_v" := 0;
2867 FOR "issue_delegation_row" IN
2868 SELECT * FROM "issue_delegation"
2869 WHERE "trustee_id" = "member_id_p"
2870 AND "issue_id" = "issue_id_p"
2871 LOOP
2872 IF NOT EXISTS (
2873 SELECT NULL FROM "direct_interest_snapshot"
2874 WHERE "issue_id" = "issue_id_p"
2875 AND "event" = 'periodic'
2876 AND "member_id" = "issue_delegation_row"."truster_id"
2877 ) AND NOT EXISTS (
2878 SELECT NULL FROM "delegating_interest_snapshot"
2879 WHERE "issue_id" = "issue_id_p"
2880 AND "event" = 'periodic'
2881 AND "member_id" = "issue_delegation_row"."truster_id"
2882 ) THEN
2883 "delegate_member_ids_v" :=
2884 "member_id_p" || "delegate_member_ids_p";
2885 INSERT INTO "delegating_interest_snapshot" (
2886 "issue_id",
2887 "event",
2888 "member_id",
2889 "scope",
2890 "delegate_member_ids"
2891 ) VALUES (
2892 "issue_id_p",
2893 'periodic',
2894 "issue_delegation_row"."truster_id",
2895 "issue_delegation_row"."scope",
2896 "delegate_member_ids_v"
2897 );
2898 "sub_weight_v" := 1 +
2899 "weight_of_added_delegations_for_interest_snapshot"(
2900 "issue_id_p",
2901 "issue_delegation_row"."truster_id",
2902 "delegate_member_ids_v"
2903 );
2904 UPDATE "delegating_interest_snapshot"
2905 SET "weight" = "sub_weight_v"
2906 WHERE "issue_id" = "issue_id_p"
2907 AND "event" = 'periodic'
2908 AND "member_id" = "issue_delegation_row"."truster_id";
2909 "weight_v" := "weight_v" + "sub_weight_v";
2910 END IF;
2911 END LOOP;
2912 RETURN "weight_v";
2913 END;
2914 $$;
2916 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2917 ( "issue"."id"%TYPE,
2918 "member"."id"%TYPE,
2919 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2920 IS 'Helper function for "create_interest_snapshot" function';
2923 CREATE FUNCTION "create_interest_snapshot"
2924 ( "issue_id_p" "issue"."id"%TYPE )
2925 RETURNS VOID
2926 LANGUAGE 'plpgsql' VOLATILE AS $$
2927 DECLARE
2928 "member_id_v" "member"."id"%TYPE;
2929 BEGIN
2930 DELETE FROM "direct_interest_snapshot"
2931 WHERE "issue_id" = "issue_id_p"
2932 AND "event" = 'periodic';
2933 DELETE FROM "delegating_interest_snapshot"
2934 WHERE "issue_id" = "issue_id_p"
2935 AND "event" = 'periodic';
2936 DELETE FROM "direct_supporter_snapshot"
2937 WHERE "issue_id" = "issue_id_p"
2938 AND "event" = 'periodic';
2939 INSERT INTO "direct_interest_snapshot"
2940 ("issue_id", "event", "member_id", "voting_requested")
2941 SELECT
2942 "issue_id_p" AS "issue_id",
2943 'periodic' AS "event",
2944 "member"."id" AS "member_id",
2945 "interest"."voting_requested"
2946 FROM "issue"
2947 JOIN "area" ON "issue"."area_id" = "area"."id"
2948 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2949 JOIN "member" ON "interest"."member_id" = "member"."id"
2950 JOIN "privilege"
2951 ON "privilege"."unit_id" = "area"."unit_id"
2952 AND "privilege"."member_id" = "member"."id"
2953 WHERE "issue"."id" = "issue_id_p"
2954 AND "member"."active" AND "privilege"."voting_right";
2955 FOR "member_id_v" IN
2956 SELECT "member_id" FROM "direct_interest_snapshot"
2957 WHERE "issue_id" = "issue_id_p"
2958 AND "event" = 'periodic'
2959 LOOP
2960 UPDATE "direct_interest_snapshot" SET
2961 "weight" = 1 +
2962 "weight_of_added_delegations_for_interest_snapshot"(
2963 "issue_id_p",
2964 "member_id_v",
2965 '{}'
2967 WHERE "issue_id" = "issue_id_p"
2968 AND "event" = 'periodic'
2969 AND "member_id" = "member_id_v";
2970 END LOOP;
2971 INSERT INTO "direct_supporter_snapshot"
2972 ( "issue_id", "initiative_id", "event", "member_id",
2973 "informed", "satisfied" )
2974 SELECT
2975 "issue_id_p" AS "issue_id",
2976 "initiative"."id" AS "initiative_id",
2977 'periodic' AS "event",
2978 "supporter"."member_id" AS "member_id",
2979 "supporter"."draft_id" = "current_draft"."id" AS "informed",
2980 NOT EXISTS (
2981 SELECT NULL FROM "critical_opinion"
2982 WHERE "initiative_id" = "initiative"."id"
2983 AND "member_id" = "supporter"."member_id"
2984 ) AS "satisfied"
2985 FROM "initiative"
2986 JOIN "supporter"
2987 ON "supporter"."initiative_id" = "initiative"."id"
2988 JOIN "current_draft"
2989 ON "initiative"."id" = "current_draft"."initiative_id"
2990 JOIN "direct_interest_snapshot"
2991 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
2992 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
2993 AND "event" = 'periodic'
2994 WHERE "initiative"."issue_id" = "issue_id_p";
2995 RETURN;
2996 END;
2997 $$;
2999 COMMENT ON FUNCTION "create_interest_snapshot"
3000 ( "issue"."id"%TYPE )
3001 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.';
3004 CREATE FUNCTION "create_snapshot"
3005 ( "issue_id_p" "issue"."id"%TYPE )
3006 RETURNS VOID
3007 LANGUAGE 'plpgsql' VOLATILE AS $$
3008 DECLARE
3009 "initiative_id_v" "initiative"."id"%TYPE;
3010 "suggestion_id_v" "suggestion"."id"%TYPE;
3011 BEGIN
3012 PERFORM "lock_issue"("issue_id_p");
3013 PERFORM "create_population_snapshot"("issue_id_p");
3014 PERFORM "create_interest_snapshot"("issue_id_p");
3015 UPDATE "issue" SET
3016 "snapshot" = now(),
3017 "latest_snapshot_event" = 'periodic',
3018 "population" = (
3019 SELECT coalesce(sum("weight"), 0)
3020 FROM "direct_population_snapshot"
3021 WHERE "issue_id" = "issue_id_p"
3022 AND "event" = 'periodic'
3023 ),
3024 "vote_now" = (
3025 SELECT coalesce(sum("weight"), 0)
3026 FROM "direct_interest_snapshot"
3027 WHERE "issue_id" = "issue_id_p"
3028 AND "event" = 'periodic'
3029 AND "voting_requested" = TRUE
3030 ),
3031 "vote_later" = (
3032 SELECT coalesce(sum("weight"), 0)
3033 FROM "direct_interest_snapshot"
3034 WHERE "issue_id" = "issue_id_p"
3035 AND "event" = 'periodic'
3036 AND "voting_requested" = FALSE
3038 WHERE "id" = "issue_id_p";
3039 FOR "initiative_id_v" IN
3040 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3041 LOOP
3042 UPDATE "initiative" SET
3043 "supporter_count" = (
3044 SELECT coalesce(sum("di"."weight"), 0)
3045 FROM "direct_interest_snapshot" AS "di"
3046 JOIN "direct_supporter_snapshot" AS "ds"
3047 ON "di"."member_id" = "ds"."member_id"
3048 WHERE "di"."issue_id" = "issue_id_p"
3049 AND "di"."event" = 'periodic'
3050 AND "ds"."initiative_id" = "initiative_id_v"
3051 AND "ds"."event" = 'periodic'
3052 ),
3053 "informed_supporter_count" = (
3054 SELECT coalesce(sum("di"."weight"), 0)
3055 FROM "direct_interest_snapshot" AS "di"
3056 JOIN "direct_supporter_snapshot" AS "ds"
3057 ON "di"."member_id" = "ds"."member_id"
3058 WHERE "di"."issue_id" = "issue_id_p"
3059 AND "di"."event" = 'periodic'
3060 AND "ds"."initiative_id" = "initiative_id_v"
3061 AND "ds"."event" = 'periodic'
3062 AND "ds"."informed"
3063 ),
3064 "satisfied_supporter_count" = (
3065 SELECT coalesce(sum("di"."weight"), 0)
3066 FROM "direct_interest_snapshot" AS "di"
3067 JOIN "direct_supporter_snapshot" AS "ds"
3068 ON "di"."member_id" = "ds"."member_id"
3069 WHERE "di"."issue_id" = "issue_id_p"
3070 AND "di"."event" = 'periodic'
3071 AND "ds"."initiative_id" = "initiative_id_v"
3072 AND "ds"."event" = 'periodic'
3073 AND "ds"."satisfied"
3074 ),
3075 "satisfied_informed_supporter_count" = (
3076 SELECT coalesce(sum("di"."weight"), 0)
3077 FROM "direct_interest_snapshot" AS "di"
3078 JOIN "direct_supporter_snapshot" AS "ds"
3079 ON "di"."member_id" = "ds"."member_id"
3080 WHERE "di"."issue_id" = "issue_id_p"
3081 AND "di"."event" = 'periodic'
3082 AND "ds"."initiative_id" = "initiative_id_v"
3083 AND "ds"."event" = 'periodic'
3084 AND "ds"."informed"
3085 AND "ds"."satisfied"
3087 WHERE "id" = "initiative_id_v";
3088 FOR "suggestion_id_v" IN
3089 SELECT "id" FROM "suggestion"
3090 WHERE "initiative_id" = "initiative_id_v"
3091 LOOP
3092 UPDATE "suggestion" SET
3093 "minus2_unfulfilled_count" = (
3094 SELECT coalesce(sum("snapshot"."weight"), 0)
3095 FROM "issue" CROSS JOIN "opinion"
3096 JOIN "direct_interest_snapshot" AS "snapshot"
3097 ON "snapshot"."issue_id" = "issue"."id"
3098 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3099 AND "snapshot"."member_id" = "opinion"."member_id"
3100 WHERE "issue"."id" = "issue_id_p"
3101 AND "opinion"."suggestion_id" = "suggestion_id_v"
3102 AND "opinion"."degree" = -2
3103 AND "opinion"."fulfilled" = FALSE
3104 ),
3105 "minus2_fulfilled_count" = (
3106 SELECT coalesce(sum("snapshot"."weight"), 0)
3107 FROM "issue" CROSS JOIN "opinion"
3108 JOIN "direct_interest_snapshot" AS "snapshot"
3109 ON "snapshot"."issue_id" = "issue"."id"
3110 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3111 AND "snapshot"."member_id" = "opinion"."member_id"
3112 WHERE "issue"."id" = "issue_id_p"
3113 AND "opinion"."suggestion_id" = "suggestion_id_v"
3114 AND "opinion"."degree" = -2
3115 AND "opinion"."fulfilled" = TRUE
3116 ),
3117 "minus1_unfulfilled_count" = (
3118 SELECT coalesce(sum("snapshot"."weight"), 0)
3119 FROM "issue" CROSS JOIN "opinion"
3120 JOIN "direct_interest_snapshot" AS "snapshot"
3121 ON "snapshot"."issue_id" = "issue"."id"
3122 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3123 AND "snapshot"."member_id" = "opinion"."member_id"
3124 WHERE "issue"."id" = "issue_id_p"
3125 AND "opinion"."suggestion_id" = "suggestion_id_v"
3126 AND "opinion"."degree" = -1
3127 AND "opinion"."fulfilled" = FALSE
3128 ),
3129 "minus1_fulfilled_count" = (
3130 SELECT coalesce(sum("snapshot"."weight"), 0)
3131 FROM "issue" CROSS JOIN "opinion"
3132 JOIN "direct_interest_snapshot" AS "snapshot"
3133 ON "snapshot"."issue_id" = "issue"."id"
3134 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3135 AND "snapshot"."member_id" = "opinion"."member_id"
3136 WHERE "issue"."id" = "issue_id_p"
3137 AND "opinion"."suggestion_id" = "suggestion_id_v"
3138 AND "opinion"."degree" = -1
3139 AND "opinion"."fulfilled" = TRUE
3140 ),
3141 "plus1_unfulfilled_count" = (
3142 SELECT coalesce(sum("snapshot"."weight"), 0)
3143 FROM "issue" CROSS JOIN "opinion"
3144 JOIN "direct_interest_snapshot" AS "snapshot"
3145 ON "snapshot"."issue_id" = "issue"."id"
3146 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3147 AND "snapshot"."member_id" = "opinion"."member_id"
3148 WHERE "issue"."id" = "issue_id_p"
3149 AND "opinion"."suggestion_id" = "suggestion_id_v"
3150 AND "opinion"."degree" = 1
3151 AND "opinion"."fulfilled" = FALSE
3152 ),
3153 "plus1_fulfilled_count" = (
3154 SELECT coalesce(sum("snapshot"."weight"), 0)
3155 FROM "issue" CROSS JOIN "opinion"
3156 JOIN "direct_interest_snapshot" AS "snapshot"
3157 ON "snapshot"."issue_id" = "issue"."id"
3158 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3159 AND "snapshot"."member_id" = "opinion"."member_id"
3160 WHERE "issue"."id" = "issue_id_p"
3161 AND "opinion"."suggestion_id" = "suggestion_id_v"
3162 AND "opinion"."degree" = 1
3163 AND "opinion"."fulfilled" = TRUE
3164 ),
3165 "plus2_unfulfilled_count" = (
3166 SELECT coalesce(sum("snapshot"."weight"), 0)
3167 FROM "issue" CROSS JOIN "opinion"
3168 JOIN "direct_interest_snapshot" AS "snapshot"
3169 ON "snapshot"."issue_id" = "issue"."id"
3170 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3171 AND "snapshot"."member_id" = "opinion"."member_id"
3172 WHERE "issue"."id" = "issue_id_p"
3173 AND "opinion"."suggestion_id" = "suggestion_id_v"
3174 AND "opinion"."degree" = 2
3175 AND "opinion"."fulfilled" = FALSE
3176 ),
3177 "plus2_fulfilled_count" = (
3178 SELECT coalesce(sum("snapshot"."weight"), 0)
3179 FROM "issue" CROSS JOIN "opinion"
3180 JOIN "direct_interest_snapshot" AS "snapshot"
3181 ON "snapshot"."issue_id" = "issue"."id"
3182 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3183 AND "snapshot"."member_id" = "opinion"."member_id"
3184 WHERE "issue"."id" = "issue_id_p"
3185 AND "opinion"."suggestion_id" = "suggestion_id_v"
3186 AND "opinion"."degree" = 2
3187 AND "opinion"."fulfilled" = TRUE
3189 WHERE "suggestion"."id" = "suggestion_id_v";
3190 END LOOP;
3191 END LOOP;
3192 RETURN;
3193 END;
3194 $$;
3196 COMMENT ON FUNCTION "create_snapshot"
3197 ( "issue"."id"%TYPE )
3198 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.';
3201 CREATE FUNCTION "set_snapshot_event"
3202 ( "issue_id_p" "issue"."id"%TYPE,
3203 "event_p" "snapshot_event" )
3204 RETURNS VOID
3205 LANGUAGE 'plpgsql' VOLATILE AS $$
3206 DECLARE
3207 "event_v" "issue"."latest_snapshot_event"%TYPE;
3208 BEGIN
3209 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3210 WHERE "id" = "issue_id_p" FOR UPDATE;
3211 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3212 WHERE "id" = "issue_id_p";
3213 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3214 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3215 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3216 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3217 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3218 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3219 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3220 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3221 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3222 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3223 RETURN;
3224 END;
3225 $$;
3227 COMMENT ON FUNCTION "set_snapshot_event"
3228 ( "issue"."id"%TYPE,
3229 "snapshot_event" )
3230 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3234 ---------------------
3235 -- Freezing issues --
3236 ---------------------
3238 CREATE FUNCTION "freeze_after_snapshot"
3239 ( "issue_id_p" "issue"."id"%TYPE )
3240 RETURNS VOID
3241 LANGUAGE 'plpgsql' VOLATILE AS $$
3242 DECLARE
3243 "issue_row" "issue"%ROWTYPE;
3244 "policy_row" "policy"%ROWTYPE;
3245 "initiative_row" "initiative"%ROWTYPE;
3246 BEGIN
3247 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3248 SELECT * INTO "policy_row"
3249 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3250 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3251 FOR "initiative_row" IN
3252 SELECT * FROM "initiative"
3253 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3254 LOOP
3255 IF
3256 "initiative_row"."satisfied_supporter_count" > 0 AND
3257 "initiative_row"."satisfied_supporter_count" *
3258 "policy_row"."initiative_quorum_den" >=
3259 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3260 THEN
3261 UPDATE "initiative" SET "admitted" = TRUE
3262 WHERE "id" = "initiative_row"."id";
3263 ELSE
3264 UPDATE "initiative" SET "admitted" = FALSE
3265 WHERE "id" = "initiative_row"."id";
3266 END IF;
3267 END LOOP;
3268 IF EXISTS (
3269 SELECT NULL FROM "initiative"
3270 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3271 ) THEN
3272 UPDATE "issue" SET
3273 "state" = 'voting',
3274 "accepted" = coalesce("accepted", now()),
3275 "half_frozen" = coalesce("half_frozen", now()),
3276 "fully_frozen" = now()
3277 WHERE "id" = "issue_id_p";
3278 ELSE
3279 UPDATE "issue" SET
3280 "state" = 'canceled_no_initiative_admitted',
3281 "accepted" = coalesce("accepted", now()),
3282 "half_frozen" = coalesce("half_frozen", now()),
3283 "fully_frozen" = now(),
3284 "closed" = now(),
3285 "ranks_available" = TRUE
3286 WHERE "id" = "issue_id_p";
3287 -- NOTE: The following DELETE statements have effect only when
3288 -- issue state has been manipulated
3289 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3290 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3291 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3292 END IF;
3293 RETURN;
3294 END;
3295 $$;
3297 COMMENT ON FUNCTION "freeze_after_snapshot"
3298 ( "issue"."id"%TYPE )
3299 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3302 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3303 RETURNS VOID
3304 LANGUAGE 'plpgsql' VOLATILE AS $$
3305 DECLARE
3306 "issue_row" "issue"%ROWTYPE;
3307 BEGIN
3308 PERFORM "create_snapshot"("issue_id_p");
3309 PERFORM "freeze_after_snapshot"("issue_id_p");
3310 RETURN;
3311 END;
3312 $$;
3314 COMMENT ON FUNCTION "manual_freeze"
3315 ( "issue"."id"%TYPE )
3316 IS 'Freeze an issue manually (fully) and start voting';
3320 -----------------------
3321 -- Counting of votes --
3322 -----------------------
3325 CREATE FUNCTION "weight_of_added_vote_delegations"
3326 ( "issue_id_p" "issue"."id"%TYPE,
3327 "member_id_p" "member"."id"%TYPE,
3328 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3329 RETURNS "direct_voter"."weight"%TYPE
3330 LANGUAGE 'plpgsql' VOLATILE AS $$
3331 DECLARE
3332 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3333 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3334 "weight_v" INT4;
3335 "sub_weight_v" INT4;
3336 BEGIN
3337 "weight_v" := 0;
3338 FOR "issue_delegation_row" IN
3339 SELECT * FROM "issue_delegation"
3340 WHERE "trustee_id" = "member_id_p"
3341 AND "issue_id" = "issue_id_p"
3342 LOOP
3343 IF NOT EXISTS (
3344 SELECT NULL FROM "direct_voter"
3345 WHERE "member_id" = "issue_delegation_row"."truster_id"
3346 AND "issue_id" = "issue_id_p"
3347 ) AND NOT EXISTS (
3348 SELECT NULL FROM "delegating_voter"
3349 WHERE "member_id" = "issue_delegation_row"."truster_id"
3350 AND "issue_id" = "issue_id_p"
3351 ) THEN
3352 "delegate_member_ids_v" :=
3353 "member_id_p" || "delegate_member_ids_p";
3354 INSERT INTO "delegating_voter" (
3355 "issue_id",
3356 "member_id",
3357 "scope",
3358 "delegate_member_ids"
3359 ) VALUES (
3360 "issue_id_p",
3361 "issue_delegation_row"."truster_id",
3362 "issue_delegation_row"."scope",
3363 "delegate_member_ids_v"
3364 );
3365 "sub_weight_v" := 1 +
3366 "weight_of_added_vote_delegations"(
3367 "issue_id_p",
3368 "issue_delegation_row"."truster_id",
3369 "delegate_member_ids_v"
3370 );
3371 UPDATE "delegating_voter"
3372 SET "weight" = "sub_weight_v"
3373 WHERE "issue_id" = "issue_id_p"
3374 AND "member_id" = "issue_delegation_row"."truster_id";
3375 "weight_v" := "weight_v" + "sub_weight_v";
3376 END IF;
3377 END LOOP;
3378 RETURN "weight_v";
3379 END;
3380 $$;
3382 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3383 ( "issue"."id"%TYPE,
3384 "member"."id"%TYPE,
3385 "delegating_voter"."delegate_member_ids"%TYPE )
3386 IS 'Helper function for "add_vote_delegations" function';
3389 CREATE FUNCTION "add_vote_delegations"
3390 ( "issue_id_p" "issue"."id"%TYPE )
3391 RETURNS VOID
3392 LANGUAGE 'plpgsql' VOLATILE AS $$
3393 DECLARE
3394 "member_id_v" "member"."id"%TYPE;
3395 BEGIN
3396 FOR "member_id_v" IN
3397 SELECT "member_id" FROM "direct_voter"
3398 WHERE "issue_id" = "issue_id_p"
3399 LOOP
3400 UPDATE "direct_voter" SET
3401 "weight" = "weight" + "weight_of_added_vote_delegations"(
3402 "issue_id_p",
3403 "member_id_v",
3404 '{}'
3406 WHERE "member_id" = "member_id_v"
3407 AND "issue_id" = "issue_id_p";
3408 END LOOP;
3409 RETURN;
3410 END;
3411 $$;
3413 COMMENT ON FUNCTION "add_vote_delegations"
3414 ( "issue_id_p" "issue"."id"%TYPE )
3415 IS 'Helper function for "close_voting" function';
3418 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3419 RETURNS VOID
3420 LANGUAGE 'plpgsql' VOLATILE AS $$
3421 DECLARE
3422 "area_id_v" "area"."id"%TYPE;
3423 "unit_id_v" "unit"."id"%TYPE;
3424 "member_id_v" "member"."id"%TYPE;
3425 BEGIN
3426 PERFORM "lock_issue"("issue_id_p");
3427 SELECT "id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3428 SELECT "id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3429 DELETE FROM "delegating_voter"
3430 WHERE "issue_id" = "issue_id_p";
3431 DELETE FROM "direct_voter"
3432 WHERE "issue_id" = "issue_id_p"
3433 AND "autoreject" = TRUE;
3434 DELETE FROM "direct_voter"
3435 USING (
3436 SELECT
3437 "direct_voter"."member_id"
3438 FROM "direct_voter"
3439 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3440 LEFT JOIN "privilege"
3441 ON "privilege"."unit_id" = "unit_id_v"
3442 AND "privilege"."member_id" = "direct_voter"."member_id"
3443 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3444 "member"."active" = FALSE OR
3445 "privilege"."voting_right" ISNULL OR
3446 "privilege"."voting_right" = FALSE
3448 ) AS "subquery"
3449 WHERE "direct_voter"."issue_id" = "issue_id_p"
3450 AND "direct_voter"."member_id" = "subquery"."member_id";
3451 UPDATE "direct_voter" SET "weight" = 1
3452 WHERE "issue_id" = "issue_id_p";
3453 PERFORM "add_vote_delegations"("issue_id_p");
3454 FOR "member_id_v" IN
3455 SELECT "interest"."member_id"
3456 FROM "interest"
3457 JOIN "member"
3458 ON "interest"."member_id" = "member"."id"
3459 LEFT JOIN "direct_voter"
3460 ON "interest"."member_id" = "direct_voter"."member_id"
3461 AND "interest"."issue_id" = "direct_voter"."issue_id"
3462 LEFT JOIN "delegating_voter"
3463 ON "interest"."member_id" = "delegating_voter"."member_id"
3464 AND "interest"."issue_id" = "delegating_voter"."issue_id"
3465 WHERE "interest"."issue_id" = "issue_id_p"
3466 AND "interest"."autoreject" = TRUE
3467 AND "member"."active"
3468 AND "direct_voter"."member_id" ISNULL
3469 AND "delegating_voter"."member_id" ISNULL
3470 UNION SELECT "membership"."member_id"
3471 FROM "membership"
3472 JOIN "member"
3473 ON "membership"."member_id" = "member"."id"
3474 LEFT JOIN "interest"
3475 ON "membership"."member_id" = "interest"."member_id"
3476 AND "interest"."issue_id" = "issue_id_p"
3477 LEFT JOIN "direct_voter"
3478 ON "membership"."member_id" = "direct_voter"."member_id"
3479 AND "direct_voter"."issue_id" = "issue_id_p"
3480 LEFT JOIN "delegating_voter"
3481 ON "membership"."member_id" = "delegating_voter"."member_id"
3482 AND "delegating_voter"."issue_id" = "issue_id_p"
3483 WHERE "membership"."area_id" = "area_id_v"
3484 AND "membership"."autoreject" = TRUE
3485 AND "member"."active"
3486 AND "interest"."autoreject" ISNULL
3487 AND "direct_voter"."member_id" ISNULL
3488 AND "delegating_voter"."member_id" ISNULL
3489 LOOP
3490 INSERT INTO "direct_voter"
3491 ("member_id", "issue_id", "weight", "autoreject") VALUES
3492 ("member_id_v", "issue_id_p", 1, TRUE);
3493 INSERT INTO "vote" (
3494 "member_id",
3495 "issue_id",
3496 "initiative_id",
3497 "grade"
3498 ) SELECT
3499 "member_id_v" AS "member_id",
3500 "issue_id_p" AS "issue_id",
3501 "id" AS "initiative_id",
3502 -1 AS "grade"
3503 FROM "initiative" WHERE "issue_id" = "issue_id_p";
3504 END LOOP;
3505 PERFORM "add_vote_delegations"("issue_id_p");
3506 UPDATE "issue" SET
3507 "state" = 'calculation',
3508 "closed" = now(),
3509 "voter_count" = (
3510 SELECT coalesce(sum("weight"), 0)
3511 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3513 WHERE "id" = "issue_id_p";
3514 UPDATE "initiative" SET
3515 "positive_votes" = "vote_counts"."positive_votes",
3516 "negative_votes" = "vote_counts"."negative_votes",
3517 "majority" = CASE WHEN "majority_strict" THEN
3518 "vote_counts"."positive_votes" * "majority_den" >
3519 "majority_num" *
3520 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
3521 ELSE
3522 "vote_counts"."positive_votes" * "majority_den" >=
3523 "majority_num" *
3524 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
3525 END
3526 FROM
3527 ( SELECT
3528 "initiative"."id" AS "initiative_id",
3529 coalesce(
3530 sum(
3531 CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
3532 ),
3534 ) AS "positive_votes",
3535 coalesce(
3536 sum(
3537 CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
3538 ),
3540 ) AS "negative_votes"
3541 FROM "initiative"
3542 JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
3543 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3544 LEFT JOIN "direct_voter"
3545 ON "direct_voter"."issue_id" = "initiative"."issue_id"
3546 LEFT JOIN "vote"
3547 ON "vote"."initiative_id" = "initiative"."id"
3548 AND "vote"."member_id" = "direct_voter"."member_id"
3549 WHERE "initiative"."issue_id" = "issue_id_p"
3550 AND "initiative"."admitted" -- NOTE: NULL case is handled too
3551 GROUP BY "initiative"."id"
3552 ) AS "vote_counts",
3553 "issue",
3554 "policy"
3555 WHERE "vote_counts"."initiative_id" = "initiative"."id"
3556 AND "issue"."id" = "initiative"."issue_id"
3557 AND "policy"."id" = "issue"."policy_id";
3558 -- NOTE: "closed" column of issue must be set at this point
3559 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3560 INSERT INTO "battle" (
3561 "issue_id",
3562 "winning_initiative_id", "losing_initiative_id",
3563 "count"
3564 ) SELECT
3565 "issue_id",
3566 "winning_initiative_id", "losing_initiative_id",
3567 "count"
3568 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3569 END;
3570 $$;
3572 COMMENT ON FUNCTION "close_voting"
3573 ( "issue"."id"%TYPE )
3574 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.';
3577 CREATE FUNCTION "defeat_strength"
3578 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3579 RETURNS INT8
3580 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3581 BEGIN
3582 IF "positive_votes_p" > "negative_votes_p" THEN
3583 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3584 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3585 RETURN 0;
3586 ELSE
3587 RETURN -1;
3588 END IF;
3589 END;
3590 $$;
3592 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';
3595 CREATE FUNCTION "array_init_string"("dim_p" INTEGER)
3596 RETURNS TEXT
3597 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3598 DECLARE
3599 "i" INTEGER;
3600 "ary_text_v" TEXT;
3601 BEGIN
3602 IF "dim_p" >= 1 THEN
3603 "ary_text_v" := '{NULL';
3604 "i" := "dim_p";
3605 LOOP
3606 "i" := "i" - 1;
3607 EXIT WHEN "i" = 0;
3608 "ary_text_v" := "ary_text_v" || ',NULL';
3609 END LOOP;
3610 "ary_text_v" := "ary_text_v" || '}';
3611 RETURN "ary_text_v";
3612 ELSE
3613 RAISE EXCEPTION 'Dimension needs to be at least 1.';
3614 END IF;
3615 END;
3616 $$;
3618 COMMENT ON FUNCTION "array_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
3621 CREATE FUNCTION "square_matrix_init_string"("dim_p" INTEGER)
3622 RETURNS TEXT
3623 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3624 DECLARE
3625 "i" INTEGER;
3626 "row_text_v" TEXT;
3627 "ary_text_v" TEXT;
3628 BEGIN
3629 IF "dim_p" >= 1 THEN
3630 "row_text_v" := '{NULL';
3631 "i" := "dim_p";
3632 LOOP
3633 "i" := "i" - 1;
3634 EXIT WHEN "i" = 0;
3635 "row_text_v" := "row_text_v" || ',NULL';
3636 END LOOP;
3637 "row_text_v" := "row_text_v" || '}';
3638 "ary_text_v" := '{' || "row_text_v";
3639 "i" := "dim_p";
3640 LOOP
3641 "i" := "i" - 1;
3642 EXIT WHEN "i" = 0;
3643 "ary_text_v" := "ary_text_v" || ',' || "row_text_v";
3644 END LOOP;
3645 "ary_text_v" := "ary_text_v" || '}';
3646 RETURN "ary_text_v";
3647 ELSE
3648 RAISE EXCEPTION 'Dimension needs to be at least 1.';
3649 END IF;
3650 END;
3651 $$;
3653 COMMENT ON FUNCTION "square_matrix_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
3656 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3657 RETURNS VOID
3658 LANGUAGE 'plpgsql' VOLATILE AS $$
3659 DECLARE
3660 "dimension_v" INTEGER;
3661 "vote_matrix" INT4[][]; -- absolute votes
3662 "matrix" INT8[][]; -- defeat strength / best paths
3663 "i" INTEGER;
3664 "j" INTEGER;
3665 "k" INTEGER;
3666 "battle_row" "battle"%ROWTYPE;
3667 "rank_ary" INT4[];
3668 "rank_v" INT4;
3669 "done_v" INTEGER;
3670 "winners_ary" INTEGER[];
3671 "initiative_id_v" "initiative"."id"%TYPE;
3672 BEGIN
3673 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
3674 SELECT count(1) INTO "dimension_v"
3675 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3676 IF "dimension_v" > 1 THEN
3677 -- Create "vote_matrix" with absolute number of votes in pairwise
3678 -- comparison:
3679 "vote_matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3680 "i" := 1;
3681 "j" := 2;
3682 FOR "battle_row" IN
3683 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3684 ORDER BY
3685 "winning_initiative_id" NULLS LAST,
3686 "losing_initiative_id" NULLS LAST
3687 LOOP
3688 "vote_matrix"["i"]["j"] := "battle_row"."count";
3689 IF "j" = "dimension_v" THEN
3690 "i" := "i" + 1;
3691 "j" := 1;
3692 ELSE
3693 "j" := "j" + 1;
3694 IF "j" = "i" THEN
3695 "j" := "j" + 1;
3696 END IF;
3697 END IF;
3698 END LOOP;
3699 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3700 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3701 END IF;
3702 -- Store defeat strengths in "matrix" using "defeat_strength"
3703 -- function:
3704 "matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3705 "i" := 1;
3706 LOOP
3707 "j" := 1;
3708 LOOP
3709 IF "i" != "j" THEN
3710 "matrix"["i"]["j"] := "defeat_strength"(
3711 "vote_matrix"["i"]["j"],
3712 "vote_matrix"["j"]["i"]
3713 );
3714 END IF;
3715 EXIT WHEN "j" = "dimension_v";
3716 "j" := "j" + 1;
3717 END LOOP;
3718 EXIT WHEN "i" = "dimension_v";
3719 "i" := "i" + 1;
3720 END LOOP;
3721 -- Find best paths:
3722 "i" := 1;
3723 LOOP
3724 "j" := 1;
3725 LOOP
3726 IF "i" != "j" THEN
3727 "k" := 1;
3728 LOOP
3729 IF "i" != "k" AND "j" != "k" THEN
3730 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3731 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3732 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3733 END IF;
3734 ELSE
3735 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3736 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3737 END IF;
3738 END IF;
3739 END IF;
3740 EXIT WHEN "k" = "dimension_v";
3741 "k" := "k" + 1;
3742 END LOOP;
3743 END IF;
3744 EXIT WHEN "j" = "dimension_v";
3745 "j" := "j" + 1;
3746 END LOOP;
3747 EXIT WHEN "i" = "dimension_v";
3748 "i" := "i" + 1;
3749 END LOOP;
3750 -- Determine order of winners:
3751 "rank_ary" := "array_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3752 "rank_v" := 1;
3753 "done_v" := 0;
3754 LOOP
3755 "winners_ary" := '{}';
3756 "i" := 1;
3757 LOOP
3758 IF "rank_ary"["i"] ISNULL THEN
3759 "j" := 1;
3760 LOOP
3761 IF
3762 "i" != "j" AND
3763 "rank_ary"["j"] ISNULL AND
3764 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3765 THEN
3766 -- someone else is better
3767 EXIT;
3768 END IF;
3769 IF "j" = "dimension_v" THEN
3770 -- noone is better
3771 "winners_ary" := "winners_ary" || "i";
3772 EXIT;
3773 END IF;
3774 "j" := "j" + 1;
3775 END LOOP;
3776 END IF;
3777 EXIT WHEN "i" = "dimension_v";
3778 "i" := "i" + 1;
3779 END LOOP;
3780 "i" := 1;
3781 LOOP
3782 "rank_ary"["winners_ary"["i"]] := "rank_v";
3783 "done_v" := "done_v" + 1;
3784 EXIT WHEN "i" = array_upper("winners_ary", 1);
3785 "i" := "i" + 1;
3786 END LOOP;
3787 EXIT WHEN "done_v" = "dimension_v";
3788 "rank_v" := "rank_v" + 1;
3789 END LOOP;
3790 -- write preliminary ranks:
3791 "i" := 1;
3792 FOR "initiative_id_v" IN
3793 SELECT "id" FROM "initiative"
3794 WHERE "issue_id" = "issue_id_p" AND "admitted"
3795 ORDER BY "id"
3796 LOOP
3797 UPDATE "initiative" SET "rank" = "rank_ary"["i"]
3798 WHERE "id" = "initiative_id_v"
3799 AND "rank_ary"["i"] < "rank_ary"["dimension_v"];
3800 "i" := "i" + 1;
3801 END LOOP;
3802 IF "i" != "dimension_v" THEN
3803 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3804 END IF;
3805 -- straighten ranks (start counting with 1, no equal ranks):
3806 "rank_v" := 1;
3807 FOR "initiative_id_v" IN
3808 SELECT "id" FROM "initiative"
3809 WHERE "issue_id" = "issue_id_p" AND "rank" NOTNULL
3810 ORDER BY
3811 "rank",
3812 "vote_ratio"("positive_votes", "negative_votes") DESC,
3813 "id"
3814 LOOP
3815 UPDATE "initiative" SET "rank" = "rank_v"
3816 WHERE "id" = "initiative_id_v";
3817 "rank_v" := "rank_v" + 1;
3818 END LOOP;
3819 -- mark final winner:
3820 UPDATE "initiative" SET "winner" =
3821 ( "majority" = TRUE AND
3822 "rank" = (
3823 SELECT min("rank") FROM "initiative"
3824 WHERE "issue_id" = "issue_id_p"
3825 AND "majority" = TRUE ) );
3826 END IF;
3827 -- mark issue as finished
3828 UPDATE "issue" SET
3829 "state" =
3830 CASE WHEN "dimension_v" = 0 THEN
3831 'finished_without_winner'::"issue_state"
3832 ELSE
3833 'finished_with_winner'::"issue_state"
3834 END,
3835 "ranks_available" = TRUE
3836 WHERE "id" = "issue_id_p";
3837 RETURN;
3838 END;
3839 $$;
3841 COMMENT ON FUNCTION "calculate_ranks"
3842 ( "issue"."id"%TYPE )
3843 IS 'Determine ranking (Votes have to be counted first)';
3847 -----------------------------
3848 -- Automatic state changes --
3849 -----------------------------
3852 CREATE FUNCTION "check_issue"
3853 ( "issue_id_p" "issue"."id"%TYPE )
3854 RETURNS VOID
3855 LANGUAGE 'plpgsql' VOLATILE AS $$
3856 DECLARE
3857 "issue_row" "issue"%ROWTYPE;
3858 "policy_row" "policy"%ROWTYPE;
3859 "voting_requested_v" BOOLEAN;
3860 BEGIN
3861 PERFORM "lock_issue"("issue_id_p");
3862 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3863 -- only process open issues:
3864 IF "issue_row"."closed" ISNULL THEN
3865 SELECT * INTO "policy_row" FROM "policy"
3866 WHERE "id" = "issue_row"."policy_id";
3867 -- create a snapshot, unless issue is already fully frozen:
3868 IF "issue_row"."fully_frozen" ISNULL THEN
3869 PERFORM "create_snapshot"("issue_id_p");
3870 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3871 END IF;
3872 -- eventually close or accept issues, which have not been accepted:
3873 IF "issue_row"."accepted" ISNULL THEN
3874 IF EXISTS (
3875 SELECT NULL FROM "initiative"
3876 WHERE "issue_id" = "issue_id_p"
3877 AND "supporter_count" > 0
3878 AND "supporter_count" * "policy_row"."issue_quorum_den"
3879 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3880 ) THEN
3881 -- accept issues, if supporter count is high enough
3882 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3883 -- NOTE: "issue_row" used later
3884 "issue_row"."state" := 'discussion';
3885 "issue_row"."accepted" := now();
3886 UPDATE "issue" SET
3887 "state" = "issue_row"."state",
3888 "accepted" = "issue_row"."accepted"
3889 WHERE "id" = "issue_row"."id";
3890 ELSIF
3891 now() >= "issue_row"."created" + "issue_row"."admission_time"
3892 THEN
3893 -- close issues, if admission time has expired
3894 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3895 UPDATE "issue" SET
3896 "state" = 'canceled_issue_not_accepted',
3897 "closed" = now()
3898 WHERE "id" = "issue_row"."id";
3899 END IF;
3900 END IF;
3901 -- eventually half freeze issues:
3902 IF
3903 -- NOTE: issue can't be closed at this point, if it has been accepted
3904 "issue_row"."accepted" NOTNULL AND
3905 "issue_row"."half_frozen" ISNULL
3906 THEN
3907 SELECT
3908 CASE
3909 WHEN "vote_now" * 2 > "issue_row"."population" THEN
3910 TRUE
3911 WHEN "vote_later" * 2 > "issue_row"."population" THEN
3912 FALSE
3913 ELSE NULL
3914 END
3915 INTO "voting_requested_v"
3916 FROM "issue" WHERE "id" = "issue_id_p";
3917 IF
3918 "voting_requested_v" OR (
3919 "voting_requested_v" ISNULL AND
3920 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3922 THEN
3923 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3924 -- NOTE: "issue_row" used later
3925 "issue_row"."state" := 'verification';
3926 "issue_row"."half_frozen" := now();
3927 UPDATE "issue" SET
3928 "state" = "issue_row"."state",
3929 "half_frozen" = "issue_row"."half_frozen"
3930 WHERE "id" = "issue_row"."id";
3931 END IF;
3932 END IF;
3933 -- close issues after some time, if all initiatives have been revoked:
3934 IF
3935 "issue_row"."closed" ISNULL AND
3936 NOT EXISTS (
3937 -- all initiatives are revoked
3938 SELECT NULL FROM "initiative"
3939 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3940 ) AND (
3941 -- and issue has not been accepted yet
3942 "issue_row"."accepted" ISNULL OR
3943 NOT EXISTS (
3944 -- or no initiatives have been revoked lately
3945 SELECT NULL FROM "initiative"
3946 WHERE "issue_id" = "issue_id_p"
3947 AND now() < "revoked" + "issue_row"."verification_time"
3948 ) OR (
3949 -- or verification time has elapsed
3950 "issue_row"."half_frozen" NOTNULL AND
3951 "issue_row"."fully_frozen" ISNULL AND
3952 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3955 THEN
3956 -- NOTE: "issue_row" used later
3957 IF "issue_row"."accepted" ISNULL THEN
3958 "issue_row"."state" := 'canceled_revoked_before_accepted';
3959 ELSIF "issue_row"."half_frozen" ISNULL THEN
3960 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
3961 ELSE
3962 "issue_row"."state" := 'canceled_after_revocation_during_verification';
3963 END IF;
3964 "issue_row"."closed" := now();
3965 UPDATE "issue" SET
3966 "state" = "issue_row"."state",
3967 "closed" = "issue_row"."closed"
3968 WHERE "id" = "issue_row"."id";
3969 END IF;
3970 -- fully freeze issue after verification time:
3971 IF
3972 "issue_row"."half_frozen" NOTNULL AND
3973 "issue_row"."fully_frozen" ISNULL AND
3974 "issue_row"."closed" ISNULL AND
3975 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3976 THEN
3977 PERFORM "freeze_after_snapshot"("issue_id_p");
3978 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
3979 END IF;
3980 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3981 -- close issue by calling close_voting(...) after voting time:
3982 IF
3983 "issue_row"."closed" ISNULL AND
3984 "issue_row"."fully_frozen" NOTNULL AND
3985 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
3986 THEN
3987 PERFORM "close_voting"("issue_id_p");
3988 -- calculate ranks will not consume much time and can be done now
3989 PERFORM "calculate_ranks"("issue_id_p");
3990 END IF;
3991 END IF;
3992 RETURN;
3993 END;
3994 $$;
3996 COMMENT ON FUNCTION "check_issue"
3997 ( "issue"."id"%TYPE )
3998 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.';
4001 CREATE FUNCTION "check_everything"()
4002 RETURNS VOID
4003 LANGUAGE 'plpgsql' VOLATILE AS $$
4004 DECLARE
4005 "issue_id_v" "issue"."id"%TYPE;
4006 BEGIN
4007 DELETE FROM "expired_session";
4008 PERFORM "check_last_login"();
4009 PERFORM "calculate_member_counts"();
4010 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4011 PERFORM "check_issue"("issue_id_v");
4012 END LOOP;
4013 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4014 PERFORM "calculate_ranks"("issue_id_v");
4015 END LOOP;
4016 RETURN;
4017 END;
4018 $$;
4020 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.';
4024 ----------------------
4025 -- Deletion of data --
4026 ----------------------
4029 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4030 RETURNS VOID
4031 LANGUAGE 'plpgsql' VOLATILE AS $$
4032 DECLARE
4033 "issue_row" "issue"%ROWTYPE;
4034 BEGIN
4035 SELECT * INTO "issue_row"
4036 FROM "issue" WHERE "id" = "issue_id_p"
4037 FOR UPDATE;
4038 IF "issue_row"."cleaned" ISNULL THEN
4039 UPDATE "issue" SET
4040 "closed" = NULL,
4041 "ranks_available" = FALSE
4042 WHERE "id" = "issue_id_p";
4043 DELETE FROM "delegating_voter"
4044 WHERE "issue_id" = "issue_id_p";
4045 DELETE FROM "direct_voter"
4046 WHERE "issue_id" = "issue_id_p";
4047 DELETE FROM "delegating_interest_snapshot"
4048 WHERE "issue_id" = "issue_id_p";
4049 DELETE FROM "direct_interest_snapshot"
4050 WHERE "issue_id" = "issue_id_p";
4051 DELETE FROM "delegating_population_snapshot"
4052 WHERE "issue_id" = "issue_id_p";
4053 DELETE FROM "direct_population_snapshot"
4054 WHERE "issue_id" = "issue_id_p";
4055 DELETE FROM "non_voter"
4056 WHERE "issue_id" = "issue_id_p";
4057 DELETE FROM "delegation"
4058 WHERE "issue_id" = "issue_id_p";
4059 DELETE FROM "supporter"
4060 WHERE "issue_id" = "issue_id_p";
4061 UPDATE "issue" SET
4062 "closed" = "issue_row"."closed",
4063 "ranks_available" = "issue_row"."ranks_available",
4064 "cleaned" = now()
4065 WHERE "id" = "issue_id_p";
4066 END IF;
4067 RETURN;
4068 END;
4069 $$;
4071 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4074 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4075 RETURNS VOID
4076 LANGUAGE 'plpgsql' VOLATILE AS $$
4077 BEGIN
4078 UPDATE "member" SET
4079 "last_login" = NULL,
4080 "last_login_public" = NULL,
4081 "login" = NULL,
4082 "password" = NULL,
4083 "locked" = TRUE,
4084 "active" = FALSE,
4085 "notify_email" = NULL,
4086 "notify_email_unconfirmed" = NULL,
4087 "notify_email_secret" = NULL,
4088 "notify_email_secret_expiry" = NULL,
4089 "notify_email_lock_expiry" = NULL,
4090 "password_reset_secret" = NULL,
4091 "password_reset_secret_expiry" = NULL,
4092 "organizational_unit" = NULL,
4093 "internal_posts" = NULL,
4094 "realname" = NULL,
4095 "birthday" = NULL,
4096 "address" = NULL,
4097 "email" = NULL,
4098 "xmpp_address" = NULL,
4099 "website" = NULL,
4100 "phone" = NULL,
4101 "mobile_phone" = NULL,
4102 "profession" = NULL,
4103 "external_memberships" = NULL,
4104 "external_posts" = NULL,
4105 "statement" = NULL
4106 WHERE "id" = "member_id_p";
4107 -- "text_search_data" is updated by triggers
4108 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4109 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4110 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4111 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4112 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4113 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4114 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4115 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4116 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4117 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4118 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4119 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4120 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4121 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4122 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4123 DELETE FROM "direct_voter" USING "issue"
4124 WHERE "direct_voter"."issue_id" = "issue"."id"
4125 AND "issue"."closed" ISNULL
4126 AND "member_id" = "member_id_p";
4127 RETURN;
4128 END;
4129 $$;
4131 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)';
4134 CREATE FUNCTION "delete_private_data"()
4135 RETURNS VOID
4136 LANGUAGE 'plpgsql' VOLATILE AS $$
4137 BEGIN
4138 UPDATE "member" SET
4139 "last_login" = NULL,
4140 "login" = NULL,
4141 "password" = NULL,
4142 "notify_email" = NULL,
4143 "notify_email_unconfirmed" = NULL,
4144 "notify_email_secret" = NULL,
4145 "notify_email_secret_expiry" = NULL,
4146 "notify_email_lock_expiry" = NULL,
4147 "password_reset_secret" = NULL,
4148 "password_reset_secret_expiry" = NULL,
4149 "organizational_unit" = NULL,
4150 "internal_posts" = NULL,
4151 "realname" = NULL,
4152 "birthday" = NULL,
4153 "address" = NULL,
4154 "email" = NULL,
4155 "xmpp_address" = NULL,
4156 "website" = NULL,
4157 "phone" = NULL,
4158 "mobile_phone" = NULL,
4159 "profession" = NULL,
4160 "external_memberships" = NULL,
4161 "external_posts" = NULL,
4162 "statement" = NULL;
4163 -- "text_search_data" is updated by triggers
4164 DELETE FROM "invite_code";
4165 DELETE FROM "setting";
4166 DELETE FROM "setting_map";
4167 DELETE FROM "member_relation_setting";
4168 DELETE FROM "member_image";
4169 DELETE FROM "contact";
4170 DELETE FROM "ignored_member";
4171 DELETE FROM "session";
4172 DELETE FROM "area_setting";
4173 DELETE FROM "issue_setting";
4174 DELETE FROM "ignored_initiative";
4175 DELETE FROM "initiative_setting";
4176 DELETE FROM "suggestion_setting";
4177 DELETE FROM "non_voter";
4178 DELETE FROM "direct_voter" USING "issue"
4179 WHERE "direct_voter"."issue_id" = "issue"."id"
4180 AND "issue"."closed" ISNULL;
4181 RETURN;
4182 END;
4183 $$;
4185 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.';
4189 COMMIT;

Impressum / About Us