liquid_feedback_core

view core.sql @ 246:dc644643db99

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

Impressum / About Us