liquid_feedback_core

view core.sql @ 230:592c6a236523

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

Impressum / About Us