liquid_feedback_core

view core.sql @ 217:9474e2038590

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

Impressum / About Us