liquid_feedback_core

view core.sql @ 232:cf8a090503c0

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

Impressum / About Us