liquid_feedback_core

view core.sql @ 184:af3d208e81be

Member deactivation based on last_activity instead of last_login
author jbe
date Fri Jul 29 20:26:45 2011 +0200 (2011-07-29)
parents ed2f94a397cd
children b0b7e0b18d78
line source
2 -- Execute the following command manually for PostgreSQL prior version 9.0:
3 -- CREATE LANGUAGE plpgsql;
5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
7 BEGIN;
9 CREATE VIEW "liquid_feedback_version" AS
10 SELECT * FROM (VALUES ('1.5.0_devel', 1, 5, -1))
11 AS "subquery"("string", "major", "minor", "revision");
15 ----------------------
16 -- Full text search --
17 ----------------------
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
21 RETURNS TSQUERY
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
23 BEGIN
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
25 END;
26 $$;
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
31 CREATE FUNCTION "highlight"
32 ( "body_p" TEXT,
33 "query_text_p" TEXT )
34 RETURNS TEXT
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
36 BEGIN
37 RETURN ts_headline(
38 'pg_catalog.simple',
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
40 "text_search_query"("query_text_p"),
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
42 END;
43 $$;
45 COMMENT ON FUNCTION "highlight"
46 ( "body_p" TEXT,
47 "query_text_p" TEXT )
48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
52 -------------------------
53 -- Tables and indicies --
54 -------------------------
57 CREATE TABLE "system_setting" (
58 "member_ttl" INTERVAL );
59 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
61 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
62 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
64 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
67 CREATE TABLE "contingent" (
68 "time_frame" INTERVAL PRIMARY KEY,
69 "text_entry_limit" INT4,
70 "initiative_limit" INT4 );
72 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
74 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
75 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
78 CREATE TYPE "notify_level" AS ENUM
79 ('none', 'voting', 'verification', 'discussion', 'all');
81 COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything';
84 CREATE TABLE "member" (
85 "id" SERIAL4 PRIMARY KEY,
86 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
87 "invite_code" TEXT UNIQUE,
88 "admin_comment" TEXT,
89 "activated" TIMESTAMPTZ,
90 "last_activity" DATE,
91 "last_login" TIMESTAMPTZ,
92 "login" TEXT UNIQUE,
93 "password" TEXT,
94 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
95 "active" BOOLEAN NOT NULL DEFAULT FALSE,
96 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
97 "notify_email" TEXT,
98 "notify_email_unconfirmed" TEXT,
99 "notify_email_secret" TEXT UNIQUE,
100 "notify_email_secret_expiry" TIMESTAMPTZ,
101 "notify_email_lock_expiry" TIMESTAMPTZ,
102 "notify_level" "notify_level" NOT NULL DEFAULT 'none',
103 "notify_event_id" INT8,
104 "password_reset_secret" TEXT UNIQUE,
105 "password_reset_secret_expiry" TIMESTAMPTZ,
106 "name" TEXT NOT NULL UNIQUE,
107 "identification" TEXT UNIQUE,
108 "organizational_unit" TEXT,
109 "internal_posts" TEXT,
110 "realname" TEXT,
111 "birthday" DATE,
112 "address" TEXT,
113 "email" TEXT,
114 "xmpp_address" TEXT,
115 "website" TEXT,
116 "phone" TEXT,
117 "mobile_phone" TEXT,
118 "profession" TEXT,
119 "external_memberships" TEXT,
120 "external_posts" TEXT,
121 "formatting_engine" TEXT,
122 "statement" TEXT,
123 "text_search_data" TSVECTOR,
124 CONSTRAINT "active_requires_activated_and_last_activity"
125 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)) );
126 CREATE INDEX "member_active_idx" ON "member" ("active");
127 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
128 CREATE TRIGGER "update_text_search_data"
129 BEFORE INSERT OR UPDATE ON "member"
130 FOR EACH ROW EXECUTE PROCEDURE
131 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
132 "name", "identification", "organizational_unit", "internal_posts",
133 "realname", "external_memberships", "external_posts", "statement" );
135 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
137 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
138 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
139 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
140 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
141 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
142 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
143 COMMENT ON COLUMN "member"."login" IS 'Login name';
144 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
145 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
146 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
147 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
148 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
149 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
150 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
151 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
152 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
153 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
154 COMMENT ON COLUMN "member"."notify_event_id" IS 'Latest "id" of an "event" the member was notified about';
155 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
156 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
157 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
158 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
159 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
160 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
161 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
162 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
163 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
164 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his homepage within the system';
167 CREATE TABLE "member_history" (
168 "id" SERIAL8 PRIMARY KEY,
169 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
170 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
171 "active" BOOLEAN NOT NULL,
172 "name" TEXT NOT NULL );
173 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
175 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
177 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
178 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
181 CREATE TABLE "rendered_member_statement" (
182 PRIMARY KEY ("member_id", "format"),
183 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
184 "format" TEXT,
185 "content" TEXT NOT NULL );
187 COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)';
190 CREATE TABLE "setting" (
191 PRIMARY KEY ("member_id", "key"),
192 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
193 "key" TEXT NOT NULL,
194 "value" TEXT NOT NULL );
195 CREATE INDEX "setting_key_idx" ON "setting" ("key");
197 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
199 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
202 CREATE TABLE "setting_map" (
203 PRIMARY KEY ("member_id", "key", "subkey"),
204 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
205 "key" TEXT NOT NULL,
206 "subkey" TEXT NOT NULL,
207 "value" TEXT NOT NULL );
208 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
210 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
212 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
213 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
214 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
217 CREATE TABLE "member_relation_setting" (
218 PRIMARY KEY ("member_id", "key", "other_member_id"),
219 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
220 "key" TEXT NOT NULL,
221 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
222 "value" TEXT NOT NULL );
224 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
227 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
229 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
232 CREATE TABLE "member_image" (
233 PRIMARY KEY ("member_id", "image_type", "scaled"),
234 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
235 "image_type" "member_image_type",
236 "scaled" BOOLEAN,
237 "content_type" TEXT,
238 "data" BYTEA NOT NULL );
240 COMMENT ON TABLE "member_image" IS 'Images of members';
242 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
245 CREATE TABLE "member_count" (
246 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
247 "total_count" INT4 NOT NULL );
249 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';
251 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
252 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
255 CREATE TABLE "contact" (
256 PRIMARY KEY ("member_id", "other_member_id"),
257 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
258 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
259 "public" BOOLEAN NOT NULL DEFAULT FALSE,
260 CONSTRAINT "cant_save_yourself_as_contact"
261 CHECK ("member_id" != "other_member_id") );
262 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
264 COMMENT ON TABLE "contact" IS 'Contact lists';
266 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
267 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
268 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
271 CREATE TABLE "ignored_member" (
272 PRIMARY KEY ("member_id", "other_member_id"),
273 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
274 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
275 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
277 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
279 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
280 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
283 CREATE TABLE "policy" (
284 "id" SERIAL4 PRIMARY KEY,
285 "index" INT4 NOT NULL,
286 "active" BOOLEAN NOT NULL DEFAULT TRUE,
287 "name" TEXT NOT NULL UNIQUE,
288 "description" TEXT NOT NULL DEFAULT '',
289 "admission_time" INTERVAL NOT NULL,
290 "discussion_time" INTERVAL NOT NULL,
291 "verification_time" INTERVAL NOT NULL,
292 "voting_time" INTERVAL NOT NULL,
293 "issue_quorum_num" INT4 NOT NULL,
294 "issue_quorum_den" INT4 NOT NULL,
295 "initiative_quorum_num" INT4 NOT NULL,
296 "initiative_quorum_den" INT4 NOT NULL,
297 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
298 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
299 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
300 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
301 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
302 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
303 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
304 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
305 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
306 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
307 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
308 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE );
309 CREATE INDEX "policy_active_idx" ON "policy" ("active");
311 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
313 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
314 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
315 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
316 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
317 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
318 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
319 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"';
320 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"';
321 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
322 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
323 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
324 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
325 COMMENT ON COLUMN "policy"."direct_majority_strict" IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.';
326 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
327 COMMENT ON COLUMN "policy"."direct_majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner';
328 COMMENT ON COLUMN "policy"."indirect_majority_num" IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
329 COMMENT ON COLUMN "policy"."indirect_majority_den" IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
330 COMMENT ON COLUMN "policy"."indirect_majority_strict" IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.';
331 COMMENT ON COLUMN "policy"."indirect_majority_positive" IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner';
332 COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner';
333 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
334 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
337 CREATE TABLE "unit" (
338 "id" SERIAL4 PRIMARY KEY,
339 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
340 "active" BOOLEAN NOT NULL DEFAULT TRUE,
341 "name" TEXT NOT NULL,
342 "description" TEXT NOT NULL DEFAULT '',
343 "member_count" INT4,
344 "text_search_data" TSVECTOR );
345 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
346 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
347 CREATE INDEX "unit_active_idx" ON "unit" ("active");
348 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
349 CREATE TRIGGER "update_text_search_data"
350 BEFORE INSERT OR UPDATE ON "unit"
351 FOR EACH ROW EXECUTE PROCEDURE
352 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
353 "name", "description" );
355 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
357 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
358 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in units of this area';
359 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
362 CREATE TABLE "area" (
363 "id" SERIAL4 PRIMARY KEY,
364 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
365 "active" BOOLEAN NOT NULL DEFAULT TRUE,
366 "name" TEXT NOT NULL,
367 "description" TEXT NOT NULL DEFAULT '',
368 "direct_member_count" INT4,
369 "member_weight" INT4,
370 "text_search_data" TSVECTOR );
371 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
372 CREATE INDEX "area_active_idx" ON "area" ("active");
373 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
374 CREATE TRIGGER "update_text_search_data"
375 BEFORE INSERT OR UPDATE ON "area"
376 FOR EACH ROW EXECUTE PROCEDURE
377 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
378 "name", "description" );
380 COMMENT ON TABLE "area" IS 'Subject areas';
382 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
383 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"';
384 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
387 CREATE TABLE "area_setting" (
388 PRIMARY KEY ("member_id", "key", "area_id"),
389 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
390 "key" TEXT NOT NULL,
391 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
392 "value" TEXT NOT NULL );
394 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
397 CREATE TABLE "allowed_policy" (
398 PRIMARY KEY ("area_id", "policy_id"),
399 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
400 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
401 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
402 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
404 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
406 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
409 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
411 COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period';
414 CREATE TYPE "issue_state" AS ENUM (
415 'admission', 'discussion', 'verification', 'voting',
416 'canceled_revoked_before_accepted',
417 'canceled_issue_not_accepted',
418 'canceled_after_revocation_during_discussion',
419 'canceled_after_revocation_during_verification',
420 'calculation',
421 'canceled_no_initiative_admitted',
422 'finished_without_winner', 'finished_with_winner');
424 COMMENT ON TYPE "issue_state" IS 'State of issues';
427 CREATE TABLE "issue" (
428 "id" SERIAL4 PRIMARY KEY,
429 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
430 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
431 "state" "issue_state" NOT NULL DEFAULT 'admission',
432 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
433 "accepted" TIMESTAMPTZ,
434 "half_frozen" TIMESTAMPTZ,
435 "fully_frozen" TIMESTAMPTZ,
436 "closed" TIMESTAMPTZ,
437 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
438 "cleaned" TIMESTAMPTZ,
439 "admission_time" INTERVAL NOT NULL,
440 "discussion_time" INTERVAL NOT NULL,
441 "verification_time" INTERVAL NOT NULL,
442 "voting_time" INTERVAL NOT NULL,
443 "snapshot" TIMESTAMPTZ,
444 "latest_snapshot_event" "snapshot_event",
445 "population" INT4,
446 "voter_count" INT4,
447 "status_quo_schulze_rank" INT4,
448 CONSTRAINT "valid_state" CHECK ((
449 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
450 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
451 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
452 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
453 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
454 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
455 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
456 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
457 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
458 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
459 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
460 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
461 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
462 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
463 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
464 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
465 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
466 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
467 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
468 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
469 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
470 )),
471 CONSTRAINT "state_change_order" CHECK (
472 "created" <= "accepted" AND
473 "accepted" <= "half_frozen" AND
474 "half_frozen" <= "fully_frozen" AND
475 "fully_frozen" <= "closed" ),
476 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
477 "cleaned" ISNULL OR "closed" NOTNULL ),
478 CONSTRAINT "last_snapshot_on_full_freeze"
479 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
480 CONSTRAINT "freeze_requires_snapshot"
481 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
482 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
483 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
484 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
485 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
486 CREATE INDEX "issue_created_idx" ON "issue" ("created");
487 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
488 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
489 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
490 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
491 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
492 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
494 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
496 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
497 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
498 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.';
499 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.';
500 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
501 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
502 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
503 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
504 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
505 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
506 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
507 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';
508 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
509 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';
510 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
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 "direct_majority" BOOLEAN,
541 "indirect_majority" BOOLEAN,
542 "schulze_rank" INT4,
543 "better_than_status_quo" BOOLEAN,
544 "worse_than_status_quo" BOOLEAN,
545 "reverse_beat_path" BOOLEAN,
546 "multistage_majority" BOOLEAN,
547 "eligible" BOOLEAN,
548 "winner" BOOLEAN,
549 "rank" INT4,
550 "text_search_data" TSVECTOR,
551 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
552 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
553 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
554 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
555 CONSTRAINT "revoked_initiatives_cant_be_admitted"
556 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
557 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
558 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
559 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
560 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
561 "schulze_rank" ISNULL AND
562 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
563 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
564 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
565 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
566 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
567 "eligible" = FALSE OR
568 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
569 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
570 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
571 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
572 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
573 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
574 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
575 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
576 CREATE TRIGGER "update_text_search_data"
577 BEFORE INSERT OR UPDATE ON "initiative"
578 FOR EACH ROW EXECUTE PROCEDURE
579 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
580 "name", "discussion_url");
582 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.';
584 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
585 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
586 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
587 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
588 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
589 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
590 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
591 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
592 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
593 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
594 COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
595 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
596 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
597 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
598 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
599 COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties), from this initiative to the status quo';
600 COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
601 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
602 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
603 COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
606 CREATE TABLE "battle" (
607 "issue_id" INT4 NOT NULL,
608 "winning_initiative_id" INT4,
609 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
610 "losing_initiative_id" INT4,
611 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
612 "count" INT4 NOT NULL,
613 CONSTRAINT "initiative_ids_not_equal" CHECK (
614 "winning_initiative_id" != "losing_initiative_id" OR
615 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
616 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
617 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
618 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
619 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
621 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';
624 CREATE TABLE "ignored_initiative" (
625 PRIMARY KEY ("initiative_id", "member_id"),
626 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
627 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
628 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
630 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
633 CREATE TABLE "initiative_setting" (
634 PRIMARY KEY ("member_id", "key", "initiative_id"),
635 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
636 "key" TEXT NOT NULL,
637 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
638 "value" TEXT NOT NULL );
640 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
643 CREATE TABLE "draft" (
644 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
645 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
646 "id" SERIAL8 PRIMARY KEY,
647 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
648 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
649 "formatting_engine" TEXT,
650 "content" TEXT NOT NULL,
651 "text_search_data" TSVECTOR );
652 CREATE INDEX "draft_created_idx" ON "draft" ("created");
653 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
654 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
655 CREATE TRIGGER "update_text_search_data"
656 BEFORE INSERT OR UPDATE ON "draft"
657 FOR EACH ROW EXECUTE PROCEDURE
658 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
660 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.';
662 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
663 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
666 CREATE TABLE "rendered_draft" (
667 PRIMARY KEY ("draft_id", "format"),
668 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
669 "format" TEXT,
670 "content" TEXT NOT NULL );
672 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)';
675 CREATE TABLE "suggestion" (
676 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
677 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
678 "id" SERIAL8 PRIMARY KEY,
679 "draft_id" INT8 NOT NULL,
680 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
681 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
682 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
683 "name" TEXT NOT NULL,
684 "formatting_engine" TEXT,
685 "content" TEXT NOT NULL DEFAULT '',
686 "text_search_data" TSVECTOR,
687 "minus2_unfulfilled_count" INT4,
688 "minus2_fulfilled_count" INT4,
689 "minus1_unfulfilled_count" INT4,
690 "minus1_fulfilled_count" INT4,
691 "plus1_unfulfilled_count" INT4,
692 "plus1_fulfilled_count" INT4,
693 "plus2_unfulfilled_count" INT4,
694 "plus2_fulfilled_count" INT4 );
695 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
696 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
697 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
698 CREATE TRIGGER "update_text_search_data"
699 BEFORE INSERT OR UPDATE ON "suggestion"
700 FOR EACH ROW EXECUTE PROCEDURE
701 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
702 "name", "content");
704 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';
706 COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
707 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
708 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
709 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
710 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
711 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
712 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
713 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
714 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
717 CREATE TABLE "rendered_suggestion" (
718 PRIMARY KEY ("suggestion_id", "format"),
719 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
720 "format" TEXT,
721 "content" TEXT NOT NULL );
723 COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
726 CREATE TABLE "suggestion_setting" (
727 PRIMARY KEY ("member_id", "key", "suggestion_id"),
728 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
729 "key" TEXT NOT NULL,
730 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
731 "value" TEXT NOT NULL );
733 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
736 CREATE TABLE "privilege" (
737 PRIMARY KEY ("unit_id", "member_id"),
738 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
739 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
740 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
741 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
742 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
743 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
744 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
746 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
748 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
749 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
750 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
751 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
752 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
755 CREATE TABLE "membership" (
756 PRIMARY KEY ("area_id", "member_id"),
757 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
758 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
759 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
761 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
764 CREATE TABLE "interest" (
765 PRIMARY KEY ("issue_id", "member_id"),
766 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
767 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
768 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
770 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.';
773 CREATE TABLE "initiator" (
774 PRIMARY KEY ("initiative_id", "member_id"),
775 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
776 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
777 "accepted" BOOLEAN );
778 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
780 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.';
782 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.';
785 CREATE TABLE "supporter" (
786 "issue_id" INT4 NOT NULL,
787 PRIMARY KEY ("initiative_id", "member_id"),
788 "initiative_id" INT4,
789 "member_id" INT4,
790 "draft_id" INT8 NOT NULL,
791 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
792 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
793 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
795 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.';
797 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
800 CREATE TABLE "opinion" (
801 "initiative_id" INT4 NOT NULL,
802 PRIMARY KEY ("suggestion_id", "member_id"),
803 "suggestion_id" INT8,
804 "member_id" INT4,
805 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
806 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
807 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
808 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
809 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
811 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.';
813 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
816 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
818 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
821 CREATE TABLE "delegation" (
822 "id" SERIAL8 PRIMARY KEY,
823 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
824 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
825 "scope" "delegation_scope" NOT NULL,
826 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
827 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
828 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
829 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
830 CONSTRAINT "no_unit_delegation_to_null"
831 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
832 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
833 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
834 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
835 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
836 UNIQUE ("unit_id", "truster_id"),
837 UNIQUE ("area_id", "truster_id"),
838 UNIQUE ("issue_id", "truster_id") );
839 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
840 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
842 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
844 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
845 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
846 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
849 CREATE TABLE "direct_population_snapshot" (
850 PRIMARY KEY ("issue_id", "event", "member_id"),
851 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
852 "event" "snapshot_event",
853 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
854 "weight" INT4 );
855 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
857 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
859 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
860 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
863 CREATE TABLE "delegating_population_snapshot" (
864 PRIMARY KEY ("issue_id", "event", "member_id"),
865 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
866 "event" "snapshot_event",
867 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
868 "weight" INT4,
869 "scope" "delegation_scope" NOT NULL,
870 "delegate_member_ids" INT4[] NOT NULL );
871 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
873 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
875 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
876 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
877 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
878 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"';
881 CREATE TABLE "direct_interest_snapshot" (
882 PRIMARY KEY ("issue_id", "event", "member_id"),
883 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
884 "event" "snapshot_event",
885 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
886 "weight" INT4 );
887 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
889 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
891 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
892 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
895 CREATE TABLE "delegating_interest_snapshot" (
896 PRIMARY KEY ("issue_id", "event", "member_id"),
897 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
898 "event" "snapshot_event",
899 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
900 "weight" INT4,
901 "scope" "delegation_scope" NOT NULL,
902 "delegate_member_ids" INT4[] NOT NULL );
903 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
905 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
907 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
908 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
909 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
910 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"';
913 CREATE TABLE "direct_supporter_snapshot" (
914 "issue_id" INT4 NOT NULL,
915 PRIMARY KEY ("initiative_id", "event", "member_id"),
916 "initiative_id" INT4,
917 "event" "snapshot_event",
918 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
919 "informed" BOOLEAN NOT NULL,
920 "satisfied" BOOLEAN NOT NULL,
921 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
922 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
923 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
925 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
927 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
928 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
929 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
932 CREATE TABLE "non_voter" (
933 PRIMARY KEY ("issue_id", "member_id"),
934 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
935 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
936 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
938 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
941 CREATE TABLE "direct_voter" (
942 PRIMARY KEY ("issue_id", "member_id"),
943 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
944 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
945 "weight" INT4 );
946 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
948 COMMENT ON TABLE "direct_voter" IS 'Members having directly voted for/against initiatives of an issue; Frontends must ensure that no voters are added or removed to/from this table when the issue has been closed.';
950 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
953 CREATE TABLE "delegating_voter" (
954 PRIMARY KEY ("issue_id", "member_id"),
955 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
956 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
957 "weight" INT4,
958 "scope" "delegation_scope" NOT NULL,
959 "delegate_member_ids" INT4[] NOT NULL );
960 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
962 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
964 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
965 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
966 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"';
969 CREATE TABLE "vote" (
970 "issue_id" INT4 NOT NULL,
971 PRIMARY KEY ("initiative_id", "member_id"),
972 "initiative_id" INT4,
973 "member_id" INT4,
974 "grade" INT4,
975 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
976 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
977 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
979 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.';
981 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.';
984 CREATE TABLE "issue_comment" (
985 PRIMARY KEY ("issue_id", "member_id"),
986 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
987 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
988 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
989 "formatting_engine" TEXT,
990 "content" TEXT NOT NULL,
991 "text_search_data" TSVECTOR );
992 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
993 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
994 CREATE TRIGGER "update_text_search_data"
995 BEFORE INSERT OR UPDATE ON "issue_comment"
996 FOR EACH ROW EXECUTE PROCEDURE
997 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
999 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
1001 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
1004 CREATE TABLE "rendered_issue_comment" (
1005 PRIMARY KEY ("issue_id", "member_id", "format"),
1006 FOREIGN KEY ("issue_id", "member_id")
1007 REFERENCES "issue_comment" ("issue_id", "member_id")
1008 ON DELETE CASCADE ON UPDATE CASCADE,
1009 "issue_id" INT4,
1010 "member_id" INT4,
1011 "format" TEXT,
1012 "content" TEXT NOT NULL );
1014 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)';
1017 CREATE TABLE "voting_comment" (
1018 PRIMARY KEY ("issue_id", "member_id"),
1019 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1020 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1021 "changed" TIMESTAMPTZ,
1022 "formatting_engine" TEXT,
1023 "content" TEXT NOT NULL,
1024 "text_search_data" TSVECTOR );
1025 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1026 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1027 CREATE TRIGGER "update_text_search_data"
1028 BEFORE INSERT OR UPDATE ON "voting_comment"
1029 FOR EACH ROW EXECUTE PROCEDURE
1030 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1032 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1034 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.';
1037 CREATE TABLE "rendered_voting_comment" (
1038 PRIMARY KEY ("issue_id", "member_id", "format"),
1039 FOREIGN KEY ("issue_id", "member_id")
1040 REFERENCES "voting_comment" ("issue_id", "member_id")
1041 ON DELETE CASCADE ON UPDATE CASCADE,
1042 "issue_id" INT4,
1043 "member_id" INT4,
1044 "format" TEXT,
1045 "content" TEXT NOT NULL );
1047 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)';
1050 CREATE TYPE "event_type" AS ENUM (
1051 'issue_state_changed',
1052 'initiative_created_in_new_issue',
1053 'initiative_created_in_existing_issue',
1054 'initiative_revoked',
1055 'new_draft_created',
1056 'suggestion_created');
1058 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1061 CREATE TABLE "event" (
1062 "id" SERIAL8 PRIMARY KEY,
1063 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1064 "event" "event_type" NOT NULL,
1065 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1066 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1067 "state" "issue_state" CHECK ("state" != 'calculation'),
1068 "initiative_id" INT4,
1069 "draft_id" INT8,
1070 "suggestion_id" INT8,
1071 FOREIGN KEY ("issue_id", "initiative_id")
1072 REFERENCES "initiative" ("issue_id", "id")
1073 ON DELETE CASCADE ON UPDATE CASCADE,
1074 FOREIGN KEY ("initiative_id", "draft_id")
1075 REFERENCES "draft" ("initiative_id", "id")
1076 ON DELETE CASCADE ON UPDATE CASCADE,
1077 FOREIGN KEY ("initiative_id", "suggestion_id")
1078 REFERENCES "suggestion" ("initiative_id", "id")
1079 ON DELETE CASCADE ON UPDATE CASCADE,
1080 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1081 "event" != 'issue_state_changed' OR (
1082 "member_id" ISNULL AND
1083 "issue_id" NOTNULL AND
1084 "state" NOTNULL AND
1085 "initiative_id" ISNULL AND
1086 "draft_id" ISNULL AND
1087 "suggestion_id" ISNULL )),
1088 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1089 "event" NOT IN (
1090 'initiative_created_in_new_issue',
1091 'initiative_created_in_existing_issue',
1092 'initiative_revoked',
1093 'new_draft_created'
1094 ) OR (
1095 "member_id" NOTNULL AND
1096 "issue_id" NOTNULL AND
1097 "state" NOTNULL AND
1098 "initiative_id" NOTNULL AND
1099 "draft_id" NOTNULL AND
1100 "suggestion_id" ISNULL )),
1101 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1102 "event" != 'suggestion_created' OR (
1103 "member_id" NOTNULL AND
1104 "issue_id" NOTNULL AND
1105 "state" NOTNULL AND
1106 "initiative_id" NOTNULL AND
1107 "draft_id" ISNULL AND
1108 "suggestion_id" NOTNULL )) );
1110 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1112 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1113 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1114 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1115 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1119 ----------------------------------------------
1120 -- Writing of history entries and event log --
1121 ----------------------------------------------
1124 CREATE FUNCTION "write_member_history_trigger"()
1125 RETURNS TRIGGER
1126 LANGUAGE 'plpgsql' VOLATILE AS $$
1127 BEGIN
1128 IF
1129 NEW."active" != OLD."active" OR
1130 NEW."name" != OLD."name"
1131 THEN
1132 INSERT INTO "member_history"
1133 ("member_id", "active", "name")
1134 VALUES (NEW."id", OLD."active", OLD."name");
1135 END IF;
1136 RETURN NULL;
1137 END;
1138 $$;
1140 CREATE TRIGGER "write_member_history"
1141 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1142 "write_member_history_trigger"();
1144 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1145 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1148 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1149 RETURNS TRIGGER
1150 LANGUAGE 'plpgsql' VOLATILE AS $$
1151 BEGIN
1152 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1153 INSERT INTO "event" ("event", "issue_id", "state")
1154 VALUES ('issue_state_changed', NEW."id", NEW."state");
1155 END IF;
1156 RETURN NULL;
1157 END;
1158 $$;
1160 CREATE TRIGGER "write_event_issue_state_changed"
1161 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1162 "write_event_issue_state_changed_trigger"();
1164 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1165 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1168 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1169 RETURNS TRIGGER
1170 LANGUAGE 'plpgsql' VOLATILE AS $$
1171 DECLARE
1172 "initiative_row" "initiative"%ROWTYPE;
1173 "issue_row" "issue"%ROWTYPE;
1174 "event_v" "event_type";
1175 BEGIN
1176 SELECT * INTO "initiative_row" FROM "initiative"
1177 WHERE "id" = NEW."initiative_id";
1178 SELECT * INTO "issue_row" FROM "issue"
1179 WHERE "id" = "initiative_row"."issue_id";
1180 IF EXISTS (
1181 SELECT NULL FROM "draft"
1182 WHERE "initiative_id" = NEW."initiative_id"
1183 AND "id" != NEW."id"
1184 ) THEN
1185 "event_v" := 'new_draft_created';
1186 ELSE
1187 IF EXISTS (
1188 SELECT NULL FROM "initiative"
1189 WHERE "issue_id" = "initiative_row"."issue_id"
1190 AND "id" != "initiative_row"."id"
1191 ) THEN
1192 "event_v" := 'initiative_created_in_existing_issue';
1193 ELSE
1194 "event_v" := 'initiative_created_in_new_issue';
1195 END IF;
1196 END IF;
1197 INSERT INTO "event" (
1198 "event", "member_id",
1199 "issue_id", "state", "initiative_id", "draft_id"
1200 ) VALUES (
1201 "event_v",
1202 NEW."author_id",
1203 "initiative_row"."issue_id",
1204 "issue_row"."state",
1205 "initiative_row"."id",
1206 NEW."id" );
1207 RETURN NULL;
1208 END;
1209 $$;
1211 CREATE TRIGGER "write_event_initiative_or_draft_created"
1212 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1213 "write_event_initiative_or_draft_created_trigger"();
1215 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1216 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1219 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1220 RETURNS TRIGGER
1221 LANGUAGE 'plpgsql' VOLATILE AS $$
1222 DECLARE
1223 "issue_row" "issue"%ROWTYPE;
1224 BEGIN
1225 SELECT * INTO "issue_row" FROM "issue"
1226 WHERE "id" = NEW."issue_id";
1227 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1228 INSERT INTO "event" (
1229 "event", "member_id", "issue_id", "state", "initiative_id"
1230 ) VALUES (
1231 'initiative_revoked',
1232 NEW."revoked_by_member_id",
1233 NEW."issue_id",
1234 "issue_row"."state",
1235 NEW."id" );
1236 END IF;
1237 RETURN NULL;
1238 END;
1239 $$;
1241 CREATE TRIGGER "write_event_initiative_revoked"
1242 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1243 "write_event_initiative_revoked_trigger"();
1245 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1246 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1249 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1250 RETURNS TRIGGER
1251 LANGUAGE 'plpgsql' VOLATILE AS $$
1252 DECLARE
1253 "initiative_row" "initiative"%ROWTYPE;
1254 "issue_row" "issue"%ROWTYPE;
1255 BEGIN
1256 SELECT * INTO "initiative_row" FROM "initiative"
1257 WHERE "id" = NEW."initiative_id";
1258 SELECT * INTO "issue_row" FROM "issue"
1259 WHERE "id" = "initiative_row"."issue_id";
1260 INSERT INTO "event" (
1261 "event", "member_id",
1262 "issue_id", "state", "initiative_id", "suggestion_id"
1263 ) VALUES (
1264 'suggestion_created',
1265 NEW."author_id",
1266 "initiative_row"."issue_id",
1267 "issue_row"."state",
1268 "initiative_row"."id",
1269 NEW."id" );
1270 RETURN NULL;
1271 END;
1272 $$;
1274 CREATE TRIGGER "write_event_suggestion_created"
1275 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1276 "write_event_suggestion_created_trigger"();
1278 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1279 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1283 ----------------------------
1284 -- Additional constraints --
1285 ----------------------------
1288 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1289 RETURNS TRIGGER
1290 LANGUAGE 'plpgsql' VOLATILE AS $$
1291 BEGIN
1292 IF NOT EXISTS (
1293 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1294 ) THEN
1295 --RAISE 'Cannot create issue without an initial initiative.' USING
1296 -- ERRCODE = 'integrity_constraint_violation',
1297 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1298 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1299 END IF;
1300 RETURN NULL;
1301 END;
1302 $$;
1304 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1305 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1306 FOR EACH ROW EXECUTE PROCEDURE
1307 "issue_requires_first_initiative_trigger"();
1309 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1310 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1313 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1314 RETURNS TRIGGER
1315 LANGUAGE 'plpgsql' VOLATILE AS $$
1316 DECLARE
1317 "reference_lost" BOOLEAN;
1318 BEGIN
1319 IF TG_OP = 'DELETE' THEN
1320 "reference_lost" := TRUE;
1321 ELSE
1322 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1323 END IF;
1324 IF
1325 "reference_lost" AND NOT EXISTS (
1326 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1328 THEN
1329 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1330 END IF;
1331 RETURN NULL;
1332 END;
1333 $$;
1335 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1336 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1337 FOR EACH ROW EXECUTE PROCEDURE
1338 "last_initiative_deletes_issue_trigger"();
1340 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1341 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1344 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1345 RETURNS TRIGGER
1346 LANGUAGE 'plpgsql' VOLATILE AS $$
1347 BEGIN
1348 IF NOT EXISTS (
1349 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1350 ) THEN
1351 --RAISE 'Cannot create initiative without an initial draft.' USING
1352 -- ERRCODE = 'integrity_constraint_violation',
1353 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1354 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1355 END IF;
1356 RETURN NULL;
1357 END;
1358 $$;
1360 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1361 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1362 FOR EACH ROW EXECUTE PROCEDURE
1363 "initiative_requires_first_draft_trigger"();
1365 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1366 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1369 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1370 RETURNS TRIGGER
1371 LANGUAGE 'plpgsql' VOLATILE AS $$
1372 DECLARE
1373 "reference_lost" BOOLEAN;
1374 BEGIN
1375 IF TG_OP = 'DELETE' THEN
1376 "reference_lost" := TRUE;
1377 ELSE
1378 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1379 END IF;
1380 IF
1381 "reference_lost" AND NOT EXISTS (
1382 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1384 THEN
1385 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1386 END IF;
1387 RETURN NULL;
1388 END;
1389 $$;
1391 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1392 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1393 FOR EACH ROW EXECUTE PROCEDURE
1394 "last_draft_deletes_initiative_trigger"();
1396 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1397 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1400 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1401 RETURNS TRIGGER
1402 LANGUAGE 'plpgsql' VOLATILE AS $$
1403 BEGIN
1404 IF NOT EXISTS (
1405 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1406 ) THEN
1407 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1408 END IF;
1409 RETURN NULL;
1410 END;
1411 $$;
1413 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1414 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1415 FOR EACH ROW EXECUTE PROCEDURE
1416 "suggestion_requires_first_opinion_trigger"();
1418 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1419 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1422 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1423 RETURNS TRIGGER
1424 LANGUAGE 'plpgsql' VOLATILE AS $$
1425 DECLARE
1426 "reference_lost" BOOLEAN;
1427 BEGIN
1428 IF TG_OP = 'DELETE' THEN
1429 "reference_lost" := TRUE;
1430 ELSE
1431 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1432 END IF;
1433 IF
1434 "reference_lost" AND NOT EXISTS (
1435 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1437 THEN
1438 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1439 END IF;
1440 RETURN NULL;
1441 END;
1442 $$;
1444 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1445 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1446 FOR EACH ROW EXECUTE PROCEDURE
1447 "last_opinion_deletes_suggestion_trigger"();
1449 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1450 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1454 ---------------------------------------------------------------
1455 -- Ensure that votes are not modified when issues are frozen --
1456 ---------------------------------------------------------------
1458 -- NOTE: Frontends should ensure this anyway, but in case of programming
1459 -- errors the following triggers ensure data integrity.
1462 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1463 RETURNS TRIGGER
1464 LANGUAGE 'plpgsql' VOLATILE AS $$
1465 DECLARE
1466 "issue_id_v" "issue"."id"%TYPE;
1467 "issue_row" "issue"%ROWTYPE;
1468 BEGIN
1469 IF TG_OP = 'DELETE' THEN
1470 "issue_id_v" := OLD."issue_id";
1471 ELSE
1472 "issue_id_v" := NEW."issue_id";
1473 END IF;
1474 SELECT INTO "issue_row" * FROM "issue"
1475 WHERE "id" = "issue_id_v" FOR SHARE;
1476 IF "issue_row"."closed" NOTNULL THEN
1477 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1478 END IF;
1479 RETURN NULL;
1480 END;
1481 $$;
1483 CREATE TRIGGER "forbid_changes_on_closed_issue"
1484 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1485 FOR EACH ROW EXECUTE PROCEDURE
1486 "forbid_changes_on_closed_issue_trigger"();
1488 CREATE TRIGGER "forbid_changes_on_closed_issue"
1489 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1490 FOR EACH ROW EXECUTE PROCEDURE
1491 "forbid_changes_on_closed_issue_trigger"();
1493 CREATE TRIGGER "forbid_changes_on_closed_issue"
1494 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1495 FOR EACH ROW EXECUTE PROCEDURE
1496 "forbid_changes_on_closed_issue_trigger"();
1498 COMMENT ON FUNCTION "forbid_changes_on_closed_issue_trigger"() IS 'Implementation of triggers "forbid_changes_on_closed_issue" on tables "direct_voter", "delegating_voter" and "vote"';
1499 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "direct_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
1500 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "delegating_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
1501 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "vote" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
1505 --------------------------------------------------------------------
1506 -- Auto-retrieval of fields only needed for referential integrity --
1507 --------------------------------------------------------------------
1510 CREATE FUNCTION "autofill_issue_id_trigger"()
1511 RETURNS TRIGGER
1512 LANGUAGE 'plpgsql' VOLATILE AS $$
1513 BEGIN
1514 IF NEW."issue_id" ISNULL THEN
1515 SELECT "issue_id" INTO NEW."issue_id"
1516 FROM "initiative" WHERE "id" = NEW."initiative_id";
1517 END IF;
1518 RETURN NEW;
1519 END;
1520 $$;
1522 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1523 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1525 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1526 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1528 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1529 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1530 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1533 CREATE FUNCTION "autofill_initiative_id_trigger"()
1534 RETURNS TRIGGER
1535 LANGUAGE 'plpgsql' VOLATILE AS $$
1536 BEGIN
1537 IF NEW."initiative_id" ISNULL THEN
1538 SELECT "initiative_id" INTO NEW."initiative_id"
1539 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1540 END IF;
1541 RETURN NEW;
1542 END;
1543 $$;
1545 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1546 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1548 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1549 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1553 -----------------------------------------------------
1554 -- Automatic calculation of certain default values --
1555 -----------------------------------------------------
1558 CREATE FUNCTION "copy_timings_trigger"()
1559 RETURNS TRIGGER
1560 LANGUAGE 'plpgsql' VOLATILE AS $$
1561 DECLARE
1562 "policy_row" "policy"%ROWTYPE;
1563 BEGIN
1564 SELECT * INTO "policy_row" FROM "policy"
1565 WHERE "id" = NEW."policy_id";
1566 IF NEW."admission_time" ISNULL THEN
1567 NEW."admission_time" := "policy_row"."admission_time";
1568 END IF;
1569 IF NEW."discussion_time" ISNULL THEN
1570 NEW."discussion_time" := "policy_row"."discussion_time";
1571 END IF;
1572 IF NEW."verification_time" ISNULL THEN
1573 NEW."verification_time" := "policy_row"."verification_time";
1574 END IF;
1575 IF NEW."voting_time" ISNULL THEN
1576 NEW."voting_time" := "policy_row"."voting_time";
1577 END IF;
1578 RETURN NEW;
1579 END;
1580 $$;
1582 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1583 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1585 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1586 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1589 CREATE FUNCTION "default_for_draft_id_trigger"()
1590 RETURNS TRIGGER
1591 LANGUAGE 'plpgsql' VOLATILE AS $$
1592 BEGIN
1593 IF NEW."draft_id" ISNULL THEN
1594 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1595 WHERE "initiative_id" = NEW."initiative_id";
1596 END IF;
1597 RETURN NEW;
1598 END;
1599 $$;
1601 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1602 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1603 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1604 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1606 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1607 COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
1608 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';
1612 ----------------------------------------
1613 -- Automatic creation of dependencies --
1614 ----------------------------------------
1617 CREATE FUNCTION "autocreate_interest_trigger"()
1618 RETURNS TRIGGER
1619 LANGUAGE 'plpgsql' VOLATILE AS $$
1620 BEGIN
1621 IF NOT EXISTS (
1622 SELECT NULL FROM "initiative" JOIN "interest"
1623 ON "initiative"."issue_id" = "interest"."issue_id"
1624 WHERE "initiative"."id" = NEW."initiative_id"
1625 AND "interest"."member_id" = NEW."member_id"
1626 ) THEN
1627 BEGIN
1628 INSERT INTO "interest" ("issue_id", "member_id")
1629 SELECT "issue_id", NEW."member_id"
1630 FROM "initiative" WHERE "id" = NEW."initiative_id";
1631 EXCEPTION WHEN unique_violation THEN END;
1632 END IF;
1633 RETURN NEW;
1634 END;
1635 $$;
1637 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1638 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1640 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1641 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';
1644 CREATE FUNCTION "autocreate_supporter_trigger"()
1645 RETURNS TRIGGER
1646 LANGUAGE 'plpgsql' VOLATILE AS $$
1647 BEGIN
1648 IF NOT EXISTS (
1649 SELECT NULL FROM "suggestion" JOIN "supporter"
1650 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1651 WHERE "suggestion"."id" = NEW."suggestion_id"
1652 AND "supporter"."member_id" = NEW."member_id"
1653 ) THEN
1654 BEGIN
1655 INSERT INTO "supporter" ("initiative_id", "member_id")
1656 SELECT "initiative_id", NEW."member_id"
1657 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1658 EXCEPTION WHEN unique_violation THEN END;
1659 END IF;
1660 RETURN NEW;
1661 END;
1662 $$;
1664 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1665 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1667 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1668 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.';
1672 ------------------------------------------
1673 -- Views and helper functions for views --
1674 ------------------------------------------
1677 CREATE VIEW "unit_delegation" AS
1678 SELECT
1679 "unit"."id" AS "unit_id",
1680 "delegation"."id",
1681 "delegation"."truster_id",
1682 "delegation"."trustee_id",
1683 "delegation"."scope"
1684 FROM "unit"
1685 JOIN "delegation"
1686 ON "delegation"."unit_id" = "unit"."id"
1687 JOIN "member"
1688 ON "delegation"."truster_id" = "member"."id"
1689 JOIN "privilege"
1690 ON "delegation"."unit_id" = "privilege"."unit_id"
1691 AND "delegation"."truster_id" = "privilege"."member_id"
1692 WHERE "member"."active" AND "privilege"."voting_right";
1694 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1697 CREATE VIEW "area_delegation" AS
1698 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1699 "area"."id" AS "area_id",
1700 "delegation"."id",
1701 "delegation"."truster_id",
1702 "delegation"."trustee_id",
1703 "delegation"."scope"
1704 FROM "area"
1705 JOIN "delegation"
1706 ON "delegation"."unit_id" = "area"."unit_id"
1707 OR "delegation"."area_id" = "area"."id"
1708 JOIN "member"
1709 ON "delegation"."truster_id" = "member"."id"
1710 JOIN "privilege"
1711 ON "area"."unit_id" = "privilege"."unit_id"
1712 AND "delegation"."truster_id" = "privilege"."member_id"
1713 WHERE "member"."active" AND "privilege"."voting_right"
1714 ORDER BY
1715 "area"."id",
1716 "delegation"."truster_id",
1717 "delegation"."scope" DESC;
1719 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1722 CREATE VIEW "issue_delegation" AS
1723 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1724 "issue"."id" AS "issue_id",
1725 "delegation"."id",
1726 "delegation"."truster_id",
1727 "delegation"."trustee_id",
1728 "delegation"."scope"
1729 FROM "issue"
1730 JOIN "area"
1731 ON "area"."id" = "issue"."area_id"
1732 JOIN "delegation"
1733 ON "delegation"."unit_id" = "area"."unit_id"
1734 OR "delegation"."area_id" = "area"."id"
1735 OR "delegation"."issue_id" = "issue"."id"
1736 JOIN "member"
1737 ON "delegation"."truster_id" = "member"."id"
1738 JOIN "privilege"
1739 ON "area"."unit_id" = "privilege"."unit_id"
1740 AND "delegation"."truster_id" = "privilege"."member_id"
1741 WHERE "member"."active" AND "privilege"."voting_right"
1742 ORDER BY
1743 "issue"."id",
1744 "delegation"."truster_id",
1745 "delegation"."scope" DESC;
1747 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1750 CREATE FUNCTION "membership_weight_with_skipping"
1751 ( "area_id_p" "area"."id"%TYPE,
1752 "member_id_p" "member"."id"%TYPE,
1753 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1754 RETURNS INT4
1755 LANGUAGE 'plpgsql' STABLE AS $$
1756 DECLARE
1757 "sum_v" INT4;
1758 "delegation_row" "area_delegation"%ROWTYPE;
1759 BEGIN
1760 "sum_v" := 1;
1761 FOR "delegation_row" IN
1762 SELECT "area_delegation".*
1763 FROM "area_delegation" LEFT JOIN "membership"
1764 ON "membership"."area_id" = "area_id_p"
1765 AND "membership"."member_id" = "area_delegation"."truster_id"
1766 WHERE "area_delegation"."area_id" = "area_id_p"
1767 AND "area_delegation"."trustee_id" = "member_id_p"
1768 AND "membership"."member_id" ISNULL
1769 LOOP
1770 IF NOT
1771 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1772 THEN
1773 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1774 "area_id_p",
1775 "delegation_row"."truster_id",
1776 "skip_member_ids_p" || "delegation_row"."truster_id"
1777 );
1778 END IF;
1779 END LOOP;
1780 RETURN "sum_v";
1781 END;
1782 $$;
1784 COMMENT ON FUNCTION "membership_weight_with_skipping"
1785 ( "area"."id"%TYPE,
1786 "member"."id"%TYPE,
1787 INT4[] )
1788 IS 'Helper function for "membership_weight" function';
1791 CREATE FUNCTION "membership_weight"
1792 ( "area_id_p" "area"."id"%TYPE,
1793 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1794 RETURNS INT4
1795 LANGUAGE 'plpgsql' STABLE AS $$
1796 BEGIN
1797 RETURN "membership_weight_with_skipping"(
1798 "area_id_p",
1799 "member_id_p",
1800 ARRAY["member_id_p"]
1801 );
1802 END;
1803 $$;
1805 COMMENT ON FUNCTION "membership_weight"
1806 ( "area"."id"%TYPE,
1807 "member"."id"%TYPE )
1808 IS 'Calculates the potential voting weight of a member in a given area';
1811 CREATE VIEW "member_count_view" AS
1812 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1814 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1817 CREATE VIEW "unit_member_count" AS
1818 SELECT
1819 "unit"."id" AS "unit_id",
1820 sum("member"."id") AS "member_count"
1821 FROM "unit"
1822 LEFT JOIN "privilege"
1823 ON "privilege"."unit_id" = "unit"."id"
1824 AND "privilege"."voting_right"
1825 LEFT JOIN "member"
1826 ON "member"."id" = "privilege"."member_id"
1827 AND "member"."active"
1828 GROUP BY "unit"."id";
1830 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1833 CREATE VIEW "area_member_count" AS
1834 SELECT
1835 "area"."id" AS "area_id",
1836 count("member"."id") AS "direct_member_count",
1837 coalesce(
1838 sum(
1839 CASE WHEN "member"."id" NOTNULL THEN
1840 "membership_weight"("area"."id", "member"."id")
1841 ELSE 0 END
1843 ) AS "member_weight"
1844 FROM "area"
1845 LEFT JOIN "membership"
1846 ON "area"."id" = "membership"."area_id"
1847 LEFT JOIN "privilege"
1848 ON "privilege"."unit_id" = "area"."unit_id"
1849 AND "privilege"."member_id" = "membership"."member_id"
1850 AND "privilege"."voting_right"
1851 LEFT JOIN "member"
1852 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1853 AND "member"."active"
1854 GROUP BY "area"."id";
1856 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1859 CREATE VIEW "opening_draft" AS
1860 SELECT "draft".* FROM (
1861 SELECT
1862 "initiative"."id" AS "initiative_id",
1863 min("draft"."id") AS "draft_id"
1864 FROM "initiative" JOIN "draft"
1865 ON "initiative"."id" = "draft"."initiative_id"
1866 GROUP BY "initiative"."id"
1867 ) AS "subquery"
1868 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1870 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1873 CREATE VIEW "current_draft" AS
1874 SELECT "draft".* FROM (
1875 SELECT
1876 "initiative"."id" AS "initiative_id",
1877 max("draft"."id") AS "draft_id"
1878 FROM "initiative" JOIN "draft"
1879 ON "initiative"."id" = "draft"."initiative_id"
1880 GROUP BY "initiative"."id"
1881 ) AS "subquery"
1882 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1884 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1887 CREATE VIEW "critical_opinion" AS
1888 SELECT * FROM "opinion"
1889 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1890 OR ("degree" = -2 AND "fulfilled" = TRUE);
1892 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1895 CREATE VIEW "battle_participant" AS
1896 SELECT "initiative"."id", "initiative"."issue_id"
1897 FROM "issue" JOIN "initiative"
1898 ON "issue"."id" = "initiative"."issue_id"
1899 WHERE "initiative"."admitted"
1900 UNION ALL
1901 SELECT NULL, "id" AS "issue_id"
1902 FROM "issue";
1904 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1907 CREATE VIEW "battle_view" AS
1908 SELECT
1909 "issue"."id" AS "issue_id",
1910 "winning_initiative"."id" AS "winning_initiative_id",
1911 "losing_initiative"."id" AS "losing_initiative_id",
1912 sum(
1913 CASE WHEN
1914 coalesce("better_vote"."grade", 0) >
1915 coalesce("worse_vote"."grade", 0)
1916 THEN "direct_voter"."weight" ELSE 0 END
1917 ) AS "count"
1918 FROM "issue"
1919 LEFT JOIN "direct_voter"
1920 ON "issue"."id" = "direct_voter"."issue_id"
1921 JOIN "battle_participant" AS "winning_initiative"
1922 ON "issue"."id" = "winning_initiative"."issue_id"
1923 JOIN "battle_participant" AS "losing_initiative"
1924 ON "issue"."id" = "losing_initiative"."issue_id"
1925 LEFT JOIN "vote" AS "better_vote"
1926 ON "direct_voter"."member_id" = "better_vote"."member_id"
1927 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1928 LEFT JOIN "vote" AS "worse_vote"
1929 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1930 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1931 WHERE "issue"."closed" NOTNULL
1932 AND "issue"."cleaned" ISNULL
1933 AND (
1934 "winning_initiative"."id" != "losing_initiative"."id" OR
1935 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1936 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1937 GROUP BY
1938 "issue"."id",
1939 "winning_initiative"."id",
1940 "losing_initiative"."id";
1942 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';
1945 CREATE VIEW "open_issue" AS
1946 SELECT * FROM "issue" WHERE "closed" ISNULL;
1948 COMMENT ON VIEW "open_issue" IS 'All open issues';
1951 CREATE VIEW "issue_with_ranks_missing" AS
1952 SELECT * FROM "issue"
1953 WHERE "fully_frozen" NOTNULL
1954 AND "closed" NOTNULL
1955 AND "ranks_available" = FALSE;
1957 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
1960 CREATE VIEW "member_contingent" AS
1961 SELECT
1962 "member"."id" AS "member_id",
1963 "contingent"."time_frame",
1964 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
1966 SELECT count(1) FROM "draft"
1967 WHERE "draft"."author_id" = "member"."id"
1968 AND "draft"."created" > now() - "contingent"."time_frame"
1969 ) + (
1970 SELECT count(1) FROM "suggestion"
1971 WHERE "suggestion"."author_id" = "member"."id"
1972 AND "suggestion"."created" > now() - "contingent"."time_frame"
1974 ELSE NULL END AS "text_entry_count",
1975 "contingent"."text_entry_limit",
1976 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
1977 SELECT count(1) FROM "opening_draft"
1978 WHERE "opening_draft"."author_id" = "member"."id"
1979 AND "opening_draft"."created" > now() - "contingent"."time_frame"
1980 ) ELSE NULL END AS "initiative_count",
1981 "contingent"."initiative_limit"
1982 FROM "member" CROSS JOIN "contingent";
1984 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
1986 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
1987 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
1990 CREATE VIEW "member_contingent_left" AS
1991 SELECT
1992 "member_id",
1993 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
1994 max("initiative_limit" - "initiative_count") AS "initiatives_left"
1995 FROM "member_contingent" GROUP BY "member_id";
1997 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.';
2000 CREATE VIEW "event_seen_by_member" AS
2001 SELECT
2002 "member"."id" AS "seen_by_member_id",
2003 CASE WHEN "event"."state" IN (
2004 'voting',
2005 'finished_without_winner',
2006 'finished_with_winner'
2007 ) THEN
2008 'voting'::"notify_level"
2009 ELSE
2010 CASE WHEN "event"."state" IN (
2011 'verification',
2012 'canceled_after_revocation_during_verification',
2013 'canceled_no_initiative_admitted'
2014 ) THEN
2015 'verification'::"notify_level"
2016 ELSE
2017 CASE WHEN "event"."state" IN (
2018 'discussion',
2019 'canceled_after_revocation_during_discussion'
2020 ) THEN
2021 'discussion'::"notify_level"
2022 ELSE
2023 'all'::"notify_level"
2024 END
2025 END
2026 END AS "notify_level",
2027 "event".*
2028 FROM "member" CROSS JOIN "event"
2029 LEFT JOIN "issue"
2030 ON "event"."issue_id" = "issue"."id"
2031 LEFT JOIN "membership"
2032 ON "member"."id" = "membership"."member_id"
2033 AND "issue"."area_id" = "membership"."area_id"
2034 LEFT JOIN "interest"
2035 ON "member"."id" = "interest"."member_id"
2036 AND "event"."issue_id" = "interest"."issue_id"
2037 LEFT JOIN "supporter"
2038 ON "member"."id" = "supporter"."member_id"
2039 AND "event"."initiative_id" = "supporter"."initiative_id"
2040 LEFT JOIN "ignored_member"
2041 ON "member"."id" = "ignored_member"."member_id"
2042 AND "event"."member_id" = "ignored_member"."other_member_id"
2043 LEFT JOIN "ignored_initiative"
2044 ON "member"."id" = "ignored_initiative"."member_id"
2045 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2046 WHERE (
2047 "supporter"."member_id" NOTNULL OR
2048 "interest"."member_id" NOTNULL OR
2049 ( "membership"."member_id" NOTNULL AND
2050 "event"."event" IN (
2051 'issue_state_changed',
2052 'initiative_created_in_new_issue',
2053 'initiative_created_in_existing_issue',
2054 'initiative_revoked' ) ) )
2055 AND "ignored_member"."member_id" ISNULL
2056 AND "ignored_initiative"."member_id" ISNULL;
2058 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
2061 CREATE VIEW "pending_notification" AS
2062 SELECT
2063 "member"."id" AS "seen_by_member_id",
2064 "event".*
2065 FROM "member" CROSS JOIN "event"
2066 LEFT JOIN "issue"
2067 ON "event"."issue_id" = "issue"."id"
2068 LEFT JOIN "membership"
2069 ON "member"."id" = "membership"."member_id"
2070 AND "issue"."area_id" = "membership"."area_id"
2071 LEFT JOIN "interest"
2072 ON "member"."id" = "interest"."member_id"
2073 AND "event"."issue_id" = "interest"."issue_id"
2074 LEFT JOIN "supporter"
2075 ON "member"."id" = "supporter"."member_id"
2076 AND "event"."initiative_id" = "supporter"."initiative_id"
2077 LEFT JOIN "ignored_member"
2078 ON "member"."id" = "ignored_member"."member_id"
2079 AND "event"."member_id" = "ignored_member"."other_member_id"
2080 LEFT JOIN "ignored_initiative"
2081 ON "member"."id" = "ignored_initiative"."member_id"
2082 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2083 WHERE (
2084 "member"."notify_event_id" ISNULL OR
2085 ( "member"."notify_event_id" NOTNULL AND
2086 "member"."notify_event_id" < "event"."id" ) )
2087 AND (
2088 ( "member"."notify_level" >= 'all' ) OR
2089 ( "member"."notify_level" >= 'voting' AND
2090 "event"."state" IN (
2091 'voting',
2092 'finished_without_winner',
2093 'finished_with_winner' ) ) OR
2094 ( "member"."notify_level" >= 'verification' AND
2095 "event"."state" IN (
2096 'verification',
2097 'canceled_after_revocation_during_verification',
2098 'canceled_no_initiative_admitted' ) ) OR
2099 ( "member"."notify_level" >= 'discussion' AND
2100 "event"."state" IN (
2101 'discussion',
2102 'canceled_after_revocation_during_discussion' ) ) )
2103 AND (
2104 "supporter"."member_id" NOTNULL OR
2105 "interest"."member_id" NOTNULL OR
2106 ( "membership"."member_id" NOTNULL AND
2107 "event"."event" IN (
2108 'issue_state_changed',
2109 'initiative_created_in_new_issue',
2110 'initiative_created_in_existing_issue',
2111 'initiative_revoked' ) ) )
2112 AND "ignored_member"."member_id" ISNULL
2113 AND "ignored_initiative"."member_id" ISNULL;
2115 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
2118 CREATE TYPE "timeline_event" AS ENUM (
2119 'issue_created',
2120 'issue_canceled',
2121 'issue_accepted',
2122 'issue_half_frozen',
2123 'issue_finished_without_voting',
2124 'issue_voting_started',
2125 'issue_finished_after_voting',
2126 'initiative_created',
2127 'initiative_revoked',
2128 'draft_created',
2129 'suggestion_created');
2131 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2134 CREATE VIEW "timeline_issue" AS
2135 SELECT
2136 "created" AS "occurrence",
2137 'issue_created'::"timeline_event" AS "event",
2138 "id" AS "issue_id"
2139 FROM "issue"
2140 UNION ALL
2141 SELECT
2142 "closed" AS "occurrence",
2143 'issue_canceled'::"timeline_event" AS "event",
2144 "id" AS "issue_id"
2145 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2146 UNION ALL
2147 SELECT
2148 "accepted" AS "occurrence",
2149 'issue_accepted'::"timeline_event" AS "event",
2150 "id" AS "issue_id"
2151 FROM "issue" WHERE "accepted" NOTNULL
2152 UNION ALL
2153 SELECT
2154 "half_frozen" AS "occurrence",
2155 'issue_half_frozen'::"timeline_event" AS "event",
2156 "id" AS "issue_id"
2157 FROM "issue" WHERE "half_frozen" NOTNULL
2158 UNION ALL
2159 SELECT
2160 "fully_frozen" AS "occurrence",
2161 'issue_voting_started'::"timeline_event" AS "event",
2162 "id" AS "issue_id"
2163 FROM "issue"
2164 WHERE "fully_frozen" NOTNULL
2165 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2166 UNION ALL
2167 SELECT
2168 "closed" AS "occurrence",
2169 CASE WHEN "fully_frozen" = "closed" THEN
2170 'issue_finished_without_voting'::"timeline_event"
2171 ELSE
2172 'issue_finished_after_voting'::"timeline_event"
2173 END AS "event",
2174 "id" AS "issue_id"
2175 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2177 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2180 CREATE VIEW "timeline_initiative" AS
2181 SELECT
2182 "created" AS "occurrence",
2183 'initiative_created'::"timeline_event" AS "event",
2184 "id" AS "initiative_id"
2185 FROM "initiative"
2186 UNION ALL
2187 SELECT
2188 "revoked" AS "occurrence",
2189 'initiative_revoked'::"timeline_event" AS "event",
2190 "id" AS "initiative_id"
2191 FROM "initiative" WHERE "revoked" NOTNULL;
2193 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2196 CREATE VIEW "timeline_draft" AS
2197 SELECT
2198 "created" AS "occurrence",
2199 'draft_created'::"timeline_event" AS "event",
2200 "id" AS "draft_id"
2201 FROM "draft";
2203 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2206 CREATE VIEW "timeline_suggestion" AS
2207 SELECT
2208 "created" AS "occurrence",
2209 'suggestion_created'::"timeline_event" AS "event",
2210 "id" AS "suggestion_id"
2211 FROM "suggestion";
2213 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2216 CREATE VIEW "timeline" AS
2217 SELECT
2218 "occurrence",
2219 "event",
2220 "issue_id",
2221 NULL AS "initiative_id",
2222 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2223 NULL::INT8 AS "suggestion_id"
2224 FROM "timeline_issue"
2225 UNION ALL
2226 SELECT
2227 "occurrence",
2228 "event",
2229 NULL AS "issue_id",
2230 "initiative_id",
2231 NULL AS "draft_id",
2232 NULL AS "suggestion_id"
2233 FROM "timeline_initiative"
2234 UNION ALL
2235 SELECT
2236 "occurrence",
2237 "event",
2238 NULL AS "issue_id",
2239 NULL AS "initiative_id",
2240 "draft_id",
2241 NULL AS "suggestion_id"
2242 FROM "timeline_draft"
2243 UNION ALL
2244 SELECT
2245 "occurrence",
2246 "event",
2247 NULL AS "issue_id",
2248 NULL AS "initiative_id",
2249 NULL AS "draft_id",
2250 "suggestion_id"
2251 FROM "timeline_suggestion";
2253 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2257 --------------------------------------------------
2258 -- Set returning function for delegation chains --
2259 --------------------------------------------------
2262 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2263 ('first', 'intermediate', 'last', 'repetition');
2265 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2268 CREATE TYPE "delegation_chain_row" AS (
2269 "index" INT4,
2270 "member_id" INT4,
2271 "member_valid" BOOLEAN,
2272 "participation" BOOLEAN,
2273 "overridden" BOOLEAN,
2274 "scope_in" "delegation_scope",
2275 "scope_out" "delegation_scope",
2276 "disabled_out" BOOLEAN,
2277 "loop" "delegation_chain_loop_tag" );
2279 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2281 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2282 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';
2283 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2284 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2285 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2286 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2287 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2290 CREATE FUNCTION "delegation_chain"
2291 ( "member_id_p" "member"."id"%TYPE,
2292 "unit_id_p" "unit"."id"%TYPE,
2293 "area_id_p" "area"."id"%TYPE,
2294 "issue_id_p" "issue"."id"%TYPE,
2295 "simulate_trustee_id_p" "member"."id"%TYPE )
2296 RETURNS SETOF "delegation_chain_row"
2297 LANGUAGE 'plpgsql' STABLE AS $$
2298 DECLARE
2299 "scope_v" "delegation_scope";
2300 "unit_id_v" "unit"."id"%TYPE;
2301 "area_id_v" "area"."id"%TYPE;
2302 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2303 "loop_member_id_v" "member"."id"%TYPE;
2304 "output_row" "delegation_chain_row";
2305 "output_rows" "delegation_chain_row"[];
2306 "delegation_row" "delegation"%ROWTYPE;
2307 "row_count" INT4;
2308 "i" INT4;
2309 "loop_v" BOOLEAN;
2310 BEGIN
2311 IF
2312 "unit_id_p" NOTNULL AND
2313 "area_id_p" ISNULL AND
2314 "issue_id_p" ISNULL
2315 THEN
2316 "scope_v" := 'unit';
2317 "unit_id_v" := "unit_id_p";
2318 ELSIF
2319 "unit_id_p" ISNULL AND
2320 "area_id_p" NOTNULL AND
2321 "issue_id_p" ISNULL
2322 THEN
2323 "scope_v" := 'area';
2324 "area_id_v" := "area_id_p";
2325 SELECT "unit_id" INTO "unit_id_v"
2326 FROM "area" WHERE "id" = "area_id_v";
2327 ELSIF
2328 "unit_id_p" ISNULL AND
2329 "area_id_p" ISNULL AND
2330 "issue_id_p" NOTNULL
2331 THEN
2332 "scope_v" := 'issue';
2333 SELECT "area_id" INTO "area_id_v"
2334 FROM "issue" WHERE "id" = "issue_id_p";
2335 SELECT "unit_id" INTO "unit_id_v"
2336 FROM "area" WHERE "id" = "area_id_v";
2337 ELSE
2338 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2339 END IF;
2340 "visited_member_ids" := '{}';
2341 "loop_member_id_v" := NULL;
2342 "output_rows" := '{}';
2343 "output_row"."index" := 0;
2344 "output_row"."member_id" := "member_id_p";
2345 "output_row"."member_valid" := TRUE;
2346 "output_row"."participation" := FALSE;
2347 "output_row"."overridden" := FALSE;
2348 "output_row"."disabled_out" := FALSE;
2349 "output_row"."scope_out" := NULL;
2350 LOOP
2351 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2352 "loop_member_id_v" := "output_row"."member_id";
2353 ELSE
2354 "visited_member_ids" :=
2355 "visited_member_ids" || "output_row"."member_id";
2356 END IF;
2357 IF "output_row"."participation" THEN
2358 "output_row"."overridden" := TRUE;
2359 END IF;
2360 "output_row"."scope_in" := "output_row"."scope_out";
2361 IF EXISTS (
2362 SELECT NULL FROM "member" JOIN "privilege"
2363 ON "privilege"."member_id" = "member"."id"
2364 AND "privilege"."unit_id" = "unit_id_v"
2365 WHERE "id" = "output_row"."member_id"
2366 AND "member"."active" AND "privilege"."voting_right"
2367 ) THEN
2368 IF "scope_v" = 'unit' THEN
2369 SELECT * INTO "delegation_row" FROM "delegation"
2370 WHERE "truster_id" = "output_row"."member_id"
2371 AND "unit_id" = "unit_id_v";
2372 ELSIF "scope_v" = 'area' THEN
2373 "output_row"."participation" := EXISTS (
2374 SELECT NULL FROM "membership"
2375 WHERE "area_id" = "area_id_p"
2376 AND "member_id" = "output_row"."member_id"
2377 );
2378 SELECT * INTO "delegation_row" FROM "delegation"
2379 WHERE "truster_id" = "output_row"."member_id"
2380 AND (
2381 "unit_id" = "unit_id_v" OR
2382 "area_id" = "area_id_v"
2384 ORDER BY "scope" DESC;
2385 ELSIF "scope_v" = 'issue' THEN
2386 "output_row"."participation" := EXISTS (
2387 SELECT NULL FROM "interest"
2388 WHERE "issue_id" = "issue_id_p"
2389 AND "member_id" = "output_row"."member_id"
2390 );
2391 SELECT * INTO "delegation_row" FROM "delegation"
2392 WHERE "truster_id" = "output_row"."member_id"
2393 AND (
2394 "unit_id" = "unit_id_v" OR
2395 "area_id" = "area_id_v" OR
2396 "issue_id" = "issue_id_p"
2398 ORDER BY "scope" DESC;
2399 END IF;
2400 ELSE
2401 "output_row"."member_valid" := FALSE;
2402 "output_row"."participation" := FALSE;
2403 "output_row"."scope_out" := NULL;
2404 "delegation_row" := ROW(NULL);
2405 END IF;
2406 IF
2407 "output_row"."member_id" = "member_id_p" AND
2408 "simulate_trustee_id_p" NOTNULL
2409 THEN
2410 "output_row"."scope_out" := "scope_v";
2411 "output_rows" := "output_rows" || "output_row";
2412 "output_row"."member_id" := "simulate_trustee_id_p";
2413 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2414 "output_row"."scope_out" := "delegation_row"."scope";
2415 "output_rows" := "output_rows" || "output_row";
2416 "output_row"."member_id" := "delegation_row"."trustee_id";
2417 ELSIF "delegation_row"."scope" NOTNULL THEN
2418 "output_row"."scope_out" := "delegation_row"."scope";
2419 "output_row"."disabled_out" := TRUE;
2420 "output_rows" := "output_rows" || "output_row";
2421 EXIT;
2422 ELSE
2423 "output_row"."scope_out" := NULL;
2424 "output_rows" := "output_rows" || "output_row";
2425 EXIT;
2426 END IF;
2427 EXIT WHEN "loop_member_id_v" NOTNULL;
2428 "output_row"."index" := "output_row"."index" + 1;
2429 END LOOP;
2430 "row_count" := array_upper("output_rows", 1);
2431 "i" := 1;
2432 "loop_v" := FALSE;
2433 LOOP
2434 "output_row" := "output_rows"["i"];
2435 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2436 IF "loop_v" THEN
2437 IF "i" + 1 = "row_count" THEN
2438 "output_row"."loop" := 'last';
2439 ELSIF "i" = "row_count" THEN
2440 "output_row"."loop" := 'repetition';
2441 ELSE
2442 "output_row"."loop" := 'intermediate';
2443 END IF;
2444 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2445 "output_row"."loop" := 'first';
2446 "loop_v" := TRUE;
2447 END IF;
2448 IF "scope_v" = 'unit' THEN
2449 "output_row"."participation" := NULL;
2450 END IF;
2451 RETURN NEXT "output_row";
2452 "i" := "i" + 1;
2453 END LOOP;
2454 RETURN;
2455 END;
2456 $$;
2458 COMMENT ON FUNCTION "delegation_chain"
2459 ( "member"."id"%TYPE,
2460 "unit"."id"%TYPE,
2461 "area"."id"%TYPE,
2462 "issue"."id"%TYPE,
2463 "member"."id"%TYPE )
2464 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2467 CREATE FUNCTION "delegation_chain"
2468 ( "member_id_p" "member"."id"%TYPE,
2469 "unit_id_p" "unit"."id"%TYPE,
2470 "area_id_p" "area"."id"%TYPE,
2471 "issue_id_p" "issue"."id"%TYPE )
2472 RETURNS SETOF "delegation_chain_row"
2473 LANGUAGE 'plpgsql' STABLE AS $$
2474 DECLARE
2475 "result_row" "delegation_chain_row";
2476 BEGIN
2477 FOR "result_row" IN
2478 SELECT * FROM "delegation_chain"(
2479 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2481 LOOP
2482 RETURN NEXT "result_row";
2483 END LOOP;
2484 RETURN;
2485 END;
2486 $$;
2488 COMMENT ON FUNCTION "delegation_chain"
2489 ( "member"."id"%TYPE,
2490 "unit"."id"%TYPE,
2491 "area"."id"%TYPE,
2492 "issue"."id"%TYPE )
2493 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2497 ------------------------------
2498 -- Comparison by vote count --
2499 ------------------------------
2501 CREATE FUNCTION "vote_ratio"
2502 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2503 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2504 RETURNS FLOAT8
2505 LANGUAGE 'plpgsql' STABLE AS $$
2506 BEGIN
2507 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2508 RETURN
2509 "positive_votes_p"::FLOAT8 /
2510 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2511 ELSIF "positive_votes_p" > 0 THEN
2512 RETURN "positive_votes_p";
2513 ELSIF "negative_votes_p" > 0 THEN
2514 RETURN 1 - "negative_votes_p";
2515 ELSE
2516 RETURN 0.5;
2517 END IF;
2518 END;
2519 $$;
2521 COMMENT ON FUNCTION "vote_ratio"
2522 ( "initiative"."positive_votes"%TYPE,
2523 "initiative"."negative_votes"%TYPE )
2524 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.';
2528 ------------------------------------------------
2529 -- Locking for snapshots and voting procedure --
2530 ------------------------------------------------
2533 CREATE FUNCTION "share_row_lock_issue_trigger"()
2534 RETURNS TRIGGER
2535 LANGUAGE 'plpgsql' VOLATILE AS $$
2536 BEGIN
2537 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2538 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2539 END IF;
2540 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2541 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2542 RETURN NEW;
2543 ELSE
2544 RETURN OLD;
2545 END IF;
2546 END;
2547 $$;
2549 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2552 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2553 RETURNS TRIGGER
2554 LANGUAGE 'plpgsql' VOLATILE AS $$
2555 BEGIN
2556 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2557 PERFORM NULL FROM "issue"
2558 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2559 WHERE "initiative"."id" = OLD."initiative_id"
2560 FOR SHARE OF "issue";
2561 END IF;
2562 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2563 PERFORM NULL FROM "issue"
2564 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2565 WHERE "initiative"."id" = NEW."initiative_id"
2566 FOR SHARE OF "issue";
2567 RETURN NEW;
2568 ELSE
2569 RETURN OLD;
2570 END IF;
2571 END;
2572 $$;
2574 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2577 CREATE TRIGGER "share_row_lock_issue"
2578 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2579 FOR EACH ROW EXECUTE PROCEDURE
2580 "share_row_lock_issue_trigger"();
2582 CREATE TRIGGER "share_row_lock_issue"
2583 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2584 FOR EACH ROW EXECUTE PROCEDURE
2585 "share_row_lock_issue_trigger"();
2587 CREATE TRIGGER "share_row_lock_issue"
2588 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2589 FOR EACH ROW EXECUTE PROCEDURE
2590 "share_row_lock_issue_trigger"();
2592 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2593 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2594 FOR EACH ROW EXECUTE PROCEDURE
2595 "share_row_lock_issue_via_initiative_trigger"();
2597 CREATE TRIGGER "share_row_lock_issue"
2598 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2599 FOR EACH ROW EXECUTE PROCEDURE
2600 "share_row_lock_issue_trigger"();
2602 CREATE TRIGGER "share_row_lock_issue"
2603 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2604 FOR EACH ROW EXECUTE PROCEDURE
2605 "share_row_lock_issue_trigger"();
2607 CREATE TRIGGER "share_row_lock_issue"
2608 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2609 FOR EACH ROW EXECUTE PROCEDURE
2610 "share_row_lock_issue_trigger"();
2612 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2613 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2614 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2615 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2616 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2617 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2618 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2621 CREATE FUNCTION "lock_issue"
2622 ( "issue_id_p" "issue"."id"%TYPE )
2623 RETURNS VOID
2624 LANGUAGE 'plpgsql' VOLATILE AS $$
2625 BEGIN
2626 LOCK TABLE "member" IN SHARE MODE;
2627 LOCK TABLE "privilege" IN SHARE MODE;
2628 LOCK TABLE "membership" IN SHARE MODE;
2629 LOCK TABLE "policy" IN SHARE MODE;
2630 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2631 -- NOTE: The row-level exclusive lock in combination with the
2632 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2633 -- acquire a row-level share lock on the issue) ensure that no data
2634 -- is changed, which could affect calculation of snapshots or
2635 -- counting of votes. Table "delegation" must be table-level-locked,
2636 -- as it also contains issue- and global-scope delegations.
2637 LOCK TABLE "delegation" IN SHARE MODE;
2638 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2639 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2640 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2641 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2642 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2643 RETURN;
2644 END;
2645 $$;
2647 COMMENT ON FUNCTION "lock_issue"
2648 ( "issue"."id"%TYPE )
2649 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2653 ------------------------------------------------------------------------
2654 -- Regular tasks, except calculcation of snapshots and voting results --
2655 ------------------------------------------------------------------------
2657 CREATE FUNCTION "check_activity"()
2658 RETURNS VOID
2659 LANGUAGE 'plpgsql' VOLATILE AS $$
2660 DECLARE
2661 "system_setting_row" "system_setting"%ROWTYPE;
2662 BEGIN
2663 SELECT * INTO "system_setting_row" FROM "system_setting";
2664 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2665 IF "system_setting_row"."member_ttl" NOTNULL THEN
2666 UPDATE "member" SET "active" = FALSE
2667 WHERE "active" = TRUE
2668 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2669 END IF;
2670 RETURN;
2671 END;
2672 $$;
2674 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2677 CREATE FUNCTION "calculate_member_counts"()
2678 RETURNS VOID
2679 LANGUAGE 'plpgsql' VOLATILE AS $$
2680 BEGIN
2681 LOCK TABLE "member" IN SHARE MODE;
2682 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2683 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2684 LOCK TABLE "area" IN EXCLUSIVE MODE;
2685 LOCK TABLE "privilege" IN SHARE MODE;
2686 LOCK TABLE "membership" IN SHARE MODE;
2687 DELETE FROM "member_count";
2688 INSERT INTO "member_count" ("total_count")
2689 SELECT "total_count" FROM "member_count_view";
2690 UPDATE "unit" SET "member_count" = "view"."member_count"
2691 FROM "unit_member_count" AS "view"
2692 WHERE "view"."unit_id" = "unit"."id";
2693 UPDATE "area" SET
2694 "direct_member_count" = "view"."direct_member_count",
2695 "member_weight" = "view"."member_weight"
2696 FROM "area_member_count" AS "view"
2697 WHERE "view"."area_id" = "area"."id";
2698 RETURN;
2699 END;
2700 $$;
2702 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"';
2706 ------------------------------
2707 -- Calculation of snapshots --
2708 ------------------------------
2710 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2711 ( "issue_id_p" "issue"."id"%TYPE,
2712 "member_id_p" "member"."id"%TYPE,
2713 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2714 RETURNS "direct_population_snapshot"."weight"%TYPE
2715 LANGUAGE 'plpgsql' VOLATILE AS $$
2716 DECLARE
2717 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2718 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2719 "weight_v" INT4;
2720 "sub_weight_v" INT4;
2721 BEGIN
2722 "weight_v" := 0;
2723 FOR "issue_delegation_row" IN
2724 SELECT * FROM "issue_delegation"
2725 WHERE "trustee_id" = "member_id_p"
2726 AND "issue_id" = "issue_id_p"
2727 LOOP
2728 IF NOT EXISTS (
2729 SELECT NULL FROM "direct_population_snapshot"
2730 WHERE "issue_id" = "issue_id_p"
2731 AND "event" = 'periodic'
2732 AND "member_id" = "issue_delegation_row"."truster_id"
2733 ) AND NOT EXISTS (
2734 SELECT NULL FROM "delegating_population_snapshot"
2735 WHERE "issue_id" = "issue_id_p"
2736 AND "event" = 'periodic'
2737 AND "member_id" = "issue_delegation_row"."truster_id"
2738 ) THEN
2739 "delegate_member_ids_v" :=
2740 "member_id_p" || "delegate_member_ids_p";
2741 INSERT INTO "delegating_population_snapshot" (
2742 "issue_id",
2743 "event",
2744 "member_id",
2745 "scope",
2746 "delegate_member_ids"
2747 ) VALUES (
2748 "issue_id_p",
2749 'periodic',
2750 "issue_delegation_row"."truster_id",
2751 "issue_delegation_row"."scope",
2752 "delegate_member_ids_v"
2753 );
2754 "sub_weight_v" := 1 +
2755 "weight_of_added_delegations_for_population_snapshot"(
2756 "issue_id_p",
2757 "issue_delegation_row"."truster_id",
2758 "delegate_member_ids_v"
2759 );
2760 UPDATE "delegating_population_snapshot"
2761 SET "weight" = "sub_weight_v"
2762 WHERE "issue_id" = "issue_id_p"
2763 AND "event" = 'periodic'
2764 AND "member_id" = "issue_delegation_row"."truster_id";
2765 "weight_v" := "weight_v" + "sub_weight_v";
2766 END IF;
2767 END LOOP;
2768 RETURN "weight_v";
2769 END;
2770 $$;
2772 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2773 ( "issue"."id"%TYPE,
2774 "member"."id"%TYPE,
2775 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2776 IS 'Helper function for "create_population_snapshot" function';
2779 CREATE FUNCTION "create_population_snapshot"
2780 ( "issue_id_p" "issue"."id"%TYPE )
2781 RETURNS VOID
2782 LANGUAGE 'plpgsql' VOLATILE AS $$
2783 DECLARE
2784 "member_id_v" "member"."id"%TYPE;
2785 BEGIN
2786 DELETE FROM "direct_population_snapshot"
2787 WHERE "issue_id" = "issue_id_p"
2788 AND "event" = 'periodic';
2789 DELETE FROM "delegating_population_snapshot"
2790 WHERE "issue_id" = "issue_id_p"
2791 AND "event" = 'periodic';
2792 INSERT INTO "direct_population_snapshot"
2793 ("issue_id", "event", "member_id")
2794 SELECT
2795 "issue_id_p" AS "issue_id",
2796 'periodic'::"snapshot_event" AS "event",
2797 "member"."id" AS "member_id"
2798 FROM "issue"
2799 JOIN "area" ON "issue"."area_id" = "area"."id"
2800 JOIN "membership" ON "area"."id" = "membership"."area_id"
2801 JOIN "member" ON "membership"."member_id" = "member"."id"
2802 JOIN "privilege"
2803 ON "privilege"."unit_id" = "area"."unit_id"
2804 AND "privilege"."member_id" = "member"."id"
2805 WHERE "issue"."id" = "issue_id_p"
2806 AND "member"."active" AND "privilege"."voting_right"
2807 UNION
2808 SELECT
2809 "issue_id_p" AS "issue_id",
2810 'periodic'::"snapshot_event" AS "event",
2811 "member"."id" AS "member_id"
2812 FROM "issue"
2813 JOIN "area" ON "issue"."area_id" = "area"."id"
2814 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2815 JOIN "member" ON "interest"."member_id" = "member"."id"
2816 JOIN "privilege"
2817 ON "privilege"."unit_id" = "area"."unit_id"
2818 AND "privilege"."member_id" = "member"."id"
2819 WHERE "issue"."id" = "issue_id_p"
2820 AND "member"."active" AND "privilege"."voting_right";
2821 FOR "member_id_v" IN
2822 SELECT "member_id" FROM "direct_population_snapshot"
2823 WHERE "issue_id" = "issue_id_p"
2824 AND "event" = 'periodic'
2825 LOOP
2826 UPDATE "direct_population_snapshot" SET
2827 "weight" = 1 +
2828 "weight_of_added_delegations_for_population_snapshot"(
2829 "issue_id_p",
2830 "member_id_v",
2831 '{}'
2833 WHERE "issue_id" = "issue_id_p"
2834 AND "event" = 'periodic'
2835 AND "member_id" = "member_id_v";
2836 END LOOP;
2837 RETURN;
2838 END;
2839 $$;
2841 COMMENT ON FUNCTION "create_population_snapshot"
2842 ( "issue"."id"%TYPE )
2843 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.';
2846 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2847 ( "issue_id_p" "issue"."id"%TYPE,
2848 "member_id_p" "member"."id"%TYPE,
2849 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2850 RETURNS "direct_interest_snapshot"."weight"%TYPE
2851 LANGUAGE 'plpgsql' VOLATILE AS $$
2852 DECLARE
2853 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2854 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2855 "weight_v" INT4;
2856 "sub_weight_v" INT4;
2857 BEGIN
2858 "weight_v" := 0;
2859 FOR "issue_delegation_row" IN
2860 SELECT * FROM "issue_delegation"
2861 WHERE "trustee_id" = "member_id_p"
2862 AND "issue_id" = "issue_id_p"
2863 LOOP
2864 IF NOT EXISTS (
2865 SELECT NULL FROM "direct_interest_snapshot"
2866 WHERE "issue_id" = "issue_id_p"
2867 AND "event" = 'periodic'
2868 AND "member_id" = "issue_delegation_row"."truster_id"
2869 ) AND NOT EXISTS (
2870 SELECT NULL FROM "delegating_interest_snapshot"
2871 WHERE "issue_id" = "issue_id_p"
2872 AND "event" = 'periodic'
2873 AND "member_id" = "issue_delegation_row"."truster_id"
2874 ) THEN
2875 "delegate_member_ids_v" :=
2876 "member_id_p" || "delegate_member_ids_p";
2877 INSERT INTO "delegating_interest_snapshot" (
2878 "issue_id",
2879 "event",
2880 "member_id",
2881 "scope",
2882 "delegate_member_ids"
2883 ) VALUES (
2884 "issue_id_p",
2885 'periodic',
2886 "issue_delegation_row"."truster_id",
2887 "issue_delegation_row"."scope",
2888 "delegate_member_ids_v"
2889 );
2890 "sub_weight_v" := 1 +
2891 "weight_of_added_delegations_for_interest_snapshot"(
2892 "issue_id_p",
2893 "issue_delegation_row"."truster_id",
2894 "delegate_member_ids_v"
2895 );
2896 UPDATE "delegating_interest_snapshot"
2897 SET "weight" = "sub_weight_v"
2898 WHERE "issue_id" = "issue_id_p"
2899 AND "event" = 'periodic'
2900 AND "member_id" = "issue_delegation_row"."truster_id";
2901 "weight_v" := "weight_v" + "sub_weight_v";
2902 END IF;
2903 END LOOP;
2904 RETURN "weight_v";
2905 END;
2906 $$;
2908 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2909 ( "issue"."id"%TYPE,
2910 "member"."id"%TYPE,
2911 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2912 IS 'Helper function for "create_interest_snapshot" function';
2915 CREATE FUNCTION "create_interest_snapshot"
2916 ( "issue_id_p" "issue"."id"%TYPE )
2917 RETURNS VOID
2918 LANGUAGE 'plpgsql' VOLATILE AS $$
2919 DECLARE
2920 "member_id_v" "member"."id"%TYPE;
2921 BEGIN
2922 DELETE FROM "direct_interest_snapshot"
2923 WHERE "issue_id" = "issue_id_p"
2924 AND "event" = 'periodic';
2925 DELETE FROM "delegating_interest_snapshot"
2926 WHERE "issue_id" = "issue_id_p"
2927 AND "event" = 'periodic';
2928 DELETE FROM "direct_supporter_snapshot"
2929 WHERE "issue_id" = "issue_id_p"
2930 AND "event" = 'periodic';
2931 INSERT INTO "direct_interest_snapshot"
2932 ("issue_id", "event", "member_id")
2933 SELECT
2934 "issue_id_p" AS "issue_id",
2935 'periodic' AS "event",
2936 "member"."id" AS "member_id"
2937 FROM "issue"
2938 JOIN "area" ON "issue"."area_id" = "area"."id"
2939 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2940 JOIN "member" ON "interest"."member_id" = "member"."id"
2941 JOIN "privilege"
2942 ON "privilege"."unit_id" = "area"."unit_id"
2943 AND "privilege"."member_id" = "member"."id"
2944 WHERE "issue"."id" = "issue_id_p"
2945 AND "member"."active" AND "privilege"."voting_right";
2946 FOR "member_id_v" IN
2947 SELECT "member_id" FROM "direct_interest_snapshot"
2948 WHERE "issue_id" = "issue_id_p"
2949 AND "event" = 'periodic'
2950 LOOP
2951 UPDATE "direct_interest_snapshot" SET
2952 "weight" = 1 +
2953 "weight_of_added_delegations_for_interest_snapshot"(
2954 "issue_id_p",
2955 "member_id_v",
2956 '{}'
2958 WHERE "issue_id" = "issue_id_p"
2959 AND "event" = 'periodic'
2960 AND "member_id" = "member_id_v";
2961 END LOOP;
2962 INSERT INTO "direct_supporter_snapshot"
2963 ( "issue_id", "initiative_id", "event", "member_id",
2964 "informed", "satisfied" )
2965 SELECT
2966 "issue_id_p" AS "issue_id",
2967 "initiative"."id" AS "initiative_id",
2968 'periodic' AS "event",
2969 "supporter"."member_id" AS "member_id",
2970 "supporter"."draft_id" = "current_draft"."id" AS "informed",
2971 NOT EXISTS (
2972 SELECT NULL FROM "critical_opinion"
2973 WHERE "initiative_id" = "initiative"."id"
2974 AND "member_id" = "supporter"."member_id"
2975 ) AS "satisfied"
2976 FROM "initiative"
2977 JOIN "supporter"
2978 ON "supporter"."initiative_id" = "initiative"."id"
2979 JOIN "current_draft"
2980 ON "initiative"."id" = "current_draft"."initiative_id"
2981 JOIN "direct_interest_snapshot"
2982 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
2983 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
2984 AND "event" = 'periodic'
2985 WHERE "initiative"."issue_id" = "issue_id_p";
2986 RETURN;
2987 END;
2988 $$;
2990 COMMENT ON FUNCTION "create_interest_snapshot"
2991 ( "issue"."id"%TYPE )
2992 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.';
2995 CREATE FUNCTION "create_snapshot"
2996 ( "issue_id_p" "issue"."id"%TYPE )
2997 RETURNS VOID
2998 LANGUAGE 'plpgsql' VOLATILE AS $$
2999 DECLARE
3000 "initiative_id_v" "initiative"."id"%TYPE;
3001 "suggestion_id_v" "suggestion"."id"%TYPE;
3002 BEGIN
3003 PERFORM "lock_issue"("issue_id_p");
3004 PERFORM "create_population_snapshot"("issue_id_p");
3005 PERFORM "create_interest_snapshot"("issue_id_p");
3006 UPDATE "issue" SET
3007 "snapshot" = now(),
3008 "latest_snapshot_event" = 'periodic',
3009 "population" = (
3010 SELECT coalesce(sum("weight"), 0)
3011 FROM "direct_population_snapshot"
3012 WHERE "issue_id" = "issue_id_p"
3013 AND "event" = 'periodic'
3015 WHERE "id" = "issue_id_p";
3016 FOR "initiative_id_v" IN
3017 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3018 LOOP
3019 UPDATE "initiative" SET
3020 "supporter_count" = (
3021 SELECT coalesce(sum("di"."weight"), 0)
3022 FROM "direct_interest_snapshot" AS "di"
3023 JOIN "direct_supporter_snapshot" AS "ds"
3024 ON "di"."member_id" = "ds"."member_id"
3025 WHERE "di"."issue_id" = "issue_id_p"
3026 AND "di"."event" = 'periodic'
3027 AND "ds"."initiative_id" = "initiative_id_v"
3028 AND "ds"."event" = 'periodic'
3029 ),
3030 "informed_supporter_count" = (
3031 SELECT coalesce(sum("di"."weight"), 0)
3032 FROM "direct_interest_snapshot" AS "di"
3033 JOIN "direct_supporter_snapshot" AS "ds"
3034 ON "di"."member_id" = "ds"."member_id"
3035 WHERE "di"."issue_id" = "issue_id_p"
3036 AND "di"."event" = 'periodic'
3037 AND "ds"."initiative_id" = "initiative_id_v"
3038 AND "ds"."event" = 'periodic'
3039 AND "ds"."informed"
3040 ),
3041 "satisfied_supporter_count" = (
3042 SELECT coalesce(sum("di"."weight"), 0)
3043 FROM "direct_interest_snapshot" AS "di"
3044 JOIN "direct_supporter_snapshot" AS "ds"
3045 ON "di"."member_id" = "ds"."member_id"
3046 WHERE "di"."issue_id" = "issue_id_p"
3047 AND "di"."event" = 'periodic'
3048 AND "ds"."initiative_id" = "initiative_id_v"
3049 AND "ds"."event" = 'periodic'
3050 AND "ds"."satisfied"
3051 ),
3052 "satisfied_informed_supporter_count" = (
3053 SELECT coalesce(sum("di"."weight"), 0)
3054 FROM "direct_interest_snapshot" AS "di"
3055 JOIN "direct_supporter_snapshot" AS "ds"
3056 ON "di"."member_id" = "ds"."member_id"
3057 WHERE "di"."issue_id" = "issue_id_p"
3058 AND "di"."event" = 'periodic'
3059 AND "ds"."initiative_id" = "initiative_id_v"
3060 AND "ds"."event" = 'periodic'
3061 AND "ds"."informed"
3062 AND "ds"."satisfied"
3064 WHERE "id" = "initiative_id_v";
3065 FOR "suggestion_id_v" IN
3066 SELECT "id" FROM "suggestion"
3067 WHERE "initiative_id" = "initiative_id_v"
3068 LOOP
3069 UPDATE "suggestion" SET
3070 "minus2_unfulfilled_count" = (
3071 SELECT coalesce(sum("snapshot"."weight"), 0)
3072 FROM "issue" CROSS JOIN "opinion"
3073 JOIN "direct_interest_snapshot" AS "snapshot"
3074 ON "snapshot"."issue_id" = "issue"."id"
3075 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3076 AND "snapshot"."member_id" = "opinion"."member_id"
3077 WHERE "issue"."id" = "issue_id_p"
3078 AND "opinion"."suggestion_id" = "suggestion_id_v"
3079 AND "opinion"."degree" = -2
3080 AND "opinion"."fulfilled" = FALSE
3081 ),
3082 "minus2_fulfilled_count" = (
3083 SELECT coalesce(sum("snapshot"."weight"), 0)
3084 FROM "issue" CROSS JOIN "opinion"
3085 JOIN "direct_interest_snapshot" AS "snapshot"
3086 ON "snapshot"."issue_id" = "issue"."id"
3087 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3088 AND "snapshot"."member_id" = "opinion"."member_id"
3089 WHERE "issue"."id" = "issue_id_p"
3090 AND "opinion"."suggestion_id" = "suggestion_id_v"
3091 AND "opinion"."degree" = -2
3092 AND "opinion"."fulfilled" = TRUE
3093 ),
3094 "minus1_unfulfilled_count" = (
3095 SELECT coalesce(sum("snapshot"."weight"), 0)
3096 FROM "issue" CROSS JOIN "opinion"
3097 JOIN "direct_interest_snapshot" AS "snapshot"
3098 ON "snapshot"."issue_id" = "issue"."id"
3099 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3100 AND "snapshot"."member_id" = "opinion"."member_id"
3101 WHERE "issue"."id" = "issue_id_p"
3102 AND "opinion"."suggestion_id" = "suggestion_id_v"
3103 AND "opinion"."degree" = -1
3104 AND "opinion"."fulfilled" = FALSE
3105 ),
3106 "minus1_fulfilled_count" = (
3107 SELECT coalesce(sum("snapshot"."weight"), 0)
3108 FROM "issue" CROSS JOIN "opinion"
3109 JOIN "direct_interest_snapshot" AS "snapshot"
3110 ON "snapshot"."issue_id" = "issue"."id"
3111 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3112 AND "snapshot"."member_id" = "opinion"."member_id"
3113 WHERE "issue"."id" = "issue_id_p"
3114 AND "opinion"."suggestion_id" = "suggestion_id_v"
3115 AND "opinion"."degree" = -1
3116 AND "opinion"."fulfilled" = TRUE
3117 ),
3118 "plus1_unfulfilled_count" = (
3119 SELECT coalesce(sum("snapshot"."weight"), 0)
3120 FROM "issue" CROSS JOIN "opinion"
3121 JOIN "direct_interest_snapshot" AS "snapshot"
3122 ON "snapshot"."issue_id" = "issue"."id"
3123 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3124 AND "snapshot"."member_id" = "opinion"."member_id"
3125 WHERE "issue"."id" = "issue_id_p"
3126 AND "opinion"."suggestion_id" = "suggestion_id_v"
3127 AND "opinion"."degree" = 1
3128 AND "opinion"."fulfilled" = FALSE
3129 ),
3130 "plus1_fulfilled_count" = (
3131 SELECT coalesce(sum("snapshot"."weight"), 0)
3132 FROM "issue" CROSS JOIN "opinion"
3133 JOIN "direct_interest_snapshot" AS "snapshot"
3134 ON "snapshot"."issue_id" = "issue"."id"
3135 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3136 AND "snapshot"."member_id" = "opinion"."member_id"
3137 WHERE "issue"."id" = "issue_id_p"
3138 AND "opinion"."suggestion_id" = "suggestion_id_v"
3139 AND "opinion"."degree" = 1
3140 AND "opinion"."fulfilled" = TRUE
3141 ),
3142 "plus2_unfulfilled_count" = (
3143 SELECT coalesce(sum("snapshot"."weight"), 0)
3144 FROM "issue" CROSS JOIN "opinion"
3145 JOIN "direct_interest_snapshot" AS "snapshot"
3146 ON "snapshot"."issue_id" = "issue"."id"
3147 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3148 AND "snapshot"."member_id" = "opinion"."member_id"
3149 WHERE "issue"."id" = "issue_id_p"
3150 AND "opinion"."suggestion_id" = "suggestion_id_v"
3151 AND "opinion"."degree" = 2
3152 AND "opinion"."fulfilled" = FALSE
3153 ),
3154 "plus2_fulfilled_count" = (
3155 SELECT coalesce(sum("snapshot"."weight"), 0)
3156 FROM "issue" CROSS JOIN "opinion"
3157 JOIN "direct_interest_snapshot" AS "snapshot"
3158 ON "snapshot"."issue_id" = "issue"."id"
3159 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3160 AND "snapshot"."member_id" = "opinion"."member_id"
3161 WHERE "issue"."id" = "issue_id_p"
3162 AND "opinion"."suggestion_id" = "suggestion_id_v"
3163 AND "opinion"."degree" = 2
3164 AND "opinion"."fulfilled" = TRUE
3166 WHERE "suggestion"."id" = "suggestion_id_v";
3167 END LOOP;
3168 END LOOP;
3169 RETURN;
3170 END;
3171 $$;
3173 COMMENT ON FUNCTION "create_snapshot"
3174 ( "issue"."id"%TYPE )
3175 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.';
3178 CREATE FUNCTION "set_snapshot_event"
3179 ( "issue_id_p" "issue"."id"%TYPE,
3180 "event_p" "snapshot_event" )
3181 RETURNS VOID
3182 LANGUAGE 'plpgsql' VOLATILE AS $$
3183 DECLARE
3184 "event_v" "issue"."latest_snapshot_event"%TYPE;
3185 BEGIN
3186 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3187 WHERE "id" = "issue_id_p" FOR UPDATE;
3188 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3189 WHERE "id" = "issue_id_p";
3190 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3191 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3192 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3193 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3194 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3195 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3196 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3197 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3198 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3199 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3200 RETURN;
3201 END;
3202 $$;
3204 COMMENT ON FUNCTION "set_snapshot_event"
3205 ( "issue"."id"%TYPE,
3206 "snapshot_event" )
3207 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3211 ---------------------
3212 -- Freezing issues --
3213 ---------------------
3215 CREATE FUNCTION "freeze_after_snapshot"
3216 ( "issue_id_p" "issue"."id"%TYPE )
3217 RETURNS VOID
3218 LANGUAGE 'plpgsql' VOLATILE AS $$
3219 DECLARE
3220 "issue_row" "issue"%ROWTYPE;
3221 "policy_row" "policy"%ROWTYPE;
3222 "initiative_row" "initiative"%ROWTYPE;
3223 BEGIN
3224 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3225 SELECT * INTO "policy_row"
3226 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3227 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3228 FOR "initiative_row" IN
3229 SELECT * FROM "initiative"
3230 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3231 LOOP
3232 IF
3233 "initiative_row"."satisfied_supporter_count" > 0 AND
3234 "initiative_row"."satisfied_supporter_count" *
3235 "policy_row"."initiative_quorum_den" >=
3236 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3237 THEN
3238 UPDATE "initiative" SET "admitted" = TRUE
3239 WHERE "id" = "initiative_row"."id";
3240 ELSE
3241 UPDATE "initiative" SET "admitted" = FALSE
3242 WHERE "id" = "initiative_row"."id";
3243 END IF;
3244 END LOOP;
3245 IF EXISTS (
3246 SELECT NULL FROM "initiative"
3247 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3248 ) THEN
3249 UPDATE "issue" SET
3250 "state" = 'voting',
3251 "accepted" = coalesce("accepted", now()),
3252 "half_frozen" = coalesce("half_frozen", now()),
3253 "fully_frozen" = now()
3254 WHERE "id" = "issue_id_p";
3255 ELSE
3256 UPDATE "issue" SET
3257 "state" = 'canceled_no_initiative_admitted',
3258 "accepted" = coalesce("accepted", now()),
3259 "half_frozen" = coalesce("half_frozen", now()),
3260 "fully_frozen" = now(),
3261 "closed" = now(),
3262 "ranks_available" = TRUE
3263 WHERE "id" = "issue_id_p";
3264 -- NOTE: The following DELETE statements have effect only when
3265 -- issue state has been manipulated
3266 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3267 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3268 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3269 END IF;
3270 RETURN;
3271 END;
3272 $$;
3274 COMMENT ON FUNCTION "freeze_after_snapshot"
3275 ( "issue"."id"%TYPE )
3276 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3279 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3280 RETURNS VOID
3281 LANGUAGE 'plpgsql' VOLATILE AS $$
3282 DECLARE
3283 "issue_row" "issue"%ROWTYPE;
3284 BEGIN
3285 PERFORM "create_snapshot"("issue_id_p");
3286 PERFORM "freeze_after_snapshot"("issue_id_p");
3287 RETURN;
3288 END;
3289 $$;
3291 COMMENT ON FUNCTION "manual_freeze"
3292 ( "issue"."id"%TYPE )
3293 IS 'Freeze an issue manually (fully) and start voting';
3297 -----------------------
3298 -- Counting of votes --
3299 -----------------------
3302 CREATE FUNCTION "weight_of_added_vote_delegations"
3303 ( "issue_id_p" "issue"."id"%TYPE,
3304 "member_id_p" "member"."id"%TYPE,
3305 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3306 RETURNS "direct_voter"."weight"%TYPE
3307 LANGUAGE 'plpgsql' VOLATILE AS $$
3308 DECLARE
3309 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3310 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3311 "weight_v" INT4;
3312 "sub_weight_v" INT4;
3313 BEGIN
3314 "weight_v" := 0;
3315 FOR "issue_delegation_row" IN
3316 SELECT * FROM "issue_delegation"
3317 WHERE "trustee_id" = "member_id_p"
3318 AND "issue_id" = "issue_id_p"
3319 LOOP
3320 IF NOT EXISTS (
3321 SELECT NULL FROM "direct_voter"
3322 WHERE "member_id" = "issue_delegation_row"."truster_id"
3323 AND "issue_id" = "issue_id_p"
3324 ) AND NOT EXISTS (
3325 SELECT NULL FROM "delegating_voter"
3326 WHERE "member_id" = "issue_delegation_row"."truster_id"
3327 AND "issue_id" = "issue_id_p"
3328 ) THEN
3329 "delegate_member_ids_v" :=
3330 "member_id_p" || "delegate_member_ids_p";
3331 INSERT INTO "delegating_voter" (
3332 "issue_id",
3333 "member_id",
3334 "scope",
3335 "delegate_member_ids"
3336 ) VALUES (
3337 "issue_id_p",
3338 "issue_delegation_row"."truster_id",
3339 "issue_delegation_row"."scope",
3340 "delegate_member_ids_v"
3341 );
3342 "sub_weight_v" := 1 +
3343 "weight_of_added_vote_delegations"(
3344 "issue_id_p",
3345 "issue_delegation_row"."truster_id",
3346 "delegate_member_ids_v"
3347 );
3348 UPDATE "delegating_voter"
3349 SET "weight" = "sub_weight_v"
3350 WHERE "issue_id" = "issue_id_p"
3351 AND "member_id" = "issue_delegation_row"."truster_id";
3352 "weight_v" := "weight_v" + "sub_weight_v";
3353 END IF;
3354 END LOOP;
3355 RETURN "weight_v";
3356 END;
3357 $$;
3359 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3360 ( "issue"."id"%TYPE,
3361 "member"."id"%TYPE,
3362 "delegating_voter"."delegate_member_ids"%TYPE )
3363 IS 'Helper function for "add_vote_delegations" function';
3366 CREATE FUNCTION "add_vote_delegations"
3367 ( "issue_id_p" "issue"."id"%TYPE )
3368 RETURNS VOID
3369 LANGUAGE 'plpgsql' VOLATILE AS $$
3370 DECLARE
3371 "member_id_v" "member"."id"%TYPE;
3372 BEGIN
3373 FOR "member_id_v" IN
3374 SELECT "member_id" FROM "direct_voter"
3375 WHERE "issue_id" = "issue_id_p"
3376 LOOP
3377 UPDATE "direct_voter" SET
3378 "weight" = "weight" + "weight_of_added_vote_delegations"(
3379 "issue_id_p",
3380 "member_id_v",
3381 '{}'
3383 WHERE "member_id" = "member_id_v"
3384 AND "issue_id" = "issue_id_p";
3385 END LOOP;
3386 RETURN;
3387 END;
3388 $$;
3390 COMMENT ON FUNCTION "add_vote_delegations"
3391 ( "issue_id_p" "issue"."id"%TYPE )
3392 IS 'Helper function for "close_voting" function';
3395 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3396 RETURNS VOID
3397 LANGUAGE 'plpgsql' VOLATILE AS $$
3398 DECLARE
3399 "area_id_v" "area"."id"%TYPE;
3400 "unit_id_v" "unit"."id"%TYPE;
3401 "member_id_v" "member"."id"%TYPE;
3402 BEGIN
3403 PERFORM "lock_issue"("issue_id_p");
3404 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3405 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3406 -- delete delegating votes (in cases of manual reset of issue state):
3407 DELETE FROM "delegating_voter"
3408 WHERE "issue_id" = "issue_id_p";
3409 -- delete votes from non-privileged voters:
3410 DELETE FROM "direct_voter"
3411 USING (
3412 SELECT
3413 "direct_voter"."member_id"
3414 FROM "direct_voter"
3415 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3416 LEFT JOIN "privilege"
3417 ON "privilege"."unit_id" = "unit_id_v"
3418 AND "privilege"."member_id" = "direct_voter"."member_id"
3419 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3420 "member"."active" = FALSE OR
3421 "privilege"."voting_right" ISNULL OR
3422 "privilege"."voting_right" = FALSE
3424 ) AS "subquery"
3425 WHERE "direct_voter"."issue_id" = "issue_id_p"
3426 AND "direct_voter"."member_id" = "subquery"."member_id";
3427 -- consider delegations:
3428 UPDATE "direct_voter" SET "weight" = 1
3429 WHERE "issue_id" = "issue_id_p";
3430 PERFORM "add_vote_delegations"("issue_id_p");
3431 -- set voter count and mark issue as being calculated:
3432 UPDATE "issue" SET
3433 "state" = 'calculation',
3434 "closed" = now(),
3435 "voter_count" = (
3436 SELECT coalesce(sum("weight"), 0)
3437 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3439 WHERE "id" = "issue_id_p";
3440 -- materialize battle_view:
3441 -- NOTE: "closed" column of issue must be set at this point
3442 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3443 INSERT INTO "battle" (
3444 "issue_id",
3445 "winning_initiative_id", "losing_initiative_id",
3446 "count"
3447 ) SELECT
3448 "issue_id",
3449 "winning_initiative_id", "losing_initiative_id",
3450 "count"
3451 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3452 -- copy "positive_votes" and "negative_votes" from "battle" table:
3453 UPDATE "initiative" SET
3454 "positive_votes" = "battle_win"."count",
3455 "negative_votes" = "battle_lose"."count"
3456 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3457 WHERE
3458 "battle_win"."issue_id" = "issue_id_p" AND
3459 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3460 "battle_win"."losing_initiative_id" ISNULL AND
3461 "battle_lose"."issue_id" = "issue_id_p" AND
3462 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3463 "battle_lose"."winning_initiative_id" ISNULL;
3464 END;
3465 $$;
3467 COMMENT ON FUNCTION "close_voting"
3468 ( "issue"."id"%TYPE )
3469 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.';
3472 CREATE FUNCTION "defeat_strength"
3473 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3474 RETURNS INT8
3475 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3476 BEGIN
3477 IF "positive_votes_p" > "negative_votes_p" THEN
3478 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3479 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3480 RETURN 0;
3481 ELSE
3482 RETURN -1;
3483 END IF;
3484 END;
3485 $$;
3487 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';
3490 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3491 RETURNS VOID
3492 LANGUAGE 'plpgsql' VOLATILE AS $$
3493 DECLARE
3494 "issue_row" "issue"%ROWTYPE;
3495 "policy_row" "policy"%ROWTYPE;
3496 "dimension_v" INTEGER;
3497 "vote_matrix" INT4[][]; -- absolute votes
3498 "matrix" INT8[][]; -- defeat strength / best paths
3499 "i" INTEGER;
3500 "j" INTEGER;
3501 "k" INTEGER;
3502 "battle_row" "battle"%ROWTYPE;
3503 "rank_ary" INT4[];
3504 "rank_v" INT4;
3505 "done_v" INTEGER;
3506 "winners_ary" INTEGER[];
3507 "initiative_id_v" "initiative"."id"%TYPE;
3508 BEGIN
3509 SELECT * INTO "issue_row"
3510 FROM "issue" WHERE "id" = "issue_id_p"
3511 FOR UPDATE;
3512 SELECT * INTO "policy_row"
3513 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3514 SELECT count(1) INTO "dimension_v"
3515 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3516 -- Create "vote_matrix" with absolute number of votes in pairwise
3517 -- comparison:
3518 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3519 "i" := 1;
3520 "j" := 2;
3521 FOR "battle_row" IN
3522 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3523 ORDER BY
3524 "winning_initiative_id" NULLS LAST,
3525 "losing_initiative_id" NULLS LAST
3526 LOOP
3527 "vote_matrix"["i"]["j"] := "battle_row"."count";
3528 IF "j" = "dimension_v" THEN
3529 "i" := "i" + 1;
3530 "j" := 1;
3531 ELSE
3532 "j" := "j" + 1;
3533 IF "j" = "i" THEN
3534 "j" := "j" + 1;
3535 END IF;
3536 END IF;
3537 END LOOP;
3538 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3539 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3540 END IF;
3541 -- Store defeat strengths in "matrix" using "defeat_strength"
3542 -- function:
3543 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3544 "i" := 1;
3545 LOOP
3546 "j" := 1;
3547 LOOP
3548 IF "i" != "j" THEN
3549 "matrix"["i"]["j"] := "defeat_strength"(
3550 "vote_matrix"["i"]["j"],
3551 "vote_matrix"["j"]["i"]
3552 );
3553 END IF;
3554 EXIT WHEN "j" = "dimension_v";
3555 "j" := "j" + 1;
3556 END LOOP;
3557 EXIT WHEN "i" = "dimension_v";
3558 "i" := "i" + 1;
3559 END LOOP;
3560 -- Find best paths:
3561 "i" := 1;
3562 LOOP
3563 "j" := 1;
3564 LOOP
3565 IF "i" != "j" THEN
3566 "k" := 1;
3567 LOOP
3568 IF "i" != "k" AND "j" != "k" THEN
3569 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3570 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3571 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3572 END IF;
3573 ELSE
3574 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3575 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3576 END IF;
3577 END IF;
3578 END IF;
3579 EXIT WHEN "k" = "dimension_v";
3580 "k" := "k" + 1;
3581 END LOOP;
3582 END IF;
3583 EXIT WHEN "j" = "dimension_v";
3584 "j" := "j" + 1;
3585 END LOOP;
3586 EXIT WHEN "i" = "dimension_v";
3587 "i" := "i" + 1;
3588 END LOOP;
3589 -- Determine order of winners:
3590 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3591 "rank_v" := 1;
3592 "done_v" := 0;
3593 LOOP
3594 "winners_ary" := '{}';
3595 "i" := 1;
3596 LOOP
3597 IF "rank_ary"["i"] ISNULL THEN
3598 "j" := 1;
3599 LOOP
3600 IF
3601 "i" != "j" AND
3602 "rank_ary"["j"] ISNULL AND
3603 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3604 THEN
3605 -- someone else is better
3606 EXIT;
3607 END IF;
3608 IF "j" = "dimension_v" THEN
3609 -- noone is better
3610 "winners_ary" := "winners_ary" || "i";
3611 EXIT;
3612 END IF;
3613 "j" := "j" + 1;
3614 END LOOP;
3615 END IF;
3616 EXIT WHEN "i" = "dimension_v";
3617 "i" := "i" + 1;
3618 END LOOP;
3619 "i" := 1;
3620 LOOP
3621 "rank_ary"["winners_ary"["i"]] := "rank_v";
3622 "done_v" := "done_v" + 1;
3623 EXIT WHEN "i" = array_upper("winners_ary", 1);
3624 "i" := "i" + 1;
3625 END LOOP;
3626 EXIT WHEN "done_v" = "dimension_v";
3627 "rank_v" := "rank_v" + 1;
3628 END LOOP;
3629 -- write preliminary results:
3630 "i" := 1;
3631 FOR "initiative_id_v" IN
3632 SELECT "id" FROM "initiative"
3633 WHERE "issue_id" = "issue_id_p" AND "admitted"
3634 ORDER BY "id"
3635 LOOP
3636 UPDATE "initiative" SET
3637 "direct_majority" =
3638 CASE WHEN "policy_row"."direct_majority_strict" THEN
3639 "positive_votes" * "policy_row"."direct_majority_den" >
3640 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3641 ELSE
3642 "positive_votes" * "policy_row"."direct_majority_den" >=
3643 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3644 END
3645 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3646 AND "issue_row"."voter_count"-"negative_votes" >=
3647 "policy_row"."direct_majority_non_negative",
3648 "indirect_majority" =
3649 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3650 "positive_votes" * "policy_row"."indirect_majority_den" >
3651 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3652 ELSE
3653 "positive_votes" * "policy_row"."indirect_majority_den" >=
3654 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3655 END
3656 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3657 AND "issue_row"."voter_count"-"negative_votes" >=
3658 "policy_row"."indirect_majority_non_negative",
3659 "schulze_rank" = "rank_ary"["i"],
3660 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3661 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3662 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3663 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3664 "winner" = FALSE
3665 WHERE "id" = "initiative_id_v";
3666 "i" := "i" + 1;
3667 END LOOP;
3668 IF "i" != "dimension_v" THEN
3669 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3670 END IF;
3671 -- take indirect majorities into account:
3672 LOOP
3673 UPDATE "initiative" SET "indirect_majority" = TRUE
3674 FROM (
3675 SELECT "new_initiative"."id" AS "initiative_id"
3676 FROM "initiative" "old_initiative"
3677 JOIN "initiative" "new_initiative"
3678 ON "new_initiative"."issue_id" = "issue_id_p"
3679 AND "new_initiative"."indirect_majority" = FALSE
3680 JOIN "battle" "battle_win"
3681 ON "battle_win"."issue_id" = "issue_id_p"
3682 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3683 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3684 JOIN "battle" "battle_lose"
3685 ON "battle_lose"."issue_id" = "issue_id_p"
3686 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3687 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3688 WHERE "old_initiative"."issue_id" = "issue_id_p"
3689 AND "old_initiative"."indirect_majority" = TRUE
3690 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3691 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3692 "policy_row"."indirect_majority_num" *
3693 ("battle_win"."count"+"battle_lose"."count")
3694 ELSE
3695 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3696 "policy_row"."indirect_majority_num" *
3697 ("battle_win"."count"+"battle_lose"."count")
3698 END
3699 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3700 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3701 "policy_row"."indirect_majority_non_negative"
3702 ) AS "subquery"
3703 WHERE "id" = "subquery"."initiative_id";
3704 EXIT WHEN NOT FOUND;
3705 END LOOP;
3706 -- set "multistage_majority" for remaining matching initiatives:
3707 UPDATE "initiative" SET "multistage_majority" = TRUE
3708 FROM (
3709 SELECT "losing_initiative"."id" AS "initiative_id"
3710 FROM "initiative" "losing_initiative"
3711 JOIN "initiative" "winning_initiative"
3712 ON "winning_initiative"."issue_id" = "issue_id_p"
3713 AND "winning_initiative"."admitted"
3714 JOIN "battle" "battle_win"
3715 ON "battle_win"."issue_id" = "issue_id_p"
3716 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3717 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3718 JOIN "battle" "battle_lose"
3719 ON "battle_lose"."issue_id" = "issue_id_p"
3720 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3721 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3722 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3723 AND "losing_initiative"."admitted"
3724 AND "winning_initiative"."schulze_rank" <
3725 "losing_initiative"."schulze_rank"
3726 AND "battle_win"."count" > "battle_lose"."count"
3727 AND (
3728 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3729 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3730 ) AS "subquery"
3731 WHERE "id" = "subquery"."initiative_id";
3732 -- mark eligible initiatives:
3733 UPDATE "initiative" SET "eligible" = TRUE
3734 WHERE "issue_id" = "issue_id_p"
3735 AND "initiative"."direct_majority"
3736 AND "initiative"."indirect_majority"
3737 AND "initiative"."better_than_status_quo"
3738 AND (
3739 "policy_row"."no_multistage_majority" = FALSE OR
3740 "initiative"."multistage_majority" = FALSE )
3741 AND (
3742 "policy_row"."no_reverse_beat_path" = FALSE OR
3743 "initiative"."reverse_beat_path" = FALSE );
3744 -- mark final winner:
3745 UPDATE "initiative" SET "winner" = TRUE
3746 FROM (
3747 SELECT "id" AS "initiative_id"
3748 FROM "initiative"
3749 WHERE "issue_id" = "issue_id_p" AND "eligible"
3750 ORDER BY "schulze_rank", "id"
3751 LIMIT 1
3752 ) AS "subquery"
3753 WHERE "id" = "subquery"."initiative_id";
3754 -- write (final) ranks:
3755 "rank_v" := 1;
3756 FOR "initiative_id_v" IN
3757 SELECT "id"
3758 FROM "initiative"
3759 WHERE "issue_id" = "issue_id_p" AND "admitted"
3760 ORDER BY
3761 "winner" DESC,
3762 ("direct_majority" AND "indirect_majority") DESC,
3763 "schulze_rank",
3764 "id"
3765 LOOP
3766 UPDATE "initiative" SET "rank" = "rank_v"
3767 WHERE "id" = "initiative_id_v";
3768 "rank_v" := "rank_v" + 1;
3769 END LOOP;
3770 -- set schulze rank of status quo and mark issue as finished:
3771 UPDATE "issue" SET
3772 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
3773 "state" =
3774 CASE WHEN EXISTS (
3775 SELECT NULL FROM "initiative"
3776 WHERE "issue_id" = "issue_id_p" AND "winner"
3777 ) THEN
3778 'finished_with_winner'::"issue_state"
3779 ELSE
3780 'finished_without_winner'::"issue_state"
3781 END,
3782 "ranks_available" = TRUE
3783 WHERE "id" = "issue_id_p";
3784 RETURN;
3785 END;
3786 $$;
3788 COMMENT ON FUNCTION "calculate_ranks"
3789 ( "issue"."id"%TYPE )
3790 IS 'Determine ranking (Votes have to be counted first)';
3794 -----------------------------
3795 -- Automatic state changes --
3796 -----------------------------
3799 CREATE FUNCTION "check_issue"
3800 ( "issue_id_p" "issue"."id"%TYPE )
3801 RETURNS VOID
3802 LANGUAGE 'plpgsql' VOLATILE AS $$
3803 DECLARE
3804 "issue_row" "issue"%ROWTYPE;
3805 "policy_row" "policy"%ROWTYPE;
3806 BEGIN
3807 PERFORM "lock_issue"("issue_id_p");
3808 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3809 -- only process open issues:
3810 IF "issue_row"."closed" ISNULL THEN
3811 SELECT * INTO "policy_row" FROM "policy"
3812 WHERE "id" = "issue_row"."policy_id";
3813 -- create a snapshot, unless issue is already fully frozen:
3814 IF "issue_row"."fully_frozen" ISNULL THEN
3815 PERFORM "create_snapshot"("issue_id_p");
3816 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3817 END IF;
3818 -- eventually close or accept issues, which have not been accepted:
3819 IF "issue_row"."accepted" ISNULL THEN
3820 IF EXISTS (
3821 SELECT NULL FROM "initiative"
3822 WHERE "issue_id" = "issue_id_p"
3823 AND "supporter_count" > 0
3824 AND "supporter_count" * "policy_row"."issue_quorum_den"
3825 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3826 ) THEN
3827 -- accept issues, if supporter count is high enough
3828 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3829 -- NOTE: "issue_row" used later
3830 "issue_row"."state" := 'discussion';
3831 "issue_row"."accepted" := now();
3832 UPDATE "issue" SET
3833 "state" = "issue_row"."state",
3834 "accepted" = "issue_row"."accepted"
3835 WHERE "id" = "issue_row"."id";
3836 ELSIF
3837 now() >= "issue_row"."created" + "issue_row"."admission_time"
3838 THEN
3839 -- close issues, if admission time has expired
3840 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3841 UPDATE "issue" SET
3842 "state" = 'canceled_issue_not_accepted',
3843 "closed" = now()
3844 WHERE "id" = "issue_row"."id";
3845 END IF;
3846 END IF;
3847 -- eventually half freeze issues:
3848 IF
3849 -- NOTE: issue can't be closed at this point, if it has been accepted
3850 "issue_row"."accepted" NOTNULL AND
3851 "issue_row"."half_frozen" ISNULL
3852 THEN
3853 IF
3854 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3855 THEN
3856 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3857 -- NOTE: "issue_row" used later
3858 "issue_row"."state" := 'verification';
3859 "issue_row"."half_frozen" := now();
3860 UPDATE "issue" SET
3861 "state" = "issue_row"."state",
3862 "half_frozen" = "issue_row"."half_frozen"
3863 WHERE "id" = "issue_row"."id";
3864 END IF;
3865 END IF;
3866 -- close issues after some time, if all initiatives have been revoked:
3867 IF
3868 "issue_row"."closed" ISNULL AND
3869 NOT EXISTS (
3870 -- all initiatives are revoked
3871 SELECT NULL FROM "initiative"
3872 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3873 ) AND (
3874 -- and issue has not been accepted yet
3875 "issue_row"."accepted" ISNULL OR
3876 NOT EXISTS (
3877 -- or no initiatives have been revoked lately
3878 SELECT NULL FROM "initiative"
3879 WHERE "issue_id" = "issue_id_p"
3880 AND now() < "revoked" + "issue_row"."verification_time"
3881 ) OR (
3882 -- or verification time has elapsed
3883 "issue_row"."half_frozen" NOTNULL AND
3884 "issue_row"."fully_frozen" ISNULL AND
3885 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3888 THEN
3889 -- NOTE: "issue_row" used later
3890 IF "issue_row"."accepted" ISNULL THEN
3891 "issue_row"."state" := 'canceled_revoked_before_accepted';
3892 ELSIF "issue_row"."half_frozen" ISNULL THEN
3893 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
3894 ELSE
3895 "issue_row"."state" := 'canceled_after_revocation_during_verification';
3896 END IF;
3897 "issue_row"."closed" := now();
3898 UPDATE "issue" SET
3899 "state" = "issue_row"."state",
3900 "closed" = "issue_row"."closed"
3901 WHERE "id" = "issue_row"."id";
3902 END IF;
3903 -- fully freeze issue after verification time:
3904 IF
3905 "issue_row"."half_frozen" NOTNULL AND
3906 "issue_row"."fully_frozen" ISNULL AND
3907 "issue_row"."closed" ISNULL AND
3908 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3909 THEN
3910 PERFORM "freeze_after_snapshot"("issue_id_p");
3911 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
3912 END IF;
3913 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3914 -- close issue by calling close_voting(...) after voting time:
3915 IF
3916 "issue_row"."closed" ISNULL AND
3917 "issue_row"."fully_frozen" NOTNULL AND
3918 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
3919 THEN
3920 PERFORM "close_voting"("issue_id_p");
3921 -- calculate ranks will not consume much time and can be done now
3922 PERFORM "calculate_ranks"("issue_id_p");
3923 END IF;
3924 END IF;
3925 RETURN;
3926 END;
3927 $$;
3929 COMMENT ON FUNCTION "check_issue"
3930 ( "issue"."id"%TYPE )
3931 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.';
3934 CREATE FUNCTION "check_everything"()
3935 RETURNS VOID
3936 LANGUAGE 'plpgsql' VOLATILE AS $$
3937 DECLARE
3938 "issue_id_v" "issue"."id"%TYPE;
3939 BEGIN
3940 PERFORM "check_activity"();
3941 PERFORM "calculate_member_counts"();
3942 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
3943 PERFORM "check_issue"("issue_id_v");
3944 END LOOP;
3945 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
3946 PERFORM "calculate_ranks"("issue_id_v");
3947 END LOOP;
3948 RETURN;
3949 END;
3950 $$;
3952 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.';
3956 ----------------------
3957 -- Deletion of data --
3958 ----------------------
3961 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
3962 RETURNS VOID
3963 LANGUAGE 'plpgsql' VOLATILE AS $$
3964 DECLARE
3965 "issue_row" "issue"%ROWTYPE;
3966 BEGIN
3967 SELECT * INTO "issue_row"
3968 FROM "issue" WHERE "id" = "issue_id_p"
3969 FOR UPDATE;
3970 IF "issue_row"."cleaned" ISNULL THEN
3971 UPDATE "issue" SET
3972 "state" = 'voting',
3973 "closed" = NULL,
3974 "ranks_available" = FALSE
3975 WHERE "id" = "issue_id_p";
3976 DELETE FROM "issue_comment"
3977 WHERE "issue_id" = "issue_id_p";
3978 DELETE FROM "voting_comment"
3979 WHERE "issue_id" = "issue_id_p";
3980 DELETE FROM "delegating_voter"
3981 WHERE "issue_id" = "issue_id_p";
3982 DELETE FROM "direct_voter"
3983 WHERE "issue_id" = "issue_id_p";
3984 DELETE FROM "delegating_interest_snapshot"
3985 WHERE "issue_id" = "issue_id_p";
3986 DELETE FROM "direct_interest_snapshot"
3987 WHERE "issue_id" = "issue_id_p";
3988 DELETE FROM "delegating_population_snapshot"
3989 WHERE "issue_id" = "issue_id_p";
3990 DELETE FROM "direct_population_snapshot"
3991 WHERE "issue_id" = "issue_id_p";
3992 DELETE FROM "non_voter"
3993 WHERE "issue_id" = "issue_id_p";
3994 DELETE FROM "delegation"
3995 WHERE "issue_id" = "issue_id_p";
3996 DELETE FROM "supporter"
3997 WHERE "issue_id" = "issue_id_p";
3998 UPDATE "issue" SET
3999 "state" = "issue_row"."state",
4000 "closed" = "issue_row"."closed",
4001 "ranks_available" = "issue_row"."ranks_available",
4002 "cleaned" = now()
4003 WHERE "id" = "issue_id_p";
4004 END IF;
4005 RETURN;
4006 END;
4007 $$;
4009 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4012 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4013 RETURNS VOID
4014 LANGUAGE 'plpgsql' VOLATILE AS $$
4015 BEGIN
4016 UPDATE "member" SET
4017 "last_login" = NULL,
4018 "login" = NULL,
4019 "password" = NULL,
4020 "locked" = TRUE,
4021 "active" = FALSE,
4022 "notify_email" = NULL,
4023 "notify_email_unconfirmed" = NULL,
4024 "notify_email_secret" = NULL,
4025 "notify_email_secret_expiry" = NULL,
4026 "notify_email_lock_expiry" = NULL,
4027 "password_reset_secret" = NULL,
4028 "password_reset_secret_expiry" = NULL,
4029 "organizational_unit" = NULL,
4030 "internal_posts" = NULL,
4031 "realname" = NULL,
4032 "birthday" = NULL,
4033 "address" = NULL,
4034 "email" = NULL,
4035 "xmpp_address" = NULL,
4036 "website" = NULL,
4037 "phone" = NULL,
4038 "mobile_phone" = NULL,
4039 "profession" = NULL,
4040 "external_memberships" = NULL,
4041 "external_posts" = NULL,
4042 "statement" = NULL
4043 WHERE "id" = "member_id_p";
4044 -- "text_search_data" is updated by triggers
4045 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4046 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4047 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4048 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4049 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4050 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4051 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4052 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4053 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4054 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4055 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4056 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4057 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4058 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4059 DELETE FROM "direct_voter" USING "issue"
4060 WHERE "direct_voter"."issue_id" = "issue"."id"
4061 AND "issue"."closed" ISNULL
4062 AND "member_id" = "member_id_p";
4063 RETURN;
4064 END;
4065 $$;
4067 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)';
4070 CREATE FUNCTION "delete_private_data"()
4071 RETURNS VOID
4072 LANGUAGE 'plpgsql' VOLATILE AS $$
4073 BEGIN
4074 UPDATE "member" SET
4075 "last_login" = NULL,
4076 "login" = NULL,
4077 "password" = NULL,
4078 "notify_email" = NULL,
4079 "notify_email_unconfirmed" = NULL,
4080 "notify_email_secret" = NULL,
4081 "notify_email_secret_expiry" = NULL,
4082 "notify_email_lock_expiry" = NULL,
4083 "password_reset_secret" = NULL,
4084 "password_reset_secret_expiry" = NULL,
4085 "organizational_unit" = NULL,
4086 "internal_posts" = NULL,
4087 "realname" = NULL,
4088 "birthday" = NULL,
4089 "address" = NULL,
4090 "email" = NULL,
4091 "xmpp_address" = NULL,
4092 "website" = NULL,
4093 "phone" = NULL,
4094 "mobile_phone" = NULL,
4095 "profession" = NULL,
4096 "external_memberships" = NULL,
4097 "external_posts" = NULL,
4098 "statement" = NULL;
4099 -- "text_search_data" is updated by triggers
4100 DELETE FROM "invite_code";
4101 DELETE FROM "setting";
4102 DELETE FROM "setting_map";
4103 DELETE FROM "member_relation_setting";
4104 DELETE FROM "member_image";
4105 DELETE FROM "contact";
4106 DELETE FROM "ignored_member";
4107 DELETE FROM "area_setting";
4108 DELETE FROM "issue_setting";
4109 DELETE FROM "ignored_initiative";
4110 DELETE FROM "initiative_setting";
4111 DELETE FROM "suggestion_setting";
4112 DELETE FROM "non_voter";
4113 DELETE FROM "direct_voter" USING "issue"
4114 WHERE "direct_voter"."issue_id" = "issue"."id"
4115 AND "issue"."closed" ISNULL;
4116 RETURN;
4117 END;
4118 $$;
4120 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.';
4124 COMMIT;

Impressum / About Us