liquid_feedback_core

view core.sql @ 284:4f935e989ff6

"non_voter" deletes "direct_voter" and vice versa
author jbe
date Sun Aug 19 19:04:22 2012 +0200 (2012-08-19)
parents 3ac4a5664f5c
children 4868a7d591de
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 ('2.1.0', 2, 1, 0))
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 "invite_code_expiry" TIMESTAMPTZ,
89 "admin_comment" TEXT,
90 "activated" TIMESTAMPTZ,
91 "last_activity" DATE,
92 "last_login" TIMESTAMPTZ,
93 "login" TEXT UNIQUE,
94 "password" TEXT,
95 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
96 "active" BOOLEAN NOT NULL DEFAULT FALSE,
97 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
98 "lang" TEXT,
99 "notify_email" TEXT,
100 "notify_email_unconfirmed" TEXT,
101 "notify_email_secret" TEXT UNIQUE,
102 "notify_email_secret_expiry" TIMESTAMPTZ,
103 "notify_email_lock_expiry" TIMESTAMPTZ,
104 "notify_level" "notify_level",
105 "password_reset_secret" TEXT UNIQUE,
106 "password_reset_secret_expiry" TIMESTAMPTZ,
107 "name" TEXT UNIQUE,
108 "identification" TEXT UNIQUE,
109 "authentication" TEXT,
110 "organizational_unit" TEXT,
111 "internal_posts" TEXT,
112 "realname" TEXT,
113 "birthday" DATE,
114 "address" TEXT,
115 "email" TEXT,
116 "xmpp_address" TEXT,
117 "website" TEXT,
118 "phone" TEXT,
119 "mobile_phone" TEXT,
120 "profession" TEXT,
121 "external_memberships" TEXT,
122 "external_posts" TEXT,
123 "formatting_engine" TEXT,
124 "statement" TEXT,
125 "text_search_data" TSVECTOR,
126 CONSTRAINT "active_requires_activated_and_last_activity"
127 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
128 CONSTRAINT "name_not_null_if_activated"
129 CHECK ("activated" ISNULL OR "name" NOTNULL) );
130 CREATE INDEX "member_active_idx" ON "member" ("active");
131 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
132 CREATE TRIGGER "update_text_search_data"
133 BEFORE INSERT OR UPDATE ON "member"
134 FOR EACH ROW EXECUTE PROCEDURE
135 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
136 "name", "identification", "organizational_unit", "internal_posts",
137 "realname", "external_memberships", "external_posts", "statement" );
139 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
141 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
142 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
143 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
144 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
145 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
146 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
147 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
148 COMMENT ON COLUMN "member"."login" IS 'Login name';
149 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
150 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
151 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".';
152 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
153 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
154 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
155 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
156 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
157 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
158 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
159 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address, may be NULL if member did not make any selection yet';
160 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
161 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
162 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
163 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
164 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
165 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
166 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
167 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
168 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
169 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
170 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
173 -- DEPRECATED API TABLES --
175 CREATE TYPE "application_access_level" AS ENUM
176 ('member', 'full', 'pseudonymous', 'anonymous');
178 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
181 CREATE TABLE "member_application" (
182 "id" SERIAL8 PRIMARY KEY,
183 UNIQUE ("member_id", "name"),
184 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
185 ON DELETE CASCADE ON UPDATE CASCADE,
186 "name" TEXT NOT NULL,
187 "comment" TEXT,
188 "access_level" "application_access_level" NOT NULL,
189 "key" TEXT NOT NULL UNIQUE,
190 "last_usage" TIMESTAMPTZ );
192 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
194 -- END OF DEPRECARED API TABLES --
197 CREATE TABLE "member_history" (
198 "id" SERIAL8 PRIMARY KEY,
199 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
200 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
201 "active" BOOLEAN NOT NULL,
202 "name" TEXT NOT NULL );
203 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
205 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
207 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
208 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
211 CREATE TABLE "rendered_member_statement" (
212 PRIMARY KEY ("member_id", "format"),
213 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
214 "format" TEXT,
215 "content" TEXT NOT NULL );
217 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)';
220 CREATE TABLE "setting" (
221 PRIMARY KEY ("member_id", "key"),
222 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
223 "key" TEXT NOT NULL,
224 "value" TEXT NOT NULL );
225 CREATE INDEX "setting_key_idx" ON "setting" ("key");
227 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
229 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
232 CREATE TABLE "setting_map" (
233 PRIMARY KEY ("member_id", "key", "subkey"),
234 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
235 "key" TEXT NOT NULL,
236 "subkey" TEXT NOT NULL,
237 "value" TEXT NOT NULL );
238 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
240 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
242 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
243 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
244 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
247 CREATE TABLE "member_relation_setting" (
248 PRIMARY KEY ("member_id", "key", "other_member_id"),
249 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
250 "key" TEXT NOT NULL,
251 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
252 "value" TEXT NOT NULL );
254 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
257 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
259 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
262 CREATE TABLE "member_image" (
263 PRIMARY KEY ("member_id", "image_type", "scaled"),
264 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
265 "image_type" "member_image_type",
266 "scaled" BOOLEAN,
267 "content_type" TEXT,
268 "data" BYTEA NOT NULL );
270 COMMENT ON TABLE "member_image" IS 'Images of members';
272 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
275 CREATE TABLE "member_count" (
276 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
277 "total_count" INT4 NOT NULL );
279 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';
281 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
282 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
285 CREATE TABLE "contact" (
286 PRIMARY KEY ("member_id", "other_member_id"),
287 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
288 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
289 "public" BOOLEAN NOT NULL DEFAULT FALSE,
290 CONSTRAINT "cant_save_yourself_as_contact"
291 CHECK ("member_id" != "other_member_id") );
292 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
294 COMMENT ON TABLE "contact" IS 'Contact lists';
296 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
297 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
298 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
301 CREATE TABLE "ignored_member" (
302 PRIMARY KEY ("member_id", "other_member_id"),
303 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
304 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
305 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
307 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
309 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
310 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
313 CREATE TABLE "session" (
314 "ident" TEXT PRIMARY KEY,
315 "additional_secret" TEXT,
316 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
317 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
318 "lang" TEXT );
319 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
321 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
323 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
324 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
325 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
326 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
329 CREATE TABLE "policy" (
330 "id" SERIAL4 PRIMARY KEY,
331 "index" INT4 NOT NULL,
332 "active" BOOLEAN NOT NULL DEFAULT TRUE,
333 "name" TEXT NOT NULL UNIQUE,
334 "description" TEXT NOT NULL DEFAULT '',
335 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
336 "admission_time" INTERVAL,
337 "discussion_time" INTERVAL,
338 "verification_time" INTERVAL,
339 "voting_time" INTERVAL,
340 "issue_quorum_num" INT4 NOT NULL,
341 "issue_quorum_den" INT4 NOT NULL,
342 "initiative_quorum_num" INT4 NOT NULL,
343 "initiative_quorum_den" INT4 NOT NULL,
344 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
345 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
346 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
347 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
348 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
349 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
350 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
351 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
352 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
353 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
354 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
355 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
356 CONSTRAINT "timing" CHECK (
357 ( "polling" = FALSE AND
358 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
359 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
360 ( "polling" = TRUE AND
361 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
362 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
363 ( "polling" = TRUE AND
364 "admission_time" ISNULL AND "discussion_time" ISNULL AND
365 "verification_time" ISNULL AND "voting_time" ISNULL ) ) );
366 CREATE INDEX "policy_active_idx" ON "policy" ("active");
368 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
370 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
371 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
372 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues, i.e. polls ("admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for issues)';
373 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
374 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
375 COMMENT ON COLUMN "policy"."verification_time" IS 'Duration of issue state ''verification''; Regular time until an issue is "fully_frozen" (e.g. entering issue state ''voting'') after being "half_frozen"';
376 COMMENT ON COLUMN "policy"."voting_time" IS 'Duration of issue state ''voting''; Time after an issue is "fully_frozen" but not "closed" (duration of issue state ''voting'')';
377 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" and enter issue state ''discussion''';
378 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" and enter issue state ''discussion''';
379 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
380 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
381 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
382 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
383 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.';
384 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
385 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';
386 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';
387 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';
388 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.';
389 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';
390 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';
391 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.';
392 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").';
395 CREATE TABLE "unit" (
396 "id" SERIAL4 PRIMARY KEY,
397 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
398 "active" BOOLEAN NOT NULL DEFAULT TRUE,
399 "name" TEXT NOT NULL,
400 "description" TEXT NOT NULL DEFAULT '',
401 "member_count" INT4,
402 "text_search_data" TSVECTOR );
403 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
404 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
405 CREATE INDEX "unit_active_idx" ON "unit" ("active");
406 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
407 CREATE TRIGGER "update_text_search_data"
408 BEFORE INSERT OR UPDATE ON "unit"
409 FOR EACH ROW EXECUTE PROCEDURE
410 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
411 "name", "description" );
413 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
415 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
416 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
417 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
420 CREATE TABLE "unit_setting" (
421 PRIMARY KEY ("member_id", "key", "unit_id"),
422 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
423 "key" TEXT NOT NULL,
424 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
425 "value" TEXT NOT NULL );
427 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
430 CREATE TABLE "area" (
431 "id" SERIAL4 PRIMARY KEY,
432 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
433 "active" BOOLEAN NOT NULL DEFAULT TRUE,
434 "name" TEXT NOT NULL,
435 "description" TEXT NOT NULL DEFAULT '',
436 "direct_member_count" INT4,
437 "member_weight" INT4,
438 "text_search_data" TSVECTOR );
439 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
440 CREATE INDEX "area_active_idx" ON "area" ("active");
441 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
442 CREATE TRIGGER "update_text_search_data"
443 BEFORE INSERT OR UPDATE ON "area"
444 FOR EACH ROW EXECUTE PROCEDURE
445 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
446 "name", "description" );
448 COMMENT ON TABLE "area" IS 'Subject areas';
450 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
451 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"';
452 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
455 CREATE TABLE "area_setting" (
456 PRIMARY KEY ("member_id", "key", "area_id"),
457 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
458 "key" TEXT NOT NULL,
459 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
460 "value" TEXT NOT NULL );
462 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
465 CREATE TABLE "allowed_policy" (
466 PRIMARY KEY ("area_id", "policy_id"),
467 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
468 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
469 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
470 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
472 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
474 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
477 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
479 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';
482 CREATE TYPE "issue_state" AS ENUM (
483 'admission', 'discussion', 'verification', 'voting',
484 'canceled_revoked_before_accepted',
485 'canceled_issue_not_accepted',
486 'canceled_after_revocation_during_discussion',
487 'canceled_after_revocation_during_verification',
488 'calculation',
489 'canceled_no_initiative_admitted',
490 'finished_without_winner', 'finished_with_winner');
492 COMMENT ON TYPE "issue_state" IS 'State of issues';
495 CREATE TABLE "issue" (
496 "id" SERIAL4 PRIMARY KEY,
497 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
498 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
499 "state" "issue_state" NOT NULL DEFAULT 'admission',
500 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
501 "accepted" TIMESTAMPTZ,
502 "half_frozen" TIMESTAMPTZ,
503 "fully_frozen" TIMESTAMPTZ,
504 "closed" TIMESTAMPTZ,
505 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
506 "cleaned" TIMESTAMPTZ,
507 "admission_time" INTERVAL NOT NULL,
508 "discussion_time" INTERVAL NOT NULL,
509 "verification_time" INTERVAL NOT NULL,
510 "voting_time" INTERVAL NOT NULL,
511 "snapshot" TIMESTAMPTZ,
512 "latest_snapshot_event" "snapshot_event",
513 "population" INT4,
514 "voter_count" INT4,
515 "status_quo_schulze_rank" INT4,
516 CONSTRAINT "valid_state" CHECK ((
517 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
518 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
519 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
520 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
521 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
522 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
523 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
524 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
525 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
526 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
527 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
528 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
529 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
530 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
531 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
532 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
533 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
534 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
535 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
536 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
537 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
538 )),
539 CONSTRAINT "state_change_order" CHECK (
540 "created" <= "accepted" AND
541 "accepted" <= "half_frozen" AND
542 "half_frozen" <= "fully_frozen" AND
543 "fully_frozen" <= "closed" ),
544 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
545 "cleaned" ISNULL OR "closed" NOTNULL ),
546 CONSTRAINT "last_snapshot_on_full_freeze"
547 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
548 CONSTRAINT "freeze_requires_snapshot"
549 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
550 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
551 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
552 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
553 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
554 CREATE INDEX "issue_created_idx" ON "issue" ("created");
555 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
556 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
557 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
558 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
559 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
560 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
562 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
564 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
565 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.';
566 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.';
567 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.';
568 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
569 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
570 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
571 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
572 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
573 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
574 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
575 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';
576 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
577 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';
578 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
581 CREATE TABLE "issue_setting" (
582 PRIMARY KEY ("member_id", "key", "issue_id"),
583 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
584 "key" TEXT NOT NULL,
585 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
586 "value" TEXT NOT NULL );
588 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
591 CREATE TABLE "initiative" (
592 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
593 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
594 "id" SERIAL4 PRIMARY KEY,
595 "name" TEXT NOT NULL,
596 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
597 "discussion_url" TEXT,
598 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
599 "revoked" TIMESTAMPTZ,
600 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
601 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
602 "admitted" BOOLEAN,
603 "supporter_count" INT4,
604 "informed_supporter_count" INT4,
605 "satisfied_supporter_count" INT4,
606 "satisfied_informed_supporter_count" INT4,
607 "positive_votes" INT4,
608 "negative_votes" INT4,
609 "direct_majority" BOOLEAN,
610 "indirect_majority" BOOLEAN,
611 "schulze_rank" INT4,
612 "better_than_status_quo" BOOLEAN,
613 "worse_than_status_quo" BOOLEAN,
614 "reverse_beat_path" BOOLEAN,
615 "multistage_majority" BOOLEAN,
616 "eligible" BOOLEAN,
617 "winner" BOOLEAN,
618 "rank" INT4,
619 "text_search_data" TSVECTOR,
620 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
621 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
622 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
623 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
624 CONSTRAINT "revoked_initiatives_cant_be_admitted"
625 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
626 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
627 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
628 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
629 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
630 "schulze_rank" ISNULL AND
631 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
632 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
633 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
634 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
635 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
636 "eligible" = FALSE OR
637 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
638 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
639 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
640 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
641 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
642 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
643 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
644 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
645 CREATE TRIGGER "update_text_search_data"
646 BEFORE INSERT OR UPDATE ON "initiative"
647 FOR EACH ROW EXECUTE PROCEDURE
648 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
649 "name", "discussion_url");
651 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.';
653 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative is an option for a poll (see "policy"."polling"), and does not need to pass the initiative quorum';
654 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
655 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
656 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
657 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
658 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
659 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
660 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
661 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
662 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
663 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
664 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"';
665 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
666 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
667 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
668 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
669 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';
670 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';
671 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative has a "direct_majority" and an "indirect_majority", is "better_than_status_quo" and depending on selected policy the initiative has no "reverse_beat_path" or "multistage_majority"';
672 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
673 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';
676 CREATE TABLE "battle" (
677 "issue_id" INT4 NOT NULL,
678 "winning_initiative_id" INT4,
679 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
680 "losing_initiative_id" INT4,
681 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
682 "count" INT4 NOT NULL,
683 CONSTRAINT "initiative_ids_not_equal" CHECK (
684 "winning_initiative_id" != "losing_initiative_id" OR
685 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
686 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
687 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
688 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
689 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
691 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';
694 CREATE TABLE "ignored_initiative" (
695 PRIMARY KEY ("initiative_id", "member_id"),
696 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
697 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
698 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
700 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
703 CREATE TABLE "initiative_setting" (
704 PRIMARY KEY ("member_id", "key", "initiative_id"),
705 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
706 "key" TEXT NOT NULL,
707 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
708 "value" TEXT NOT NULL );
710 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
713 CREATE TABLE "draft" (
714 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
715 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
716 "id" SERIAL8 PRIMARY KEY,
717 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
718 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
719 "formatting_engine" TEXT,
720 "content" TEXT NOT NULL,
721 "text_search_data" TSVECTOR );
722 CREATE INDEX "draft_created_idx" ON "draft" ("created");
723 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
724 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
725 CREATE TRIGGER "update_text_search_data"
726 BEFORE INSERT OR UPDATE ON "draft"
727 FOR EACH ROW EXECUTE PROCEDURE
728 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
730 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.';
732 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
733 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
736 CREATE TABLE "rendered_draft" (
737 PRIMARY KEY ("draft_id", "format"),
738 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
739 "format" TEXT,
740 "content" TEXT NOT NULL );
742 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)';
745 CREATE TABLE "suggestion" (
746 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
747 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
748 "id" SERIAL8 PRIMARY KEY,
749 "draft_id" INT8 NOT NULL,
750 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
751 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
752 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
753 "name" TEXT NOT NULL,
754 "formatting_engine" TEXT,
755 "content" TEXT NOT NULL DEFAULT '',
756 "text_search_data" TSVECTOR,
757 "minus2_unfulfilled_count" INT4,
758 "minus2_fulfilled_count" INT4,
759 "minus1_unfulfilled_count" INT4,
760 "minus1_fulfilled_count" INT4,
761 "plus1_unfulfilled_count" INT4,
762 "plus1_fulfilled_count" INT4,
763 "plus2_unfulfilled_count" INT4,
764 "plus2_fulfilled_count" INT4 );
765 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
766 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
767 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
768 CREATE TRIGGER "update_text_search_data"
769 BEFORE INSERT OR UPDATE ON "suggestion"
770 FOR EACH ROW EXECUTE PROCEDURE
771 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
772 "name", "content");
774 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';
776 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")';
777 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
778 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
779 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
780 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
781 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
782 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
783 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
784 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
787 CREATE TABLE "rendered_suggestion" (
788 PRIMARY KEY ("suggestion_id", "format"),
789 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
790 "format" TEXT,
791 "content" TEXT NOT NULL );
793 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)';
796 CREATE TABLE "suggestion_setting" (
797 PRIMARY KEY ("member_id", "key", "suggestion_id"),
798 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
799 "key" TEXT NOT NULL,
800 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "value" TEXT NOT NULL );
803 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
806 CREATE TABLE "privilege" (
807 PRIMARY KEY ("unit_id", "member_id"),
808 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
809 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
810 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
811 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
812 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
813 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
814 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
815 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
816 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
818 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
820 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
821 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
822 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
823 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
824 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
825 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
826 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create polls (see "policy"."polling" and "initiative"."polling")';
829 CREATE TABLE "membership" (
830 PRIMARY KEY ("area_id", "member_id"),
831 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
832 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
833 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
835 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
838 CREATE TABLE "interest" (
839 PRIMARY KEY ("issue_id", "member_id"),
840 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
841 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
842 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
844 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.';
847 CREATE TABLE "initiator" (
848 PRIMARY KEY ("initiative_id", "member_id"),
849 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
850 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
851 "accepted" BOOLEAN );
852 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
854 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.';
856 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.';
859 CREATE TABLE "supporter" (
860 "issue_id" INT4 NOT NULL,
861 PRIMARY KEY ("initiative_id", "member_id"),
862 "initiative_id" INT4,
863 "member_id" INT4,
864 "draft_id" INT8 NOT NULL,
865 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
866 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
867 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
869 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.';
871 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
872 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")';
875 CREATE TABLE "opinion" (
876 "initiative_id" INT4 NOT NULL,
877 PRIMARY KEY ("suggestion_id", "member_id"),
878 "suggestion_id" INT8,
879 "member_id" INT4,
880 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
881 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
882 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
883 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
884 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
886 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.';
888 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
891 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
893 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
896 CREATE TABLE "delegation" (
897 "id" SERIAL8 PRIMARY KEY,
898 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
899 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
900 "scope" "delegation_scope" NOT NULL,
901 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
902 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
903 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
904 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
905 CONSTRAINT "no_unit_delegation_to_null"
906 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
907 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
908 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
909 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
910 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
911 UNIQUE ("unit_id", "truster_id"),
912 UNIQUE ("area_id", "truster_id"),
913 UNIQUE ("issue_id", "truster_id") );
914 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
915 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
917 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
919 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
920 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
921 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
924 CREATE TABLE "direct_population_snapshot" (
925 PRIMARY KEY ("issue_id", "event", "member_id"),
926 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
927 "event" "snapshot_event",
928 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
929 "weight" INT4 );
930 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
932 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
934 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
935 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
938 CREATE TABLE "delegating_population_snapshot" (
939 PRIMARY KEY ("issue_id", "event", "member_id"),
940 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
941 "event" "snapshot_event",
942 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
943 "weight" INT4,
944 "scope" "delegation_scope" NOT NULL,
945 "delegate_member_ids" INT4[] NOT NULL );
946 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
948 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
950 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
951 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
952 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
953 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"';
956 CREATE TABLE "direct_interest_snapshot" (
957 PRIMARY KEY ("issue_id", "event", "member_id"),
958 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
959 "event" "snapshot_event",
960 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
961 "weight" INT4 );
962 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
964 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
966 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
967 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
970 CREATE TABLE "delegating_interest_snapshot" (
971 PRIMARY KEY ("issue_id", "event", "member_id"),
972 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
973 "event" "snapshot_event",
974 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
975 "weight" INT4,
976 "scope" "delegation_scope" NOT NULL,
977 "delegate_member_ids" INT4[] NOT NULL );
978 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
980 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
982 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
983 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
984 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
985 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"';
988 CREATE TABLE "direct_supporter_snapshot" (
989 "issue_id" INT4 NOT NULL,
990 PRIMARY KEY ("initiative_id", "event", "member_id"),
991 "initiative_id" INT4,
992 "event" "snapshot_event",
993 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
994 "draft_id" INT8 NOT NULL,
995 "informed" BOOLEAN NOT NULL,
996 "satisfied" BOOLEAN NOT NULL,
997 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
998 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
999 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1000 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1002 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1004 COMMENT ON COLUMN "direct_supporter_snapshot"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1005 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1006 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1007 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1010 CREATE TABLE "non_voter" (
1011 PRIMARY KEY ("issue_id", "member_id"),
1012 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1013 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1014 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1016 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1019 CREATE TABLE "direct_voter" (
1020 PRIMARY KEY ("issue_id", "member_id"),
1021 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1022 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1023 "weight" INT4 );
1024 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1026 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.';
1028 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1031 CREATE TABLE "delegating_voter" (
1032 PRIMARY KEY ("issue_id", "member_id"),
1033 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1034 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1035 "weight" INT4,
1036 "scope" "delegation_scope" NOT NULL,
1037 "delegate_member_ids" INT4[] NOT NULL );
1038 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1040 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1042 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1043 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1044 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"';
1047 CREATE TABLE "vote" (
1048 "issue_id" INT4 NOT NULL,
1049 PRIMARY KEY ("initiative_id", "member_id"),
1050 "initiative_id" INT4,
1051 "member_id" INT4,
1052 "grade" INT4,
1053 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1054 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1055 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1057 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.';
1059 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1060 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.';
1063 CREATE TABLE "voting_comment" (
1064 PRIMARY KEY ("issue_id", "member_id"),
1065 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1066 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1067 "changed" TIMESTAMPTZ,
1068 "formatting_engine" TEXT,
1069 "content" TEXT NOT NULL,
1070 "text_search_data" TSVECTOR );
1071 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1072 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1073 CREATE TRIGGER "update_text_search_data"
1074 BEFORE INSERT OR UPDATE ON "voting_comment"
1075 FOR EACH ROW EXECUTE PROCEDURE
1076 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1078 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1080 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.';
1083 CREATE TABLE "rendered_voting_comment" (
1084 PRIMARY KEY ("issue_id", "member_id", "format"),
1085 FOREIGN KEY ("issue_id", "member_id")
1086 REFERENCES "voting_comment" ("issue_id", "member_id")
1087 ON DELETE CASCADE ON UPDATE CASCADE,
1088 "issue_id" INT4,
1089 "member_id" INT4,
1090 "format" TEXT,
1091 "content" TEXT NOT NULL );
1093 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)';
1096 CREATE TYPE "event_type" AS ENUM (
1097 'issue_state_changed',
1098 'initiative_created_in_new_issue',
1099 'initiative_created_in_existing_issue',
1100 'initiative_revoked',
1101 'new_draft_created',
1102 'suggestion_created');
1104 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1107 CREATE TABLE "event" (
1108 "id" SERIAL8 PRIMARY KEY,
1109 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1110 "event" "event_type" NOT NULL,
1111 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1112 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1113 "state" "issue_state" CHECK ("state" != 'calculation'),
1114 "initiative_id" INT4,
1115 "draft_id" INT8,
1116 "suggestion_id" INT8,
1117 FOREIGN KEY ("issue_id", "initiative_id")
1118 REFERENCES "initiative" ("issue_id", "id")
1119 ON DELETE CASCADE ON UPDATE CASCADE,
1120 FOREIGN KEY ("initiative_id", "draft_id")
1121 REFERENCES "draft" ("initiative_id", "id")
1122 ON DELETE CASCADE ON UPDATE CASCADE,
1123 FOREIGN KEY ("initiative_id", "suggestion_id")
1124 REFERENCES "suggestion" ("initiative_id", "id")
1125 ON DELETE CASCADE ON UPDATE CASCADE,
1126 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1127 "event" != 'issue_state_changed' OR (
1128 "member_id" ISNULL AND
1129 "issue_id" NOTNULL AND
1130 "state" NOTNULL AND
1131 "initiative_id" ISNULL AND
1132 "draft_id" ISNULL AND
1133 "suggestion_id" ISNULL )),
1134 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1135 "event" NOT IN (
1136 'initiative_created_in_new_issue',
1137 'initiative_created_in_existing_issue',
1138 'initiative_revoked',
1139 'new_draft_created'
1140 ) OR (
1141 "member_id" NOTNULL AND
1142 "issue_id" NOTNULL AND
1143 "state" NOTNULL AND
1144 "initiative_id" NOTNULL AND
1145 "draft_id" NOTNULL AND
1146 "suggestion_id" ISNULL )),
1147 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1148 "event" != 'suggestion_created' OR (
1149 "member_id" NOTNULL AND
1150 "issue_id" NOTNULL AND
1151 "state" NOTNULL AND
1152 "initiative_id" NOTNULL AND
1153 "draft_id" ISNULL AND
1154 "suggestion_id" NOTNULL )) );
1155 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1157 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1159 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1160 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1161 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1162 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1165 CREATE TABLE "notification_sent" (
1166 "event_id" INT8 NOT NULL );
1167 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1169 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1170 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1174 ----------------------------------------------
1175 -- Writing of history entries and event log --
1176 ----------------------------------------------
1179 CREATE FUNCTION "write_member_history_trigger"()
1180 RETURNS TRIGGER
1181 LANGUAGE 'plpgsql' VOLATILE AS $$
1182 BEGIN
1183 IF
1184 ( NEW."active" != OLD."active" OR
1185 NEW."name" != OLD."name" ) AND
1186 OLD."activated" NOTNULL
1187 THEN
1188 INSERT INTO "member_history"
1189 ("member_id", "active", "name")
1190 VALUES (NEW."id", OLD."active", OLD."name");
1191 END IF;
1192 RETURN NULL;
1193 END;
1194 $$;
1196 CREATE TRIGGER "write_member_history"
1197 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1198 "write_member_history_trigger"();
1200 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1201 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1204 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1205 RETURNS TRIGGER
1206 LANGUAGE 'plpgsql' VOLATILE AS $$
1207 BEGIN
1208 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1209 INSERT INTO "event" ("event", "issue_id", "state")
1210 VALUES ('issue_state_changed', NEW."id", NEW."state");
1211 END IF;
1212 RETURN NULL;
1213 END;
1214 $$;
1216 CREATE TRIGGER "write_event_issue_state_changed"
1217 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1218 "write_event_issue_state_changed_trigger"();
1220 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1221 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1224 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1225 RETURNS TRIGGER
1226 LANGUAGE 'plpgsql' VOLATILE AS $$
1227 DECLARE
1228 "initiative_row" "initiative"%ROWTYPE;
1229 "issue_row" "issue"%ROWTYPE;
1230 "event_v" "event_type";
1231 BEGIN
1232 SELECT * INTO "initiative_row" FROM "initiative"
1233 WHERE "id" = NEW."initiative_id";
1234 SELECT * INTO "issue_row" FROM "issue"
1235 WHERE "id" = "initiative_row"."issue_id";
1236 IF EXISTS (
1237 SELECT NULL FROM "draft"
1238 WHERE "initiative_id" = NEW."initiative_id"
1239 AND "id" != NEW."id"
1240 ) THEN
1241 "event_v" := 'new_draft_created';
1242 ELSE
1243 IF EXISTS (
1244 SELECT NULL FROM "initiative"
1245 WHERE "issue_id" = "initiative_row"."issue_id"
1246 AND "id" != "initiative_row"."id"
1247 ) THEN
1248 "event_v" := 'initiative_created_in_existing_issue';
1249 ELSE
1250 "event_v" := 'initiative_created_in_new_issue';
1251 END IF;
1252 END IF;
1253 INSERT INTO "event" (
1254 "event", "member_id",
1255 "issue_id", "state", "initiative_id", "draft_id"
1256 ) VALUES (
1257 "event_v",
1258 NEW."author_id",
1259 "initiative_row"."issue_id",
1260 "issue_row"."state",
1261 "initiative_row"."id",
1262 NEW."id" );
1263 RETURN NULL;
1264 END;
1265 $$;
1267 CREATE TRIGGER "write_event_initiative_or_draft_created"
1268 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1269 "write_event_initiative_or_draft_created_trigger"();
1271 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1272 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1275 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1276 RETURNS TRIGGER
1277 LANGUAGE 'plpgsql' VOLATILE AS $$
1278 DECLARE
1279 "issue_row" "issue"%ROWTYPE;
1280 "draft_id_v" "draft"."id"%TYPE;
1281 BEGIN
1282 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1283 SELECT * INTO "issue_row" FROM "issue"
1284 WHERE "id" = NEW."issue_id";
1285 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1286 WHERE "initiative_id" = NEW."id";
1287 INSERT INTO "event" (
1288 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1289 ) VALUES (
1290 'initiative_revoked',
1291 NEW."revoked_by_member_id",
1292 NEW."issue_id",
1293 "issue_row"."state",
1294 NEW."id",
1295 "draft_id_v");
1296 END IF;
1297 RETURN NULL;
1298 END;
1299 $$;
1301 CREATE TRIGGER "write_event_initiative_revoked"
1302 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1303 "write_event_initiative_revoked_trigger"();
1305 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1306 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1309 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1310 RETURNS TRIGGER
1311 LANGUAGE 'plpgsql' VOLATILE AS $$
1312 DECLARE
1313 "initiative_row" "initiative"%ROWTYPE;
1314 "issue_row" "issue"%ROWTYPE;
1315 BEGIN
1316 SELECT * INTO "initiative_row" FROM "initiative"
1317 WHERE "id" = NEW."initiative_id";
1318 SELECT * INTO "issue_row" FROM "issue"
1319 WHERE "id" = "initiative_row"."issue_id";
1320 INSERT INTO "event" (
1321 "event", "member_id",
1322 "issue_id", "state", "initiative_id", "suggestion_id"
1323 ) VALUES (
1324 'suggestion_created',
1325 NEW."author_id",
1326 "initiative_row"."issue_id",
1327 "issue_row"."state",
1328 "initiative_row"."id",
1329 NEW."id" );
1330 RETURN NULL;
1331 END;
1332 $$;
1334 CREATE TRIGGER "write_event_suggestion_created"
1335 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1336 "write_event_suggestion_created_trigger"();
1338 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1339 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1343 ----------------------------
1344 -- Additional constraints --
1345 ----------------------------
1348 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1349 RETURNS TRIGGER
1350 LANGUAGE 'plpgsql' VOLATILE AS $$
1351 BEGIN
1352 IF NOT EXISTS (
1353 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1354 ) THEN
1355 --RAISE 'Cannot create issue without an initial initiative.' USING
1356 -- ERRCODE = 'integrity_constraint_violation',
1357 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1358 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1359 END IF;
1360 RETURN NULL;
1361 END;
1362 $$;
1364 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1365 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1366 FOR EACH ROW EXECUTE PROCEDURE
1367 "issue_requires_first_initiative_trigger"();
1369 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1370 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1373 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1374 RETURNS TRIGGER
1375 LANGUAGE 'plpgsql' VOLATILE AS $$
1376 DECLARE
1377 "reference_lost" BOOLEAN;
1378 BEGIN
1379 IF TG_OP = 'DELETE' THEN
1380 "reference_lost" := TRUE;
1381 ELSE
1382 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1383 END IF;
1384 IF
1385 "reference_lost" AND NOT EXISTS (
1386 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1388 THEN
1389 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1390 END IF;
1391 RETURN NULL;
1392 END;
1393 $$;
1395 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1396 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1397 FOR EACH ROW EXECUTE PROCEDURE
1398 "last_initiative_deletes_issue_trigger"();
1400 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1401 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1404 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1405 RETURNS TRIGGER
1406 LANGUAGE 'plpgsql' VOLATILE AS $$
1407 BEGIN
1408 IF NOT EXISTS (
1409 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1410 ) THEN
1411 --RAISE 'Cannot create initiative without an initial draft.' USING
1412 -- ERRCODE = 'integrity_constraint_violation',
1413 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1414 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1415 END IF;
1416 RETURN NULL;
1417 END;
1418 $$;
1420 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1421 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1422 FOR EACH ROW EXECUTE PROCEDURE
1423 "initiative_requires_first_draft_trigger"();
1425 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1426 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1429 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1430 RETURNS TRIGGER
1431 LANGUAGE 'plpgsql' VOLATILE AS $$
1432 DECLARE
1433 "reference_lost" BOOLEAN;
1434 BEGIN
1435 IF TG_OP = 'DELETE' THEN
1436 "reference_lost" := TRUE;
1437 ELSE
1438 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1439 END IF;
1440 IF
1441 "reference_lost" AND NOT EXISTS (
1442 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1444 THEN
1445 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1446 END IF;
1447 RETURN NULL;
1448 END;
1449 $$;
1451 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1452 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1453 FOR EACH ROW EXECUTE PROCEDURE
1454 "last_draft_deletes_initiative_trigger"();
1456 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1457 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1460 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1461 RETURNS TRIGGER
1462 LANGUAGE 'plpgsql' VOLATILE AS $$
1463 BEGIN
1464 IF NOT EXISTS (
1465 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1466 ) THEN
1467 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1468 END IF;
1469 RETURN NULL;
1470 END;
1471 $$;
1473 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1474 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1475 FOR EACH ROW EXECUTE PROCEDURE
1476 "suggestion_requires_first_opinion_trigger"();
1478 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1479 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1482 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1483 RETURNS TRIGGER
1484 LANGUAGE 'plpgsql' VOLATILE AS $$
1485 DECLARE
1486 "reference_lost" BOOLEAN;
1487 BEGIN
1488 IF TG_OP = 'DELETE' THEN
1489 "reference_lost" := TRUE;
1490 ELSE
1491 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1492 END IF;
1493 IF
1494 "reference_lost" AND NOT EXISTS (
1495 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1497 THEN
1498 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1499 END IF;
1500 RETURN NULL;
1501 END;
1502 $$;
1504 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1505 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1506 FOR EACH ROW EXECUTE PROCEDURE
1507 "last_opinion_deletes_suggestion_trigger"();
1509 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1510 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1513 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1514 RETURNS TRIGGER
1515 LANGUAGE 'plpgsql' VOLATILE AS $$
1516 BEGIN
1517 DELETE FROM "direct_voter"
1518 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1519 RETURN NULL;
1520 END;
1521 $$;
1523 CREATE TRIGGER "non_voter_deletes_direct_voter"
1524 AFTER INSERT OR UPDATE ON "non_voter"
1525 FOR EACH ROW EXECUTE PROCEDURE
1526 "non_voter_deletes_direct_voter_trigger"();
1528 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1529 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
1532 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1533 RETURNS TRIGGER
1534 LANGUAGE 'plpgsql' VOLATILE AS $$
1535 BEGIN
1536 DELETE FROM "non_voter"
1537 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1538 RETURN NULL;
1539 END;
1540 $$;
1542 CREATE TRIGGER "direct_voter_deletes_non_voter"
1543 AFTER INSERT OR UPDATE ON "direct_voter"
1544 FOR EACH ROW EXECUTE PROCEDURE
1545 "direct_voter_deletes_non_voter_trigger"();
1547 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1548 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
1552 ---------------------------------------------------------------
1553 -- Ensure that votes are not modified when issues are frozen --
1554 ---------------------------------------------------------------
1556 -- NOTE: Frontends should ensure this anyway, but in case of programming
1557 -- errors the following triggers ensure data integrity.
1560 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1561 RETURNS TRIGGER
1562 LANGUAGE 'plpgsql' VOLATILE AS $$
1563 DECLARE
1564 "issue_id_v" "issue"."id"%TYPE;
1565 "issue_row" "issue"%ROWTYPE;
1566 BEGIN
1567 IF TG_OP = 'DELETE' THEN
1568 "issue_id_v" := OLD."issue_id";
1569 ELSE
1570 "issue_id_v" := NEW."issue_id";
1571 END IF;
1572 SELECT INTO "issue_row" * FROM "issue"
1573 WHERE "id" = "issue_id_v" FOR SHARE;
1574 IF "issue_row"."closed" NOTNULL THEN
1575 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1576 END IF;
1577 RETURN NULL;
1578 END;
1579 $$;
1581 CREATE TRIGGER "forbid_changes_on_closed_issue"
1582 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1583 FOR EACH ROW EXECUTE PROCEDURE
1584 "forbid_changes_on_closed_issue_trigger"();
1586 CREATE TRIGGER "forbid_changes_on_closed_issue"
1587 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1588 FOR EACH ROW EXECUTE PROCEDURE
1589 "forbid_changes_on_closed_issue_trigger"();
1591 CREATE TRIGGER "forbid_changes_on_closed_issue"
1592 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1593 FOR EACH ROW EXECUTE PROCEDURE
1594 "forbid_changes_on_closed_issue_trigger"();
1596 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"';
1597 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';
1598 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';
1599 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';
1603 --------------------------------------------------------------------
1604 -- Auto-retrieval of fields only needed for referential integrity --
1605 --------------------------------------------------------------------
1608 CREATE FUNCTION "autofill_issue_id_trigger"()
1609 RETURNS TRIGGER
1610 LANGUAGE 'plpgsql' VOLATILE AS $$
1611 BEGIN
1612 IF NEW."issue_id" ISNULL THEN
1613 SELECT "issue_id" INTO NEW."issue_id"
1614 FROM "initiative" WHERE "id" = NEW."initiative_id";
1615 END IF;
1616 RETURN NEW;
1617 END;
1618 $$;
1620 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1621 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1623 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1624 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1626 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1627 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1628 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1631 CREATE FUNCTION "autofill_initiative_id_trigger"()
1632 RETURNS TRIGGER
1633 LANGUAGE 'plpgsql' VOLATILE AS $$
1634 BEGIN
1635 IF NEW."initiative_id" ISNULL THEN
1636 SELECT "initiative_id" INTO NEW."initiative_id"
1637 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1638 END IF;
1639 RETURN NEW;
1640 END;
1641 $$;
1643 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1644 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1646 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1647 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1651 -----------------------------------------------------
1652 -- Automatic calculation of certain default values --
1653 -----------------------------------------------------
1656 CREATE FUNCTION "copy_timings_trigger"()
1657 RETURNS TRIGGER
1658 LANGUAGE 'plpgsql' VOLATILE AS $$
1659 DECLARE
1660 "policy_row" "policy"%ROWTYPE;
1661 BEGIN
1662 SELECT * INTO "policy_row" FROM "policy"
1663 WHERE "id" = NEW."policy_id";
1664 IF NEW."admission_time" ISNULL THEN
1665 NEW."admission_time" := "policy_row"."admission_time";
1666 END IF;
1667 IF NEW."discussion_time" ISNULL THEN
1668 NEW."discussion_time" := "policy_row"."discussion_time";
1669 END IF;
1670 IF NEW."verification_time" ISNULL THEN
1671 NEW."verification_time" := "policy_row"."verification_time";
1672 END IF;
1673 IF NEW."voting_time" ISNULL THEN
1674 NEW."voting_time" := "policy_row"."voting_time";
1675 END IF;
1676 RETURN NEW;
1677 END;
1678 $$;
1680 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1681 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1683 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1684 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1687 CREATE FUNCTION "default_for_draft_id_trigger"()
1688 RETURNS TRIGGER
1689 LANGUAGE 'plpgsql' VOLATILE AS $$
1690 BEGIN
1691 IF NEW."draft_id" ISNULL THEN
1692 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1693 WHERE "initiative_id" = NEW."initiative_id";
1694 END IF;
1695 RETURN NEW;
1696 END;
1697 $$;
1699 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1700 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1701 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1702 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1704 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1705 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';
1706 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';
1710 ----------------------------------------
1711 -- Automatic creation of dependencies --
1712 ----------------------------------------
1715 CREATE FUNCTION "autocreate_interest_trigger"()
1716 RETURNS TRIGGER
1717 LANGUAGE 'plpgsql' VOLATILE AS $$
1718 BEGIN
1719 IF NOT EXISTS (
1720 SELECT NULL FROM "initiative" JOIN "interest"
1721 ON "initiative"."issue_id" = "interest"."issue_id"
1722 WHERE "initiative"."id" = NEW."initiative_id"
1723 AND "interest"."member_id" = NEW."member_id"
1724 ) THEN
1725 BEGIN
1726 INSERT INTO "interest" ("issue_id", "member_id")
1727 SELECT "issue_id", NEW."member_id"
1728 FROM "initiative" WHERE "id" = NEW."initiative_id";
1729 EXCEPTION WHEN unique_violation THEN END;
1730 END IF;
1731 RETURN NEW;
1732 END;
1733 $$;
1735 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1736 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1738 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1739 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';
1742 CREATE FUNCTION "autocreate_supporter_trigger"()
1743 RETURNS TRIGGER
1744 LANGUAGE 'plpgsql' VOLATILE AS $$
1745 BEGIN
1746 IF NOT EXISTS (
1747 SELECT NULL FROM "suggestion" JOIN "supporter"
1748 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1749 WHERE "suggestion"."id" = NEW."suggestion_id"
1750 AND "supporter"."member_id" = NEW."member_id"
1751 ) THEN
1752 BEGIN
1753 INSERT INTO "supporter" ("initiative_id", "member_id")
1754 SELECT "initiative_id", NEW."member_id"
1755 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1756 EXCEPTION WHEN unique_violation THEN END;
1757 END IF;
1758 RETURN NEW;
1759 END;
1760 $$;
1762 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1763 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1765 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1766 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.';
1770 ------------------------------------------
1771 -- Views and helper functions for views --
1772 ------------------------------------------
1775 CREATE VIEW "unit_delegation" AS
1776 SELECT
1777 "unit"."id" AS "unit_id",
1778 "delegation"."id",
1779 "delegation"."truster_id",
1780 "delegation"."trustee_id",
1781 "delegation"."scope"
1782 FROM "unit"
1783 JOIN "delegation"
1784 ON "delegation"."unit_id" = "unit"."id"
1785 JOIN "member"
1786 ON "delegation"."truster_id" = "member"."id"
1787 JOIN "privilege"
1788 ON "delegation"."unit_id" = "privilege"."unit_id"
1789 AND "delegation"."truster_id" = "privilege"."member_id"
1790 WHERE "member"."active" AND "privilege"."voting_right";
1792 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1795 CREATE VIEW "area_delegation" AS
1796 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1797 "area"."id" AS "area_id",
1798 "delegation"."id",
1799 "delegation"."truster_id",
1800 "delegation"."trustee_id",
1801 "delegation"."scope"
1802 FROM "area"
1803 JOIN "delegation"
1804 ON "delegation"."unit_id" = "area"."unit_id"
1805 OR "delegation"."area_id" = "area"."id"
1806 JOIN "member"
1807 ON "delegation"."truster_id" = "member"."id"
1808 JOIN "privilege"
1809 ON "area"."unit_id" = "privilege"."unit_id"
1810 AND "delegation"."truster_id" = "privilege"."member_id"
1811 WHERE "member"."active" AND "privilege"."voting_right"
1812 ORDER BY
1813 "area"."id",
1814 "delegation"."truster_id",
1815 "delegation"."scope" DESC;
1817 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1820 CREATE VIEW "issue_delegation" AS
1821 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1822 "issue"."id" AS "issue_id",
1823 "delegation"."id",
1824 "delegation"."truster_id",
1825 "delegation"."trustee_id",
1826 "delegation"."scope"
1827 FROM "issue"
1828 JOIN "area"
1829 ON "area"."id" = "issue"."area_id"
1830 JOIN "delegation"
1831 ON "delegation"."unit_id" = "area"."unit_id"
1832 OR "delegation"."area_id" = "area"."id"
1833 OR "delegation"."issue_id" = "issue"."id"
1834 JOIN "member"
1835 ON "delegation"."truster_id" = "member"."id"
1836 JOIN "privilege"
1837 ON "area"."unit_id" = "privilege"."unit_id"
1838 AND "delegation"."truster_id" = "privilege"."member_id"
1839 WHERE "member"."active" AND "privilege"."voting_right"
1840 ORDER BY
1841 "issue"."id",
1842 "delegation"."truster_id",
1843 "delegation"."scope" DESC;
1845 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1848 CREATE FUNCTION "membership_weight_with_skipping"
1849 ( "area_id_p" "area"."id"%TYPE,
1850 "member_id_p" "member"."id"%TYPE,
1851 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1852 RETURNS INT4
1853 LANGUAGE 'plpgsql' STABLE AS $$
1854 DECLARE
1855 "sum_v" INT4;
1856 "delegation_row" "area_delegation"%ROWTYPE;
1857 BEGIN
1858 "sum_v" := 1;
1859 FOR "delegation_row" IN
1860 SELECT "area_delegation".*
1861 FROM "area_delegation" LEFT JOIN "membership"
1862 ON "membership"."area_id" = "area_id_p"
1863 AND "membership"."member_id" = "area_delegation"."truster_id"
1864 WHERE "area_delegation"."area_id" = "area_id_p"
1865 AND "area_delegation"."trustee_id" = "member_id_p"
1866 AND "membership"."member_id" ISNULL
1867 LOOP
1868 IF NOT
1869 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1870 THEN
1871 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1872 "area_id_p",
1873 "delegation_row"."truster_id",
1874 "skip_member_ids_p" || "delegation_row"."truster_id"
1875 );
1876 END IF;
1877 END LOOP;
1878 RETURN "sum_v";
1879 END;
1880 $$;
1882 COMMENT ON FUNCTION "membership_weight_with_skipping"
1883 ( "area"."id"%TYPE,
1884 "member"."id"%TYPE,
1885 INT4[] )
1886 IS 'Helper function for "membership_weight" function';
1889 CREATE FUNCTION "membership_weight"
1890 ( "area_id_p" "area"."id"%TYPE,
1891 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1892 RETURNS INT4
1893 LANGUAGE 'plpgsql' STABLE AS $$
1894 BEGIN
1895 RETURN "membership_weight_with_skipping"(
1896 "area_id_p",
1897 "member_id_p",
1898 ARRAY["member_id_p"]
1899 );
1900 END;
1901 $$;
1903 COMMENT ON FUNCTION "membership_weight"
1904 ( "area"."id"%TYPE,
1905 "member"."id"%TYPE )
1906 IS 'Calculates the potential voting weight of a member in a given area';
1909 CREATE VIEW "member_count_view" AS
1910 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1912 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1915 CREATE VIEW "unit_member_count" AS
1916 SELECT
1917 "unit"."id" AS "unit_id",
1918 count("member"."id") AS "member_count"
1919 FROM "unit"
1920 LEFT JOIN "privilege"
1921 ON "privilege"."unit_id" = "unit"."id"
1922 AND "privilege"."voting_right"
1923 LEFT JOIN "member"
1924 ON "member"."id" = "privilege"."member_id"
1925 AND "member"."active"
1926 GROUP BY "unit"."id";
1928 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1931 CREATE VIEW "area_member_count" AS
1932 SELECT
1933 "area"."id" AS "area_id",
1934 count("member"."id") AS "direct_member_count",
1935 coalesce(
1936 sum(
1937 CASE WHEN "member"."id" NOTNULL THEN
1938 "membership_weight"("area"."id", "member"."id")
1939 ELSE 0 END
1941 ) AS "member_weight"
1942 FROM "area"
1943 LEFT JOIN "membership"
1944 ON "area"."id" = "membership"."area_id"
1945 LEFT JOIN "privilege"
1946 ON "privilege"."unit_id" = "area"."unit_id"
1947 AND "privilege"."member_id" = "membership"."member_id"
1948 AND "privilege"."voting_right"
1949 LEFT JOIN "member"
1950 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1951 AND "member"."active"
1952 GROUP BY "area"."id";
1954 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1957 CREATE VIEW "opening_draft" AS
1958 SELECT "draft".* FROM (
1959 SELECT
1960 "initiative"."id" AS "initiative_id",
1961 min("draft"."id") AS "draft_id"
1962 FROM "initiative" JOIN "draft"
1963 ON "initiative"."id" = "draft"."initiative_id"
1964 GROUP BY "initiative"."id"
1965 ) AS "subquery"
1966 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1968 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1971 CREATE VIEW "current_draft" AS
1972 SELECT "draft".* FROM (
1973 SELECT
1974 "initiative"."id" AS "initiative_id",
1975 max("draft"."id") AS "draft_id"
1976 FROM "initiative" JOIN "draft"
1977 ON "initiative"."id" = "draft"."initiative_id"
1978 GROUP BY "initiative"."id"
1979 ) AS "subquery"
1980 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1982 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1985 CREATE VIEW "critical_opinion" AS
1986 SELECT * FROM "opinion"
1987 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1988 OR ("degree" = -2 AND "fulfilled" = TRUE);
1990 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1993 CREATE VIEW "battle_participant" AS
1994 SELECT "initiative"."id", "initiative"."issue_id"
1995 FROM "issue" JOIN "initiative"
1996 ON "issue"."id" = "initiative"."issue_id"
1997 WHERE "initiative"."admitted"
1998 UNION ALL
1999 SELECT NULL, "id" AS "issue_id"
2000 FROM "issue";
2002 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2005 CREATE VIEW "battle_view" AS
2006 SELECT
2007 "issue"."id" AS "issue_id",
2008 "winning_initiative"."id" AS "winning_initiative_id",
2009 "losing_initiative"."id" AS "losing_initiative_id",
2010 sum(
2011 CASE WHEN
2012 coalesce("better_vote"."grade", 0) >
2013 coalesce("worse_vote"."grade", 0)
2014 THEN "direct_voter"."weight" ELSE 0 END
2015 ) AS "count"
2016 FROM "issue"
2017 LEFT JOIN "direct_voter"
2018 ON "issue"."id" = "direct_voter"."issue_id"
2019 JOIN "battle_participant" AS "winning_initiative"
2020 ON "issue"."id" = "winning_initiative"."issue_id"
2021 JOIN "battle_participant" AS "losing_initiative"
2022 ON "issue"."id" = "losing_initiative"."issue_id"
2023 LEFT JOIN "vote" AS "better_vote"
2024 ON "direct_voter"."member_id" = "better_vote"."member_id"
2025 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2026 LEFT JOIN "vote" AS "worse_vote"
2027 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2028 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2029 WHERE "issue"."closed" NOTNULL
2030 AND "issue"."cleaned" ISNULL
2031 AND (
2032 "winning_initiative"."id" != "losing_initiative"."id" OR
2033 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2034 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2035 GROUP BY
2036 "issue"."id",
2037 "winning_initiative"."id",
2038 "losing_initiative"."id";
2040 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';
2043 CREATE VIEW "expired_session" AS
2044 SELECT * FROM "session" WHERE now() > "expiry";
2046 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2047 DELETE FROM "session" WHERE "ident" = OLD."ident";
2049 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2050 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2053 CREATE VIEW "open_issue" AS
2054 SELECT * FROM "issue" WHERE "closed" ISNULL;
2056 COMMENT ON VIEW "open_issue" IS 'All open issues';
2059 CREATE VIEW "issue_with_ranks_missing" AS
2060 SELECT * FROM "issue"
2061 WHERE "fully_frozen" NOTNULL
2062 AND "closed" NOTNULL
2063 AND "ranks_available" = FALSE;
2065 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2068 CREATE VIEW "member_contingent" AS
2069 SELECT
2070 "member"."id" AS "member_id",
2071 "contingent"."time_frame",
2072 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2074 SELECT count(1) FROM "draft"
2075 WHERE "draft"."author_id" = "member"."id"
2076 AND "draft"."created" > now() - "contingent"."time_frame"
2077 ) + (
2078 SELECT count(1) FROM "suggestion"
2079 WHERE "suggestion"."author_id" = "member"."id"
2080 AND "suggestion"."created" > now() - "contingent"."time_frame"
2082 ELSE NULL END AS "text_entry_count",
2083 "contingent"."text_entry_limit",
2084 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2085 SELECT count(1) FROM "opening_draft"
2086 WHERE "opening_draft"."author_id" = "member"."id"
2087 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2088 ) ELSE NULL END AS "initiative_count",
2089 "contingent"."initiative_limit"
2090 FROM "member" CROSS JOIN "contingent";
2092 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2094 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2095 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2098 CREATE VIEW "member_contingent_left" AS
2099 SELECT
2100 "member_id",
2101 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2102 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2103 FROM "member_contingent" GROUP BY "member_id";
2105 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.';
2108 CREATE VIEW "event_seen_by_member" AS
2109 SELECT
2110 "member"."id" AS "seen_by_member_id",
2111 CASE WHEN "event"."state" IN (
2112 'voting',
2113 'finished_without_winner',
2114 'finished_with_winner'
2115 ) THEN
2116 'voting'::"notify_level"
2117 ELSE
2118 CASE WHEN "event"."state" IN (
2119 'verification',
2120 'canceled_after_revocation_during_verification',
2121 'canceled_no_initiative_admitted'
2122 ) THEN
2123 'verification'::"notify_level"
2124 ELSE
2125 CASE WHEN "event"."state" IN (
2126 'discussion',
2127 'canceled_after_revocation_during_discussion'
2128 ) THEN
2129 'discussion'::"notify_level"
2130 ELSE
2131 'all'::"notify_level"
2132 END
2133 END
2134 END AS "notify_level",
2135 "event".*
2136 FROM "member" CROSS JOIN "event"
2137 LEFT JOIN "issue"
2138 ON "event"."issue_id" = "issue"."id"
2139 LEFT JOIN "membership"
2140 ON "member"."id" = "membership"."member_id"
2141 AND "issue"."area_id" = "membership"."area_id"
2142 LEFT JOIN "interest"
2143 ON "member"."id" = "interest"."member_id"
2144 AND "event"."issue_id" = "interest"."issue_id"
2145 LEFT JOIN "supporter"
2146 ON "member"."id" = "supporter"."member_id"
2147 AND "event"."initiative_id" = "supporter"."initiative_id"
2148 LEFT JOIN "ignored_member"
2149 ON "member"."id" = "ignored_member"."member_id"
2150 AND "event"."member_id" = "ignored_member"."other_member_id"
2151 LEFT JOIN "ignored_initiative"
2152 ON "member"."id" = "ignored_initiative"."member_id"
2153 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2154 WHERE (
2155 "supporter"."member_id" NOTNULL OR
2156 "interest"."member_id" NOTNULL OR
2157 ( "membership"."member_id" NOTNULL AND
2158 "event"."event" IN (
2159 'issue_state_changed',
2160 'initiative_created_in_new_issue',
2161 'initiative_created_in_existing_issue',
2162 'initiative_revoked' ) ) )
2163 AND "ignored_member"."member_id" ISNULL
2164 AND "ignored_initiative"."member_id" ISNULL;
2166 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support, but ignoring members "notify_level"';
2169 CREATE VIEW "selected_event_seen_by_member" AS
2170 SELECT
2171 "member"."id" AS "seen_by_member_id",
2172 CASE WHEN "event"."state" IN (
2173 'voting',
2174 'finished_without_winner',
2175 'finished_with_winner'
2176 ) THEN
2177 'voting'::"notify_level"
2178 ELSE
2179 CASE WHEN "event"."state" IN (
2180 'verification',
2181 'canceled_after_revocation_during_verification',
2182 'canceled_no_initiative_admitted'
2183 ) THEN
2184 'verification'::"notify_level"
2185 ELSE
2186 CASE WHEN "event"."state" IN (
2187 'discussion',
2188 'canceled_after_revocation_during_discussion'
2189 ) THEN
2190 'discussion'::"notify_level"
2191 ELSE
2192 'all'::"notify_level"
2193 END
2194 END
2195 END AS "notify_level",
2196 "event".*
2197 FROM "member" CROSS JOIN "event"
2198 LEFT JOIN "issue"
2199 ON "event"."issue_id" = "issue"."id"
2200 LEFT JOIN "membership"
2201 ON "member"."id" = "membership"."member_id"
2202 AND "issue"."area_id" = "membership"."area_id"
2203 LEFT JOIN "interest"
2204 ON "member"."id" = "interest"."member_id"
2205 AND "event"."issue_id" = "interest"."issue_id"
2206 LEFT JOIN "supporter"
2207 ON "member"."id" = "supporter"."member_id"
2208 AND "event"."initiative_id" = "supporter"."initiative_id"
2209 LEFT JOIN "ignored_member"
2210 ON "member"."id" = "ignored_member"."member_id"
2211 AND "event"."member_id" = "ignored_member"."other_member_id"
2212 LEFT JOIN "ignored_initiative"
2213 ON "member"."id" = "ignored_initiative"."member_id"
2214 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2215 WHERE (
2216 ( "member"."notify_level" >= 'all' ) OR
2217 ( "member"."notify_level" >= 'voting' AND
2218 "event"."state" IN (
2219 'voting',
2220 'finished_without_winner',
2221 'finished_with_winner' ) ) OR
2222 ( "member"."notify_level" >= 'verification' AND
2223 "event"."state" IN (
2224 'verification',
2225 'canceled_after_revocation_during_verification',
2226 'canceled_no_initiative_admitted' ) ) OR
2227 ( "member"."notify_level" >= 'discussion' AND
2228 "event"."state" IN (
2229 'discussion',
2230 'canceled_after_revocation_during_discussion' ) ) )
2231 AND (
2232 "supporter"."member_id" NOTNULL OR
2233 "interest"."member_id" NOTNULL OR
2234 ( "membership"."member_id" NOTNULL AND
2235 "event"."event" IN (
2236 'issue_state_changed',
2237 'initiative_created_in_new_issue',
2238 'initiative_created_in_existing_issue',
2239 'initiative_revoked' ) ) )
2240 AND "ignored_member"."member_id" ISNULL
2241 AND "ignored_initiative"."member_id" ISNULL;
2243 COMMENT ON VIEW "selected_event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests, support and members "notify_level"';
2246 CREATE TYPE "timeline_event" AS ENUM (
2247 'issue_created',
2248 'issue_canceled',
2249 'issue_accepted',
2250 'issue_half_frozen',
2251 'issue_finished_without_voting',
2252 'issue_voting_started',
2253 'issue_finished_after_voting',
2254 'initiative_created',
2255 'initiative_revoked',
2256 'draft_created',
2257 'suggestion_created');
2259 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2262 CREATE VIEW "timeline_issue" AS
2263 SELECT
2264 "created" AS "occurrence",
2265 'issue_created'::"timeline_event" AS "event",
2266 "id" AS "issue_id"
2267 FROM "issue"
2268 UNION ALL
2269 SELECT
2270 "closed" AS "occurrence",
2271 'issue_canceled'::"timeline_event" AS "event",
2272 "id" AS "issue_id"
2273 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2274 UNION ALL
2275 SELECT
2276 "accepted" AS "occurrence",
2277 'issue_accepted'::"timeline_event" AS "event",
2278 "id" AS "issue_id"
2279 FROM "issue" WHERE "accepted" NOTNULL
2280 UNION ALL
2281 SELECT
2282 "half_frozen" AS "occurrence",
2283 'issue_half_frozen'::"timeline_event" AS "event",
2284 "id" AS "issue_id"
2285 FROM "issue" WHERE "half_frozen" NOTNULL
2286 UNION ALL
2287 SELECT
2288 "fully_frozen" AS "occurrence",
2289 'issue_voting_started'::"timeline_event" AS "event",
2290 "id" AS "issue_id"
2291 FROM "issue"
2292 WHERE "fully_frozen" NOTNULL
2293 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2294 UNION ALL
2295 SELECT
2296 "closed" AS "occurrence",
2297 CASE WHEN "fully_frozen" = "closed" THEN
2298 'issue_finished_without_voting'::"timeline_event"
2299 ELSE
2300 'issue_finished_after_voting'::"timeline_event"
2301 END AS "event",
2302 "id" AS "issue_id"
2303 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2305 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2308 CREATE VIEW "timeline_initiative" AS
2309 SELECT
2310 "created" AS "occurrence",
2311 'initiative_created'::"timeline_event" AS "event",
2312 "id" AS "initiative_id"
2313 FROM "initiative"
2314 UNION ALL
2315 SELECT
2316 "revoked" AS "occurrence",
2317 'initiative_revoked'::"timeline_event" AS "event",
2318 "id" AS "initiative_id"
2319 FROM "initiative" WHERE "revoked" NOTNULL;
2321 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2324 CREATE VIEW "timeline_draft" AS
2325 SELECT
2326 "created" AS "occurrence",
2327 'draft_created'::"timeline_event" AS "event",
2328 "id" AS "draft_id"
2329 FROM "draft";
2331 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2334 CREATE VIEW "timeline_suggestion" AS
2335 SELECT
2336 "created" AS "occurrence",
2337 'suggestion_created'::"timeline_event" AS "event",
2338 "id" AS "suggestion_id"
2339 FROM "suggestion";
2341 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2344 CREATE VIEW "timeline" AS
2345 SELECT
2346 "occurrence",
2347 "event",
2348 "issue_id",
2349 NULL AS "initiative_id",
2350 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2351 NULL::INT8 AS "suggestion_id"
2352 FROM "timeline_issue"
2353 UNION ALL
2354 SELECT
2355 "occurrence",
2356 "event",
2357 NULL AS "issue_id",
2358 "initiative_id",
2359 NULL AS "draft_id",
2360 NULL AS "suggestion_id"
2361 FROM "timeline_initiative"
2362 UNION ALL
2363 SELECT
2364 "occurrence",
2365 "event",
2366 NULL AS "issue_id",
2367 NULL AS "initiative_id",
2368 "draft_id",
2369 NULL AS "suggestion_id"
2370 FROM "timeline_draft"
2371 UNION ALL
2372 SELECT
2373 "occurrence",
2374 "event",
2375 NULL AS "issue_id",
2376 NULL AS "initiative_id",
2377 NULL AS "draft_id",
2378 "suggestion_id"
2379 FROM "timeline_suggestion";
2381 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2385 ------------------------------------------------------
2386 -- Row set returning function for delegation chains --
2387 ------------------------------------------------------
2390 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2391 ('first', 'intermediate', 'last', 'repetition');
2393 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2396 CREATE TYPE "delegation_chain_row" AS (
2397 "index" INT4,
2398 "member_id" INT4,
2399 "member_valid" BOOLEAN,
2400 "participation" BOOLEAN,
2401 "overridden" BOOLEAN,
2402 "scope_in" "delegation_scope",
2403 "scope_out" "delegation_scope",
2404 "disabled_out" BOOLEAN,
2405 "loop" "delegation_chain_loop_tag" );
2407 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2409 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2410 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';
2411 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2412 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2413 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2414 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2415 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2418 CREATE FUNCTION "delegation_chain_for_closed_issue"
2419 ( "member_id_p" "member"."id"%TYPE,
2420 "issue_id_p" "issue"."id"%TYPE )
2421 RETURNS SETOF "delegation_chain_row"
2422 LANGUAGE 'plpgsql' STABLE AS $$
2423 DECLARE
2424 "output_row" "delegation_chain_row";
2425 "direct_voter_row" "direct_voter"%ROWTYPE;
2426 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2427 BEGIN
2428 "output_row"."index" := 0;
2429 "output_row"."member_id" := "member_id_p";
2430 "output_row"."member_valid" := TRUE;
2431 "output_row"."participation" := FALSE;
2432 "output_row"."overridden" := FALSE;
2433 "output_row"."disabled_out" := FALSE;
2434 LOOP
2435 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2436 WHERE "issue_id" = "issue_id_p"
2437 AND "member_id" = "output_row"."member_id";
2438 IF "direct_voter_row"."member_id" NOTNULL THEN
2439 "output_row"."participation" := TRUE;
2440 "output_row"."scope_out" := NULL;
2441 "output_row"."disabled_out" := NULL;
2442 RETURN NEXT "output_row";
2443 RETURN;
2444 END IF;
2445 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2446 WHERE "issue_id" = "issue_id_p"
2447 AND "member_id" = "output_row"."member_id";
2448 IF "delegating_voter_row"."member_id" ISNULL THEN
2449 RETURN;
2450 END IF;
2451 "output_row"."scope_out" := "delegating_voter_row"."scope";
2452 RETURN NEXT "output_row";
2453 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2454 "output_row"."scope_in" := "output_row"."scope_out";
2455 END LOOP;
2456 END;
2457 $$;
2459 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2460 ( "member"."id"%TYPE,
2461 "member"."id"%TYPE )
2462 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2465 CREATE FUNCTION "delegation_chain"
2466 ( "member_id_p" "member"."id"%TYPE,
2467 "unit_id_p" "unit"."id"%TYPE,
2468 "area_id_p" "area"."id"%TYPE,
2469 "issue_id_p" "issue"."id"%TYPE,
2470 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2471 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2472 RETURNS SETOF "delegation_chain_row"
2473 LANGUAGE 'plpgsql' STABLE AS $$
2474 DECLARE
2475 "scope_v" "delegation_scope";
2476 "unit_id_v" "unit"."id"%TYPE;
2477 "area_id_v" "area"."id"%TYPE;
2478 "issue_row" "issue"%ROWTYPE;
2479 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2480 "loop_member_id_v" "member"."id"%TYPE;
2481 "output_row" "delegation_chain_row";
2482 "output_rows" "delegation_chain_row"[];
2483 "simulate_v" BOOLEAN;
2484 "simulate_here_v" BOOLEAN;
2485 "delegation_row" "delegation"%ROWTYPE;
2486 "row_count" INT4;
2487 "i" INT4;
2488 "loop_v" BOOLEAN;
2489 BEGIN
2490 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2491 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2492 END IF;
2493 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2494 "simulate_v" := TRUE;
2495 ELSE
2496 "simulate_v" := FALSE;
2497 END IF;
2498 IF
2499 "unit_id_p" NOTNULL AND
2500 "area_id_p" ISNULL AND
2501 "issue_id_p" ISNULL
2502 THEN
2503 "scope_v" := 'unit';
2504 "unit_id_v" := "unit_id_p";
2505 ELSIF
2506 "unit_id_p" ISNULL AND
2507 "area_id_p" NOTNULL AND
2508 "issue_id_p" ISNULL
2509 THEN
2510 "scope_v" := 'area';
2511 "area_id_v" := "area_id_p";
2512 SELECT "unit_id" INTO "unit_id_v"
2513 FROM "area" WHERE "id" = "area_id_v";
2514 ELSIF
2515 "unit_id_p" ISNULL AND
2516 "area_id_p" ISNULL AND
2517 "issue_id_p" NOTNULL
2518 THEN
2519 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2520 IF "issue_row"."id" ISNULL THEN
2521 RETURN;
2522 END IF;
2523 IF "issue_row"."closed" NOTNULL THEN
2524 IF "simulate_v" THEN
2525 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2526 END IF;
2527 FOR "output_row" IN
2528 SELECT * FROM
2529 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2530 LOOP
2531 RETURN NEXT "output_row";
2532 END LOOP;
2533 RETURN;
2534 END IF;
2535 "scope_v" := 'issue';
2536 SELECT "area_id" INTO "area_id_v"
2537 FROM "issue" WHERE "id" = "issue_id_p";
2538 SELECT "unit_id" INTO "unit_id_v"
2539 FROM "area" WHERE "id" = "area_id_v";
2540 ELSE
2541 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2542 END IF;
2543 "visited_member_ids" := '{}';
2544 "loop_member_id_v" := NULL;
2545 "output_rows" := '{}';
2546 "output_row"."index" := 0;
2547 "output_row"."member_id" := "member_id_p";
2548 "output_row"."member_valid" := TRUE;
2549 "output_row"."participation" := FALSE;
2550 "output_row"."overridden" := FALSE;
2551 "output_row"."disabled_out" := FALSE;
2552 "output_row"."scope_out" := NULL;
2553 LOOP
2554 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2555 "loop_member_id_v" := "output_row"."member_id";
2556 ELSE
2557 "visited_member_ids" :=
2558 "visited_member_ids" || "output_row"."member_id";
2559 END IF;
2560 IF "output_row"."participation" ISNULL THEN
2561 "output_row"."overridden" := NULL;
2562 ELSIF "output_row"."participation" THEN
2563 "output_row"."overridden" := TRUE;
2564 END IF;
2565 "output_row"."scope_in" := "output_row"."scope_out";
2566 "output_row"."member_valid" := EXISTS (
2567 SELECT NULL FROM "member" JOIN "privilege"
2568 ON "privilege"."member_id" = "member"."id"
2569 AND "privilege"."unit_id" = "unit_id_v"
2570 WHERE "id" = "output_row"."member_id"
2571 AND "member"."active" AND "privilege"."voting_right"
2572 );
2573 "simulate_here_v" := (
2574 "simulate_v" AND
2575 "output_row"."member_id" = "member_id_p"
2576 );
2577 "delegation_row" := ROW(NULL);
2578 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2579 IF "scope_v" = 'unit' THEN
2580 IF NOT "simulate_here_v" THEN
2581 SELECT * INTO "delegation_row" FROM "delegation"
2582 WHERE "truster_id" = "output_row"."member_id"
2583 AND "unit_id" = "unit_id_v";
2584 END IF;
2585 ELSIF "scope_v" = 'area' THEN
2586 "output_row"."participation" := EXISTS (
2587 SELECT NULL FROM "membership"
2588 WHERE "area_id" = "area_id_p"
2589 AND "member_id" = "output_row"."member_id"
2590 );
2591 IF "simulate_here_v" THEN
2592 IF "simulate_trustee_id_p" ISNULL THEN
2593 SELECT * INTO "delegation_row" FROM "delegation"
2594 WHERE "truster_id" = "output_row"."member_id"
2595 AND "unit_id" = "unit_id_v";
2596 END IF;
2597 ELSE
2598 SELECT * INTO "delegation_row" FROM "delegation"
2599 WHERE "truster_id" = "output_row"."member_id"
2600 AND (
2601 "unit_id" = "unit_id_v" OR
2602 "area_id" = "area_id_v"
2604 ORDER BY "scope" DESC;
2605 END IF;
2606 ELSIF "scope_v" = 'issue' THEN
2607 IF "issue_row"."fully_frozen" ISNULL THEN
2608 "output_row"."participation" := EXISTS (
2609 SELECT NULL FROM "interest"
2610 WHERE "issue_id" = "issue_id_p"
2611 AND "member_id" = "output_row"."member_id"
2612 );
2613 ELSE
2614 IF "output_row"."member_id" = "member_id_p" THEN
2615 "output_row"."participation" := EXISTS (
2616 SELECT NULL FROM "direct_voter"
2617 WHERE "issue_id" = "issue_id_p"
2618 AND "member_id" = "output_row"."member_id"
2619 );
2620 ELSE
2621 "output_row"."participation" := NULL;
2622 END IF;
2623 END IF;
2624 IF "simulate_here_v" THEN
2625 IF "simulate_trustee_id_p" ISNULL THEN
2626 SELECT * INTO "delegation_row" FROM "delegation"
2627 WHERE "truster_id" = "output_row"."member_id"
2628 AND (
2629 "unit_id" = "unit_id_v" OR
2630 "area_id" = "area_id_v"
2632 ORDER BY "scope" DESC;
2633 END IF;
2634 ELSE
2635 SELECT * INTO "delegation_row" FROM "delegation"
2636 WHERE "truster_id" = "output_row"."member_id"
2637 AND (
2638 "unit_id" = "unit_id_v" OR
2639 "area_id" = "area_id_v" OR
2640 "issue_id" = "issue_id_p"
2642 ORDER BY "scope" DESC;
2643 END IF;
2644 END IF;
2645 ELSE
2646 "output_row"."participation" := FALSE;
2647 END IF;
2648 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2649 "output_row"."scope_out" := "scope_v";
2650 "output_rows" := "output_rows" || "output_row";
2651 "output_row"."member_id" := "simulate_trustee_id_p";
2652 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2653 "output_row"."scope_out" := "delegation_row"."scope";
2654 "output_rows" := "output_rows" || "output_row";
2655 "output_row"."member_id" := "delegation_row"."trustee_id";
2656 ELSIF "delegation_row"."scope" NOTNULL THEN
2657 "output_row"."scope_out" := "delegation_row"."scope";
2658 "output_row"."disabled_out" := TRUE;
2659 "output_rows" := "output_rows" || "output_row";
2660 EXIT;
2661 ELSE
2662 "output_row"."scope_out" := NULL;
2663 "output_rows" := "output_rows" || "output_row";
2664 EXIT;
2665 END IF;
2666 EXIT WHEN "loop_member_id_v" NOTNULL;
2667 "output_row"."index" := "output_row"."index" + 1;
2668 END LOOP;
2669 "row_count" := array_upper("output_rows", 1);
2670 "i" := 1;
2671 "loop_v" := FALSE;
2672 LOOP
2673 "output_row" := "output_rows"["i"];
2674 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2675 IF "loop_v" THEN
2676 IF "i" + 1 = "row_count" THEN
2677 "output_row"."loop" := 'last';
2678 ELSIF "i" = "row_count" THEN
2679 "output_row"."loop" := 'repetition';
2680 ELSE
2681 "output_row"."loop" := 'intermediate';
2682 END IF;
2683 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2684 "output_row"."loop" := 'first';
2685 "loop_v" := TRUE;
2686 END IF;
2687 IF "scope_v" = 'unit' THEN
2688 "output_row"."participation" := NULL;
2689 END IF;
2690 RETURN NEXT "output_row";
2691 "i" := "i" + 1;
2692 END LOOP;
2693 RETURN;
2694 END;
2695 $$;
2697 COMMENT ON FUNCTION "delegation_chain"
2698 ( "member"."id"%TYPE,
2699 "unit"."id"%TYPE,
2700 "area"."id"%TYPE,
2701 "issue"."id"%TYPE,
2702 "member"."id"%TYPE,
2703 BOOLEAN )
2704 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2708 ---------------------------------------------------------
2709 -- Single row returning function for delegation chains --
2710 ---------------------------------------------------------
2713 CREATE TYPE "delegation_info_loop_type" AS ENUM
2714 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2716 COMMENT ON TYPE "delegation_info_loop_type" IS 'Type of "delegation_loop" in "delegation_info_type"; ''own'' means loop to self, ''first'' means loop to first trustee, ''first_ellipsis'' means loop to ellipsis after first trustee, ''other'' means loop to other trustee, ''other_ellipsis'' means loop to ellipsis after other trustee''';
2719 CREATE TYPE "delegation_info_type" AS (
2720 "own_participation" BOOLEAN,
2721 "own_delegation_scope" "delegation_scope",
2722 "first_trustee_id" INT4,
2723 "first_trustee_participation" BOOLEAN,
2724 "first_trustee_ellipsis" BOOLEAN,
2725 "other_trustee_id" INT4,
2726 "other_trustee_participation" BOOLEAN,
2727 "other_trustee_ellipsis" BOOLEAN,
2728 "delegation_loop" "delegation_info_loop_type",
2729 "participating_member_id" INT4 );
2731 COMMENT ON TYPE "delegation_info_type" IS 'Type of result returned by "delegation_info" function; For meaning of "participation" check comment on "delegation_chain_row" type';
2733 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2734 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2735 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2736 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2737 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2738 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2739 COMMENT ON COLUMN "delegation_info_type"."other_trustee_participation" IS 'Another trustee is participating (redundant field: if "other_trustee_id" is set, then "other_trustee_participation" is always TRUE, else "other_trustee_participation" is NULL)';
2740 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2741 COMMENT ON COLUMN "delegation_info_type"."delegation_loop" IS 'Non-NULL value, if delegation chain contains a circle; See comment on "delegation_info_loop_type" for details';
2742 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2745 CREATE FUNCTION "delegation_info"
2746 ( "member_id_p" "member"."id"%TYPE,
2747 "unit_id_p" "unit"."id"%TYPE,
2748 "area_id_p" "area"."id"%TYPE,
2749 "issue_id_p" "issue"."id"%TYPE,
2750 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2751 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2752 RETURNS "delegation_info_type"
2753 LANGUAGE 'plpgsql' STABLE AS $$
2754 DECLARE
2755 "current_row" "delegation_chain_row";
2756 "result" "delegation_info_type";
2757 BEGIN
2758 "result"."own_participation" := FALSE;
2759 FOR "current_row" IN
2760 SELECT * FROM "delegation_chain"(
2761 "member_id_p",
2762 "unit_id_p", "area_id_p", "issue_id_p",
2763 "simulate_trustee_id_p", "simulate_default_p")
2764 LOOP
2765 IF
2766 "result"."participating_member_id" ISNULL AND
2767 "current_row"."participation"
2768 THEN
2769 "result"."participating_member_id" := "current_row"."member_id";
2770 END IF;
2771 IF "current_row"."member_id" = "member_id_p" THEN
2772 "result"."own_participation" := "current_row"."participation";
2773 "result"."own_delegation_scope" := "current_row"."scope_out";
2774 IF "current_row"."loop" = 'first' THEN
2775 "result"."delegation_loop" := 'own';
2776 END IF;
2777 ELSIF
2778 "current_row"."member_valid" AND
2779 ( "current_row"."loop" ISNULL OR
2780 "current_row"."loop" != 'repetition' )
2781 THEN
2782 IF "result"."first_trustee_id" ISNULL THEN
2783 "result"."first_trustee_id" := "current_row"."member_id";
2784 "result"."first_trustee_participation" := "current_row"."participation";
2785 "result"."first_trustee_ellipsis" := FALSE;
2786 IF "current_row"."loop" = 'first' THEN
2787 "result"."delegation_loop" := 'first';
2788 END IF;
2789 ELSIF "result"."other_trustee_id" ISNULL THEN
2790 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2791 "result"."other_trustee_id" := "current_row"."member_id";
2792 "result"."other_trustee_participation" := TRUE;
2793 "result"."other_trustee_ellipsis" := FALSE;
2794 IF "current_row"."loop" = 'first' THEN
2795 "result"."delegation_loop" := 'other';
2796 END IF;
2797 ELSE
2798 "result"."first_trustee_ellipsis" := TRUE;
2799 IF "current_row"."loop" = 'first' THEN
2800 "result"."delegation_loop" := 'first_ellipsis';
2801 END IF;
2802 END IF;
2803 ELSE
2804 "result"."other_trustee_ellipsis" := TRUE;
2805 IF "current_row"."loop" = 'first' THEN
2806 "result"."delegation_loop" := 'other_ellipsis';
2807 END IF;
2808 END IF;
2809 END IF;
2810 END LOOP;
2811 RETURN "result";
2812 END;
2813 $$;
2815 COMMENT ON FUNCTION "delegation_info"
2816 ( "member"."id"%TYPE,
2817 "unit"."id"%TYPE,
2818 "area"."id"%TYPE,
2819 "issue"."id"%TYPE,
2820 "member"."id"%TYPE,
2821 BOOLEAN )
2822 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2826 ------------------------------
2827 -- Comparison by vote count --
2828 ------------------------------
2830 CREATE FUNCTION "vote_ratio"
2831 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2832 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2833 RETURNS FLOAT8
2834 LANGUAGE 'plpgsql' STABLE AS $$
2835 BEGIN
2836 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2837 RETURN
2838 "positive_votes_p"::FLOAT8 /
2839 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2840 ELSIF "positive_votes_p" > 0 THEN
2841 RETURN "positive_votes_p";
2842 ELSIF "negative_votes_p" > 0 THEN
2843 RETURN 1 - "negative_votes_p";
2844 ELSE
2845 RETURN 0.5;
2846 END IF;
2847 END;
2848 $$;
2850 COMMENT ON FUNCTION "vote_ratio"
2851 ( "initiative"."positive_votes"%TYPE,
2852 "initiative"."negative_votes"%TYPE )
2853 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.';
2857 ------------------------------------------------
2858 -- Locking for snapshots and voting procedure --
2859 ------------------------------------------------
2862 CREATE FUNCTION "share_row_lock_issue_trigger"()
2863 RETURNS TRIGGER
2864 LANGUAGE 'plpgsql' VOLATILE AS $$
2865 BEGIN
2866 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2867 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2868 END IF;
2869 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2870 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2871 RETURN NEW;
2872 ELSE
2873 RETURN OLD;
2874 END IF;
2875 END;
2876 $$;
2878 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2881 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2882 RETURNS TRIGGER
2883 LANGUAGE 'plpgsql' VOLATILE AS $$
2884 BEGIN
2885 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2886 PERFORM NULL FROM "issue"
2887 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2888 WHERE "initiative"."id" = OLD."initiative_id"
2889 FOR SHARE OF "issue";
2890 END IF;
2891 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2892 PERFORM NULL FROM "issue"
2893 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2894 WHERE "initiative"."id" = NEW."initiative_id"
2895 FOR SHARE OF "issue";
2896 RETURN NEW;
2897 ELSE
2898 RETURN OLD;
2899 END IF;
2900 END;
2901 $$;
2903 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2906 CREATE TRIGGER "share_row_lock_issue"
2907 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2908 FOR EACH ROW EXECUTE PROCEDURE
2909 "share_row_lock_issue_trigger"();
2911 CREATE TRIGGER "share_row_lock_issue"
2912 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2913 FOR EACH ROW EXECUTE PROCEDURE
2914 "share_row_lock_issue_trigger"();
2916 CREATE TRIGGER "share_row_lock_issue"
2917 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2918 FOR EACH ROW EXECUTE PROCEDURE
2919 "share_row_lock_issue_trigger"();
2921 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2922 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2923 FOR EACH ROW EXECUTE PROCEDURE
2924 "share_row_lock_issue_via_initiative_trigger"();
2926 CREATE TRIGGER "share_row_lock_issue"
2927 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2928 FOR EACH ROW EXECUTE PROCEDURE
2929 "share_row_lock_issue_trigger"();
2931 CREATE TRIGGER "share_row_lock_issue"
2932 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2933 FOR EACH ROW EXECUTE PROCEDURE
2934 "share_row_lock_issue_trigger"();
2936 CREATE TRIGGER "share_row_lock_issue"
2937 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2938 FOR EACH ROW EXECUTE PROCEDURE
2939 "share_row_lock_issue_trigger"();
2941 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2942 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2943 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2944 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2945 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2946 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2947 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2950 CREATE FUNCTION "lock_issue"
2951 ( "issue_id_p" "issue"."id"%TYPE )
2952 RETURNS VOID
2953 LANGUAGE 'plpgsql' VOLATILE AS $$
2954 BEGIN
2955 LOCK TABLE "member" IN SHARE MODE;
2956 LOCK TABLE "privilege" IN SHARE MODE;
2957 LOCK TABLE "membership" IN SHARE MODE;
2958 LOCK TABLE "policy" IN SHARE MODE;
2959 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2960 -- NOTE: The row-level exclusive lock in combination with the
2961 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2962 -- acquire a row-level share lock on the issue) ensure that no data
2963 -- is changed, which could affect calculation of snapshots or
2964 -- counting of votes. Table "delegation" must be table-level-locked,
2965 -- as it also contains issue- and global-scope delegations.
2966 LOCK TABLE "delegation" IN SHARE MODE;
2967 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2968 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2969 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2970 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2971 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2972 RETURN;
2973 END;
2974 $$;
2976 COMMENT ON FUNCTION "lock_issue"
2977 ( "issue"."id"%TYPE )
2978 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2982 ------------------------------------------------------------------------
2983 -- Regular tasks, except calculcation of snapshots and voting results --
2984 ------------------------------------------------------------------------
2986 CREATE FUNCTION "check_activity"()
2987 RETURNS VOID
2988 LANGUAGE 'plpgsql' VOLATILE AS $$
2989 DECLARE
2990 "system_setting_row" "system_setting"%ROWTYPE;
2991 BEGIN
2992 SELECT * INTO "system_setting_row" FROM "system_setting";
2993 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2994 IF "system_setting_row"."member_ttl" NOTNULL THEN
2995 UPDATE "member" SET "active" = FALSE
2996 WHERE "active" = TRUE
2997 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2998 END IF;
2999 RETURN;
3000 END;
3001 $$;
3003 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
3006 CREATE FUNCTION "calculate_member_counts"()
3007 RETURNS VOID
3008 LANGUAGE 'plpgsql' VOLATILE AS $$
3009 BEGIN
3010 LOCK TABLE "member" IN SHARE MODE;
3011 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
3012 LOCK TABLE "unit" IN EXCLUSIVE MODE;
3013 LOCK TABLE "area" IN EXCLUSIVE MODE;
3014 LOCK TABLE "privilege" IN SHARE MODE;
3015 LOCK TABLE "membership" IN SHARE MODE;
3016 DELETE FROM "member_count";
3017 INSERT INTO "member_count" ("total_count")
3018 SELECT "total_count" FROM "member_count_view";
3019 UPDATE "unit" SET "member_count" = "view"."member_count"
3020 FROM "unit_member_count" AS "view"
3021 WHERE "view"."unit_id" = "unit"."id";
3022 UPDATE "area" SET
3023 "direct_member_count" = "view"."direct_member_count",
3024 "member_weight" = "view"."member_weight"
3025 FROM "area_member_count" AS "view"
3026 WHERE "view"."area_id" = "area"."id";
3027 RETURN;
3028 END;
3029 $$;
3031 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"';
3035 ------------------------------
3036 -- Calculation of snapshots --
3037 ------------------------------
3039 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3040 ( "issue_id_p" "issue"."id"%TYPE,
3041 "member_id_p" "member"."id"%TYPE,
3042 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3043 RETURNS "direct_population_snapshot"."weight"%TYPE
3044 LANGUAGE 'plpgsql' VOLATILE AS $$
3045 DECLARE
3046 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3047 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3048 "weight_v" INT4;
3049 "sub_weight_v" INT4;
3050 BEGIN
3051 "weight_v" := 0;
3052 FOR "issue_delegation_row" IN
3053 SELECT * FROM "issue_delegation"
3054 WHERE "trustee_id" = "member_id_p"
3055 AND "issue_id" = "issue_id_p"
3056 LOOP
3057 IF NOT EXISTS (
3058 SELECT NULL FROM "direct_population_snapshot"
3059 WHERE "issue_id" = "issue_id_p"
3060 AND "event" = 'periodic'
3061 AND "member_id" = "issue_delegation_row"."truster_id"
3062 ) AND NOT EXISTS (
3063 SELECT NULL FROM "delegating_population_snapshot"
3064 WHERE "issue_id" = "issue_id_p"
3065 AND "event" = 'periodic'
3066 AND "member_id" = "issue_delegation_row"."truster_id"
3067 ) THEN
3068 "delegate_member_ids_v" :=
3069 "member_id_p" || "delegate_member_ids_p";
3070 INSERT INTO "delegating_population_snapshot" (
3071 "issue_id",
3072 "event",
3073 "member_id",
3074 "scope",
3075 "delegate_member_ids"
3076 ) VALUES (
3077 "issue_id_p",
3078 'periodic',
3079 "issue_delegation_row"."truster_id",
3080 "issue_delegation_row"."scope",
3081 "delegate_member_ids_v"
3082 );
3083 "sub_weight_v" := 1 +
3084 "weight_of_added_delegations_for_population_snapshot"(
3085 "issue_id_p",
3086 "issue_delegation_row"."truster_id",
3087 "delegate_member_ids_v"
3088 );
3089 UPDATE "delegating_population_snapshot"
3090 SET "weight" = "sub_weight_v"
3091 WHERE "issue_id" = "issue_id_p"
3092 AND "event" = 'periodic'
3093 AND "member_id" = "issue_delegation_row"."truster_id";
3094 "weight_v" := "weight_v" + "sub_weight_v";
3095 END IF;
3096 END LOOP;
3097 RETURN "weight_v";
3098 END;
3099 $$;
3101 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3102 ( "issue"."id"%TYPE,
3103 "member"."id"%TYPE,
3104 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3105 IS 'Helper function for "create_population_snapshot" function';
3108 CREATE FUNCTION "create_population_snapshot"
3109 ( "issue_id_p" "issue"."id"%TYPE )
3110 RETURNS VOID
3111 LANGUAGE 'plpgsql' VOLATILE AS $$
3112 DECLARE
3113 "member_id_v" "member"."id"%TYPE;
3114 BEGIN
3115 DELETE FROM "direct_population_snapshot"
3116 WHERE "issue_id" = "issue_id_p"
3117 AND "event" = 'periodic';
3118 DELETE FROM "delegating_population_snapshot"
3119 WHERE "issue_id" = "issue_id_p"
3120 AND "event" = 'periodic';
3121 INSERT INTO "direct_population_snapshot"
3122 ("issue_id", "event", "member_id")
3123 SELECT
3124 "issue_id_p" AS "issue_id",
3125 'periodic'::"snapshot_event" AS "event",
3126 "member"."id" AS "member_id"
3127 FROM "issue"
3128 JOIN "area" ON "issue"."area_id" = "area"."id"
3129 JOIN "membership" ON "area"."id" = "membership"."area_id"
3130 JOIN "member" ON "membership"."member_id" = "member"."id"
3131 JOIN "privilege"
3132 ON "privilege"."unit_id" = "area"."unit_id"
3133 AND "privilege"."member_id" = "member"."id"
3134 WHERE "issue"."id" = "issue_id_p"
3135 AND "member"."active" AND "privilege"."voting_right"
3136 UNION
3137 SELECT
3138 "issue_id_p" AS "issue_id",
3139 'periodic'::"snapshot_event" AS "event",
3140 "member"."id" AS "member_id"
3141 FROM "issue"
3142 JOIN "area" ON "issue"."area_id" = "area"."id"
3143 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3144 JOIN "member" ON "interest"."member_id" = "member"."id"
3145 JOIN "privilege"
3146 ON "privilege"."unit_id" = "area"."unit_id"
3147 AND "privilege"."member_id" = "member"."id"
3148 WHERE "issue"."id" = "issue_id_p"
3149 AND "member"."active" AND "privilege"."voting_right";
3150 FOR "member_id_v" IN
3151 SELECT "member_id" FROM "direct_population_snapshot"
3152 WHERE "issue_id" = "issue_id_p"
3153 AND "event" = 'periodic'
3154 LOOP
3155 UPDATE "direct_population_snapshot" SET
3156 "weight" = 1 +
3157 "weight_of_added_delegations_for_population_snapshot"(
3158 "issue_id_p",
3159 "member_id_v",
3160 '{}'
3162 WHERE "issue_id" = "issue_id_p"
3163 AND "event" = 'periodic'
3164 AND "member_id" = "member_id_v";
3165 END LOOP;
3166 RETURN;
3167 END;
3168 $$;
3170 COMMENT ON FUNCTION "create_population_snapshot"
3171 ( "issue"."id"%TYPE )
3172 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.';
3175 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3176 ( "issue_id_p" "issue"."id"%TYPE,
3177 "member_id_p" "member"."id"%TYPE,
3178 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3179 RETURNS "direct_interest_snapshot"."weight"%TYPE
3180 LANGUAGE 'plpgsql' VOLATILE AS $$
3181 DECLARE
3182 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3183 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3184 "weight_v" INT4;
3185 "sub_weight_v" INT4;
3186 BEGIN
3187 "weight_v" := 0;
3188 FOR "issue_delegation_row" IN
3189 SELECT * FROM "issue_delegation"
3190 WHERE "trustee_id" = "member_id_p"
3191 AND "issue_id" = "issue_id_p"
3192 LOOP
3193 IF NOT EXISTS (
3194 SELECT NULL FROM "direct_interest_snapshot"
3195 WHERE "issue_id" = "issue_id_p"
3196 AND "event" = 'periodic'
3197 AND "member_id" = "issue_delegation_row"."truster_id"
3198 ) AND NOT EXISTS (
3199 SELECT NULL FROM "delegating_interest_snapshot"
3200 WHERE "issue_id" = "issue_id_p"
3201 AND "event" = 'periodic'
3202 AND "member_id" = "issue_delegation_row"."truster_id"
3203 ) THEN
3204 "delegate_member_ids_v" :=
3205 "member_id_p" || "delegate_member_ids_p";
3206 INSERT INTO "delegating_interest_snapshot" (
3207 "issue_id",
3208 "event",
3209 "member_id",
3210 "scope",
3211 "delegate_member_ids"
3212 ) VALUES (
3213 "issue_id_p",
3214 'periodic',
3215 "issue_delegation_row"."truster_id",
3216 "issue_delegation_row"."scope",
3217 "delegate_member_ids_v"
3218 );
3219 "sub_weight_v" := 1 +
3220 "weight_of_added_delegations_for_interest_snapshot"(
3221 "issue_id_p",
3222 "issue_delegation_row"."truster_id",
3223 "delegate_member_ids_v"
3224 );
3225 UPDATE "delegating_interest_snapshot"
3226 SET "weight" = "sub_weight_v"
3227 WHERE "issue_id" = "issue_id_p"
3228 AND "event" = 'periodic'
3229 AND "member_id" = "issue_delegation_row"."truster_id";
3230 "weight_v" := "weight_v" + "sub_weight_v";
3231 END IF;
3232 END LOOP;
3233 RETURN "weight_v";
3234 END;
3235 $$;
3237 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3238 ( "issue"."id"%TYPE,
3239 "member"."id"%TYPE,
3240 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3241 IS 'Helper function for "create_interest_snapshot" function';
3244 CREATE FUNCTION "create_interest_snapshot"
3245 ( "issue_id_p" "issue"."id"%TYPE )
3246 RETURNS VOID
3247 LANGUAGE 'plpgsql' VOLATILE AS $$
3248 DECLARE
3249 "member_id_v" "member"."id"%TYPE;
3250 BEGIN
3251 DELETE FROM "direct_interest_snapshot"
3252 WHERE "issue_id" = "issue_id_p"
3253 AND "event" = 'periodic';
3254 DELETE FROM "delegating_interest_snapshot"
3255 WHERE "issue_id" = "issue_id_p"
3256 AND "event" = 'periodic';
3257 DELETE FROM "direct_supporter_snapshot"
3258 WHERE "issue_id" = "issue_id_p"
3259 AND "event" = 'periodic';
3260 INSERT INTO "direct_interest_snapshot"
3261 ("issue_id", "event", "member_id")
3262 SELECT
3263 "issue_id_p" AS "issue_id",
3264 'periodic' AS "event",
3265 "member"."id" AS "member_id"
3266 FROM "issue"
3267 JOIN "area" ON "issue"."area_id" = "area"."id"
3268 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3269 JOIN "member" ON "interest"."member_id" = "member"."id"
3270 JOIN "privilege"
3271 ON "privilege"."unit_id" = "area"."unit_id"
3272 AND "privilege"."member_id" = "member"."id"
3273 WHERE "issue"."id" = "issue_id_p"
3274 AND "member"."active" AND "privilege"."voting_right";
3275 FOR "member_id_v" IN
3276 SELECT "member_id" FROM "direct_interest_snapshot"
3277 WHERE "issue_id" = "issue_id_p"
3278 AND "event" = 'periodic'
3279 LOOP
3280 UPDATE "direct_interest_snapshot" SET
3281 "weight" = 1 +
3282 "weight_of_added_delegations_for_interest_snapshot"(
3283 "issue_id_p",
3284 "member_id_v",
3285 '{}'
3287 WHERE "issue_id" = "issue_id_p"
3288 AND "event" = 'periodic'
3289 AND "member_id" = "member_id_v";
3290 END LOOP;
3291 INSERT INTO "direct_supporter_snapshot"
3292 ( "issue_id", "initiative_id", "event", "member_id",
3293 "draft_id", "informed", "satisfied" )
3294 SELECT
3295 "issue_id_p" AS "issue_id",
3296 "initiative"."id" AS "initiative_id",
3297 'periodic' AS "event",
3298 "supporter"."member_id" AS "member_id",
3299 "supporter"."draft_id" AS "draft_id",
3300 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3301 NOT EXISTS (
3302 SELECT NULL FROM "critical_opinion"
3303 WHERE "initiative_id" = "initiative"."id"
3304 AND "member_id" = "supporter"."member_id"
3305 ) AS "satisfied"
3306 FROM "initiative"
3307 JOIN "supporter"
3308 ON "supporter"."initiative_id" = "initiative"."id"
3309 JOIN "current_draft"
3310 ON "initiative"."id" = "current_draft"."initiative_id"
3311 JOIN "direct_interest_snapshot"
3312 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3313 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3314 AND "event" = 'periodic'
3315 WHERE "initiative"."issue_id" = "issue_id_p";
3316 RETURN;
3317 END;
3318 $$;
3320 COMMENT ON FUNCTION "create_interest_snapshot"
3321 ( "issue"."id"%TYPE )
3322 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.';
3325 CREATE FUNCTION "create_snapshot"
3326 ( "issue_id_p" "issue"."id"%TYPE )
3327 RETURNS VOID
3328 LANGUAGE 'plpgsql' VOLATILE AS $$
3329 DECLARE
3330 "initiative_id_v" "initiative"."id"%TYPE;
3331 "suggestion_id_v" "suggestion"."id"%TYPE;
3332 BEGIN
3333 PERFORM "lock_issue"("issue_id_p");
3334 PERFORM "create_population_snapshot"("issue_id_p");
3335 PERFORM "create_interest_snapshot"("issue_id_p");
3336 UPDATE "issue" SET
3337 "snapshot" = now(),
3338 "latest_snapshot_event" = 'periodic',
3339 "population" = (
3340 SELECT coalesce(sum("weight"), 0)
3341 FROM "direct_population_snapshot"
3342 WHERE "issue_id" = "issue_id_p"
3343 AND "event" = 'periodic'
3345 WHERE "id" = "issue_id_p";
3346 FOR "initiative_id_v" IN
3347 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3348 LOOP
3349 UPDATE "initiative" SET
3350 "supporter_count" = (
3351 SELECT coalesce(sum("di"."weight"), 0)
3352 FROM "direct_interest_snapshot" AS "di"
3353 JOIN "direct_supporter_snapshot" AS "ds"
3354 ON "di"."member_id" = "ds"."member_id"
3355 WHERE "di"."issue_id" = "issue_id_p"
3356 AND "di"."event" = 'periodic'
3357 AND "ds"."initiative_id" = "initiative_id_v"
3358 AND "ds"."event" = 'periodic'
3359 ),
3360 "informed_supporter_count" = (
3361 SELECT coalesce(sum("di"."weight"), 0)
3362 FROM "direct_interest_snapshot" AS "di"
3363 JOIN "direct_supporter_snapshot" AS "ds"
3364 ON "di"."member_id" = "ds"."member_id"
3365 WHERE "di"."issue_id" = "issue_id_p"
3366 AND "di"."event" = 'periodic'
3367 AND "ds"."initiative_id" = "initiative_id_v"
3368 AND "ds"."event" = 'periodic'
3369 AND "ds"."informed"
3370 ),
3371 "satisfied_supporter_count" = (
3372 SELECT coalesce(sum("di"."weight"), 0)
3373 FROM "direct_interest_snapshot" AS "di"
3374 JOIN "direct_supporter_snapshot" AS "ds"
3375 ON "di"."member_id" = "ds"."member_id"
3376 WHERE "di"."issue_id" = "issue_id_p"
3377 AND "di"."event" = 'periodic'
3378 AND "ds"."initiative_id" = "initiative_id_v"
3379 AND "ds"."event" = 'periodic'
3380 AND "ds"."satisfied"
3381 ),
3382 "satisfied_informed_supporter_count" = (
3383 SELECT coalesce(sum("di"."weight"), 0)
3384 FROM "direct_interest_snapshot" AS "di"
3385 JOIN "direct_supporter_snapshot" AS "ds"
3386 ON "di"."member_id" = "ds"."member_id"
3387 WHERE "di"."issue_id" = "issue_id_p"
3388 AND "di"."event" = 'periodic'
3389 AND "ds"."initiative_id" = "initiative_id_v"
3390 AND "ds"."event" = 'periodic'
3391 AND "ds"."informed"
3392 AND "ds"."satisfied"
3394 WHERE "id" = "initiative_id_v";
3395 FOR "suggestion_id_v" IN
3396 SELECT "id" FROM "suggestion"
3397 WHERE "initiative_id" = "initiative_id_v"
3398 LOOP
3399 UPDATE "suggestion" SET
3400 "minus2_unfulfilled_count" = (
3401 SELECT coalesce(sum("snapshot"."weight"), 0)
3402 FROM "issue" CROSS JOIN "opinion"
3403 JOIN "direct_interest_snapshot" AS "snapshot"
3404 ON "snapshot"."issue_id" = "issue"."id"
3405 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3406 AND "snapshot"."member_id" = "opinion"."member_id"
3407 WHERE "issue"."id" = "issue_id_p"
3408 AND "opinion"."suggestion_id" = "suggestion_id_v"
3409 AND "opinion"."degree" = -2
3410 AND "opinion"."fulfilled" = FALSE
3411 ),
3412 "minus2_fulfilled_count" = (
3413 SELECT coalesce(sum("snapshot"."weight"), 0)
3414 FROM "issue" CROSS JOIN "opinion"
3415 JOIN "direct_interest_snapshot" AS "snapshot"
3416 ON "snapshot"."issue_id" = "issue"."id"
3417 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3418 AND "snapshot"."member_id" = "opinion"."member_id"
3419 WHERE "issue"."id" = "issue_id_p"
3420 AND "opinion"."suggestion_id" = "suggestion_id_v"
3421 AND "opinion"."degree" = -2
3422 AND "opinion"."fulfilled" = TRUE
3423 ),
3424 "minus1_unfulfilled_count" = (
3425 SELECT coalesce(sum("snapshot"."weight"), 0)
3426 FROM "issue" CROSS JOIN "opinion"
3427 JOIN "direct_interest_snapshot" AS "snapshot"
3428 ON "snapshot"."issue_id" = "issue"."id"
3429 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3430 AND "snapshot"."member_id" = "opinion"."member_id"
3431 WHERE "issue"."id" = "issue_id_p"
3432 AND "opinion"."suggestion_id" = "suggestion_id_v"
3433 AND "opinion"."degree" = -1
3434 AND "opinion"."fulfilled" = FALSE
3435 ),
3436 "minus1_fulfilled_count" = (
3437 SELECT coalesce(sum("snapshot"."weight"), 0)
3438 FROM "issue" CROSS JOIN "opinion"
3439 JOIN "direct_interest_snapshot" AS "snapshot"
3440 ON "snapshot"."issue_id" = "issue"."id"
3441 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3442 AND "snapshot"."member_id" = "opinion"."member_id"
3443 WHERE "issue"."id" = "issue_id_p"
3444 AND "opinion"."suggestion_id" = "suggestion_id_v"
3445 AND "opinion"."degree" = -1
3446 AND "opinion"."fulfilled" = TRUE
3447 ),
3448 "plus1_unfulfilled_count" = (
3449 SELECT coalesce(sum("snapshot"."weight"), 0)
3450 FROM "issue" CROSS JOIN "opinion"
3451 JOIN "direct_interest_snapshot" AS "snapshot"
3452 ON "snapshot"."issue_id" = "issue"."id"
3453 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3454 AND "snapshot"."member_id" = "opinion"."member_id"
3455 WHERE "issue"."id" = "issue_id_p"
3456 AND "opinion"."suggestion_id" = "suggestion_id_v"
3457 AND "opinion"."degree" = 1
3458 AND "opinion"."fulfilled" = FALSE
3459 ),
3460 "plus1_fulfilled_count" = (
3461 SELECT coalesce(sum("snapshot"."weight"), 0)
3462 FROM "issue" CROSS JOIN "opinion"
3463 JOIN "direct_interest_snapshot" AS "snapshot"
3464 ON "snapshot"."issue_id" = "issue"."id"
3465 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3466 AND "snapshot"."member_id" = "opinion"."member_id"
3467 WHERE "issue"."id" = "issue_id_p"
3468 AND "opinion"."suggestion_id" = "suggestion_id_v"
3469 AND "opinion"."degree" = 1
3470 AND "opinion"."fulfilled" = TRUE
3471 ),
3472 "plus2_unfulfilled_count" = (
3473 SELECT coalesce(sum("snapshot"."weight"), 0)
3474 FROM "issue" CROSS JOIN "opinion"
3475 JOIN "direct_interest_snapshot" AS "snapshot"
3476 ON "snapshot"."issue_id" = "issue"."id"
3477 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3478 AND "snapshot"."member_id" = "opinion"."member_id"
3479 WHERE "issue"."id" = "issue_id_p"
3480 AND "opinion"."suggestion_id" = "suggestion_id_v"
3481 AND "opinion"."degree" = 2
3482 AND "opinion"."fulfilled" = FALSE
3483 ),
3484 "plus2_fulfilled_count" = (
3485 SELECT coalesce(sum("snapshot"."weight"), 0)
3486 FROM "issue" CROSS JOIN "opinion"
3487 JOIN "direct_interest_snapshot" AS "snapshot"
3488 ON "snapshot"."issue_id" = "issue"."id"
3489 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3490 AND "snapshot"."member_id" = "opinion"."member_id"
3491 WHERE "issue"."id" = "issue_id_p"
3492 AND "opinion"."suggestion_id" = "suggestion_id_v"
3493 AND "opinion"."degree" = 2
3494 AND "opinion"."fulfilled" = TRUE
3496 WHERE "suggestion"."id" = "suggestion_id_v";
3497 END LOOP;
3498 END LOOP;
3499 RETURN;
3500 END;
3501 $$;
3503 COMMENT ON FUNCTION "create_snapshot"
3504 ( "issue"."id"%TYPE )
3505 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.';
3508 CREATE FUNCTION "set_snapshot_event"
3509 ( "issue_id_p" "issue"."id"%TYPE,
3510 "event_p" "snapshot_event" )
3511 RETURNS VOID
3512 LANGUAGE 'plpgsql' VOLATILE AS $$
3513 DECLARE
3514 "event_v" "issue"."latest_snapshot_event"%TYPE;
3515 BEGIN
3516 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3517 WHERE "id" = "issue_id_p" FOR UPDATE;
3518 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3519 WHERE "id" = "issue_id_p";
3520 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3521 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3522 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3523 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3524 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3525 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3526 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3527 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3528 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3529 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3530 RETURN;
3531 END;
3532 $$;
3534 COMMENT ON FUNCTION "set_snapshot_event"
3535 ( "issue"."id"%TYPE,
3536 "snapshot_event" )
3537 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3541 ---------------------
3542 -- Freezing issues --
3543 ---------------------
3545 CREATE FUNCTION "freeze_after_snapshot"
3546 ( "issue_id_p" "issue"."id"%TYPE )
3547 RETURNS VOID
3548 LANGUAGE 'plpgsql' VOLATILE AS $$
3549 DECLARE
3550 "issue_row" "issue"%ROWTYPE;
3551 "policy_row" "policy"%ROWTYPE;
3552 "initiative_row" "initiative"%ROWTYPE;
3553 BEGIN
3554 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3555 SELECT * INTO "policy_row"
3556 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3557 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3558 FOR "initiative_row" IN
3559 SELECT * FROM "initiative"
3560 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3561 LOOP
3562 IF
3563 "initiative_row"."polling" OR (
3564 "initiative_row"."satisfied_supporter_count" > 0 AND
3565 "initiative_row"."satisfied_supporter_count" *
3566 "policy_row"."initiative_quorum_den" >=
3567 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3569 THEN
3570 UPDATE "initiative" SET "admitted" = TRUE
3571 WHERE "id" = "initiative_row"."id";
3572 ELSE
3573 UPDATE "initiative" SET "admitted" = FALSE
3574 WHERE "id" = "initiative_row"."id";
3575 END IF;
3576 END LOOP;
3577 IF EXISTS (
3578 SELECT NULL FROM "initiative"
3579 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3580 ) THEN
3581 UPDATE "issue" SET
3582 "state" = 'voting',
3583 "accepted" = coalesce("accepted", now()),
3584 "half_frozen" = coalesce("half_frozen", now()),
3585 "fully_frozen" = now()
3586 WHERE "id" = "issue_id_p";
3587 ELSE
3588 UPDATE "issue" SET
3589 "state" = 'canceled_no_initiative_admitted',
3590 "accepted" = coalesce("accepted", now()),
3591 "half_frozen" = coalesce("half_frozen", now()),
3592 "fully_frozen" = now(),
3593 "closed" = now(),
3594 "ranks_available" = TRUE
3595 WHERE "id" = "issue_id_p";
3596 -- NOTE: The following DELETE statements have effect only when
3597 -- issue state has been manipulated
3598 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3599 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3600 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3601 END IF;
3602 RETURN;
3603 END;
3604 $$;
3606 COMMENT ON FUNCTION "freeze_after_snapshot"
3607 ( "issue"."id"%TYPE )
3608 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3611 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3612 RETURNS VOID
3613 LANGUAGE 'plpgsql' VOLATILE AS $$
3614 DECLARE
3615 "issue_row" "issue"%ROWTYPE;
3616 BEGIN
3617 PERFORM "create_snapshot"("issue_id_p");
3618 PERFORM "freeze_after_snapshot"("issue_id_p");
3619 RETURN;
3620 END;
3621 $$;
3623 COMMENT ON FUNCTION "manual_freeze"
3624 ( "issue"."id"%TYPE )
3625 IS 'Freeze an issue manually (fully) and start voting';
3629 -----------------------
3630 -- Counting of votes --
3631 -----------------------
3634 CREATE FUNCTION "weight_of_added_vote_delegations"
3635 ( "issue_id_p" "issue"."id"%TYPE,
3636 "member_id_p" "member"."id"%TYPE,
3637 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3638 RETURNS "direct_voter"."weight"%TYPE
3639 LANGUAGE 'plpgsql' VOLATILE AS $$
3640 DECLARE
3641 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3642 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3643 "weight_v" INT4;
3644 "sub_weight_v" INT4;
3645 BEGIN
3646 "weight_v" := 0;
3647 FOR "issue_delegation_row" IN
3648 SELECT * FROM "issue_delegation"
3649 WHERE "trustee_id" = "member_id_p"
3650 AND "issue_id" = "issue_id_p"
3651 LOOP
3652 IF NOT EXISTS (
3653 SELECT NULL FROM "direct_voter"
3654 WHERE "member_id" = "issue_delegation_row"."truster_id"
3655 AND "issue_id" = "issue_id_p"
3656 ) AND NOT EXISTS (
3657 SELECT NULL FROM "delegating_voter"
3658 WHERE "member_id" = "issue_delegation_row"."truster_id"
3659 AND "issue_id" = "issue_id_p"
3660 ) THEN
3661 "delegate_member_ids_v" :=
3662 "member_id_p" || "delegate_member_ids_p";
3663 INSERT INTO "delegating_voter" (
3664 "issue_id",
3665 "member_id",
3666 "scope",
3667 "delegate_member_ids"
3668 ) VALUES (
3669 "issue_id_p",
3670 "issue_delegation_row"."truster_id",
3671 "issue_delegation_row"."scope",
3672 "delegate_member_ids_v"
3673 );
3674 "sub_weight_v" := 1 +
3675 "weight_of_added_vote_delegations"(
3676 "issue_id_p",
3677 "issue_delegation_row"."truster_id",
3678 "delegate_member_ids_v"
3679 );
3680 UPDATE "delegating_voter"
3681 SET "weight" = "sub_weight_v"
3682 WHERE "issue_id" = "issue_id_p"
3683 AND "member_id" = "issue_delegation_row"."truster_id";
3684 "weight_v" := "weight_v" + "sub_weight_v";
3685 END IF;
3686 END LOOP;
3687 RETURN "weight_v";
3688 END;
3689 $$;
3691 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3692 ( "issue"."id"%TYPE,
3693 "member"."id"%TYPE,
3694 "delegating_voter"."delegate_member_ids"%TYPE )
3695 IS 'Helper function for "add_vote_delegations" function';
3698 CREATE FUNCTION "add_vote_delegations"
3699 ( "issue_id_p" "issue"."id"%TYPE )
3700 RETURNS VOID
3701 LANGUAGE 'plpgsql' VOLATILE AS $$
3702 DECLARE
3703 "member_id_v" "member"."id"%TYPE;
3704 BEGIN
3705 FOR "member_id_v" IN
3706 SELECT "member_id" FROM "direct_voter"
3707 WHERE "issue_id" = "issue_id_p"
3708 LOOP
3709 UPDATE "direct_voter" SET
3710 "weight" = "weight" + "weight_of_added_vote_delegations"(
3711 "issue_id_p",
3712 "member_id_v",
3713 '{}'
3715 WHERE "member_id" = "member_id_v"
3716 AND "issue_id" = "issue_id_p";
3717 END LOOP;
3718 RETURN;
3719 END;
3720 $$;
3722 COMMENT ON FUNCTION "add_vote_delegations"
3723 ( "issue_id_p" "issue"."id"%TYPE )
3724 IS 'Helper function for "close_voting" function';
3727 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3728 RETURNS VOID
3729 LANGUAGE 'plpgsql' VOLATILE AS $$
3730 DECLARE
3731 "area_id_v" "area"."id"%TYPE;
3732 "unit_id_v" "unit"."id"%TYPE;
3733 "member_id_v" "member"."id"%TYPE;
3734 BEGIN
3735 PERFORM "lock_issue"("issue_id_p");
3736 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3737 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3738 -- delete delegating votes (in cases of manual reset of issue state):
3739 DELETE FROM "delegating_voter"
3740 WHERE "issue_id" = "issue_id_p";
3741 -- delete votes from non-privileged voters:
3742 DELETE FROM "direct_voter"
3743 USING (
3744 SELECT
3745 "direct_voter"."member_id"
3746 FROM "direct_voter"
3747 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3748 LEFT JOIN "privilege"
3749 ON "privilege"."unit_id" = "unit_id_v"
3750 AND "privilege"."member_id" = "direct_voter"."member_id"
3751 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3752 "member"."active" = FALSE OR
3753 "privilege"."voting_right" ISNULL OR
3754 "privilege"."voting_right" = FALSE
3756 ) AS "subquery"
3757 WHERE "direct_voter"."issue_id" = "issue_id_p"
3758 AND "direct_voter"."member_id" = "subquery"."member_id";
3759 -- consider delegations:
3760 UPDATE "direct_voter" SET "weight" = 1
3761 WHERE "issue_id" = "issue_id_p";
3762 PERFORM "add_vote_delegations"("issue_id_p");
3763 -- set voter count and mark issue as being calculated:
3764 UPDATE "issue" SET
3765 "state" = 'calculation',
3766 "closed" = now(),
3767 "voter_count" = (
3768 SELECT coalesce(sum("weight"), 0)
3769 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3771 WHERE "id" = "issue_id_p";
3772 -- materialize battle_view:
3773 -- NOTE: "closed" column of issue must be set at this point
3774 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3775 INSERT INTO "battle" (
3776 "issue_id",
3777 "winning_initiative_id", "losing_initiative_id",
3778 "count"
3779 ) SELECT
3780 "issue_id",
3781 "winning_initiative_id", "losing_initiative_id",
3782 "count"
3783 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3784 -- copy "positive_votes" and "negative_votes" from "battle" table:
3785 UPDATE "initiative" SET
3786 "positive_votes" = "battle_win"."count",
3787 "negative_votes" = "battle_lose"."count"
3788 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3789 WHERE
3790 "battle_win"."issue_id" = "issue_id_p" AND
3791 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3792 "battle_win"."losing_initiative_id" ISNULL AND
3793 "battle_lose"."issue_id" = "issue_id_p" AND
3794 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3795 "battle_lose"."winning_initiative_id" ISNULL;
3796 END;
3797 $$;
3799 COMMENT ON FUNCTION "close_voting"
3800 ( "issue"."id"%TYPE )
3801 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.';
3804 CREATE FUNCTION "defeat_strength"
3805 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3806 RETURNS INT8
3807 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3808 BEGIN
3809 IF "positive_votes_p" > "negative_votes_p" THEN
3810 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3811 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3812 RETURN 0;
3813 ELSE
3814 RETURN -1;
3815 END IF;
3816 END;
3817 $$;
3819 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';
3822 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3823 RETURNS VOID
3824 LANGUAGE 'plpgsql' VOLATILE AS $$
3825 DECLARE
3826 "issue_row" "issue"%ROWTYPE;
3827 "policy_row" "policy"%ROWTYPE;
3828 "dimension_v" INTEGER;
3829 "vote_matrix" INT4[][]; -- absolute votes
3830 "matrix" INT8[][]; -- defeat strength / best paths
3831 "i" INTEGER;
3832 "j" INTEGER;
3833 "k" INTEGER;
3834 "battle_row" "battle"%ROWTYPE;
3835 "rank_ary" INT4[];
3836 "rank_v" INT4;
3837 "done_v" INTEGER;
3838 "winners_ary" INTEGER[];
3839 "initiative_id_v" "initiative"."id"%TYPE;
3840 BEGIN
3841 SELECT * INTO "issue_row"
3842 FROM "issue" WHERE "id" = "issue_id_p"
3843 FOR UPDATE;
3844 SELECT * INTO "policy_row"
3845 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3846 SELECT count(1) INTO "dimension_v"
3847 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3848 -- Create "vote_matrix" with absolute number of votes in pairwise
3849 -- comparison:
3850 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3851 "i" := 1;
3852 "j" := 2;
3853 FOR "battle_row" IN
3854 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3855 ORDER BY
3856 "winning_initiative_id" NULLS LAST,
3857 "losing_initiative_id" NULLS LAST
3858 LOOP
3859 "vote_matrix"["i"]["j"] := "battle_row"."count";
3860 IF "j" = "dimension_v" THEN
3861 "i" := "i" + 1;
3862 "j" := 1;
3863 ELSE
3864 "j" := "j" + 1;
3865 IF "j" = "i" THEN
3866 "j" := "j" + 1;
3867 END IF;
3868 END IF;
3869 END LOOP;
3870 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3871 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3872 END IF;
3873 -- Store defeat strengths in "matrix" using "defeat_strength"
3874 -- function:
3875 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3876 "i" := 1;
3877 LOOP
3878 "j" := 1;
3879 LOOP
3880 IF "i" != "j" THEN
3881 "matrix"["i"]["j"] := "defeat_strength"(
3882 "vote_matrix"["i"]["j"],
3883 "vote_matrix"["j"]["i"]
3884 );
3885 END IF;
3886 EXIT WHEN "j" = "dimension_v";
3887 "j" := "j" + 1;
3888 END LOOP;
3889 EXIT WHEN "i" = "dimension_v";
3890 "i" := "i" + 1;
3891 END LOOP;
3892 -- Find best paths:
3893 "i" := 1;
3894 LOOP
3895 "j" := 1;
3896 LOOP
3897 IF "i" != "j" THEN
3898 "k" := 1;
3899 LOOP
3900 IF "i" != "k" AND "j" != "k" THEN
3901 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3902 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3903 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3904 END IF;
3905 ELSE
3906 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3907 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3908 END IF;
3909 END IF;
3910 END IF;
3911 EXIT WHEN "k" = "dimension_v";
3912 "k" := "k" + 1;
3913 END LOOP;
3914 END IF;
3915 EXIT WHEN "j" = "dimension_v";
3916 "j" := "j" + 1;
3917 END LOOP;
3918 EXIT WHEN "i" = "dimension_v";
3919 "i" := "i" + 1;
3920 END LOOP;
3921 -- Determine order of winners:
3922 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3923 "rank_v" := 1;
3924 "done_v" := 0;
3925 LOOP
3926 "winners_ary" := '{}';
3927 "i" := 1;
3928 LOOP
3929 IF "rank_ary"["i"] ISNULL THEN
3930 "j" := 1;
3931 LOOP
3932 IF
3933 "i" != "j" AND
3934 "rank_ary"["j"] ISNULL AND
3935 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3936 THEN
3937 -- someone else is better
3938 EXIT;
3939 END IF;
3940 IF "j" = "dimension_v" THEN
3941 -- noone is better
3942 "winners_ary" := "winners_ary" || "i";
3943 EXIT;
3944 END IF;
3945 "j" := "j" + 1;
3946 END LOOP;
3947 END IF;
3948 EXIT WHEN "i" = "dimension_v";
3949 "i" := "i" + 1;
3950 END LOOP;
3951 "i" := 1;
3952 LOOP
3953 "rank_ary"["winners_ary"["i"]] := "rank_v";
3954 "done_v" := "done_v" + 1;
3955 EXIT WHEN "i" = array_upper("winners_ary", 1);
3956 "i" := "i" + 1;
3957 END LOOP;
3958 EXIT WHEN "done_v" = "dimension_v";
3959 "rank_v" := "rank_v" + 1;
3960 END LOOP;
3961 -- write preliminary results:
3962 "i" := 1;
3963 FOR "initiative_id_v" IN
3964 SELECT "id" FROM "initiative"
3965 WHERE "issue_id" = "issue_id_p" AND "admitted"
3966 ORDER BY "id"
3967 LOOP
3968 UPDATE "initiative" SET
3969 "direct_majority" =
3970 CASE WHEN "policy_row"."direct_majority_strict" THEN
3971 "positive_votes" * "policy_row"."direct_majority_den" >
3972 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3973 ELSE
3974 "positive_votes" * "policy_row"."direct_majority_den" >=
3975 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3976 END
3977 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3978 AND "issue_row"."voter_count"-"negative_votes" >=
3979 "policy_row"."direct_majority_non_negative",
3980 "indirect_majority" =
3981 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3982 "positive_votes" * "policy_row"."indirect_majority_den" >
3983 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3984 ELSE
3985 "positive_votes" * "policy_row"."indirect_majority_den" >=
3986 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3987 END
3988 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3989 AND "issue_row"."voter_count"-"negative_votes" >=
3990 "policy_row"."indirect_majority_non_negative",
3991 "schulze_rank" = "rank_ary"["i"],
3992 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3993 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3994 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3995 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3996 "eligible" = FALSE,
3997 "winner" = FALSE,
3998 "rank" = NULL -- NOTE: in cases of manual reset of issue state
3999 WHERE "id" = "initiative_id_v";
4000 "i" := "i" + 1;
4001 END LOOP;
4002 IF "i" != "dimension_v" THEN
4003 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4004 END IF;
4005 -- take indirect majorities into account:
4006 LOOP
4007 UPDATE "initiative" SET "indirect_majority" = TRUE
4008 FROM (
4009 SELECT "new_initiative"."id" AS "initiative_id"
4010 FROM "initiative" "old_initiative"
4011 JOIN "initiative" "new_initiative"
4012 ON "new_initiative"."issue_id" = "issue_id_p"
4013 AND "new_initiative"."indirect_majority" = FALSE
4014 JOIN "battle" "battle_win"
4015 ON "battle_win"."issue_id" = "issue_id_p"
4016 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4017 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4018 JOIN "battle" "battle_lose"
4019 ON "battle_lose"."issue_id" = "issue_id_p"
4020 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4021 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4022 WHERE "old_initiative"."issue_id" = "issue_id_p"
4023 AND "old_initiative"."indirect_majority" = TRUE
4024 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4025 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4026 "policy_row"."indirect_majority_num" *
4027 ("battle_win"."count"+"battle_lose"."count")
4028 ELSE
4029 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4030 "policy_row"."indirect_majority_num" *
4031 ("battle_win"."count"+"battle_lose"."count")
4032 END
4033 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4034 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4035 "policy_row"."indirect_majority_non_negative"
4036 ) AS "subquery"
4037 WHERE "id" = "subquery"."initiative_id";
4038 EXIT WHEN NOT FOUND;
4039 END LOOP;
4040 -- set "multistage_majority" for remaining matching initiatives:
4041 UPDATE "initiative" SET "multistage_majority" = TRUE
4042 FROM (
4043 SELECT "losing_initiative"."id" AS "initiative_id"
4044 FROM "initiative" "losing_initiative"
4045 JOIN "initiative" "winning_initiative"
4046 ON "winning_initiative"."issue_id" = "issue_id_p"
4047 AND "winning_initiative"."admitted"
4048 JOIN "battle" "battle_win"
4049 ON "battle_win"."issue_id" = "issue_id_p"
4050 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4051 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4052 JOIN "battle" "battle_lose"
4053 ON "battle_lose"."issue_id" = "issue_id_p"
4054 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4055 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4056 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4057 AND "losing_initiative"."admitted"
4058 AND "winning_initiative"."schulze_rank" <
4059 "losing_initiative"."schulze_rank"
4060 AND "battle_win"."count" > "battle_lose"."count"
4061 AND (
4062 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4063 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4064 ) AS "subquery"
4065 WHERE "id" = "subquery"."initiative_id";
4066 -- mark eligible initiatives:
4067 UPDATE "initiative" SET "eligible" = TRUE
4068 WHERE "issue_id" = "issue_id_p"
4069 AND "initiative"."direct_majority"
4070 AND "initiative"."indirect_majority"
4071 AND "initiative"."better_than_status_quo"
4072 AND (
4073 "policy_row"."no_multistage_majority" = FALSE OR
4074 "initiative"."multistage_majority" = FALSE )
4075 AND (
4076 "policy_row"."no_reverse_beat_path" = FALSE OR
4077 "initiative"."reverse_beat_path" = FALSE );
4078 -- mark final winner:
4079 UPDATE "initiative" SET "winner" = TRUE
4080 FROM (
4081 SELECT "id" AS "initiative_id"
4082 FROM "initiative"
4083 WHERE "issue_id" = "issue_id_p" AND "eligible"
4084 ORDER BY
4085 "schulze_rank",
4086 "vote_ratio"("positive_votes", "negative_votes"),
4087 "id"
4088 LIMIT 1
4089 ) AS "subquery"
4090 WHERE "id" = "subquery"."initiative_id";
4091 -- write (final) ranks:
4092 "rank_v" := 1;
4093 FOR "initiative_id_v" IN
4094 SELECT "id"
4095 FROM "initiative"
4096 WHERE "issue_id" = "issue_id_p" AND "admitted"
4097 ORDER BY
4098 "winner" DESC,
4099 "eligible" DESC,
4100 "schulze_rank",
4101 "vote_ratio"("positive_votes", "negative_votes"),
4102 "id"
4103 LOOP
4104 UPDATE "initiative" SET "rank" = "rank_v"
4105 WHERE "id" = "initiative_id_v";
4106 "rank_v" := "rank_v" + 1;
4107 END LOOP;
4108 -- set schulze rank of status quo and mark issue as finished:
4109 UPDATE "issue" SET
4110 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4111 "state" =
4112 CASE WHEN EXISTS (
4113 SELECT NULL FROM "initiative"
4114 WHERE "issue_id" = "issue_id_p" AND "winner"
4115 ) THEN
4116 'finished_with_winner'::"issue_state"
4117 ELSE
4118 'finished_without_winner'::"issue_state"
4119 END,
4120 "ranks_available" = TRUE
4121 WHERE "id" = "issue_id_p";
4122 RETURN;
4123 END;
4124 $$;
4126 COMMENT ON FUNCTION "calculate_ranks"
4127 ( "issue"."id"%TYPE )
4128 IS 'Determine ranking (Votes have to be counted first)';
4132 -----------------------------
4133 -- Automatic state changes --
4134 -----------------------------
4137 CREATE FUNCTION "check_issue"
4138 ( "issue_id_p" "issue"."id"%TYPE )
4139 RETURNS VOID
4140 LANGUAGE 'plpgsql' VOLATILE AS $$
4141 DECLARE
4142 "issue_row" "issue"%ROWTYPE;
4143 "policy_row" "policy"%ROWTYPE;
4144 BEGIN
4145 PERFORM "lock_issue"("issue_id_p");
4146 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4147 -- only process open issues:
4148 IF "issue_row"."closed" ISNULL THEN
4149 SELECT * INTO "policy_row" FROM "policy"
4150 WHERE "id" = "issue_row"."policy_id";
4151 -- create a snapshot, unless issue is already fully frozen:
4152 IF "issue_row"."fully_frozen" ISNULL THEN
4153 PERFORM "create_snapshot"("issue_id_p");
4154 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4155 END IF;
4156 -- eventually close or accept issues, which have not been accepted:
4157 IF "issue_row"."accepted" ISNULL THEN
4158 IF EXISTS (
4159 SELECT NULL FROM "initiative"
4160 WHERE "issue_id" = "issue_id_p"
4161 AND "supporter_count" > 0
4162 AND "supporter_count" * "policy_row"."issue_quorum_den"
4163 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4164 ) THEN
4165 -- accept issues, if supporter count is high enough
4166 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4167 -- NOTE: "issue_row" used later
4168 "issue_row"."state" := 'discussion';
4169 "issue_row"."accepted" := now();
4170 UPDATE "issue" SET
4171 "state" = "issue_row"."state",
4172 "accepted" = "issue_row"."accepted"
4173 WHERE "id" = "issue_row"."id";
4174 ELSIF
4175 now() >= "issue_row"."created" + "issue_row"."admission_time"
4176 THEN
4177 -- close issues, if admission time has expired
4178 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4179 UPDATE "issue" SET
4180 "state" = 'canceled_issue_not_accepted',
4181 "closed" = now()
4182 WHERE "id" = "issue_row"."id";
4183 END IF;
4184 END IF;
4185 -- eventually half freeze issues:
4186 IF
4187 -- NOTE: issue can't be closed at this point, if it has been accepted
4188 "issue_row"."accepted" NOTNULL AND
4189 "issue_row"."half_frozen" ISNULL
4190 THEN
4191 IF
4192 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4193 THEN
4194 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4195 -- NOTE: "issue_row" used later
4196 "issue_row"."state" := 'verification';
4197 "issue_row"."half_frozen" := now();
4198 UPDATE "issue" SET
4199 "state" = "issue_row"."state",
4200 "half_frozen" = "issue_row"."half_frozen"
4201 WHERE "id" = "issue_row"."id";
4202 END IF;
4203 END IF;
4204 -- close issues after some time, if all initiatives have been revoked:
4205 IF
4206 "issue_row"."closed" ISNULL AND
4207 NOT EXISTS (
4208 -- all initiatives are revoked
4209 SELECT NULL FROM "initiative"
4210 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4211 ) AND (
4212 -- and issue has not been accepted yet
4213 "issue_row"."accepted" ISNULL OR
4214 NOT EXISTS (
4215 -- or no initiatives have been revoked lately
4216 SELECT NULL FROM "initiative"
4217 WHERE "issue_id" = "issue_id_p"
4218 AND now() < "revoked" + "issue_row"."verification_time"
4219 ) OR (
4220 -- or verification time has elapsed
4221 "issue_row"."half_frozen" NOTNULL AND
4222 "issue_row"."fully_frozen" ISNULL AND
4223 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4226 THEN
4227 -- NOTE: "issue_row" used later
4228 IF "issue_row"."accepted" ISNULL THEN
4229 "issue_row"."state" := 'canceled_revoked_before_accepted';
4230 ELSIF "issue_row"."half_frozen" ISNULL THEN
4231 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4232 ELSE
4233 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4234 END IF;
4235 "issue_row"."closed" := now();
4236 UPDATE "issue" SET
4237 "state" = "issue_row"."state",
4238 "closed" = "issue_row"."closed"
4239 WHERE "id" = "issue_row"."id";
4240 END IF;
4241 -- fully freeze issue after verification time:
4242 IF
4243 "issue_row"."half_frozen" NOTNULL AND
4244 "issue_row"."fully_frozen" ISNULL AND
4245 "issue_row"."closed" ISNULL AND
4246 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4247 THEN
4248 PERFORM "freeze_after_snapshot"("issue_id_p");
4249 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4250 END IF;
4251 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4252 -- close issue by calling close_voting(...) after voting time:
4253 IF
4254 "issue_row"."closed" ISNULL AND
4255 "issue_row"."fully_frozen" NOTNULL AND
4256 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4257 THEN
4258 PERFORM "close_voting"("issue_id_p");
4259 -- calculate ranks will not consume much time and can be done now
4260 PERFORM "calculate_ranks"("issue_id_p");
4261 END IF;
4262 END IF;
4263 RETURN;
4264 END;
4265 $$;
4267 COMMENT ON FUNCTION "check_issue"
4268 ( "issue"."id"%TYPE )
4269 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.';
4272 CREATE FUNCTION "check_everything"()
4273 RETURNS VOID
4274 LANGUAGE 'plpgsql' VOLATILE AS $$
4275 DECLARE
4276 "issue_id_v" "issue"."id"%TYPE;
4277 BEGIN
4278 DELETE FROM "expired_session";
4279 PERFORM "check_activity"();
4280 PERFORM "calculate_member_counts"();
4281 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4282 PERFORM "check_issue"("issue_id_v");
4283 END LOOP;
4284 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4285 PERFORM "calculate_ranks"("issue_id_v");
4286 END LOOP;
4287 RETURN;
4288 END;
4289 $$;
4291 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.';
4295 ----------------------
4296 -- Deletion of data --
4297 ----------------------
4300 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4301 RETURNS VOID
4302 LANGUAGE 'plpgsql' VOLATILE AS $$
4303 DECLARE
4304 "issue_row" "issue"%ROWTYPE;
4305 BEGIN
4306 SELECT * INTO "issue_row"
4307 FROM "issue" WHERE "id" = "issue_id_p"
4308 FOR UPDATE;
4309 IF "issue_row"."cleaned" ISNULL THEN
4310 UPDATE "issue" SET
4311 "state" = 'voting',
4312 "closed" = NULL,
4313 "ranks_available" = FALSE
4314 WHERE "id" = "issue_id_p";
4315 DELETE FROM "voting_comment"
4316 WHERE "issue_id" = "issue_id_p";
4317 DELETE FROM "delegating_voter"
4318 WHERE "issue_id" = "issue_id_p";
4319 DELETE FROM "direct_voter"
4320 WHERE "issue_id" = "issue_id_p";
4321 DELETE FROM "delegating_interest_snapshot"
4322 WHERE "issue_id" = "issue_id_p";
4323 DELETE FROM "direct_interest_snapshot"
4324 WHERE "issue_id" = "issue_id_p";
4325 DELETE FROM "delegating_population_snapshot"
4326 WHERE "issue_id" = "issue_id_p";
4327 DELETE FROM "direct_population_snapshot"
4328 WHERE "issue_id" = "issue_id_p";
4329 DELETE FROM "non_voter"
4330 WHERE "issue_id" = "issue_id_p";
4331 DELETE FROM "delegation"
4332 WHERE "issue_id" = "issue_id_p";
4333 DELETE FROM "supporter"
4334 WHERE "issue_id" = "issue_id_p";
4335 UPDATE "issue" SET
4336 "state" = "issue_row"."state",
4337 "closed" = "issue_row"."closed",
4338 "ranks_available" = "issue_row"."ranks_available",
4339 "cleaned" = now()
4340 WHERE "id" = "issue_id_p";
4341 END IF;
4342 RETURN;
4343 END;
4344 $$;
4346 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4349 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4350 RETURNS VOID
4351 LANGUAGE 'plpgsql' VOLATILE AS $$
4352 BEGIN
4353 UPDATE "member" SET
4354 "last_login" = NULL,
4355 "login" = NULL,
4356 "password" = NULL,
4357 "locked" = TRUE,
4358 "active" = FALSE,
4359 "notify_email" = NULL,
4360 "notify_email_unconfirmed" = NULL,
4361 "notify_email_secret" = NULL,
4362 "notify_email_secret_expiry" = NULL,
4363 "notify_email_lock_expiry" = NULL,
4364 "password_reset_secret" = NULL,
4365 "password_reset_secret_expiry" = NULL,
4366 "organizational_unit" = NULL,
4367 "internal_posts" = NULL,
4368 "realname" = NULL,
4369 "birthday" = NULL,
4370 "address" = NULL,
4371 "email" = NULL,
4372 "xmpp_address" = NULL,
4373 "website" = NULL,
4374 "phone" = NULL,
4375 "mobile_phone" = NULL,
4376 "profession" = NULL,
4377 "external_memberships" = NULL,
4378 "external_posts" = NULL,
4379 "statement" = NULL
4380 WHERE "id" = "member_id_p";
4381 -- "text_search_data" is updated by triggers
4382 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4383 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4384 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4385 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4386 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4387 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4388 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4389 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4390 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4391 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4392 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4393 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4394 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4395 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4396 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4397 DELETE FROM "direct_voter" USING "issue"
4398 WHERE "direct_voter"."issue_id" = "issue"."id"
4399 AND "issue"."closed" ISNULL
4400 AND "member_id" = "member_id_p";
4401 RETURN;
4402 END;
4403 $$;
4405 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)';
4408 CREATE FUNCTION "delete_private_data"()
4409 RETURNS VOID
4410 LANGUAGE 'plpgsql' VOLATILE AS $$
4411 BEGIN
4412 DELETE FROM "member" WHERE "activated" ISNULL;
4413 UPDATE "member" SET
4414 "invite_code" = NULL,
4415 "invite_code_expiry" = NULL,
4416 "admin_comment" = NULL,
4417 "last_login" = NULL,
4418 "login" = NULL,
4419 "password" = NULL,
4420 "lang" = NULL,
4421 "notify_email" = NULL,
4422 "notify_email_unconfirmed" = NULL,
4423 "notify_email_secret" = NULL,
4424 "notify_email_secret_expiry" = NULL,
4425 "notify_email_lock_expiry" = NULL,
4426 "notify_level" = NULL,
4427 "password_reset_secret" = NULL,
4428 "password_reset_secret_expiry" = NULL,
4429 "organizational_unit" = NULL,
4430 "internal_posts" = NULL,
4431 "realname" = NULL,
4432 "birthday" = NULL,
4433 "address" = NULL,
4434 "email" = NULL,
4435 "xmpp_address" = NULL,
4436 "website" = NULL,
4437 "phone" = NULL,
4438 "mobile_phone" = NULL,
4439 "profession" = NULL,
4440 "external_memberships" = NULL,
4441 "external_posts" = NULL,
4442 "formatting_engine" = NULL,
4443 "statement" = NULL;
4444 -- "text_search_data" is updated by triggers
4445 DELETE FROM "setting";
4446 DELETE FROM "setting_map";
4447 DELETE FROM "member_relation_setting";
4448 DELETE FROM "member_image";
4449 DELETE FROM "contact";
4450 DELETE FROM "ignored_member";
4451 DELETE FROM "session";
4452 DELETE FROM "area_setting";
4453 DELETE FROM "issue_setting";
4454 DELETE FROM "ignored_initiative";
4455 DELETE FROM "initiative_setting";
4456 DELETE FROM "suggestion_setting";
4457 DELETE FROM "non_voter";
4458 DELETE FROM "direct_voter" USING "issue"
4459 WHERE "direct_voter"."issue_id" = "issue"."id"
4460 AND "issue"."closed" ISNULL;
4461 RETURN;
4462 END;
4463 $$;
4465 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. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
4469 COMMIT;

Impressum / About Us