liquid_feedback_core

view core.sql @ 128:5ea2f9c5ba9a

Set "rank" for all "admitted" initiatives after voting is finished; Additional columns in "initiative" table store voting result information

Changes in detail:
- Renamed column "majority" of table "initiative" to "attainable"
- Added columns "favored", "unfavored" and "eligible" to "initiative" table
- Added constraints to "initiative" table, restricting certain value combinations in the the new columns
- Modified "calculate_ranks" function to update the new columns and always write "rank" information
- Marking the final winner is now done utilizing the new "eligible" column
author jbe
date Tue May 24 14:58:42 2011 +0200 (2011-05-24)
parents bbadd6b2634d
children 284113a50c3b
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 "attainable" BOOLEAN,
541 "favored" BOOLEAN,
542 "unfavored" BOOLEAN,
543 "eligible" BOOLEAN,
544 "rank" INT4,
545 "winner" BOOLEAN,
546 "text_search_data" TSVECTOR,
547 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
548 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
549 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
550 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
551 CONSTRAINT "revoked_initiatives_cant_be_admitted"
552 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
553 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
554 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
555 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
556 "attainable" ISNULL AND "favored" ISNULL AND "unfavored" ISNULL AND
557 "eligible" ISNULL AND "rank" ISNULL AND "winner" ISNULL ) ),
558 CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_attainable_must_be_null"
559 CHECK ("positive_votes" NOTNULL = "negative_votes" NOTNULL AND "positive_votes" NOTNULL = "attainable" NOTNULL),
560 CONSTRAINT "favored_forbids_unfavored" CHECK (NOT ("favored" AND "unfavored")),
561 CONSTRAINT "attainable_and_favored_result_in_eligible" CHECK (
562 ( "favored" ISNULL AND "eligible" ISNULL ) OR
563 ( "attainable" NOTNULL AND "favored" NOTNULL AND "eligible" NOTNULL AND
564 ("attainable" AND "favored") = "eligible" ) ) );
565 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
566 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
567 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
568 CREATE TRIGGER "update_text_search_data"
569 BEFORE INSERT OR UPDATE ON "initiative"
570 FOR EACH ROW EXECUTE PROCEDURE
571 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
572 "name", "discussion_url");
574 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.';
576 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
577 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
578 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
579 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
580 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
581 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
582 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
583 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
584 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
585 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
586 COMMENT ON COLUMN "initiative"."attainable" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "majority_num"/"majority_den"';
587 COMMENT ON COLUMN "initiative"."favored" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
588 COMMENT ON COLUMN "initiative"."unfavored" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
589 COMMENT ON COLUMN "initiative"."eligible" IS 'TRUE, if initiative is "attainable" and "favored"';
590 COMMENT ON COLUMN "initiative"."rank" IS 'Schulze-Ranking after tie-breaking';
591 COMMENT ON COLUMN "initiative"."winner" IS 'TRUE, if initiative is final winner (best ranked initiative being "eligible")';
594 CREATE TABLE "battle" (
595 "issue_id" INT4 NOT NULL,
596 "winning_initiative_id" INT4,
597 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
598 "losing_initiative_id" INT4,
599 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
600 "count" INT4 NOT NULL,
601 CONSTRAINT "initiative_ids_not_equal" CHECK (
602 "winning_initiative_id" != "losing_initiative_id" OR
603 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
604 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
605 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
606 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
607 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
609 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';
612 CREATE TABLE "ignored_initiative" (
613 PRIMARY KEY ("initiative_id", "member_id"),
614 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
615 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
616 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
618 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
621 CREATE TABLE "initiative_setting" (
622 PRIMARY KEY ("member_id", "key", "initiative_id"),
623 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
624 "key" TEXT NOT NULL,
625 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
626 "value" TEXT NOT NULL );
628 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
631 CREATE TABLE "draft" (
632 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
633 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
634 "id" SERIAL8 PRIMARY KEY,
635 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
636 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
637 "formatting_engine" TEXT,
638 "content" TEXT NOT NULL,
639 "text_search_data" TSVECTOR );
640 CREATE INDEX "draft_created_idx" ON "draft" ("created");
641 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
642 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
643 CREATE TRIGGER "update_text_search_data"
644 BEFORE INSERT OR UPDATE ON "draft"
645 FOR EACH ROW EXECUTE PROCEDURE
646 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
648 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.';
650 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
651 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
654 CREATE TABLE "rendered_draft" (
655 PRIMARY KEY ("draft_id", "format"),
656 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
657 "format" TEXT,
658 "content" TEXT NOT NULL );
660 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)';
663 CREATE TABLE "suggestion" (
664 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
665 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
666 "id" SERIAL8 PRIMARY KEY,
667 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
668 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
669 "name" TEXT NOT NULL,
670 "description" TEXT NOT NULL DEFAULT '',
671 "text_search_data" TSVECTOR,
672 "minus2_unfulfilled_count" INT4,
673 "minus2_fulfilled_count" INT4,
674 "minus1_unfulfilled_count" INT4,
675 "minus1_fulfilled_count" INT4,
676 "plus1_unfulfilled_count" INT4,
677 "plus1_fulfilled_count" INT4,
678 "plus2_unfulfilled_count" INT4,
679 "plus2_fulfilled_count" INT4 );
680 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
681 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
682 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
683 CREATE TRIGGER "update_text_search_data"
684 BEFORE INSERT OR UPDATE ON "suggestion"
685 FOR EACH ROW EXECUTE PROCEDURE
686 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
687 "name", "description");
689 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';
691 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
692 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
693 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
694 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
695 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
696 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
697 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
698 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
701 CREATE TABLE "suggestion_setting" (
702 PRIMARY KEY ("member_id", "key", "suggestion_id"),
703 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
704 "key" TEXT NOT NULL,
705 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
706 "value" TEXT NOT NULL );
708 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
711 CREATE TABLE "invite_code_unit" (
712 PRIMARY KEY ("invite_code_id", "unit_id"),
713 "invite_code_id" INT8 REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
714 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
716 COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
719 CREATE TABLE "privilege" (
720 PRIMARY KEY ("unit_id", "member_id"),
721 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
722 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
723 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
724 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
725 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
726 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
727 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
729 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
731 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
732 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
733 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
734 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
735 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
738 CREATE TABLE "membership" (
739 PRIMARY KEY ("area_id", "member_id"),
740 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
741 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
742 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
743 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
745 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
747 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.';
750 CREATE TABLE "interest" (
751 PRIMARY KEY ("issue_id", "member_id"),
752 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
753 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
754 "autoreject" BOOLEAN,
755 "voting_requested" BOOLEAN );
756 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
758 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.';
760 COMMENT ON COLUMN "interest"."autoreject" IS 'TRUE = member votes against all initiatives in case of not explicitly taking part in the voting procedure';
761 COMMENT ON COLUMN "interest"."voting_requested" IS 'TRUE = member wants to vote now, FALSE = member wants to vote later, NULL = policy rules should apply';
764 CREATE TABLE "initiator" (
765 PRIMARY KEY ("initiative_id", "member_id"),
766 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
767 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
768 "accepted" BOOLEAN );
769 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
771 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.';
773 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.';
776 CREATE TABLE "supporter" (
777 "issue_id" INT4 NOT NULL,
778 PRIMARY KEY ("initiative_id", "member_id"),
779 "initiative_id" INT4,
780 "member_id" INT4,
781 "draft_id" INT8 NOT NULL,
782 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
783 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE );
784 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
786 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.';
788 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft, defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
791 CREATE TABLE "opinion" (
792 "initiative_id" INT4 NOT NULL,
793 PRIMARY KEY ("suggestion_id", "member_id"),
794 "suggestion_id" INT8,
795 "member_id" INT4,
796 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
797 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
798 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
799 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
800 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
802 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.';
804 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
807 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
809 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
812 CREATE TABLE "delegation" (
813 "id" SERIAL8 PRIMARY KEY,
814 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
815 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
816 "scope" "delegation_scope" NOT NULL,
817 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
818 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
819 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
820 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
821 CONSTRAINT "no_unit_delegation_to_null"
822 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
823 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
824 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
825 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
826 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
827 UNIQUE ("unit_id", "truster_id"),
828 UNIQUE ("area_id", "truster_id"),
829 UNIQUE ("issue_id", "truster_id") );
830 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
831 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
833 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
835 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
836 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
837 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
840 CREATE TABLE "direct_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 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
848 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
850 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
851 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
854 CREATE TABLE "delegating_population_snapshot" (
855 PRIMARY KEY ("issue_id", "event", "member_id"),
856 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
857 "event" "snapshot_event",
858 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
859 "weight" INT4,
860 "scope" "delegation_scope" NOT NULL,
861 "delegate_member_ids" INT4[] NOT NULL );
862 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
864 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
866 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
867 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
868 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
869 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"';
872 CREATE TABLE "direct_interest_snapshot" (
873 PRIMARY KEY ("issue_id", "event", "member_id"),
874 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
875 "event" "snapshot_event",
876 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
877 "weight" INT4,
878 "voting_requested" BOOLEAN );
879 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
881 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
883 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
884 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
885 COMMENT ON COLUMN "direct_interest_snapshot"."voting_requested" IS 'Copied from column "voting_requested" of table "interest"';
888 CREATE TABLE "delegating_interest_snapshot" (
889 PRIMARY KEY ("issue_id", "event", "member_id"),
890 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
891 "event" "snapshot_event",
892 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
893 "weight" INT4,
894 "scope" "delegation_scope" NOT NULL,
895 "delegate_member_ids" INT4[] NOT NULL );
896 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
898 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
900 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
901 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
902 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
903 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"';
906 CREATE TABLE "direct_supporter_snapshot" (
907 "issue_id" INT4 NOT NULL,
908 PRIMARY KEY ("initiative_id", "event", "member_id"),
909 "initiative_id" INT4,
910 "event" "snapshot_event",
911 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
912 "informed" BOOLEAN NOT NULL,
913 "satisfied" BOOLEAN NOT NULL,
914 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
915 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
916 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
918 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
920 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
921 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
922 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
925 CREATE TABLE "non_voter" (
926 PRIMARY KEY ("issue_id", "member_id"),
927 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
928 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
929 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
931 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
934 CREATE TABLE "direct_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 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
940 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
942 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.';
944 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
945 COMMENT ON COLUMN "direct_voter"."autoreject" IS 'Votes were inserted due to "autoreject" feature';
948 CREATE TABLE "delegating_voter" (
949 PRIMARY KEY ("issue_id", "member_id"),
950 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
951 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
952 "weight" INT4,
953 "scope" "delegation_scope" NOT NULL,
954 "delegate_member_ids" INT4[] NOT NULL );
955 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
957 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
959 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
960 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
961 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"';
964 CREATE TABLE "vote" (
965 "issue_id" INT4 NOT NULL,
966 PRIMARY KEY ("initiative_id", "member_id"),
967 "initiative_id" INT4,
968 "member_id" INT4,
969 "grade" INT4,
970 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
971 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
972 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
974 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.';
976 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.';
979 CREATE TABLE "issue_comment" (
980 PRIMARY KEY ("issue_id", "member_id"),
981 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
982 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
983 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
984 "formatting_engine" TEXT,
985 "content" TEXT NOT NULL,
986 "text_search_data" TSVECTOR );
987 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
988 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
989 CREATE TRIGGER "update_text_search_data"
990 BEFORE INSERT OR UPDATE ON "issue_comment"
991 FOR EACH ROW EXECUTE PROCEDURE
992 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
994 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
996 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
999 CREATE TABLE "rendered_issue_comment" (
1000 PRIMARY KEY ("issue_id", "member_id", "format"),
1001 FOREIGN KEY ("issue_id", "member_id")
1002 REFERENCES "issue_comment" ("issue_id", "member_id")
1003 ON DELETE CASCADE ON UPDATE CASCADE,
1004 "issue_id" INT4,
1005 "member_id" INT4,
1006 "format" TEXT,
1007 "content" TEXT NOT NULL );
1009 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)';
1012 CREATE TABLE "voting_comment" (
1013 PRIMARY KEY ("issue_id", "member_id"),
1014 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1015 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1016 "changed" TIMESTAMPTZ,
1017 "formatting_engine" TEXT,
1018 "content" TEXT NOT NULL,
1019 "text_search_data" TSVECTOR );
1020 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1021 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1022 CREATE TRIGGER "update_text_search_data"
1023 BEFORE INSERT OR UPDATE ON "voting_comment"
1024 FOR EACH ROW EXECUTE PROCEDURE
1025 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1027 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1029 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.';
1032 CREATE TABLE "rendered_voting_comment" (
1033 PRIMARY KEY ("issue_id", "member_id", "format"),
1034 FOREIGN KEY ("issue_id", "member_id")
1035 REFERENCES "voting_comment" ("issue_id", "member_id")
1036 ON DELETE CASCADE ON UPDATE CASCADE,
1037 "issue_id" INT4,
1038 "member_id" INT4,
1039 "format" TEXT,
1040 "content" TEXT NOT NULL );
1042 COMMENT ON TABLE "rendered_voting_comment" IS 'This table may be used by frontends to cache "rendered" voting comments (e.g. HTML output generated from wiki text)';
1045 CREATE TYPE "event_type" AS ENUM (
1046 'issue_state_changed',
1047 'initiative_created_in_new_issue',
1048 'initiative_created_in_existing_issue',
1049 'initiative_revoked',
1050 'new_draft_created',
1051 'suggestion_created');
1053 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1056 CREATE TABLE "event" (
1057 "id" SERIAL8 PRIMARY KEY,
1058 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1059 "event" "event_type" NOT NULL,
1060 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1061 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1062 "state" "issue_state" CHECK ("state" != 'calculation'),
1063 "initiative_id" INT4,
1064 "draft_id" INT8,
1065 "suggestion_id" INT8,
1066 FOREIGN KEY ("issue_id", "initiative_id")
1067 REFERENCES "initiative" ("issue_id", "id")
1068 ON DELETE CASCADE ON UPDATE CASCADE,
1069 FOREIGN KEY ("initiative_id", "draft_id")
1070 REFERENCES "draft" ("initiative_id", "id")
1071 ON DELETE CASCADE ON UPDATE CASCADE,
1072 FOREIGN KEY ("initiative_id", "suggestion_id")
1073 REFERENCES "suggestion" ("initiative_id", "id")
1074 ON DELETE CASCADE ON UPDATE CASCADE,
1075 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1076 "event" != 'issue_state_changed' OR (
1077 "member_id" ISNULL AND
1078 "issue_id" NOTNULL AND
1079 "state" NOTNULL AND
1080 "initiative_id" ISNULL AND
1081 "draft_id" ISNULL AND
1082 "suggestion_id" ISNULL )),
1083 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1084 "event" NOT IN (
1085 'initiative_created_in_new_issue',
1086 'initiative_created_in_existing_issue',
1087 'initiative_revoked',
1088 'new_draft_created'
1089 ) OR (
1090 "member_id" NOTNULL AND
1091 "issue_id" NOTNULL AND
1092 "state" NOTNULL AND
1093 "initiative_id" NOTNULL AND
1094 "draft_id" NOTNULL AND
1095 "suggestion_id" ISNULL )),
1096 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1097 "event" != 'suggestion_created' OR (
1098 "member_id" NOTNULL AND
1099 "issue_id" NOTNULL AND
1100 "state" NOTNULL AND
1101 "initiative_id" NOTNULL AND
1102 "draft_id" ISNULL AND
1103 "suggestion_id" NOTNULL )) );
1105 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1107 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1108 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1109 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1110 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1114 ----------------------------------------------
1115 -- Writing of history entries and event log --
1116 ----------------------------------------------
1118 CREATE FUNCTION "write_member_history_trigger"()
1119 RETURNS TRIGGER
1120 LANGUAGE 'plpgsql' VOLATILE AS $$
1121 BEGIN
1122 IF
1123 NEW."active" != OLD."active" OR
1124 NEW."name" != OLD."name"
1125 THEN
1126 INSERT INTO "member_history"
1127 ("member_id", "active", "name")
1128 VALUES (NEW."id", OLD."active", OLD."name");
1129 END IF;
1130 RETURN NULL;
1131 END;
1132 $$;
1134 CREATE TRIGGER "write_member_history"
1135 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1136 "write_member_history_trigger"();
1138 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1139 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1142 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1143 RETURNS TRIGGER
1144 LANGUAGE 'plpgsql' VOLATILE AS $$
1145 BEGIN
1146 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1147 INSERT INTO "event" ("event", "issue_id", "state")
1148 VALUES ('issue_state_changed', NEW."id", NEW."state");
1149 END IF;
1150 RETURN NULL;
1151 END;
1152 $$;
1154 CREATE TRIGGER "write_event_issue_state_changed"
1155 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1156 "write_event_issue_state_changed_trigger"();
1158 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1159 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1162 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1163 RETURNS TRIGGER
1164 LANGUAGE 'plpgsql' VOLATILE AS $$
1165 DECLARE
1166 "initiative_row" "initiative"%ROWTYPE;
1167 "issue_row" "issue"%ROWTYPE;
1168 "event_v" "event_type";
1169 BEGIN
1170 SELECT * INTO "initiative_row" FROM "initiative"
1171 WHERE "id" = NEW."initiative_id";
1172 SELECT * INTO "issue_row" FROM "issue"
1173 WHERE "id" = "initiative_row"."issue_id";
1174 IF EXISTS (
1175 SELECT NULL FROM "draft"
1176 WHERE "initiative_id" = NEW."initiative_id"
1177 AND "id" != NEW."id"
1178 ) THEN
1179 "event_v" := 'new_draft_created';
1180 ELSE
1181 IF EXISTS (
1182 SELECT NULL FROM "initiative"
1183 WHERE "issue_id" = "initiative_row"."issue_id"
1184 AND "id" != "initiative_row"."id"
1185 ) THEN
1186 "event_v" := 'initiative_created_in_existing_issue';
1187 ELSE
1188 "event_v" := 'initiative_created_in_new_issue';
1189 END IF;
1190 END IF;
1191 INSERT INTO "event" (
1192 "event", "member_id",
1193 "issue_id", "state", "initiative_id", "draft_id"
1194 ) VALUES (
1195 "event_v",
1196 NEW."author_id",
1197 "initiative_row"."issue_id",
1198 "issue_row"."state",
1199 "initiative_row"."id",
1200 NEW."id" );
1201 RETURN NULL;
1202 END;
1203 $$;
1205 CREATE TRIGGER "write_event_initiative_or_draft_created"
1206 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1207 "write_event_initiative_or_draft_created_trigger"();
1209 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1210 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1213 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1214 RETURNS TRIGGER
1215 LANGUAGE 'plpgsql' VOLATILE AS $$
1216 DECLARE
1217 "issue_row" "issue"%ROWTYPE;
1218 BEGIN
1219 SELECT * INTO "issue_row" FROM "issue"
1220 WHERE "id" = NEW."issue_id";
1221 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1222 INSERT INTO "event" (
1223 "event", "member_id", "issue_id", "state", "initiative_id"
1224 ) VALUES (
1225 'initiative_revoked',
1226 NEW."revoked_by_member_id",
1227 NEW."issue_id",
1228 "issue_row"."state",
1229 NEW."id" );
1230 END IF;
1231 RETURN NULL;
1232 END;
1233 $$;
1235 CREATE TRIGGER "write_event_initiative_revoked"
1236 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1237 "write_event_initiative_revoked_trigger"();
1239 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1240 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1243 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1244 RETURNS TRIGGER
1245 LANGUAGE 'plpgsql' VOLATILE AS $$
1246 DECLARE
1247 "initiative_row" "initiative"%ROWTYPE;
1248 "issue_row" "issue"%ROWTYPE;
1249 BEGIN
1250 SELECT * INTO "initiative_row" FROM "initiative"
1251 WHERE "id" = NEW."initiative_id";
1252 SELECT * INTO "issue_row" FROM "issue"
1253 WHERE "id" = "initiative_row"."issue_id";
1254 INSERT INTO "event" (
1255 "event", "member_id",
1256 "issue_id", "state", "initiative_id", "suggestion_id"
1257 ) VALUES (
1258 'suggestion_created',
1259 NEW."author_id",
1260 "initiative_row"."issue_id",
1261 "issue_row"."state",
1262 "initiative_row"."id",
1263 NEW."id" );
1264 RETURN NULL;
1265 END;
1266 $$;
1268 CREATE TRIGGER "write_event_suggestion_created"
1269 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1270 "write_event_suggestion_created_trigger"();
1272 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1273 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1277 ----------------------------
1278 -- Additional constraints --
1279 ----------------------------
1282 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1283 RETURNS TRIGGER
1284 LANGUAGE 'plpgsql' VOLATILE AS $$
1285 BEGIN
1286 IF NOT EXISTS (
1287 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1288 ) THEN
1289 --RAISE 'Cannot create issue without an initial initiative.' USING
1290 -- ERRCODE = 'integrity_constraint_violation',
1291 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1292 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1293 END IF;
1294 RETURN NULL;
1295 END;
1296 $$;
1298 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1299 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1300 FOR EACH ROW EXECUTE PROCEDURE
1301 "issue_requires_first_initiative_trigger"();
1303 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1304 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1307 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1308 RETURNS TRIGGER
1309 LANGUAGE 'plpgsql' VOLATILE AS $$
1310 DECLARE
1311 "reference_lost" BOOLEAN;
1312 BEGIN
1313 IF TG_OP = 'DELETE' THEN
1314 "reference_lost" := TRUE;
1315 ELSE
1316 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1317 END IF;
1318 IF
1319 "reference_lost" AND NOT EXISTS (
1320 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1322 THEN
1323 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1324 END IF;
1325 RETURN NULL;
1326 END;
1327 $$;
1329 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1330 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1331 FOR EACH ROW EXECUTE PROCEDURE
1332 "last_initiative_deletes_issue_trigger"();
1334 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1335 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1338 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1339 RETURNS TRIGGER
1340 LANGUAGE 'plpgsql' VOLATILE AS $$
1341 BEGIN
1342 IF NOT EXISTS (
1343 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1344 ) THEN
1345 --RAISE 'Cannot create initiative without an initial draft.' USING
1346 -- ERRCODE = 'integrity_constraint_violation',
1347 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1348 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1349 END IF;
1350 RETURN NULL;
1351 END;
1352 $$;
1354 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1355 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1356 FOR EACH ROW EXECUTE PROCEDURE
1357 "initiative_requires_first_draft_trigger"();
1359 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1360 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1363 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1364 RETURNS TRIGGER
1365 LANGUAGE 'plpgsql' VOLATILE AS $$
1366 DECLARE
1367 "reference_lost" BOOLEAN;
1368 BEGIN
1369 IF TG_OP = 'DELETE' THEN
1370 "reference_lost" := TRUE;
1371 ELSE
1372 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1373 END IF;
1374 IF
1375 "reference_lost" AND NOT EXISTS (
1376 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1378 THEN
1379 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1380 END IF;
1381 RETURN NULL;
1382 END;
1383 $$;
1385 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1386 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1387 FOR EACH ROW EXECUTE PROCEDURE
1388 "last_draft_deletes_initiative_trigger"();
1390 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1391 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1394 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1395 RETURNS TRIGGER
1396 LANGUAGE 'plpgsql' VOLATILE AS $$
1397 BEGIN
1398 IF NOT EXISTS (
1399 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1400 ) THEN
1401 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1402 END IF;
1403 RETURN NULL;
1404 END;
1405 $$;
1407 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1408 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1409 FOR EACH ROW EXECUTE PROCEDURE
1410 "suggestion_requires_first_opinion_trigger"();
1412 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1413 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1416 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1417 RETURNS TRIGGER
1418 LANGUAGE 'plpgsql' VOLATILE AS $$
1419 DECLARE
1420 "reference_lost" BOOLEAN;
1421 BEGIN
1422 IF TG_OP = 'DELETE' THEN
1423 "reference_lost" := TRUE;
1424 ELSE
1425 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1426 END IF;
1427 IF
1428 "reference_lost" AND NOT EXISTS (
1429 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1431 THEN
1432 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1433 END IF;
1434 RETURN NULL;
1435 END;
1436 $$;
1438 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1439 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1440 FOR EACH ROW EXECUTE PROCEDURE
1441 "last_opinion_deletes_suggestion_trigger"();
1443 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1444 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1448 ---------------------------------------------------------------
1449 -- Ensure that votes are not modified when issues are frozen --
1450 ---------------------------------------------------------------
1452 -- NOTE: Frontends should ensure this anyway, but in case of programming
1453 -- errors the following triggers ensure data integrity.
1456 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1457 RETURNS TRIGGER
1458 LANGUAGE 'plpgsql' VOLATILE AS $$
1459 DECLARE
1460 "issue_id_v" "issue"."id"%TYPE;
1461 "issue_row" "issue"%ROWTYPE;
1462 BEGIN
1463 IF TG_OP = 'DELETE' THEN
1464 "issue_id_v" := OLD."issue_id";
1465 ELSE
1466 "issue_id_v" := NEW."issue_id";
1467 END IF;
1468 SELECT INTO "issue_row" * FROM "issue"
1469 WHERE "id" = "issue_id_v" FOR SHARE;
1470 IF "issue_row"."closed" NOTNULL THEN
1471 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1472 END IF;
1473 RETURN NULL;
1474 END;
1475 $$;
1477 CREATE TRIGGER "forbid_changes_on_closed_issue"
1478 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1479 FOR EACH ROW EXECUTE PROCEDURE
1480 "forbid_changes_on_closed_issue_trigger"();
1482 CREATE TRIGGER "forbid_changes_on_closed_issue"
1483 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1484 FOR EACH ROW EXECUTE PROCEDURE
1485 "forbid_changes_on_closed_issue_trigger"();
1487 CREATE TRIGGER "forbid_changes_on_closed_issue"
1488 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1489 FOR EACH ROW EXECUTE PROCEDURE
1490 "forbid_changes_on_closed_issue_trigger"();
1492 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"';
1493 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';
1494 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';
1495 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';
1499 --------------------------------------------------------------------
1500 -- Auto-retrieval of fields only needed for referential integrity --
1501 --------------------------------------------------------------------
1504 CREATE FUNCTION "autofill_issue_id_trigger"()
1505 RETURNS TRIGGER
1506 LANGUAGE 'plpgsql' VOLATILE AS $$
1507 BEGIN
1508 IF NEW."issue_id" ISNULL THEN
1509 SELECT "issue_id" INTO NEW."issue_id"
1510 FROM "initiative" WHERE "id" = NEW."initiative_id";
1511 END IF;
1512 RETURN NEW;
1513 END;
1514 $$;
1516 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1517 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1519 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1520 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1522 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1523 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1524 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1527 CREATE FUNCTION "autofill_initiative_id_trigger"()
1528 RETURNS TRIGGER
1529 LANGUAGE 'plpgsql' VOLATILE AS $$
1530 BEGIN
1531 IF NEW."initiative_id" ISNULL THEN
1532 SELECT "initiative_id" INTO NEW."initiative_id"
1533 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1534 END IF;
1535 RETURN NEW;
1536 END;
1537 $$;
1539 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1540 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1542 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1543 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1547 -----------------------------------------------------
1548 -- Automatic calculation of certain default values --
1549 -----------------------------------------------------
1552 CREATE FUNCTION "copy_timings_trigger"()
1553 RETURNS TRIGGER
1554 LANGUAGE 'plpgsql' VOLATILE AS $$
1555 DECLARE
1556 "policy_row" "policy"%ROWTYPE;
1557 BEGIN
1558 SELECT * INTO "policy_row" FROM "policy"
1559 WHERE "id" = NEW."policy_id";
1560 IF NEW."admission_time" ISNULL THEN
1561 NEW."admission_time" := "policy_row"."admission_time";
1562 END IF;
1563 IF NEW."discussion_time" ISNULL THEN
1564 NEW."discussion_time" := "policy_row"."discussion_time";
1565 END IF;
1566 IF NEW."verification_time" ISNULL THEN
1567 NEW."verification_time" := "policy_row"."verification_time";
1568 END IF;
1569 IF NEW."voting_time" ISNULL THEN
1570 NEW."voting_time" := "policy_row"."voting_time";
1571 END IF;
1572 RETURN NEW;
1573 END;
1574 $$;
1576 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1577 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1579 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1580 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1583 CREATE FUNCTION "supporter_default_for_draft_id_trigger"()
1584 RETURNS TRIGGER
1585 LANGUAGE 'plpgsql' VOLATILE AS $$
1586 BEGIN
1587 IF NEW."draft_id" ISNULL THEN
1588 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1589 WHERE "initiative_id" = NEW."initiative_id";
1590 END IF;
1591 RETURN NEW;
1592 END;
1593 $$;
1595 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1596 FOR EACH ROW EXECUTE PROCEDURE "supporter_default_for_draft_id_trigger"();
1598 COMMENT ON FUNCTION "supporter_default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on table "supporter"';
1599 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';
1603 ----------------------------------------
1604 -- Automatic creation of dependencies --
1605 ----------------------------------------
1608 CREATE FUNCTION "autocreate_interest_trigger"()
1609 RETURNS TRIGGER
1610 LANGUAGE 'plpgsql' VOLATILE AS $$
1611 BEGIN
1612 IF NOT EXISTS (
1613 SELECT NULL FROM "initiative" JOIN "interest"
1614 ON "initiative"."issue_id" = "interest"."issue_id"
1615 WHERE "initiative"."id" = NEW."initiative_id"
1616 AND "interest"."member_id" = NEW."member_id"
1617 ) THEN
1618 BEGIN
1619 INSERT INTO "interest" ("issue_id", "member_id")
1620 SELECT "issue_id", NEW."member_id"
1621 FROM "initiative" WHERE "id" = NEW."initiative_id";
1622 EXCEPTION WHEN unique_violation THEN END;
1623 END IF;
1624 RETURN NEW;
1625 END;
1626 $$;
1628 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1629 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1631 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1632 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';
1635 CREATE FUNCTION "autocreate_supporter_trigger"()
1636 RETURNS TRIGGER
1637 LANGUAGE 'plpgsql' VOLATILE AS $$
1638 BEGIN
1639 IF NOT EXISTS (
1640 SELECT NULL FROM "suggestion" JOIN "supporter"
1641 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1642 WHERE "suggestion"."id" = NEW."suggestion_id"
1643 AND "supporter"."member_id" = NEW."member_id"
1644 ) THEN
1645 BEGIN
1646 INSERT INTO "supporter" ("initiative_id", "member_id")
1647 SELECT "initiative_id", NEW."member_id"
1648 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1649 EXCEPTION WHEN unique_violation THEN END;
1650 END IF;
1651 RETURN NEW;
1652 END;
1653 $$;
1655 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1656 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1658 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1659 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.';
1663 ------------------------------------------
1664 -- Views and helper functions for views --
1665 ------------------------------------------
1668 CREATE VIEW "unit_delegation" AS
1669 SELECT
1670 "unit"."id" AS "unit_id",
1671 "delegation"."id",
1672 "delegation"."truster_id",
1673 "delegation"."trustee_id",
1674 "delegation"."scope"
1675 FROM "unit"
1676 JOIN "delegation"
1677 ON "delegation"."unit_id" = "unit"."id"
1678 JOIN "member"
1679 ON "delegation"."truster_id" = "member"."id"
1680 JOIN "privilege"
1681 ON "delegation"."unit_id" = "privilege"."unit_id"
1682 AND "delegation"."truster_id" = "privilege"."member_id"
1683 WHERE "member"."active" AND "privilege"."voting_right";
1685 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1688 CREATE VIEW "area_delegation" AS
1689 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1690 "area"."id" AS "area_id",
1691 "delegation"."id",
1692 "delegation"."truster_id",
1693 "delegation"."trustee_id",
1694 "delegation"."scope"
1695 FROM "area"
1696 JOIN "delegation"
1697 ON "delegation"."unit_id" = "area"."unit_id"
1698 OR "delegation"."area_id" = "area"."id"
1699 JOIN "member"
1700 ON "delegation"."truster_id" = "member"."id"
1701 JOIN "privilege"
1702 ON "area"."unit_id" = "privilege"."unit_id"
1703 AND "delegation"."truster_id" = "privilege"."member_id"
1704 WHERE "member"."active" AND "privilege"."voting_right"
1705 ORDER BY
1706 "area"."id",
1707 "delegation"."truster_id",
1708 "delegation"."scope" DESC;
1710 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1713 CREATE VIEW "issue_delegation" AS
1714 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1715 "issue"."id" AS "issue_id",
1716 "delegation"."id",
1717 "delegation"."truster_id",
1718 "delegation"."trustee_id",
1719 "delegation"."scope"
1720 FROM "issue"
1721 JOIN "area"
1722 ON "area"."id" = "issue"."area_id"
1723 JOIN "delegation"
1724 ON "delegation"."unit_id" = "area"."unit_id"
1725 OR "delegation"."area_id" = "area"."id"
1726 OR "delegation"."issue_id" = "issue"."id"
1727 JOIN "member"
1728 ON "delegation"."truster_id" = "member"."id"
1729 JOIN "privilege"
1730 ON "area"."unit_id" = "privilege"."unit_id"
1731 AND "delegation"."truster_id" = "privilege"."member_id"
1732 WHERE "member"."active" AND "privilege"."voting_right"
1733 ORDER BY
1734 "issue"."id",
1735 "delegation"."truster_id",
1736 "delegation"."scope" DESC;
1738 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1741 CREATE FUNCTION "membership_weight_with_skipping"
1742 ( "area_id_p" "area"."id"%TYPE,
1743 "member_id_p" "member"."id"%TYPE,
1744 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1745 RETURNS INT4
1746 LANGUAGE 'plpgsql' STABLE AS $$
1747 DECLARE
1748 "sum_v" INT4;
1749 "delegation_row" "area_delegation"%ROWTYPE;
1750 BEGIN
1751 "sum_v" := 1;
1752 FOR "delegation_row" IN
1753 SELECT "area_delegation".*
1754 FROM "area_delegation" LEFT JOIN "membership"
1755 ON "membership"."area_id" = "area_id_p"
1756 AND "membership"."member_id" = "area_delegation"."truster_id"
1757 WHERE "area_delegation"."area_id" = "area_id_p"
1758 AND "area_delegation"."trustee_id" = "member_id_p"
1759 AND "membership"."member_id" ISNULL
1760 LOOP
1761 IF NOT
1762 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1763 THEN
1764 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1765 "area_id_p",
1766 "delegation_row"."truster_id",
1767 "skip_member_ids_p" || "delegation_row"."truster_id"
1768 );
1769 END IF;
1770 END LOOP;
1771 RETURN "sum_v";
1772 END;
1773 $$;
1775 COMMENT ON FUNCTION "membership_weight_with_skipping"
1776 ( "area"."id"%TYPE,
1777 "member"."id"%TYPE,
1778 INT4[] )
1779 IS 'Helper function for "membership_weight" function';
1782 CREATE FUNCTION "membership_weight"
1783 ( "area_id_p" "area"."id"%TYPE,
1784 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1785 RETURNS INT4
1786 LANGUAGE 'plpgsql' STABLE AS $$
1787 BEGIN
1788 RETURN "membership_weight_with_skipping"(
1789 "area_id_p",
1790 "member_id_p",
1791 ARRAY["member_id_p"]
1792 );
1793 END;
1794 $$;
1796 COMMENT ON FUNCTION "membership_weight"
1797 ( "area"."id"%TYPE,
1798 "member"."id"%TYPE )
1799 IS 'Calculates the potential voting weight of a member in a given area';
1802 CREATE VIEW "member_count_view" AS
1803 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1805 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1808 CREATE VIEW "unit_member_count" AS
1809 SELECT
1810 "unit"."id" AS "unit_id",
1811 sum("member"."id") AS "member_count"
1812 FROM "unit"
1813 LEFT JOIN "privilege"
1814 ON "privilege"."unit_id" = "unit"."id"
1815 AND "privilege"."voting_right"
1816 LEFT JOIN "member"
1817 ON "member"."id" = "privilege"."member_id"
1818 AND "member"."active"
1819 GROUP BY "unit"."id";
1821 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1824 CREATE VIEW "area_member_count" AS
1825 SELECT
1826 "area"."id" AS "area_id",
1827 count("member"."id") AS "direct_member_count",
1828 coalesce(
1829 sum(
1830 CASE WHEN "member"."id" NOTNULL THEN
1831 "membership_weight"("area"."id", "member"."id")
1832 ELSE 0 END
1834 ) AS "member_weight",
1835 coalesce(
1836 sum(
1837 CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
1838 "membership_weight"("area"."id", "member"."id")
1839 ELSE 0 END
1841 ) AS "autoreject_weight"
1842 FROM "area"
1843 LEFT JOIN "membership"
1844 ON "area"."id" = "membership"."area_id"
1845 LEFT JOIN "privilege"
1846 ON "privilege"."unit_id" = "area"."unit_id"
1847 AND "privilege"."member_id" = "membership"."member_id"
1848 AND "privilege"."voting_right"
1849 LEFT JOIN "member"
1850 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1851 AND "member"."active"
1852 GROUP BY "area"."id";
1854 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count", "member_weight" and "autoreject_weight" columns of table "area"';
1857 CREATE VIEW "opening_draft" AS
1858 SELECT "draft".* FROM (
1859 SELECT
1860 "initiative"."id" AS "initiative_id",
1861 min("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 "opening_draft" IS 'First drafts of all initiatives';
1871 CREATE VIEW "current_draft" AS
1872 SELECT "draft".* FROM (
1873 SELECT
1874 "initiative"."id" AS "initiative_id",
1875 max("draft"."id") AS "draft_id"
1876 FROM "initiative" JOIN "draft"
1877 ON "initiative"."id" = "draft"."initiative_id"
1878 GROUP BY "initiative"."id"
1879 ) AS "subquery"
1880 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1882 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1885 CREATE VIEW "critical_opinion" AS
1886 SELECT * FROM "opinion"
1887 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1888 OR ("degree" = -2 AND "fulfilled" = TRUE);
1890 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1893 CREATE VIEW "battle_participant" AS
1894 SELECT "initiative"."id", "initiative"."issue_id"
1895 FROM "issue" JOIN "initiative"
1896 ON "issue"."id" = "initiative"."issue_id"
1897 WHERE "initiative"."admitted"
1898 UNION ALL
1899 SELECT NULL, "id" AS "issue_id"
1900 FROM "issue";
1902 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1905 CREATE VIEW "battle_view" AS
1906 SELECT
1907 "issue"."id" AS "issue_id",
1908 "winning_initiative"."id" AS "winning_initiative_id",
1909 "losing_initiative"."id" AS "losing_initiative_id",
1910 sum(
1911 CASE WHEN
1912 coalesce("better_vote"."grade", 0) >
1913 coalesce("worse_vote"."grade", 0)
1914 THEN "direct_voter"."weight" ELSE 0 END
1915 ) AS "count"
1916 FROM "issue"
1917 LEFT JOIN "direct_voter"
1918 ON "issue"."id" = "direct_voter"."issue_id"
1919 JOIN "battle_participant" AS "winning_initiative"
1920 ON "issue"."id" = "winning_initiative"."issue_id"
1921 JOIN "battle_participant" AS "losing_initiative"
1922 ON "issue"."id" = "losing_initiative"."issue_id"
1923 LEFT JOIN "vote" AS "better_vote"
1924 ON "direct_voter"."member_id" = "better_vote"."member_id"
1925 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1926 LEFT JOIN "vote" AS "worse_vote"
1927 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1928 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1929 WHERE "issue"."closed" NOTNULL
1930 AND "issue"."cleaned" ISNULL
1931 AND (
1932 "winning_initiative"."id" != "losing_initiative"."id" OR
1933 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1934 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1935 GROUP BY
1936 "issue"."id",
1937 "winning_initiative"."id",
1938 "losing_initiative"."id";
1940 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';
1943 CREATE VIEW "expired_session" AS
1944 SELECT * FROM "session" WHERE now() > "expiry";
1946 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
1947 DELETE FROM "session" WHERE "ident" = OLD."ident";
1949 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
1950 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
1953 CREATE VIEW "open_issue" AS
1954 SELECT * FROM "issue" WHERE "closed" ISNULL;
1956 COMMENT ON VIEW "open_issue" IS 'All open issues';
1959 CREATE VIEW "issue_with_ranks_missing" AS
1960 SELECT * FROM "issue"
1961 WHERE "fully_frozen" NOTNULL
1962 AND "closed" NOTNULL
1963 AND "ranks_available" = FALSE;
1965 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
1968 CREATE VIEW "member_contingent" AS
1969 SELECT
1970 "member"."id" AS "member_id",
1971 "contingent"."time_frame",
1972 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
1974 SELECT count(1) FROM "draft"
1975 WHERE "draft"."author_id" = "member"."id"
1976 AND "draft"."created" > now() - "contingent"."time_frame"
1977 ) + (
1978 SELECT count(1) FROM "suggestion"
1979 WHERE "suggestion"."author_id" = "member"."id"
1980 AND "suggestion"."created" > now() - "contingent"."time_frame"
1982 ELSE NULL END AS "text_entry_count",
1983 "contingent"."text_entry_limit",
1984 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
1985 SELECT count(1) FROM "opening_draft"
1986 WHERE "opening_draft"."author_id" = "member"."id"
1987 AND "opening_draft"."created" > now() - "contingent"."time_frame"
1988 ) ELSE NULL END AS "initiative_count",
1989 "contingent"."initiative_limit"
1990 FROM "member" CROSS JOIN "contingent";
1992 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
1994 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
1995 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
1998 CREATE VIEW "member_contingent_left" AS
1999 SELECT
2000 "member_id",
2001 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2002 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2003 FROM "member_contingent" GROUP BY "member_id";
2005 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.';
2008 CREATE VIEW "event_seen_by_member" AS
2009 SELECT
2010 "member"."id" AS "seen_by_member_id",
2011 CASE WHEN "event"."state" IN (
2012 'voting',
2013 'finished_without_winner',
2014 'finished_with_winner'
2015 ) THEN
2016 'voting'::"notify_level"
2017 ELSE
2018 CASE WHEN "event"."state" IN (
2019 'verification',
2020 'canceled_after_revocation_during_verification',
2021 'canceled_no_initiative_admitted'
2022 ) THEN
2023 'verification'::"notify_level"
2024 ELSE
2025 CASE WHEN "event"."state" IN (
2026 'discussion',
2027 'canceled_after_revocation_during_discussion'
2028 ) THEN
2029 'discussion'::"notify_level"
2030 ELSE
2031 'all'::"notify_level"
2032 END
2033 END
2034 END AS "notify_level",
2035 "event".*
2036 FROM "member" CROSS JOIN "event"
2037 LEFT JOIN "issue"
2038 ON "event"."issue_id" = "issue"."id"
2039 LEFT JOIN "membership"
2040 ON "member"."id" = "membership"."member_id"
2041 AND "issue"."area_id" = "membership"."area_id"
2042 LEFT JOIN "interest"
2043 ON "member"."id" = "interest"."member_id"
2044 AND "event"."issue_id" = "interest"."issue_id"
2045 LEFT JOIN "supporter"
2046 ON "member"."id" = "supporter"."member_id"
2047 AND "event"."initiative_id" = "supporter"."initiative_id"
2048 LEFT JOIN "ignored_member"
2049 ON "member"."id" = "ignored_member"."member_id"
2050 AND "event"."member_id" = "ignored_member"."other_member_id"
2051 LEFT JOIN "ignored_initiative"
2052 ON "member"."id" = "ignored_initiative"."member_id"
2053 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2054 WHERE (
2055 "supporter"."member_id" NOTNULL OR
2056 "interest"."member_id" NOTNULL OR
2057 ( "membership"."member_id" NOTNULL AND
2058 "event"."event" IN (
2059 'issue_state_changed',
2060 'initiative_created_in_new_issue',
2061 'initiative_created_in_existing_issue',
2062 'initiative_revoked' ) ) )
2063 AND "ignored_member"."member_id" ISNULL
2064 AND "ignored_initiative"."member_id" ISNULL;
2066 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
2069 CREATE VIEW "pending_notification" AS
2070 SELECT
2071 "member"."id" AS "seen_by_member_id",
2072 "event".*
2073 FROM "member" CROSS JOIN "event"
2074 LEFT JOIN "issue"
2075 ON "event"."issue_id" = "issue"."id"
2076 LEFT JOIN "membership"
2077 ON "member"."id" = "membership"."member_id"
2078 AND "issue"."area_id" = "membership"."area_id"
2079 LEFT JOIN "interest"
2080 ON "member"."id" = "interest"."member_id"
2081 AND "event"."issue_id" = "interest"."issue_id"
2082 LEFT JOIN "supporter"
2083 ON "member"."id" = "supporter"."member_id"
2084 AND "event"."initiative_id" = "supporter"."initiative_id"
2085 LEFT JOIN "ignored_member"
2086 ON "member"."id" = "ignored_member"."member_id"
2087 AND "event"."member_id" = "ignored_member"."other_member_id"
2088 LEFT JOIN "ignored_initiative"
2089 ON "member"."id" = "ignored_initiative"."member_id"
2090 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2091 WHERE (
2092 "member"."notify_event_id" ISNULL OR
2093 ( "member"."notify_event_id" NOTNULL AND
2094 "member"."notify_event_id" < "event"."id" ) )
2095 AND (
2096 ( "member"."notify_level" >= 'all' ) OR
2097 ( "member"."notify_level" >= 'voting' AND
2098 "event"."state" IN (
2099 'voting',
2100 'finished_without_winner',
2101 'finished_with_winner' ) ) OR
2102 ( "member"."notify_level" >= 'verification' AND
2103 "event"."state" IN (
2104 'verification',
2105 'canceled_after_revocation_during_verification',
2106 'canceled_no_initiative_admitted' ) ) OR
2107 ( "member"."notify_level" >= 'discussion' AND
2108 "event"."state" IN (
2109 'discussion',
2110 'canceled_after_revocation_during_discussion' ) ) )
2111 AND (
2112 "supporter"."member_id" NOTNULL OR
2113 "interest"."member_id" NOTNULL OR
2114 ( "membership"."member_id" NOTNULL AND
2115 "event"."event" IN (
2116 'issue_state_changed',
2117 'initiative_created_in_new_issue',
2118 'initiative_created_in_existing_issue',
2119 'initiative_revoked' ) ) )
2120 AND "ignored_member"."member_id" ISNULL
2121 AND "ignored_initiative"."member_id" ISNULL;
2123 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
2126 CREATE TYPE "timeline_event" AS ENUM (
2127 'issue_created',
2128 'issue_canceled',
2129 'issue_accepted',
2130 'issue_half_frozen',
2131 'issue_finished_without_voting',
2132 'issue_voting_started',
2133 'issue_finished_after_voting',
2134 'initiative_created',
2135 'initiative_revoked',
2136 'draft_created',
2137 'suggestion_created');
2139 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2142 CREATE VIEW "timeline_issue" AS
2143 SELECT
2144 "created" AS "occurrence",
2145 'issue_created'::"timeline_event" AS "event",
2146 "id" AS "issue_id"
2147 FROM "issue"
2148 UNION ALL
2149 SELECT
2150 "closed" AS "occurrence",
2151 'issue_canceled'::"timeline_event" AS "event",
2152 "id" AS "issue_id"
2153 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2154 UNION ALL
2155 SELECT
2156 "accepted" AS "occurrence",
2157 'issue_accepted'::"timeline_event" AS "event",
2158 "id" AS "issue_id"
2159 FROM "issue" WHERE "accepted" NOTNULL
2160 UNION ALL
2161 SELECT
2162 "half_frozen" AS "occurrence",
2163 'issue_half_frozen'::"timeline_event" AS "event",
2164 "id" AS "issue_id"
2165 FROM "issue" WHERE "half_frozen" NOTNULL
2166 UNION ALL
2167 SELECT
2168 "fully_frozen" AS "occurrence",
2169 'issue_voting_started'::"timeline_event" AS "event",
2170 "id" AS "issue_id"
2171 FROM "issue"
2172 WHERE "fully_frozen" NOTNULL
2173 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2174 UNION ALL
2175 SELECT
2176 "closed" AS "occurrence",
2177 CASE WHEN "fully_frozen" = "closed" THEN
2178 'issue_finished_without_voting'::"timeline_event"
2179 ELSE
2180 'issue_finished_after_voting'::"timeline_event"
2181 END AS "event",
2182 "id" AS "issue_id"
2183 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2185 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2188 CREATE VIEW "timeline_initiative" AS
2189 SELECT
2190 "created" AS "occurrence",
2191 'initiative_created'::"timeline_event" AS "event",
2192 "id" AS "initiative_id"
2193 FROM "initiative"
2194 UNION ALL
2195 SELECT
2196 "revoked" AS "occurrence",
2197 'initiative_revoked'::"timeline_event" AS "event",
2198 "id" AS "initiative_id"
2199 FROM "initiative" WHERE "revoked" NOTNULL;
2201 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2204 CREATE VIEW "timeline_draft" AS
2205 SELECT
2206 "created" AS "occurrence",
2207 'draft_created'::"timeline_event" AS "event",
2208 "id" AS "draft_id"
2209 FROM "draft";
2211 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2214 CREATE VIEW "timeline_suggestion" AS
2215 SELECT
2216 "created" AS "occurrence",
2217 'suggestion_created'::"timeline_event" AS "event",
2218 "id" AS "suggestion_id"
2219 FROM "suggestion";
2221 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2224 CREATE VIEW "timeline" AS
2225 SELECT
2226 "occurrence",
2227 "event",
2228 "issue_id",
2229 NULL AS "initiative_id",
2230 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2231 NULL::INT8 AS "suggestion_id"
2232 FROM "timeline_issue"
2233 UNION ALL
2234 SELECT
2235 "occurrence",
2236 "event",
2237 NULL AS "issue_id",
2238 "initiative_id",
2239 NULL AS "draft_id",
2240 NULL AS "suggestion_id"
2241 FROM "timeline_initiative"
2242 UNION ALL
2243 SELECT
2244 "occurrence",
2245 "event",
2246 NULL AS "issue_id",
2247 NULL AS "initiative_id",
2248 "draft_id",
2249 NULL AS "suggestion_id"
2250 FROM "timeline_draft"
2251 UNION ALL
2252 SELECT
2253 "occurrence",
2254 "event",
2255 NULL AS "issue_id",
2256 NULL AS "initiative_id",
2257 NULL AS "draft_id",
2258 "suggestion_id"
2259 FROM "timeline_suggestion";
2261 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2265 --------------------------------------------------
2266 -- Set returning function for delegation chains --
2267 --------------------------------------------------
2270 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2271 ('first', 'intermediate', 'last', 'repetition');
2273 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2276 CREATE TYPE "delegation_chain_row" AS (
2277 "index" INT4,
2278 "member_id" INT4,
2279 "member_valid" BOOLEAN,
2280 "participation" BOOLEAN,
2281 "overridden" BOOLEAN,
2282 "scope_in" "delegation_scope",
2283 "scope_out" "delegation_scope",
2284 "disabled_out" BOOLEAN,
2285 "loop" "delegation_chain_loop_tag" );
2287 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2289 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2290 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';
2291 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2292 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2293 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2294 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2295 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2298 CREATE FUNCTION "delegation_chain"
2299 ( "member_id_p" "member"."id"%TYPE,
2300 "unit_id_p" "unit"."id"%TYPE,
2301 "area_id_p" "area"."id"%TYPE,
2302 "issue_id_p" "issue"."id"%TYPE,
2303 "simulate_trustee_id_p" "member"."id"%TYPE )
2304 RETURNS SETOF "delegation_chain_row"
2305 LANGUAGE 'plpgsql' STABLE AS $$
2306 DECLARE
2307 "scope_v" "delegation_scope";
2308 "unit_id_v" "unit"."id"%TYPE;
2309 "area_id_v" "area"."id"%TYPE;
2310 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2311 "loop_member_id_v" "member"."id"%TYPE;
2312 "output_row" "delegation_chain_row";
2313 "output_rows" "delegation_chain_row"[];
2314 "delegation_row" "delegation"%ROWTYPE;
2315 "row_count" INT4;
2316 "i" INT4;
2317 "loop_v" BOOLEAN;
2318 BEGIN
2319 IF
2320 "unit_id_p" NOTNULL AND
2321 "area_id_p" ISNULL AND
2322 "issue_id_p" ISNULL
2323 THEN
2324 "scope_v" := 'unit';
2325 "unit_id_v" := "unit_id_p";
2326 ELSIF
2327 "unit_id_p" ISNULL AND
2328 "area_id_p" NOTNULL AND
2329 "issue_id_p" ISNULL
2330 THEN
2331 "scope_v" := 'area';
2332 "area_id_v" := "area_id_p";
2333 SELECT "unit_id" INTO "unit_id_v"
2334 FROM "area" WHERE "id" = "area_id_v";
2335 ELSIF
2336 "unit_id_p" ISNULL AND
2337 "area_id_p" ISNULL AND
2338 "issue_id_p" NOTNULL
2339 THEN
2340 "scope_v" := 'issue';
2341 SELECT "area_id" INTO "area_id_v"
2342 FROM "issue" WHERE "id" = "issue_id_p";
2343 SELECT "unit_id" INTO "unit_id_v"
2344 FROM "area" WHERE "id" = "area_id_v";
2345 ELSE
2346 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2347 END IF;
2348 "visited_member_ids" := '{}';
2349 "loop_member_id_v" := NULL;
2350 "output_rows" := '{}';
2351 "output_row"."index" := 0;
2352 "output_row"."member_id" := "member_id_p";
2353 "output_row"."member_valid" := TRUE;
2354 "output_row"."participation" := FALSE;
2355 "output_row"."overridden" := FALSE;
2356 "output_row"."disabled_out" := FALSE;
2357 "output_row"."scope_out" := NULL;
2358 LOOP
2359 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2360 "loop_member_id_v" := "output_row"."member_id";
2361 ELSE
2362 "visited_member_ids" :=
2363 "visited_member_ids" || "output_row"."member_id";
2364 END IF;
2365 IF "output_row"."participation" THEN
2366 "output_row"."overridden" := TRUE;
2367 END IF;
2368 "output_row"."scope_in" := "output_row"."scope_out";
2369 IF EXISTS (
2370 SELECT NULL FROM "member" JOIN "privilege"
2371 ON "privilege"."member_id" = "member"."id"
2372 AND "privilege"."unit_id" = "unit_id_v"
2373 WHERE "id" = "output_row"."member_id"
2374 AND "member"."active" AND "privilege"."voting_right"
2375 ) THEN
2376 IF "scope_v" = 'unit' THEN
2377 SELECT * INTO "delegation_row" FROM "delegation"
2378 WHERE "truster_id" = "output_row"."member_id"
2379 AND "unit_id" = "unit_id_v";
2380 ELSIF "scope_v" = 'area' THEN
2381 "output_row"."participation" := EXISTS (
2382 SELECT NULL FROM "membership"
2383 WHERE "area_id" = "area_id_p"
2384 AND "member_id" = "output_row"."member_id"
2385 );
2386 SELECT * INTO "delegation_row" FROM "delegation"
2387 WHERE "truster_id" = "output_row"."member_id"
2388 AND (
2389 "unit_id" = "unit_id_v" OR
2390 "area_id" = "area_id_v"
2392 ORDER BY "scope" DESC;
2393 ELSIF "scope_v" = 'issue' THEN
2394 "output_row"."participation" := EXISTS (
2395 SELECT NULL FROM "interest"
2396 WHERE "issue_id" = "issue_id_p"
2397 AND "member_id" = "output_row"."member_id"
2398 );
2399 SELECT * INTO "delegation_row" FROM "delegation"
2400 WHERE "truster_id" = "output_row"."member_id"
2401 AND (
2402 "unit_id" = "unit_id_v" OR
2403 "area_id" = "area_id_v" OR
2404 "issue_id" = "issue_id_p"
2406 ORDER BY "scope" DESC;
2407 END IF;
2408 ELSE
2409 "output_row"."member_valid" := FALSE;
2410 "output_row"."participation" := FALSE;
2411 "output_row"."scope_out" := NULL;
2412 "delegation_row" := ROW(NULL);
2413 END IF;
2414 IF
2415 "output_row"."member_id" = "member_id_p" AND
2416 "simulate_trustee_id_p" NOTNULL
2417 THEN
2418 "output_row"."scope_out" := "scope_v";
2419 "output_rows" := "output_rows" || "output_row";
2420 "output_row"."member_id" := "simulate_trustee_id_p";
2421 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2422 "output_row"."scope_out" := "delegation_row"."scope";
2423 "output_rows" := "output_rows" || "output_row";
2424 "output_row"."member_id" := "delegation_row"."trustee_id";
2425 ELSIF "delegation_row"."scope" NOTNULL THEN
2426 "output_row"."scope_out" := "delegation_row"."scope";
2427 "output_row"."disabled_out" := TRUE;
2428 "output_rows" := "output_rows" || "output_row";
2429 EXIT;
2430 ELSE
2431 "output_row"."scope_out" := NULL;
2432 "output_rows" := "output_rows" || "output_row";
2433 EXIT;
2434 END IF;
2435 EXIT WHEN "loop_member_id_v" NOTNULL;
2436 "output_row"."index" := "output_row"."index" + 1;
2437 END LOOP;
2438 "row_count" := array_upper("output_rows", 1);
2439 "i" := 1;
2440 "loop_v" := FALSE;
2441 LOOP
2442 "output_row" := "output_rows"["i"];
2443 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2444 IF "loop_v" THEN
2445 IF "i" + 1 = "row_count" THEN
2446 "output_row"."loop" := 'last';
2447 ELSIF "i" = "row_count" THEN
2448 "output_row"."loop" := 'repetition';
2449 ELSE
2450 "output_row"."loop" := 'intermediate';
2451 END IF;
2452 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2453 "output_row"."loop" := 'first';
2454 "loop_v" := TRUE;
2455 END IF;
2456 IF "scope_v" = 'unit' THEN
2457 "output_row"."participation" := NULL;
2458 END IF;
2459 RETURN NEXT "output_row";
2460 "i" := "i" + 1;
2461 END LOOP;
2462 RETURN;
2463 END;
2464 $$;
2466 COMMENT ON FUNCTION "delegation_chain"
2467 ( "member"."id"%TYPE,
2468 "unit"."id"%TYPE,
2469 "area"."id"%TYPE,
2470 "issue"."id"%TYPE,
2471 "member"."id"%TYPE )
2472 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2475 CREATE FUNCTION "delegation_chain"
2476 ( "member_id_p" "member"."id"%TYPE,
2477 "unit_id_p" "unit"."id"%TYPE,
2478 "area_id_p" "area"."id"%TYPE,
2479 "issue_id_p" "issue"."id"%TYPE )
2480 RETURNS SETOF "delegation_chain_row"
2481 LANGUAGE 'plpgsql' STABLE AS $$
2482 DECLARE
2483 "result_row" "delegation_chain_row";
2484 BEGIN
2485 FOR "result_row" IN
2486 SELECT * FROM "delegation_chain"(
2487 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2489 LOOP
2490 RETURN NEXT "result_row";
2491 END LOOP;
2492 RETURN;
2493 END;
2494 $$;
2496 COMMENT ON FUNCTION "delegation_chain"
2497 ( "member"."id"%TYPE,
2498 "unit"."id"%TYPE,
2499 "area"."id"%TYPE,
2500 "issue"."id"%TYPE )
2501 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2505 ------------------------------
2506 -- Comparison by vote count --
2507 ------------------------------
2509 CREATE FUNCTION "vote_ratio"
2510 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2511 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2512 RETURNS FLOAT8
2513 LANGUAGE 'plpgsql' STABLE AS $$
2514 BEGIN
2515 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2516 RETURN
2517 "positive_votes_p"::FLOAT8 /
2518 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2519 ELSIF "positive_votes_p" > 0 THEN
2520 RETURN "positive_votes_p";
2521 ELSIF "negative_votes_p" > 0 THEN
2522 RETURN 1 - "negative_votes_p";
2523 ELSE
2524 RETURN 0.5;
2525 END IF;
2526 END;
2527 $$;
2529 COMMENT ON FUNCTION "vote_ratio"
2530 ( "initiative"."positive_votes"%TYPE,
2531 "initiative"."negative_votes"%TYPE )
2532 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.';
2536 ------------------------------------------------
2537 -- Locking for snapshots and voting procedure --
2538 ------------------------------------------------
2541 CREATE FUNCTION "share_row_lock_issue_trigger"()
2542 RETURNS TRIGGER
2543 LANGUAGE 'plpgsql' VOLATILE AS $$
2544 BEGIN
2545 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2546 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2547 END IF;
2548 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2549 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2550 RETURN NEW;
2551 ELSE
2552 RETURN OLD;
2553 END IF;
2554 END;
2555 $$;
2557 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2560 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2561 RETURNS TRIGGER
2562 LANGUAGE 'plpgsql' VOLATILE AS $$
2563 BEGIN
2564 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2565 PERFORM NULL FROM "issue"
2566 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2567 WHERE "initiative"."id" = OLD."initiative_id"
2568 FOR SHARE OF "issue";
2569 END IF;
2570 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2571 PERFORM NULL FROM "issue"
2572 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2573 WHERE "initiative"."id" = NEW."initiative_id"
2574 FOR SHARE OF "issue";
2575 RETURN NEW;
2576 ELSE
2577 RETURN OLD;
2578 END IF;
2579 END;
2580 $$;
2582 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2585 CREATE TRIGGER "share_row_lock_issue"
2586 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2587 FOR EACH ROW EXECUTE PROCEDURE
2588 "share_row_lock_issue_trigger"();
2590 CREATE TRIGGER "share_row_lock_issue"
2591 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2592 FOR EACH ROW EXECUTE PROCEDURE
2593 "share_row_lock_issue_trigger"();
2595 CREATE TRIGGER "share_row_lock_issue"
2596 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2597 FOR EACH ROW EXECUTE PROCEDURE
2598 "share_row_lock_issue_trigger"();
2600 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2601 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2602 FOR EACH ROW EXECUTE PROCEDURE
2603 "share_row_lock_issue_via_initiative_trigger"();
2605 CREATE TRIGGER "share_row_lock_issue"
2606 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2607 FOR EACH ROW EXECUTE PROCEDURE
2608 "share_row_lock_issue_trigger"();
2610 CREATE TRIGGER "share_row_lock_issue"
2611 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2612 FOR EACH ROW EXECUTE PROCEDURE
2613 "share_row_lock_issue_trigger"();
2615 CREATE TRIGGER "share_row_lock_issue"
2616 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2617 FOR EACH ROW EXECUTE PROCEDURE
2618 "share_row_lock_issue_trigger"();
2620 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2621 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2622 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2623 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2624 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2625 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2626 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2629 CREATE FUNCTION "lock_issue"
2630 ( "issue_id_p" "issue"."id"%TYPE )
2631 RETURNS VOID
2632 LANGUAGE 'plpgsql' VOLATILE AS $$
2633 BEGIN
2634 LOCK TABLE "member" IN SHARE MODE;
2635 LOCK TABLE "privilege" IN SHARE MODE;
2636 LOCK TABLE "membership" IN SHARE MODE;
2637 LOCK TABLE "policy" IN SHARE MODE;
2638 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2639 -- NOTE: The row-level exclusive lock in combination with the
2640 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2641 -- acquire a row-level share lock on the issue) ensure that no data
2642 -- is changed, which could affect calculation of snapshots or
2643 -- counting of votes. Table "delegation" must be table-level-locked,
2644 -- as it also contains issue- and global-scope delegations.
2645 LOCK TABLE "delegation" IN SHARE MODE;
2646 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2647 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2648 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2649 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2650 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2651 RETURN;
2652 END;
2653 $$;
2655 COMMENT ON FUNCTION "lock_issue"
2656 ( "issue"."id"%TYPE )
2657 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2661 ------------------------------------------------------------------------
2662 -- Regular tasks, except calculcation of snapshots and voting results --
2663 ------------------------------------------------------------------------
2665 CREATE FUNCTION "check_last_login"()
2666 RETURNS VOID
2667 LANGUAGE 'plpgsql' VOLATILE AS $$
2668 DECLARE
2669 "system_setting_row" "system_setting"%ROWTYPE;
2670 BEGIN
2671 SELECT * INTO "system_setting_row" FROM "system_setting";
2672 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2673 UPDATE "member" SET "last_login_public" = "last_login"::date
2674 FROM (
2675 SELECT DISTINCT "member"."id"
2676 FROM "member" LEFT JOIN "member_history"
2677 ON "member"."id" = "member_history"."member_id"
2678 WHERE "member"."last_login"::date < 'today' OR (
2679 "member_history"."until"::date >= 'today' AND
2680 "member_history"."active" = FALSE AND "member"."active" = TRUE
2682 ) AS "subquery"
2683 WHERE "member"."id" = "subquery"."id";
2684 IF "system_setting_row"."member_ttl" NOTNULL THEN
2685 UPDATE "member" SET "active" = FALSE
2686 WHERE "active" = TRUE
2687 AND "last_login"::date < 'today'
2688 AND "last_login_public" <
2689 (now() - "system_setting_row"."member_ttl")::date;
2690 END IF;
2691 RETURN;
2692 END;
2693 $$;
2695 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).';
2698 CREATE FUNCTION "calculate_member_counts"()
2699 RETURNS VOID
2700 LANGUAGE 'plpgsql' VOLATILE AS $$
2701 BEGIN
2702 LOCK TABLE "member" IN SHARE MODE;
2703 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2704 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2705 LOCK TABLE "area" IN EXCLUSIVE MODE;
2706 LOCK TABLE "privilege" IN SHARE MODE;
2707 LOCK TABLE "membership" IN SHARE MODE;
2708 DELETE FROM "member_count";
2709 INSERT INTO "member_count" ("total_count")
2710 SELECT "total_count" FROM "member_count_view";
2711 UPDATE "unit" SET "member_count" = "view"."member_count"
2712 FROM "unit_member_count" AS "view"
2713 WHERE "view"."unit_id" = "unit"."id";
2714 UPDATE "area" SET
2715 "direct_member_count" = "view"."direct_member_count",
2716 "member_weight" = "view"."member_weight",
2717 "autoreject_weight" = "view"."autoreject_weight"
2718 FROM "area_member_count" AS "view"
2719 WHERE "view"."area_id" = "area"."id";
2720 RETURN;
2721 END;
2722 $$;
2724 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"';
2728 ------------------------------
2729 -- Calculation of snapshots --
2730 ------------------------------
2732 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2733 ( "issue_id_p" "issue"."id"%TYPE,
2734 "member_id_p" "member"."id"%TYPE,
2735 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2736 RETURNS "direct_population_snapshot"."weight"%TYPE
2737 LANGUAGE 'plpgsql' VOLATILE AS $$
2738 DECLARE
2739 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2740 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2741 "weight_v" INT4;
2742 "sub_weight_v" INT4;
2743 BEGIN
2744 "weight_v" := 0;
2745 FOR "issue_delegation_row" IN
2746 SELECT * FROM "issue_delegation"
2747 WHERE "trustee_id" = "member_id_p"
2748 AND "issue_id" = "issue_id_p"
2749 LOOP
2750 IF NOT EXISTS (
2751 SELECT NULL FROM "direct_population_snapshot"
2752 WHERE "issue_id" = "issue_id_p"
2753 AND "event" = 'periodic'
2754 AND "member_id" = "issue_delegation_row"."truster_id"
2755 ) AND NOT EXISTS (
2756 SELECT NULL FROM "delegating_population_snapshot"
2757 WHERE "issue_id" = "issue_id_p"
2758 AND "event" = 'periodic'
2759 AND "member_id" = "issue_delegation_row"."truster_id"
2760 ) THEN
2761 "delegate_member_ids_v" :=
2762 "member_id_p" || "delegate_member_ids_p";
2763 INSERT INTO "delegating_population_snapshot" (
2764 "issue_id",
2765 "event",
2766 "member_id",
2767 "scope",
2768 "delegate_member_ids"
2769 ) VALUES (
2770 "issue_id_p",
2771 'periodic',
2772 "issue_delegation_row"."truster_id",
2773 "issue_delegation_row"."scope",
2774 "delegate_member_ids_v"
2775 );
2776 "sub_weight_v" := 1 +
2777 "weight_of_added_delegations_for_population_snapshot"(
2778 "issue_id_p",
2779 "issue_delegation_row"."truster_id",
2780 "delegate_member_ids_v"
2781 );
2782 UPDATE "delegating_population_snapshot"
2783 SET "weight" = "sub_weight_v"
2784 WHERE "issue_id" = "issue_id_p"
2785 AND "event" = 'periodic'
2786 AND "member_id" = "issue_delegation_row"."truster_id";
2787 "weight_v" := "weight_v" + "sub_weight_v";
2788 END IF;
2789 END LOOP;
2790 RETURN "weight_v";
2791 END;
2792 $$;
2794 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2795 ( "issue"."id"%TYPE,
2796 "member"."id"%TYPE,
2797 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2798 IS 'Helper function for "create_population_snapshot" function';
2801 CREATE FUNCTION "create_population_snapshot"
2802 ( "issue_id_p" "issue"."id"%TYPE )
2803 RETURNS VOID
2804 LANGUAGE 'plpgsql' VOLATILE AS $$
2805 DECLARE
2806 "member_id_v" "member"."id"%TYPE;
2807 BEGIN
2808 DELETE FROM "direct_population_snapshot"
2809 WHERE "issue_id" = "issue_id_p"
2810 AND "event" = 'periodic';
2811 DELETE FROM "delegating_population_snapshot"
2812 WHERE "issue_id" = "issue_id_p"
2813 AND "event" = 'periodic';
2814 INSERT INTO "direct_population_snapshot"
2815 ("issue_id", "event", "member_id")
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 "membership" ON "area"."id" = "membership"."area_id"
2823 JOIN "member" ON "membership"."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 UNION
2830 SELECT
2831 "issue_id_p" AS "issue_id",
2832 'periodic'::"snapshot_event" AS "event",
2833 "member"."id" AS "member_id"
2834 FROM "issue"
2835 JOIN "area" ON "issue"."area_id" = "area"."id"
2836 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2837 JOIN "member" ON "interest"."member_id" = "member"."id"
2838 JOIN "privilege"
2839 ON "privilege"."unit_id" = "area"."unit_id"
2840 AND "privilege"."member_id" = "member"."id"
2841 WHERE "issue"."id" = "issue_id_p"
2842 AND "member"."active" AND "privilege"."voting_right";
2843 FOR "member_id_v" IN
2844 SELECT "member_id" FROM "direct_population_snapshot"
2845 WHERE "issue_id" = "issue_id_p"
2846 AND "event" = 'periodic'
2847 LOOP
2848 UPDATE "direct_population_snapshot" SET
2849 "weight" = 1 +
2850 "weight_of_added_delegations_for_population_snapshot"(
2851 "issue_id_p",
2852 "member_id_v",
2853 '{}'
2855 WHERE "issue_id" = "issue_id_p"
2856 AND "event" = 'periodic'
2857 AND "member_id" = "member_id_v";
2858 END LOOP;
2859 RETURN;
2860 END;
2861 $$;
2863 COMMENT ON FUNCTION "create_population_snapshot"
2864 ( "issue"."id"%TYPE )
2865 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.';
2868 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2869 ( "issue_id_p" "issue"."id"%TYPE,
2870 "member_id_p" "member"."id"%TYPE,
2871 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2872 RETURNS "direct_interest_snapshot"."weight"%TYPE
2873 LANGUAGE 'plpgsql' VOLATILE AS $$
2874 DECLARE
2875 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2876 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2877 "weight_v" INT4;
2878 "sub_weight_v" INT4;
2879 BEGIN
2880 "weight_v" := 0;
2881 FOR "issue_delegation_row" IN
2882 SELECT * FROM "issue_delegation"
2883 WHERE "trustee_id" = "member_id_p"
2884 AND "issue_id" = "issue_id_p"
2885 LOOP
2886 IF NOT EXISTS (
2887 SELECT NULL FROM "direct_interest_snapshot"
2888 WHERE "issue_id" = "issue_id_p"
2889 AND "event" = 'periodic'
2890 AND "member_id" = "issue_delegation_row"."truster_id"
2891 ) AND NOT EXISTS (
2892 SELECT NULL FROM "delegating_interest_snapshot"
2893 WHERE "issue_id" = "issue_id_p"
2894 AND "event" = 'periodic'
2895 AND "member_id" = "issue_delegation_row"."truster_id"
2896 ) THEN
2897 "delegate_member_ids_v" :=
2898 "member_id_p" || "delegate_member_ids_p";
2899 INSERT INTO "delegating_interest_snapshot" (
2900 "issue_id",
2901 "event",
2902 "member_id",
2903 "scope",
2904 "delegate_member_ids"
2905 ) VALUES (
2906 "issue_id_p",
2907 'periodic',
2908 "issue_delegation_row"."truster_id",
2909 "issue_delegation_row"."scope",
2910 "delegate_member_ids_v"
2911 );
2912 "sub_weight_v" := 1 +
2913 "weight_of_added_delegations_for_interest_snapshot"(
2914 "issue_id_p",
2915 "issue_delegation_row"."truster_id",
2916 "delegate_member_ids_v"
2917 );
2918 UPDATE "delegating_interest_snapshot"
2919 SET "weight" = "sub_weight_v"
2920 WHERE "issue_id" = "issue_id_p"
2921 AND "event" = 'periodic'
2922 AND "member_id" = "issue_delegation_row"."truster_id";
2923 "weight_v" := "weight_v" + "sub_weight_v";
2924 END IF;
2925 END LOOP;
2926 RETURN "weight_v";
2927 END;
2928 $$;
2930 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2931 ( "issue"."id"%TYPE,
2932 "member"."id"%TYPE,
2933 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2934 IS 'Helper function for "create_interest_snapshot" function';
2937 CREATE FUNCTION "create_interest_snapshot"
2938 ( "issue_id_p" "issue"."id"%TYPE )
2939 RETURNS VOID
2940 LANGUAGE 'plpgsql' VOLATILE AS $$
2941 DECLARE
2942 "member_id_v" "member"."id"%TYPE;
2943 BEGIN
2944 DELETE FROM "direct_interest_snapshot"
2945 WHERE "issue_id" = "issue_id_p"
2946 AND "event" = 'periodic';
2947 DELETE FROM "delegating_interest_snapshot"
2948 WHERE "issue_id" = "issue_id_p"
2949 AND "event" = 'periodic';
2950 DELETE FROM "direct_supporter_snapshot"
2951 WHERE "issue_id" = "issue_id_p"
2952 AND "event" = 'periodic';
2953 INSERT INTO "direct_interest_snapshot"
2954 ("issue_id", "event", "member_id", "voting_requested")
2955 SELECT
2956 "issue_id_p" AS "issue_id",
2957 'periodic' AS "event",
2958 "member"."id" AS "member_id",
2959 "interest"."voting_requested"
2960 FROM "issue"
2961 JOIN "area" ON "issue"."area_id" = "area"."id"
2962 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2963 JOIN "member" ON "interest"."member_id" = "member"."id"
2964 JOIN "privilege"
2965 ON "privilege"."unit_id" = "area"."unit_id"
2966 AND "privilege"."member_id" = "member"."id"
2967 WHERE "issue"."id" = "issue_id_p"
2968 AND "member"."active" AND "privilege"."voting_right";
2969 FOR "member_id_v" IN
2970 SELECT "member_id" FROM "direct_interest_snapshot"
2971 WHERE "issue_id" = "issue_id_p"
2972 AND "event" = 'periodic'
2973 LOOP
2974 UPDATE "direct_interest_snapshot" SET
2975 "weight" = 1 +
2976 "weight_of_added_delegations_for_interest_snapshot"(
2977 "issue_id_p",
2978 "member_id_v",
2979 '{}'
2981 WHERE "issue_id" = "issue_id_p"
2982 AND "event" = 'periodic'
2983 AND "member_id" = "member_id_v";
2984 END LOOP;
2985 INSERT INTO "direct_supporter_snapshot"
2986 ( "issue_id", "initiative_id", "event", "member_id",
2987 "informed", "satisfied" )
2988 SELECT
2989 "issue_id_p" AS "issue_id",
2990 "initiative"."id" AS "initiative_id",
2991 'periodic' AS "event",
2992 "supporter"."member_id" AS "member_id",
2993 "supporter"."draft_id" = "current_draft"."id" AS "informed",
2994 NOT EXISTS (
2995 SELECT NULL FROM "critical_opinion"
2996 WHERE "initiative_id" = "initiative"."id"
2997 AND "member_id" = "supporter"."member_id"
2998 ) AS "satisfied"
2999 FROM "initiative"
3000 JOIN "supporter"
3001 ON "supporter"."initiative_id" = "initiative"."id"
3002 JOIN "current_draft"
3003 ON "initiative"."id" = "current_draft"."initiative_id"
3004 JOIN "direct_interest_snapshot"
3005 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3006 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3007 AND "event" = 'periodic'
3008 WHERE "initiative"."issue_id" = "issue_id_p";
3009 RETURN;
3010 END;
3011 $$;
3013 COMMENT ON FUNCTION "create_interest_snapshot"
3014 ( "issue"."id"%TYPE )
3015 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.';
3018 CREATE FUNCTION "create_snapshot"
3019 ( "issue_id_p" "issue"."id"%TYPE )
3020 RETURNS VOID
3021 LANGUAGE 'plpgsql' VOLATILE AS $$
3022 DECLARE
3023 "initiative_id_v" "initiative"."id"%TYPE;
3024 "suggestion_id_v" "suggestion"."id"%TYPE;
3025 BEGIN
3026 PERFORM "lock_issue"("issue_id_p");
3027 PERFORM "create_population_snapshot"("issue_id_p");
3028 PERFORM "create_interest_snapshot"("issue_id_p");
3029 UPDATE "issue" SET
3030 "snapshot" = now(),
3031 "latest_snapshot_event" = 'periodic',
3032 "population" = (
3033 SELECT coalesce(sum("weight"), 0)
3034 FROM "direct_population_snapshot"
3035 WHERE "issue_id" = "issue_id_p"
3036 AND "event" = 'periodic'
3037 ),
3038 "vote_now" = (
3039 SELECT coalesce(sum("weight"), 0)
3040 FROM "direct_interest_snapshot"
3041 WHERE "issue_id" = "issue_id_p"
3042 AND "event" = 'periodic'
3043 AND "voting_requested" = TRUE
3044 ),
3045 "vote_later" = (
3046 SELECT coalesce(sum("weight"), 0)
3047 FROM "direct_interest_snapshot"
3048 WHERE "issue_id" = "issue_id_p"
3049 AND "event" = 'periodic'
3050 AND "voting_requested" = FALSE
3052 WHERE "id" = "issue_id_p";
3053 FOR "initiative_id_v" IN
3054 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3055 LOOP
3056 UPDATE "initiative" SET
3057 "supporter_count" = (
3058 SELECT coalesce(sum("di"."weight"), 0)
3059 FROM "direct_interest_snapshot" AS "di"
3060 JOIN "direct_supporter_snapshot" AS "ds"
3061 ON "di"."member_id" = "ds"."member_id"
3062 WHERE "di"."issue_id" = "issue_id_p"
3063 AND "di"."event" = 'periodic'
3064 AND "ds"."initiative_id" = "initiative_id_v"
3065 AND "ds"."event" = 'periodic'
3066 ),
3067 "informed_supporter_count" = (
3068 SELECT coalesce(sum("di"."weight"), 0)
3069 FROM "direct_interest_snapshot" AS "di"
3070 JOIN "direct_supporter_snapshot" AS "ds"
3071 ON "di"."member_id" = "ds"."member_id"
3072 WHERE "di"."issue_id" = "issue_id_p"
3073 AND "di"."event" = 'periodic'
3074 AND "ds"."initiative_id" = "initiative_id_v"
3075 AND "ds"."event" = 'periodic'
3076 AND "ds"."informed"
3077 ),
3078 "satisfied_supporter_count" = (
3079 SELECT coalesce(sum("di"."weight"), 0)
3080 FROM "direct_interest_snapshot" AS "di"
3081 JOIN "direct_supporter_snapshot" AS "ds"
3082 ON "di"."member_id" = "ds"."member_id"
3083 WHERE "di"."issue_id" = "issue_id_p"
3084 AND "di"."event" = 'periodic'
3085 AND "ds"."initiative_id" = "initiative_id_v"
3086 AND "ds"."event" = 'periodic'
3087 AND "ds"."satisfied"
3088 ),
3089 "satisfied_informed_supporter_count" = (
3090 SELECT coalesce(sum("di"."weight"), 0)
3091 FROM "direct_interest_snapshot" AS "di"
3092 JOIN "direct_supporter_snapshot" AS "ds"
3093 ON "di"."member_id" = "ds"."member_id"
3094 WHERE "di"."issue_id" = "issue_id_p"
3095 AND "di"."event" = 'periodic'
3096 AND "ds"."initiative_id" = "initiative_id_v"
3097 AND "ds"."event" = 'periodic'
3098 AND "ds"."informed"
3099 AND "ds"."satisfied"
3101 WHERE "id" = "initiative_id_v";
3102 FOR "suggestion_id_v" IN
3103 SELECT "id" FROM "suggestion"
3104 WHERE "initiative_id" = "initiative_id_v"
3105 LOOP
3106 UPDATE "suggestion" SET
3107 "minus2_unfulfilled_count" = (
3108 SELECT coalesce(sum("snapshot"."weight"), 0)
3109 FROM "issue" CROSS JOIN "opinion"
3110 JOIN "direct_interest_snapshot" AS "snapshot"
3111 ON "snapshot"."issue_id" = "issue"."id"
3112 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3113 AND "snapshot"."member_id" = "opinion"."member_id"
3114 WHERE "issue"."id" = "issue_id_p"
3115 AND "opinion"."suggestion_id" = "suggestion_id_v"
3116 AND "opinion"."degree" = -2
3117 AND "opinion"."fulfilled" = FALSE
3118 ),
3119 "minus2_fulfilled_count" = (
3120 SELECT coalesce(sum("snapshot"."weight"), 0)
3121 FROM "issue" CROSS JOIN "opinion"
3122 JOIN "direct_interest_snapshot" AS "snapshot"
3123 ON "snapshot"."issue_id" = "issue"."id"
3124 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3125 AND "snapshot"."member_id" = "opinion"."member_id"
3126 WHERE "issue"."id" = "issue_id_p"
3127 AND "opinion"."suggestion_id" = "suggestion_id_v"
3128 AND "opinion"."degree" = -2
3129 AND "opinion"."fulfilled" = TRUE
3130 ),
3131 "minus1_unfulfilled_count" = (
3132 SELECT coalesce(sum("snapshot"."weight"), 0)
3133 FROM "issue" CROSS JOIN "opinion"
3134 JOIN "direct_interest_snapshot" AS "snapshot"
3135 ON "snapshot"."issue_id" = "issue"."id"
3136 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3137 AND "snapshot"."member_id" = "opinion"."member_id"
3138 WHERE "issue"."id" = "issue_id_p"
3139 AND "opinion"."suggestion_id" = "suggestion_id_v"
3140 AND "opinion"."degree" = -1
3141 AND "opinion"."fulfilled" = FALSE
3142 ),
3143 "minus1_fulfilled_count" = (
3144 SELECT coalesce(sum("snapshot"."weight"), 0)
3145 FROM "issue" CROSS JOIN "opinion"
3146 JOIN "direct_interest_snapshot" AS "snapshot"
3147 ON "snapshot"."issue_id" = "issue"."id"
3148 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3149 AND "snapshot"."member_id" = "opinion"."member_id"
3150 WHERE "issue"."id" = "issue_id_p"
3151 AND "opinion"."suggestion_id" = "suggestion_id_v"
3152 AND "opinion"."degree" = -1
3153 AND "opinion"."fulfilled" = TRUE
3154 ),
3155 "plus1_unfulfilled_count" = (
3156 SELECT coalesce(sum("snapshot"."weight"), 0)
3157 FROM "issue" CROSS JOIN "opinion"
3158 JOIN "direct_interest_snapshot" AS "snapshot"
3159 ON "snapshot"."issue_id" = "issue"."id"
3160 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3161 AND "snapshot"."member_id" = "opinion"."member_id"
3162 WHERE "issue"."id" = "issue_id_p"
3163 AND "opinion"."suggestion_id" = "suggestion_id_v"
3164 AND "opinion"."degree" = 1
3165 AND "opinion"."fulfilled" = FALSE
3166 ),
3167 "plus1_fulfilled_count" = (
3168 SELECT coalesce(sum("snapshot"."weight"), 0)
3169 FROM "issue" CROSS JOIN "opinion"
3170 JOIN "direct_interest_snapshot" AS "snapshot"
3171 ON "snapshot"."issue_id" = "issue"."id"
3172 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3173 AND "snapshot"."member_id" = "opinion"."member_id"
3174 WHERE "issue"."id" = "issue_id_p"
3175 AND "opinion"."suggestion_id" = "suggestion_id_v"
3176 AND "opinion"."degree" = 1
3177 AND "opinion"."fulfilled" = TRUE
3178 ),
3179 "plus2_unfulfilled_count" = (
3180 SELECT coalesce(sum("snapshot"."weight"), 0)
3181 FROM "issue" CROSS JOIN "opinion"
3182 JOIN "direct_interest_snapshot" AS "snapshot"
3183 ON "snapshot"."issue_id" = "issue"."id"
3184 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3185 AND "snapshot"."member_id" = "opinion"."member_id"
3186 WHERE "issue"."id" = "issue_id_p"
3187 AND "opinion"."suggestion_id" = "suggestion_id_v"
3188 AND "opinion"."degree" = 2
3189 AND "opinion"."fulfilled" = FALSE
3190 ),
3191 "plus2_fulfilled_count" = (
3192 SELECT coalesce(sum("snapshot"."weight"), 0)
3193 FROM "issue" CROSS JOIN "opinion"
3194 JOIN "direct_interest_snapshot" AS "snapshot"
3195 ON "snapshot"."issue_id" = "issue"."id"
3196 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3197 AND "snapshot"."member_id" = "opinion"."member_id"
3198 WHERE "issue"."id" = "issue_id_p"
3199 AND "opinion"."suggestion_id" = "suggestion_id_v"
3200 AND "opinion"."degree" = 2
3201 AND "opinion"."fulfilled" = TRUE
3203 WHERE "suggestion"."id" = "suggestion_id_v";
3204 END LOOP;
3205 END LOOP;
3206 RETURN;
3207 END;
3208 $$;
3210 COMMENT ON FUNCTION "create_snapshot"
3211 ( "issue"."id"%TYPE )
3212 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.';
3215 CREATE FUNCTION "set_snapshot_event"
3216 ( "issue_id_p" "issue"."id"%TYPE,
3217 "event_p" "snapshot_event" )
3218 RETURNS VOID
3219 LANGUAGE 'plpgsql' VOLATILE AS $$
3220 DECLARE
3221 "event_v" "issue"."latest_snapshot_event"%TYPE;
3222 BEGIN
3223 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3224 WHERE "id" = "issue_id_p" FOR UPDATE;
3225 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3226 WHERE "id" = "issue_id_p";
3227 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3228 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3229 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3230 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3231 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3232 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3233 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3234 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3235 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3236 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3237 RETURN;
3238 END;
3239 $$;
3241 COMMENT ON FUNCTION "set_snapshot_event"
3242 ( "issue"."id"%TYPE,
3243 "snapshot_event" )
3244 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3248 ---------------------
3249 -- Freezing issues --
3250 ---------------------
3252 CREATE FUNCTION "freeze_after_snapshot"
3253 ( "issue_id_p" "issue"."id"%TYPE )
3254 RETURNS VOID
3255 LANGUAGE 'plpgsql' VOLATILE AS $$
3256 DECLARE
3257 "issue_row" "issue"%ROWTYPE;
3258 "policy_row" "policy"%ROWTYPE;
3259 "initiative_row" "initiative"%ROWTYPE;
3260 BEGIN
3261 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3262 SELECT * INTO "policy_row"
3263 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3264 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3265 FOR "initiative_row" IN
3266 SELECT * FROM "initiative"
3267 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3268 LOOP
3269 IF
3270 "initiative_row"."satisfied_supporter_count" > 0 AND
3271 "initiative_row"."satisfied_supporter_count" *
3272 "policy_row"."initiative_quorum_den" >=
3273 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3274 THEN
3275 UPDATE "initiative" SET "admitted" = TRUE
3276 WHERE "id" = "initiative_row"."id";
3277 ELSE
3278 UPDATE "initiative" SET "admitted" = FALSE
3279 WHERE "id" = "initiative_row"."id";
3280 END IF;
3281 END LOOP;
3282 IF EXISTS (
3283 SELECT NULL FROM "initiative"
3284 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3285 ) THEN
3286 UPDATE "issue" SET
3287 "state" = 'voting',
3288 "accepted" = coalesce("accepted", now()),
3289 "half_frozen" = coalesce("half_frozen", now()),
3290 "fully_frozen" = now()
3291 WHERE "id" = "issue_id_p";
3292 ELSE
3293 UPDATE "issue" SET
3294 "state" = 'canceled_no_initiative_admitted',
3295 "accepted" = coalesce("accepted", now()),
3296 "half_frozen" = coalesce("half_frozen", now()),
3297 "fully_frozen" = now(),
3298 "closed" = now(),
3299 "ranks_available" = TRUE
3300 WHERE "id" = "issue_id_p";
3301 -- NOTE: The following DELETE statements have effect only when
3302 -- issue state has been manipulated
3303 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3304 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3305 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3306 END IF;
3307 RETURN;
3308 END;
3309 $$;
3311 COMMENT ON FUNCTION "freeze_after_snapshot"
3312 ( "issue"."id"%TYPE )
3313 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3316 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3317 RETURNS VOID
3318 LANGUAGE 'plpgsql' VOLATILE AS $$
3319 DECLARE
3320 "issue_row" "issue"%ROWTYPE;
3321 BEGIN
3322 PERFORM "create_snapshot"("issue_id_p");
3323 PERFORM "freeze_after_snapshot"("issue_id_p");
3324 RETURN;
3325 END;
3326 $$;
3328 COMMENT ON FUNCTION "manual_freeze"
3329 ( "issue"."id"%TYPE )
3330 IS 'Freeze an issue manually (fully) and start voting';
3334 -----------------------
3335 -- Counting of votes --
3336 -----------------------
3339 CREATE FUNCTION "weight_of_added_vote_delegations"
3340 ( "issue_id_p" "issue"."id"%TYPE,
3341 "member_id_p" "member"."id"%TYPE,
3342 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3343 RETURNS "direct_voter"."weight"%TYPE
3344 LANGUAGE 'plpgsql' VOLATILE AS $$
3345 DECLARE
3346 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3347 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3348 "weight_v" INT4;
3349 "sub_weight_v" INT4;
3350 BEGIN
3351 "weight_v" := 0;
3352 FOR "issue_delegation_row" IN
3353 SELECT * FROM "issue_delegation"
3354 WHERE "trustee_id" = "member_id_p"
3355 AND "issue_id" = "issue_id_p"
3356 LOOP
3357 IF NOT EXISTS (
3358 SELECT NULL FROM "direct_voter"
3359 WHERE "member_id" = "issue_delegation_row"."truster_id"
3360 AND "issue_id" = "issue_id_p"
3361 ) AND NOT EXISTS (
3362 SELECT NULL FROM "delegating_voter"
3363 WHERE "member_id" = "issue_delegation_row"."truster_id"
3364 AND "issue_id" = "issue_id_p"
3365 ) THEN
3366 "delegate_member_ids_v" :=
3367 "member_id_p" || "delegate_member_ids_p";
3368 INSERT INTO "delegating_voter" (
3369 "issue_id",
3370 "member_id",
3371 "scope",
3372 "delegate_member_ids"
3373 ) VALUES (
3374 "issue_id_p",
3375 "issue_delegation_row"."truster_id",
3376 "issue_delegation_row"."scope",
3377 "delegate_member_ids_v"
3378 );
3379 "sub_weight_v" := 1 +
3380 "weight_of_added_vote_delegations"(
3381 "issue_id_p",
3382 "issue_delegation_row"."truster_id",
3383 "delegate_member_ids_v"
3384 );
3385 UPDATE "delegating_voter"
3386 SET "weight" = "sub_weight_v"
3387 WHERE "issue_id" = "issue_id_p"
3388 AND "member_id" = "issue_delegation_row"."truster_id";
3389 "weight_v" := "weight_v" + "sub_weight_v";
3390 END IF;
3391 END LOOP;
3392 RETURN "weight_v";
3393 END;
3394 $$;
3396 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3397 ( "issue"."id"%TYPE,
3398 "member"."id"%TYPE,
3399 "delegating_voter"."delegate_member_ids"%TYPE )
3400 IS 'Helper function for "add_vote_delegations" function';
3403 CREATE FUNCTION "add_vote_delegations"
3404 ( "issue_id_p" "issue"."id"%TYPE )
3405 RETURNS VOID
3406 LANGUAGE 'plpgsql' VOLATILE AS $$
3407 DECLARE
3408 "member_id_v" "member"."id"%TYPE;
3409 BEGIN
3410 FOR "member_id_v" IN
3411 SELECT "member_id" FROM "direct_voter"
3412 WHERE "issue_id" = "issue_id_p"
3413 LOOP
3414 UPDATE "direct_voter" SET
3415 "weight" = "weight" + "weight_of_added_vote_delegations"(
3416 "issue_id_p",
3417 "member_id_v",
3418 '{}'
3420 WHERE "member_id" = "member_id_v"
3421 AND "issue_id" = "issue_id_p";
3422 END LOOP;
3423 RETURN;
3424 END;
3425 $$;
3427 COMMENT ON FUNCTION "add_vote_delegations"
3428 ( "issue_id_p" "issue"."id"%TYPE )
3429 IS 'Helper function for "close_voting" function';
3432 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3433 RETURNS VOID
3434 LANGUAGE 'plpgsql' VOLATILE AS $$
3435 DECLARE
3436 "area_id_v" "area"."id"%TYPE;
3437 "unit_id_v" "unit"."id"%TYPE;
3438 "member_id_v" "member"."id"%TYPE;
3439 BEGIN
3440 PERFORM "lock_issue"("issue_id_p");
3441 SELECT "id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3442 SELECT "id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3443 DELETE FROM "delegating_voter"
3444 WHERE "issue_id" = "issue_id_p";
3445 DELETE FROM "direct_voter"
3446 WHERE "issue_id" = "issue_id_p"
3447 AND "autoreject" = TRUE;
3448 DELETE FROM "direct_voter"
3449 USING (
3450 SELECT
3451 "direct_voter"."member_id"
3452 FROM "direct_voter"
3453 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3454 LEFT JOIN "privilege"
3455 ON "privilege"."unit_id" = "unit_id_v"
3456 AND "privilege"."member_id" = "direct_voter"."member_id"
3457 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3458 "member"."active" = FALSE OR
3459 "privilege"."voting_right" ISNULL OR
3460 "privilege"."voting_right" = FALSE
3462 ) AS "subquery"
3463 WHERE "direct_voter"."issue_id" = "issue_id_p"
3464 AND "direct_voter"."member_id" = "subquery"."member_id";
3465 UPDATE "direct_voter" SET "weight" = 1
3466 WHERE "issue_id" = "issue_id_p";
3467 PERFORM "add_vote_delegations"("issue_id_p");
3468 FOR "member_id_v" IN
3469 SELECT "interest"."member_id"
3470 FROM "interest"
3471 JOIN "member"
3472 ON "interest"."member_id" = "member"."id"
3473 LEFT JOIN "direct_voter"
3474 ON "interest"."member_id" = "direct_voter"."member_id"
3475 AND "interest"."issue_id" = "direct_voter"."issue_id"
3476 LEFT JOIN "delegating_voter"
3477 ON "interest"."member_id" = "delegating_voter"."member_id"
3478 AND "interest"."issue_id" = "delegating_voter"."issue_id"
3479 WHERE "interest"."issue_id" = "issue_id_p"
3480 AND "interest"."autoreject" = TRUE
3481 AND "member"."active"
3482 AND "direct_voter"."member_id" ISNULL
3483 AND "delegating_voter"."member_id" ISNULL
3484 UNION SELECT "membership"."member_id"
3485 FROM "membership"
3486 JOIN "member"
3487 ON "membership"."member_id" = "member"."id"
3488 LEFT JOIN "interest"
3489 ON "membership"."member_id" = "interest"."member_id"
3490 AND "interest"."issue_id" = "issue_id_p"
3491 LEFT JOIN "direct_voter"
3492 ON "membership"."member_id" = "direct_voter"."member_id"
3493 AND "direct_voter"."issue_id" = "issue_id_p"
3494 LEFT JOIN "delegating_voter"
3495 ON "membership"."member_id" = "delegating_voter"."member_id"
3496 AND "delegating_voter"."issue_id" = "issue_id_p"
3497 WHERE "membership"."area_id" = "area_id_v"
3498 AND "membership"."autoreject" = TRUE
3499 AND "member"."active"
3500 AND "interest"."autoreject" ISNULL
3501 AND "direct_voter"."member_id" ISNULL
3502 AND "delegating_voter"."member_id" ISNULL
3503 LOOP
3504 INSERT INTO "direct_voter"
3505 ("member_id", "issue_id", "weight", "autoreject") VALUES
3506 ("member_id_v", "issue_id_p", 1, TRUE);
3507 INSERT INTO "vote" (
3508 "member_id",
3509 "issue_id",
3510 "initiative_id",
3511 "grade"
3512 ) SELECT
3513 "member_id_v" AS "member_id",
3514 "issue_id_p" AS "issue_id",
3515 "id" AS "initiative_id",
3516 -1 AS "grade"
3517 FROM "initiative" WHERE "issue_id" = "issue_id_p";
3518 END LOOP;
3519 PERFORM "add_vote_delegations"("issue_id_p");
3520 UPDATE "issue" SET
3521 "state" = 'calculation',
3522 "closed" = now(),
3523 "voter_count" = (
3524 SELECT coalesce(sum("weight"), 0)
3525 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3527 WHERE "id" = "issue_id_p";
3528 UPDATE "initiative" SET
3529 "positive_votes" = "vote_counts"."positive_votes",
3530 "negative_votes" = "vote_counts"."negative_votes",
3531 "attainable" = CASE WHEN "majority_strict" THEN
3532 "vote_counts"."positive_votes" * "majority_den" >
3533 "majority_num" *
3534 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
3535 ELSE
3536 "vote_counts"."positive_votes" * "majority_den" >=
3537 "majority_num" *
3538 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
3539 END
3540 FROM
3541 ( SELECT
3542 "initiative"."id" AS "initiative_id",
3543 coalesce(
3544 sum(
3545 CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
3546 ),
3548 ) AS "positive_votes",
3549 coalesce(
3550 sum(
3551 CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
3552 ),
3554 ) AS "negative_votes"
3555 FROM "initiative"
3556 JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
3557 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3558 LEFT JOIN "direct_voter"
3559 ON "direct_voter"."issue_id" = "initiative"."issue_id"
3560 LEFT JOIN "vote"
3561 ON "vote"."initiative_id" = "initiative"."id"
3562 AND "vote"."member_id" = "direct_voter"."member_id"
3563 WHERE "initiative"."issue_id" = "issue_id_p"
3564 AND "initiative"."admitted" -- NOTE: NULL case is handled too
3565 GROUP BY "initiative"."id"
3566 ) AS "vote_counts",
3567 "issue",
3568 "policy"
3569 WHERE "vote_counts"."initiative_id" = "initiative"."id"
3570 AND "issue"."id" = "initiative"."issue_id"
3571 AND "policy"."id" = "issue"."policy_id";
3572 -- NOTE: "closed" column of issue must be set at this point
3573 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3574 INSERT INTO "battle" (
3575 "issue_id",
3576 "winning_initiative_id", "losing_initiative_id",
3577 "count"
3578 ) SELECT
3579 "issue_id",
3580 "winning_initiative_id", "losing_initiative_id",
3581 "count"
3582 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3583 END;
3584 $$;
3586 COMMENT ON FUNCTION "close_voting"
3587 ( "issue"."id"%TYPE )
3588 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.';
3591 CREATE FUNCTION "defeat_strength"
3592 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3593 RETURNS INT8
3594 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3595 BEGIN
3596 IF "positive_votes_p" > "negative_votes_p" THEN
3597 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3598 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3599 RETURN 0;
3600 ELSE
3601 RETURN -1;
3602 END IF;
3603 END;
3604 $$;
3606 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';
3609 CREATE FUNCTION "array_init_string"("dim_p" INTEGER)
3610 RETURNS TEXT
3611 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3612 DECLARE
3613 "i" INTEGER;
3614 "ary_text_v" TEXT;
3615 BEGIN
3616 IF "dim_p" >= 1 THEN
3617 "ary_text_v" := '{NULL';
3618 "i" := "dim_p";
3619 LOOP
3620 "i" := "i" - 1;
3621 EXIT WHEN "i" = 0;
3622 "ary_text_v" := "ary_text_v" || ',NULL';
3623 END LOOP;
3624 "ary_text_v" := "ary_text_v" || '}';
3625 RETURN "ary_text_v";
3626 ELSE
3627 RAISE EXCEPTION 'Dimension needs to be at least 1.';
3628 END IF;
3629 END;
3630 $$;
3632 COMMENT ON FUNCTION "array_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
3635 CREATE FUNCTION "square_matrix_init_string"("dim_p" INTEGER)
3636 RETURNS TEXT
3637 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3638 DECLARE
3639 "i" INTEGER;
3640 "row_text_v" TEXT;
3641 "ary_text_v" TEXT;
3642 BEGIN
3643 IF "dim_p" >= 1 THEN
3644 "row_text_v" := '{NULL';
3645 "i" := "dim_p";
3646 LOOP
3647 "i" := "i" - 1;
3648 EXIT WHEN "i" = 0;
3649 "row_text_v" := "row_text_v" || ',NULL';
3650 END LOOP;
3651 "row_text_v" := "row_text_v" || '}';
3652 "ary_text_v" := '{' || "row_text_v";
3653 "i" := "dim_p";
3654 LOOP
3655 "i" := "i" - 1;
3656 EXIT WHEN "i" = 0;
3657 "ary_text_v" := "ary_text_v" || ',' || "row_text_v";
3658 END LOOP;
3659 "ary_text_v" := "ary_text_v" || '}';
3660 RETURN "ary_text_v";
3661 ELSE
3662 RAISE EXCEPTION 'Dimension needs to be at least 1.';
3663 END IF;
3664 END;
3665 $$;
3667 COMMENT ON FUNCTION "square_matrix_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
3670 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3671 RETURNS VOID
3672 LANGUAGE 'plpgsql' VOLATILE AS $$
3673 DECLARE
3674 "dimension_v" INTEGER;
3675 "vote_matrix" INT4[][]; -- absolute votes
3676 "matrix" INT8[][]; -- defeat strength / best paths
3677 "i" INTEGER;
3678 "j" INTEGER;
3679 "k" INTEGER;
3680 "battle_row" "battle"%ROWTYPE;
3681 "rank_ary" INT4[];
3682 "rank_v" INT4;
3683 "done_v" INTEGER;
3684 "winners_ary" INTEGER[];
3685 "initiative_id_v" "initiative"."id"%TYPE;
3686 BEGIN
3687 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
3688 SELECT count(1) INTO "dimension_v"
3689 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3690 IF "dimension_v" > 1 THEN
3691 -- Create "vote_matrix" with absolute number of votes in pairwise
3692 -- comparison:
3693 "vote_matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3694 "i" := 1;
3695 "j" := 2;
3696 FOR "battle_row" IN
3697 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3698 ORDER BY
3699 "winning_initiative_id" NULLS LAST,
3700 "losing_initiative_id" NULLS LAST
3701 LOOP
3702 "vote_matrix"["i"]["j"] := "battle_row"."count";
3703 IF "j" = "dimension_v" THEN
3704 "i" := "i" + 1;
3705 "j" := 1;
3706 ELSE
3707 "j" := "j" + 1;
3708 IF "j" = "i" THEN
3709 "j" := "j" + 1;
3710 END IF;
3711 END IF;
3712 END LOOP;
3713 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3714 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3715 END IF;
3716 -- Store defeat strengths in "matrix" using "defeat_strength"
3717 -- function:
3718 "matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3719 "i" := 1;
3720 LOOP
3721 "j" := 1;
3722 LOOP
3723 IF "i" != "j" THEN
3724 "matrix"["i"]["j"] := "defeat_strength"(
3725 "vote_matrix"["i"]["j"],
3726 "vote_matrix"["j"]["i"]
3727 );
3728 END IF;
3729 EXIT WHEN "j" = "dimension_v";
3730 "j" := "j" + 1;
3731 END LOOP;
3732 EXIT WHEN "i" = "dimension_v";
3733 "i" := "i" + 1;
3734 END LOOP;
3735 -- Find best paths:
3736 "i" := 1;
3737 LOOP
3738 "j" := 1;
3739 LOOP
3740 IF "i" != "j" THEN
3741 "k" := 1;
3742 LOOP
3743 IF "i" != "k" AND "j" != "k" THEN
3744 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3745 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3746 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3747 END IF;
3748 ELSE
3749 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3750 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3751 END IF;
3752 END IF;
3753 END IF;
3754 EXIT WHEN "k" = "dimension_v";
3755 "k" := "k" + 1;
3756 END LOOP;
3757 END IF;
3758 EXIT WHEN "j" = "dimension_v";
3759 "j" := "j" + 1;
3760 END LOOP;
3761 EXIT WHEN "i" = "dimension_v";
3762 "i" := "i" + 1;
3763 END LOOP;
3764 -- Determine order of winners:
3765 "rank_ary" := "array_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3766 "rank_v" := 1;
3767 "done_v" := 0;
3768 LOOP
3769 "winners_ary" := '{}';
3770 "i" := 1;
3771 LOOP
3772 IF "rank_ary"["i"] ISNULL THEN
3773 "j" := 1;
3774 LOOP
3775 IF
3776 "i" != "j" AND
3777 "rank_ary"["j"] ISNULL AND
3778 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3779 THEN
3780 -- someone else is better
3781 EXIT;
3782 END IF;
3783 IF "j" = "dimension_v" THEN
3784 -- noone is better
3785 "winners_ary" := "winners_ary" || "i";
3786 EXIT;
3787 END IF;
3788 "j" := "j" + 1;
3789 END LOOP;
3790 END IF;
3791 EXIT WHEN "i" = "dimension_v";
3792 "i" := "i" + 1;
3793 END LOOP;
3794 "i" := 1;
3795 LOOP
3796 "rank_ary"["winners_ary"["i"]] := "rank_v";
3797 "done_v" := "done_v" + 1;
3798 EXIT WHEN "i" = array_upper("winners_ary", 1);
3799 "i" := "i" + 1;
3800 END LOOP;
3801 EXIT WHEN "done_v" = "dimension_v";
3802 "rank_v" := "rank_v" + 1;
3803 END LOOP;
3804 -- write preliminary results:
3805 "i" := 1;
3806 FOR "initiative_id_v" IN
3807 SELECT "id" FROM "initiative"
3808 WHERE "issue_id" = "issue_id_p" AND "admitted"
3809 ORDER BY "id"
3810 LOOP
3811 UPDATE "initiative" SET
3812 "favored" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3813 "unfavored" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3814 "eligible" = "attainable" AND
3815 "rank_ary"["i"] < "rank_ary"["dimension_v"],
3816 "rank" = "rank_ary"["i"]
3817 WHERE "id" = "initiative_id_v";
3818 "i" := "i" + 1;
3819 END LOOP;
3820 IF "i" != "dimension_v" THEN
3821 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3822 END IF;
3823 -- straighten ranks (start counting with 1, no equal ranks):
3824 "rank_v" := 1;
3825 FOR "initiative_id_v" IN
3826 SELECT "id" FROM "initiative"
3827 WHERE "issue_id" = "issue_id_p" AND "rank" NOTNULL
3828 ORDER BY
3829 "rank",
3830 "vote_ratio"("positive_votes", "negative_votes") DESC,
3831 "id"
3832 LOOP
3833 UPDATE "initiative" SET "rank" = "rank_v"
3834 WHERE "id" = "initiative_id_v";
3835 "rank_v" := "rank_v" + 1;
3836 END LOOP;
3837 -- mark final winner:
3838 UPDATE "initiative" SET "winner" =
3839 ( "eligible" = TRUE AND
3840 "rank" = (
3841 SELECT min("rank") FROM "initiative"
3842 WHERE "issue_id" = "issue_id_p"
3843 AND "eligible" = TRUE ) );
3844 END IF;
3845 -- mark issue as finished
3846 UPDATE "issue" SET
3847 "state" =
3848 CASE WHEN "dimension_v" = 0 THEN
3849 'finished_without_winner'::"issue_state"
3850 ELSE
3851 'finished_with_winner'::"issue_state"
3852 END,
3853 "ranks_available" = TRUE
3854 WHERE "id" = "issue_id_p";
3855 RETURN;
3856 END;
3857 $$;
3859 COMMENT ON FUNCTION "calculate_ranks"
3860 ( "issue"."id"%TYPE )
3861 IS 'Determine ranking (Votes have to be counted first)';
3865 -----------------------------
3866 -- Automatic state changes --
3867 -----------------------------
3870 CREATE FUNCTION "check_issue"
3871 ( "issue_id_p" "issue"."id"%TYPE )
3872 RETURNS VOID
3873 LANGUAGE 'plpgsql' VOLATILE AS $$
3874 DECLARE
3875 "issue_row" "issue"%ROWTYPE;
3876 "policy_row" "policy"%ROWTYPE;
3877 "voting_requested_v" BOOLEAN;
3878 BEGIN
3879 PERFORM "lock_issue"("issue_id_p");
3880 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3881 -- only process open issues:
3882 IF "issue_row"."closed" ISNULL THEN
3883 SELECT * INTO "policy_row" FROM "policy"
3884 WHERE "id" = "issue_row"."policy_id";
3885 -- create a snapshot, unless issue is already fully frozen:
3886 IF "issue_row"."fully_frozen" ISNULL THEN
3887 PERFORM "create_snapshot"("issue_id_p");
3888 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3889 END IF;
3890 -- eventually close or accept issues, which have not been accepted:
3891 IF "issue_row"."accepted" ISNULL THEN
3892 IF EXISTS (
3893 SELECT NULL FROM "initiative"
3894 WHERE "issue_id" = "issue_id_p"
3895 AND "supporter_count" > 0
3896 AND "supporter_count" * "policy_row"."issue_quorum_den"
3897 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3898 ) THEN
3899 -- accept issues, if supporter count is high enough
3900 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3901 -- NOTE: "issue_row" used later
3902 "issue_row"."state" := 'discussion';
3903 "issue_row"."accepted" := now();
3904 UPDATE "issue" SET
3905 "state" = "issue_row"."state",
3906 "accepted" = "issue_row"."accepted"
3907 WHERE "id" = "issue_row"."id";
3908 ELSIF
3909 now() >= "issue_row"."created" + "issue_row"."admission_time"
3910 THEN
3911 -- close issues, if admission time has expired
3912 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3913 UPDATE "issue" SET
3914 "state" = 'canceled_issue_not_accepted',
3915 "closed" = now()
3916 WHERE "id" = "issue_row"."id";
3917 END IF;
3918 END IF;
3919 -- eventually half freeze issues:
3920 IF
3921 -- NOTE: issue can't be closed at this point, if it has been accepted
3922 "issue_row"."accepted" NOTNULL AND
3923 "issue_row"."half_frozen" ISNULL
3924 THEN
3925 SELECT
3926 CASE
3927 WHEN "vote_now" * 2 > "issue_row"."population" THEN
3928 TRUE
3929 WHEN "vote_later" * 2 > "issue_row"."population" THEN
3930 FALSE
3931 ELSE NULL
3932 END
3933 INTO "voting_requested_v"
3934 FROM "issue" WHERE "id" = "issue_id_p";
3935 IF
3936 "voting_requested_v" OR (
3937 "voting_requested_v" ISNULL AND
3938 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3940 THEN
3941 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3942 -- NOTE: "issue_row" used later
3943 "issue_row"."state" := 'verification';
3944 "issue_row"."half_frozen" := now();
3945 UPDATE "issue" SET
3946 "state" = "issue_row"."state",
3947 "half_frozen" = "issue_row"."half_frozen"
3948 WHERE "id" = "issue_row"."id";
3949 END IF;
3950 END IF;
3951 -- close issues after some time, if all initiatives have been revoked:
3952 IF
3953 "issue_row"."closed" ISNULL AND
3954 NOT EXISTS (
3955 -- all initiatives are revoked
3956 SELECT NULL FROM "initiative"
3957 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3958 ) AND (
3959 -- and issue has not been accepted yet
3960 "issue_row"."accepted" ISNULL OR
3961 NOT EXISTS (
3962 -- or no initiatives have been revoked lately
3963 SELECT NULL FROM "initiative"
3964 WHERE "issue_id" = "issue_id_p"
3965 AND now() < "revoked" + "issue_row"."verification_time"
3966 ) OR (
3967 -- or verification time has elapsed
3968 "issue_row"."half_frozen" NOTNULL AND
3969 "issue_row"."fully_frozen" ISNULL AND
3970 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3973 THEN
3974 -- NOTE: "issue_row" used later
3975 IF "issue_row"."accepted" ISNULL THEN
3976 "issue_row"."state" := 'canceled_revoked_before_accepted';
3977 ELSIF "issue_row"."half_frozen" ISNULL THEN
3978 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
3979 ELSE
3980 "issue_row"."state" := 'canceled_after_revocation_during_verification';
3981 END IF;
3982 "issue_row"."closed" := now();
3983 UPDATE "issue" SET
3984 "state" = "issue_row"."state",
3985 "closed" = "issue_row"."closed"
3986 WHERE "id" = "issue_row"."id";
3987 END IF;
3988 -- fully freeze issue after verification time:
3989 IF
3990 "issue_row"."half_frozen" NOTNULL AND
3991 "issue_row"."fully_frozen" ISNULL AND
3992 "issue_row"."closed" ISNULL AND
3993 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3994 THEN
3995 PERFORM "freeze_after_snapshot"("issue_id_p");
3996 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
3997 END IF;
3998 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3999 -- close issue by calling close_voting(...) after voting time:
4000 IF
4001 "issue_row"."closed" ISNULL AND
4002 "issue_row"."fully_frozen" NOTNULL AND
4003 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4004 THEN
4005 PERFORM "close_voting"("issue_id_p");
4006 -- calculate ranks will not consume much time and can be done now
4007 PERFORM "calculate_ranks"("issue_id_p");
4008 END IF;
4009 END IF;
4010 RETURN;
4011 END;
4012 $$;
4014 COMMENT ON FUNCTION "check_issue"
4015 ( "issue"."id"%TYPE )
4016 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.';
4019 CREATE FUNCTION "check_everything"()
4020 RETURNS VOID
4021 LANGUAGE 'plpgsql' VOLATILE AS $$
4022 DECLARE
4023 "issue_id_v" "issue"."id"%TYPE;
4024 BEGIN
4025 DELETE FROM "expired_session";
4026 PERFORM "check_last_login"();
4027 PERFORM "calculate_member_counts"();
4028 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4029 PERFORM "check_issue"("issue_id_v");
4030 END LOOP;
4031 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4032 PERFORM "calculate_ranks"("issue_id_v");
4033 END LOOP;
4034 RETURN;
4035 END;
4036 $$;
4038 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.';
4042 ----------------------
4043 -- Deletion of data --
4044 ----------------------
4047 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4048 RETURNS VOID
4049 LANGUAGE 'plpgsql' VOLATILE AS $$
4050 DECLARE
4051 "issue_row" "issue"%ROWTYPE;
4052 BEGIN
4053 SELECT * INTO "issue_row"
4054 FROM "issue" WHERE "id" = "issue_id_p"
4055 FOR UPDATE;
4056 IF "issue_row"."cleaned" ISNULL THEN
4057 UPDATE "issue" SET
4058 "closed" = NULL,
4059 "ranks_available" = FALSE
4060 WHERE "id" = "issue_id_p";
4061 DELETE FROM "delegating_voter"
4062 WHERE "issue_id" = "issue_id_p";
4063 DELETE FROM "direct_voter"
4064 WHERE "issue_id" = "issue_id_p";
4065 DELETE FROM "delegating_interest_snapshot"
4066 WHERE "issue_id" = "issue_id_p";
4067 DELETE FROM "direct_interest_snapshot"
4068 WHERE "issue_id" = "issue_id_p";
4069 DELETE FROM "delegating_population_snapshot"
4070 WHERE "issue_id" = "issue_id_p";
4071 DELETE FROM "direct_population_snapshot"
4072 WHERE "issue_id" = "issue_id_p";
4073 DELETE FROM "non_voter"
4074 WHERE "issue_id" = "issue_id_p";
4075 DELETE FROM "delegation"
4076 WHERE "issue_id" = "issue_id_p";
4077 DELETE FROM "supporter"
4078 WHERE "issue_id" = "issue_id_p";
4079 UPDATE "issue" SET
4080 "closed" = "issue_row"."closed",
4081 "ranks_available" = "issue_row"."ranks_available",
4082 "cleaned" = now()
4083 WHERE "id" = "issue_id_p";
4084 END IF;
4085 RETURN;
4086 END;
4087 $$;
4089 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4092 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4093 RETURNS VOID
4094 LANGUAGE 'plpgsql' VOLATILE AS $$
4095 BEGIN
4096 UPDATE "member" SET
4097 "last_login" = NULL,
4098 "last_login_public" = NULL,
4099 "login" = NULL,
4100 "password" = NULL,
4101 "locked" = TRUE,
4102 "active" = FALSE,
4103 "notify_email" = NULL,
4104 "notify_email_unconfirmed" = NULL,
4105 "notify_email_secret" = NULL,
4106 "notify_email_secret_expiry" = NULL,
4107 "notify_email_lock_expiry" = NULL,
4108 "password_reset_secret" = NULL,
4109 "password_reset_secret_expiry" = NULL,
4110 "organizational_unit" = NULL,
4111 "internal_posts" = NULL,
4112 "realname" = NULL,
4113 "birthday" = NULL,
4114 "address" = NULL,
4115 "email" = NULL,
4116 "xmpp_address" = NULL,
4117 "website" = NULL,
4118 "phone" = NULL,
4119 "mobile_phone" = NULL,
4120 "profession" = NULL,
4121 "external_memberships" = NULL,
4122 "external_posts" = NULL,
4123 "statement" = NULL
4124 WHERE "id" = "member_id_p";
4125 -- "text_search_data" is updated by triggers
4126 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4127 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4128 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4129 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4130 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4131 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4132 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4133 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4134 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4135 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4136 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4137 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4138 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4139 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4140 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4141 DELETE FROM "direct_voter" USING "issue"
4142 WHERE "direct_voter"."issue_id" = "issue"."id"
4143 AND "issue"."closed" ISNULL
4144 AND "member_id" = "member_id_p";
4145 RETURN;
4146 END;
4147 $$;
4149 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)';
4152 CREATE FUNCTION "delete_private_data"()
4153 RETURNS VOID
4154 LANGUAGE 'plpgsql' VOLATILE AS $$
4155 BEGIN
4156 UPDATE "member" SET
4157 "last_login" = NULL,
4158 "login" = NULL,
4159 "password" = NULL,
4160 "notify_email" = NULL,
4161 "notify_email_unconfirmed" = NULL,
4162 "notify_email_secret" = NULL,
4163 "notify_email_secret_expiry" = NULL,
4164 "notify_email_lock_expiry" = NULL,
4165 "password_reset_secret" = NULL,
4166 "password_reset_secret_expiry" = NULL,
4167 "organizational_unit" = NULL,
4168 "internal_posts" = NULL,
4169 "realname" = NULL,
4170 "birthday" = NULL,
4171 "address" = NULL,
4172 "email" = NULL,
4173 "xmpp_address" = NULL,
4174 "website" = NULL,
4175 "phone" = NULL,
4176 "mobile_phone" = NULL,
4177 "profession" = NULL,
4178 "external_memberships" = NULL,
4179 "external_posts" = NULL,
4180 "statement" = NULL;
4181 -- "text_search_data" is updated by triggers
4182 DELETE FROM "invite_code";
4183 DELETE FROM "setting";
4184 DELETE FROM "setting_map";
4185 DELETE FROM "member_relation_setting";
4186 DELETE FROM "member_image";
4187 DELETE FROM "contact";
4188 DELETE FROM "ignored_member";
4189 DELETE FROM "session";
4190 DELETE FROM "area_setting";
4191 DELETE FROM "issue_setting";
4192 DELETE FROM "ignored_initiative";
4193 DELETE FROM "initiative_setting";
4194 DELETE FROM "suggestion_setting";
4195 DELETE FROM "non_voter";
4196 DELETE FROM "direct_voter" USING "issue"
4197 WHERE "direct_voter"."issue_id" = "issue"."id"
4198 AND "issue"."closed" ISNULL;
4199 RETURN;
4200 END;
4201 $$;
4203 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.';
4207 COMMIT;

Impressum / About Us