liquid_feedback_core

view core.sql @ 305:a839e7efde9f

Removed unwanted (and broken) tie-breaking by approval rate
author jbe
date Fri Oct 05 11:41:51 2012 +0200 (2012-10-05)
parents a1db85ce10ea
children 847d59f94ceb
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.12', 2, 0, 12))
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 count("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 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2445 RETURNS SETOF "delegation_chain_row"
2446 LANGUAGE 'plpgsql' STABLE AS $$
2447 DECLARE
2448 "scope_v" "delegation_scope";
2449 "unit_id_v" "unit"."id"%TYPE;
2450 "area_id_v" "area"."id"%TYPE;
2451 "issue_row" "issue"%ROWTYPE;
2452 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2453 "loop_member_id_v" "member"."id"%TYPE;
2454 "output_row" "delegation_chain_row";
2455 "output_rows" "delegation_chain_row"[];
2456 "simulate_v" BOOLEAN;
2457 "simulate_here_v" BOOLEAN;
2458 "delegation_row" "delegation"%ROWTYPE;
2459 "row_count" INT4;
2460 "i" INT4;
2461 "loop_v" BOOLEAN;
2462 BEGIN
2463 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2464 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2465 END IF;
2466 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2467 "simulate_v" := TRUE;
2468 ELSE
2469 "simulate_v" := FALSE;
2470 END IF;
2471 IF
2472 "unit_id_p" NOTNULL AND
2473 "area_id_p" ISNULL AND
2474 "issue_id_p" ISNULL
2475 THEN
2476 "scope_v" := 'unit';
2477 "unit_id_v" := "unit_id_p";
2478 ELSIF
2479 "unit_id_p" ISNULL AND
2480 "area_id_p" NOTNULL AND
2481 "issue_id_p" ISNULL
2482 THEN
2483 "scope_v" := 'area';
2484 "area_id_v" := "area_id_p";
2485 SELECT "unit_id" INTO "unit_id_v"
2486 FROM "area" WHERE "id" = "area_id_v";
2487 ELSIF
2488 "unit_id_p" ISNULL AND
2489 "area_id_p" ISNULL AND
2490 "issue_id_p" NOTNULL
2491 THEN
2492 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2493 IF "issue_row"."id" ISNULL THEN
2494 RETURN;
2495 END IF;
2496 IF "issue_row"."closed" NOTNULL THEN
2497 IF "simulate_v" THEN
2498 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2499 END IF;
2500 FOR "output_row" IN
2501 SELECT * FROM
2502 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2503 LOOP
2504 RETURN NEXT "output_row";
2505 END LOOP;
2506 RETURN;
2507 END IF;
2508 "scope_v" := 'issue';
2509 SELECT "area_id" INTO "area_id_v"
2510 FROM "issue" WHERE "id" = "issue_id_p";
2511 SELECT "unit_id" INTO "unit_id_v"
2512 FROM "area" WHERE "id" = "area_id_v";
2513 ELSE
2514 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2515 END IF;
2516 "visited_member_ids" := '{}';
2517 "loop_member_id_v" := NULL;
2518 "output_rows" := '{}';
2519 "output_row"."index" := 0;
2520 "output_row"."member_id" := "member_id_p";
2521 "output_row"."member_valid" := TRUE;
2522 "output_row"."participation" := FALSE;
2523 "output_row"."overridden" := FALSE;
2524 "output_row"."disabled_out" := FALSE;
2525 "output_row"."scope_out" := NULL;
2526 LOOP
2527 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2528 "loop_member_id_v" := "output_row"."member_id";
2529 ELSE
2530 "visited_member_ids" :=
2531 "visited_member_ids" || "output_row"."member_id";
2532 END IF;
2533 IF "output_row"."participation" ISNULL THEN
2534 "output_row"."overridden" := NULL;
2535 ELSIF "output_row"."participation" THEN
2536 "output_row"."overridden" := TRUE;
2537 END IF;
2538 "output_row"."scope_in" := "output_row"."scope_out";
2539 "output_row"."member_valid" := EXISTS (
2540 SELECT NULL FROM "member" JOIN "privilege"
2541 ON "privilege"."member_id" = "member"."id"
2542 AND "privilege"."unit_id" = "unit_id_v"
2543 WHERE "id" = "output_row"."member_id"
2544 AND "member"."active" AND "privilege"."voting_right"
2545 );
2546 "simulate_here_v" := (
2547 "simulate_v" AND
2548 "output_row"."member_id" = "member_id_p"
2549 );
2550 "delegation_row" := ROW(NULL);
2551 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2552 IF "scope_v" = 'unit' THEN
2553 IF NOT "simulate_here_v" THEN
2554 SELECT * INTO "delegation_row" FROM "delegation"
2555 WHERE "truster_id" = "output_row"."member_id"
2556 AND "unit_id" = "unit_id_v";
2557 END IF;
2558 ELSIF "scope_v" = 'area' THEN
2559 "output_row"."participation" := EXISTS (
2560 SELECT NULL FROM "membership"
2561 WHERE "area_id" = "area_id_p"
2562 AND "member_id" = "output_row"."member_id"
2563 );
2564 IF "simulate_here_v" THEN
2565 IF "simulate_trustee_id_p" ISNULL THEN
2566 SELECT * INTO "delegation_row" FROM "delegation"
2567 WHERE "truster_id" = "output_row"."member_id"
2568 AND "unit_id" = "unit_id_v";
2569 END IF;
2570 ELSE
2571 SELECT * INTO "delegation_row" FROM "delegation"
2572 WHERE "truster_id" = "output_row"."member_id"
2573 AND (
2574 "unit_id" = "unit_id_v" OR
2575 "area_id" = "area_id_v"
2577 ORDER BY "scope" DESC;
2578 END IF;
2579 ELSIF "scope_v" = 'issue' THEN
2580 IF "issue_row"."fully_frozen" ISNULL THEN
2581 "output_row"."participation" := EXISTS (
2582 SELECT NULL FROM "interest"
2583 WHERE "issue_id" = "issue_id_p"
2584 AND "member_id" = "output_row"."member_id"
2585 );
2586 ELSE
2587 IF "output_row"."member_id" = "member_id_p" THEN
2588 "output_row"."participation" := EXISTS (
2589 SELECT NULL FROM "direct_voter"
2590 WHERE "issue_id" = "issue_id_p"
2591 AND "member_id" = "output_row"."member_id"
2592 );
2593 ELSE
2594 "output_row"."participation" := NULL;
2595 END IF;
2596 END IF;
2597 IF "simulate_here_v" THEN
2598 IF "simulate_trustee_id_p" ISNULL THEN
2599 SELECT * INTO "delegation_row" FROM "delegation"
2600 WHERE "truster_id" = "output_row"."member_id"
2601 AND (
2602 "unit_id" = "unit_id_v" OR
2603 "area_id" = "area_id_v"
2605 ORDER BY "scope" DESC;
2606 END IF;
2607 ELSE
2608 SELECT * INTO "delegation_row" FROM "delegation"
2609 WHERE "truster_id" = "output_row"."member_id"
2610 AND (
2611 "unit_id" = "unit_id_v" OR
2612 "area_id" = "area_id_v" OR
2613 "issue_id" = "issue_id_p"
2615 ORDER BY "scope" DESC;
2616 END IF;
2617 END IF;
2618 ELSE
2619 "output_row"."participation" := FALSE;
2620 END IF;
2621 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2622 "output_row"."scope_out" := "scope_v";
2623 "output_rows" := "output_rows" || "output_row";
2624 "output_row"."member_id" := "simulate_trustee_id_p";
2625 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2626 "output_row"."scope_out" := "delegation_row"."scope";
2627 "output_rows" := "output_rows" || "output_row";
2628 "output_row"."member_id" := "delegation_row"."trustee_id";
2629 ELSIF "delegation_row"."scope" NOTNULL THEN
2630 "output_row"."scope_out" := "delegation_row"."scope";
2631 "output_row"."disabled_out" := TRUE;
2632 "output_rows" := "output_rows" || "output_row";
2633 EXIT;
2634 ELSE
2635 "output_row"."scope_out" := NULL;
2636 "output_rows" := "output_rows" || "output_row";
2637 EXIT;
2638 END IF;
2639 EXIT WHEN "loop_member_id_v" NOTNULL;
2640 "output_row"."index" := "output_row"."index" + 1;
2641 END LOOP;
2642 "row_count" := array_upper("output_rows", 1);
2643 "i" := 1;
2644 "loop_v" := FALSE;
2645 LOOP
2646 "output_row" := "output_rows"["i"];
2647 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2648 IF "loop_v" THEN
2649 IF "i" + 1 = "row_count" THEN
2650 "output_row"."loop" := 'last';
2651 ELSIF "i" = "row_count" THEN
2652 "output_row"."loop" := 'repetition';
2653 ELSE
2654 "output_row"."loop" := 'intermediate';
2655 END IF;
2656 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2657 "output_row"."loop" := 'first';
2658 "loop_v" := TRUE;
2659 END IF;
2660 IF "scope_v" = 'unit' THEN
2661 "output_row"."participation" := NULL;
2662 END IF;
2663 RETURN NEXT "output_row";
2664 "i" := "i" + 1;
2665 END LOOP;
2666 RETURN;
2667 END;
2668 $$;
2670 COMMENT ON FUNCTION "delegation_chain"
2671 ( "member"."id"%TYPE,
2672 "unit"."id"%TYPE,
2673 "area"."id"%TYPE,
2674 "issue"."id"%TYPE,
2675 "member"."id"%TYPE,
2676 BOOLEAN )
2677 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2681 ---------------------------------------------------------
2682 -- Single row returning function for delegation chains --
2683 ---------------------------------------------------------
2686 CREATE TYPE "delegation_info_loop_type" AS ENUM
2687 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2689 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''';
2692 CREATE TYPE "delegation_info_type" AS (
2693 "own_participation" BOOLEAN,
2694 "own_delegation_scope" "delegation_scope",
2695 "first_trustee_id" INT4,
2696 "first_trustee_participation" BOOLEAN,
2697 "first_trustee_ellipsis" BOOLEAN,
2698 "other_trustee_id" INT4,
2699 "other_trustee_participation" BOOLEAN,
2700 "other_trustee_ellipsis" BOOLEAN,
2701 "delegation_loop" "delegation_info_loop_type",
2702 "participating_member_id" INT4 );
2704 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';
2706 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2707 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2708 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2709 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2710 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2711 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2712 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)';
2713 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2714 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';
2715 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2718 CREATE FUNCTION "delegation_info"
2719 ( "member_id_p" "member"."id"%TYPE,
2720 "unit_id_p" "unit"."id"%TYPE,
2721 "area_id_p" "area"."id"%TYPE,
2722 "issue_id_p" "issue"."id"%TYPE,
2723 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2724 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2725 RETURNS "delegation_info_type"
2726 LANGUAGE 'plpgsql' STABLE AS $$
2727 DECLARE
2728 "current_row" "delegation_chain_row";
2729 "result" "delegation_info_type";
2730 BEGIN
2731 "result"."own_participation" := FALSE;
2732 FOR "current_row" IN
2733 SELECT * FROM "delegation_chain"(
2734 "member_id_p",
2735 "unit_id_p", "area_id_p", "issue_id_p",
2736 "simulate_trustee_id_p", "simulate_default_p")
2737 LOOP
2738 IF
2739 "result"."participating_member_id" ISNULL AND
2740 "current_row"."participation"
2741 THEN
2742 "result"."participating_member_id" := "current_row"."member_id";
2743 END IF;
2744 IF "current_row"."member_id" = "member_id_p" THEN
2745 "result"."own_participation" := "current_row"."participation";
2746 "result"."own_delegation_scope" := "current_row"."scope_out";
2747 IF "current_row"."loop" = 'first' THEN
2748 "result"."delegation_loop" := 'own';
2749 END IF;
2750 ELSIF
2751 "current_row"."member_valid" AND
2752 ( "current_row"."loop" ISNULL OR
2753 "current_row"."loop" != 'repetition' )
2754 THEN
2755 IF "result"."first_trustee_id" ISNULL THEN
2756 "result"."first_trustee_id" := "current_row"."member_id";
2757 "result"."first_trustee_participation" := "current_row"."participation";
2758 "result"."first_trustee_ellipsis" := FALSE;
2759 IF "current_row"."loop" = 'first' THEN
2760 "result"."delegation_loop" := 'first';
2761 END IF;
2762 ELSIF "result"."other_trustee_id" ISNULL THEN
2763 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2764 "result"."other_trustee_id" := "current_row"."member_id";
2765 "result"."other_trustee_participation" := TRUE;
2766 "result"."other_trustee_ellipsis" := FALSE;
2767 IF "current_row"."loop" = 'first' THEN
2768 "result"."delegation_loop" := 'other';
2769 END IF;
2770 ELSE
2771 "result"."first_trustee_ellipsis" := TRUE;
2772 IF "current_row"."loop" = 'first' THEN
2773 "result"."delegation_loop" := 'first_ellipsis';
2774 END IF;
2775 END IF;
2776 ELSE
2777 "result"."other_trustee_ellipsis" := TRUE;
2778 IF "current_row"."loop" = 'first' THEN
2779 "result"."delegation_loop" := 'other_ellipsis';
2780 END IF;
2781 END IF;
2782 END IF;
2783 END LOOP;
2784 RETURN "result";
2785 END;
2786 $$;
2788 COMMENT ON FUNCTION "delegation_info"
2789 ( "member"."id"%TYPE,
2790 "unit"."id"%TYPE,
2791 "area"."id"%TYPE,
2792 "issue"."id"%TYPE,
2793 "member"."id"%TYPE,
2794 BOOLEAN )
2795 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2799 ------------------------------------------------
2800 -- Locking for snapshots and voting procedure --
2801 ------------------------------------------------
2804 CREATE FUNCTION "share_row_lock_issue_trigger"()
2805 RETURNS TRIGGER
2806 LANGUAGE 'plpgsql' VOLATILE AS $$
2807 BEGIN
2808 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2809 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2810 END IF;
2811 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2812 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2813 RETURN NEW;
2814 ELSE
2815 RETURN OLD;
2816 END IF;
2817 END;
2818 $$;
2820 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2823 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2824 RETURNS TRIGGER
2825 LANGUAGE 'plpgsql' VOLATILE AS $$
2826 BEGIN
2827 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2828 PERFORM NULL FROM "issue"
2829 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2830 WHERE "initiative"."id" = OLD."initiative_id"
2831 FOR SHARE OF "issue";
2832 END IF;
2833 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2834 PERFORM NULL FROM "issue"
2835 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2836 WHERE "initiative"."id" = NEW."initiative_id"
2837 FOR SHARE OF "issue";
2838 RETURN NEW;
2839 ELSE
2840 RETURN OLD;
2841 END IF;
2842 END;
2843 $$;
2845 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2848 CREATE TRIGGER "share_row_lock_issue"
2849 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2850 FOR EACH ROW EXECUTE PROCEDURE
2851 "share_row_lock_issue_trigger"();
2853 CREATE TRIGGER "share_row_lock_issue"
2854 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2855 FOR EACH ROW EXECUTE PROCEDURE
2856 "share_row_lock_issue_trigger"();
2858 CREATE TRIGGER "share_row_lock_issue"
2859 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2860 FOR EACH ROW EXECUTE PROCEDURE
2861 "share_row_lock_issue_trigger"();
2863 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2864 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2865 FOR EACH ROW EXECUTE PROCEDURE
2866 "share_row_lock_issue_via_initiative_trigger"();
2868 CREATE TRIGGER "share_row_lock_issue"
2869 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2870 FOR EACH ROW EXECUTE PROCEDURE
2871 "share_row_lock_issue_trigger"();
2873 CREATE TRIGGER "share_row_lock_issue"
2874 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2875 FOR EACH ROW EXECUTE PROCEDURE
2876 "share_row_lock_issue_trigger"();
2878 CREATE TRIGGER "share_row_lock_issue"
2879 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2880 FOR EACH ROW EXECUTE PROCEDURE
2881 "share_row_lock_issue_trigger"();
2883 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2884 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2885 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2886 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2887 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2888 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2889 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2892 CREATE FUNCTION "lock_issue"
2893 ( "issue_id_p" "issue"."id"%TYPE )
2894 RETURNS VOID
2895 LANGUAGE 'plpgsql' VOLATILE AS $$
2896 BEGIN
2897 LOCK TABLE "member" IN SHARE MODE;
2898 LOCK TABLE "privilege" IN SHARE MODE;
2899 LOCK TABLE "membership" IN SHARE MODE;
2900 LOCK TABLE "policy" IN SHARE MODE;
2901 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2902 -- NOTE: The row-level exclusive lock in combination with the
2903 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2904 -- acquire a row-level share lock on the issue) ensure that no data
2905 -- is changed, which could affect calculation of snapshots or
2906 -- counting of votes. Table "delegation" must be table-level-locked,
2907 -- as it also contains issue- and global-scope delegations.
2908 LOCK TABLE "delegation" IN SHARE MODE;
2909 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2910 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2911 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2912 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2913 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2914 RETURN;
2915 END;
2916 $$;
2918 COMMENT ON FUNCTION "lock_issue"
2919 ( "issue"."id"%TYPE )
2920 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2924 ------------------------------------------------------------------------
2925 -- Regular tasks, except calculcation of snapshots and voting results --
2926 ------------------------------------------------------------------------
2928 CREATE FUNCTION "check_activity"()
2929 RETURNS VOID
2930 LANGUAGE 'plpgsql' VOLATILE AS $$
2931 DECLARE
2932 "system_setting_row" "system_setting"%ROWTYPE;
2933 BEGIN
2934 SELECT * INTO "system_setting_row" FROM "system_setting";
2935 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2936 IF "system_setting_row"."member_ttl" NOTNULL THEN
2937 UPDATE "member" SET "active" = FALSE
2938 WHERE "active" = TRUE
2939 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2940 END IF;
2941 RETURN;
2942 END;
2943 $$;
2945 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2948 CREATE FUNCTION "calculate_member_counts"()
2949 RETURNS VOID
2950 LANGUAGE 'plpgsql' VOLATILE AS $$
2951 BEGIN
2952 LOCK TABLE "member" IN SHARE MODE;
2953 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2954 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2955 LOCK TABLE "area" IN EXCLUSIVE MODE;
2956 LOCK TABLE "privilege" IN SHARE MODE;
2957 LOCK TABLE "membership" IN SHARE MODE;
2958 DELETE FROM "member_count";
2959 INSERT INTO "member_count" ("total_count")
2960 SELECT "total_count" FROM "member_count_view";
2961 UPDATE "unit" SET "member_count" = "view"."member_count"
2962 FROM "unit_member_count" AS "view"
2963 WHERE "view"."unit_id" = "unit"."id";
2964 UPDATE "area" SET
2965 "direct_member_count" = "view"."direct_member_count",
2966 "member_weight" = "view"."member_weight"
2967 FROM "area_member_count" AS "view"
2968 WHERE "view"."area_id" = "area"."id";
2969 RETURN;
2970 END;
2971 $$;
2973 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"';
2977 ------------------------------
2978 -- Calculation of snapshots --
2979 ------------------------------
2981 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2982 ( "issue_id_p" "issue"."id"%TYPE,
2983 "member_id_p" "member"."id"%TYPE,
2984 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2985 RETURNS "direct_population_snapshot"."weight"%TYPE
2986 LANGUAGE 'plpgsql' VOLATILE AS $$
2987 DECLARE
2988 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2989 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2990 "weight_v" INT4;
2991 "sub_weight_v" INT4;
2992 BEGIN
2993 "weight_v" := 0;
2994 FOR "issue_delegation_row" IN
2995 SELECT * FROM "issue_delegation"
2996 WHERE "trustee_id" = "member_id_p"
2997 AND "issue_id" = "issue_id_p"
2998 LOOP
2999 IF NOT EXISTS (
3000 SELECT NULL FROM "direct_population_snapshot"
3001 WHERE "issue_id" = "issue_id_p"
3002 AND "event" = 'periodic'
3003 AND "member_id" = "issue_delegation_row"."truster_id"
3004 ) AND NOT EXISTS (
3005 SELECT NULL FROM "delegating_population_snapshot"
3006 WHERE "issue_id" = "issue_id_p"
3007 AND "event" = 'periodic'
3008 AND "member_id" = "issue_delegation_row"."truster_id"
3009 ) THEN
3010 "delegate_member_ids_v" :=
3011 "member_id_p" || "delegate_member_ids_p";
3012 INSERT INTO "delegating_population_snapshot" (
3013 "issue_id",
3014 "event",
3015 "member_id",
3016 "scope",
3017 "delegate_member_ids"
3018 ) VALUES (
3019 "issue_id_p",
3020 'periodic',
3021 "issue_delegation_row"."truster_id",
3022 "issue_delegation_row"."scope",
3023 "delegate_member_ids_v"
3024 );
3025 "sub_weight_v" := 1 +
3026 "weight_of_added_delegations_for_population_snapshot"(
3027 "issue_id_p",
3028 "issue_delegation_row"."truster_id",
3029 "delegate_member_ids_v"
3030 );
3031 UPDATE "delegating_population_snapshot"
3032 SET "weight" = "sub_weight_v"
3033 WHERE "issue_id" = "issue_id_p"
3034 AND "event" = 'periodic'
3035 AND "member_id" = "issue_delegation_row"."truster_id";
3036 "weight_v" := "weight_v" + "sub_weight_v";
3037 END IF;
3038 END LOOP;
3039 RETURN "weight_v";
3040 END;
3041 $$;
3043 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3044 ( "issue"."id"%TYPE,
3045 "member"."id"%TYPE,
3046 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3047 IS 'Helper function for "create_population_snapshot" function';
3050 CREATE FUNCTION "create_population_snapshot"
3051 ( "issue_id_p" "issue"."id"%TYPE )
3052 RETURNS VOID
3053 LANGUAGE 'plpgsql' VOLATILE AS $$
3054 DECLARE
3055 "member_id_v" "member"."id"%TYPE;
3056 BEGIN
3057 DELETE FROM "direct_population_snapshot"
3058 WHERE "issue_id" = "issue_id_p"
3059 AND "event" = 'periodic';
3060 DELETE FROM "delegating_population_snapshot"
3061 WHERE "issue_id" = "issue_id_p"
3062 AND "event" = 'periodic';
3063 INSERT INTO "direct_population_snapshot"
3064 ("issue_id", "event", "member_id")
3065 SELECT
3066 "issue_id_p" AS "issue_id",
3067 'periodic'::"snapshot_event" AS "event",
3068 "member"."id" AS "member_id"
3069 FROM "issue"
3070 JOIN "area" ON "issue"."area_id" = "area"."id"
3071 JOIN "membership" ON "area"."id" = "membership"."area_id"
3072 JOIN "member" ON "membership"."member_id" = "member"."id"
3073 JOIN "privilege"
3074 ON "privilege"."unit_id" = "area"."unit_id"
3075 AND "privilege"."member_id" = "member"."id"
3076 WHERE "issue"."id" = "issue_id_p"
3077 AND "member"."active" AND "privilege"."voting_right"
3078 UNION
3079 SELECT
3080 "issue_id_p" AS "issue_id",
3081 'periodic'::"snapshot_event" AS "event",
3082 "member"."id" AS "member_id"
3083 FROM "issue"
3084 JOIN "area" ON "issue"."area_id" = "area"."id"
3085 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3086 JOIN "member" ON "interest"."member_id" = "member"."id"
3087 JOIN "privilege"
3088 ON "privilege"."unit_id" = "area"."unit_id"
3089 AND "privilege"."member_id" = "member"."id"
3090 WHERE "issue"."id" = "issue_id_p"
3091 AND "member"."active" AND "privilege"."voting_right";
3092 FOR "member_id_v" IN
3093 SELECT "member_id" FROM "direct_population_snapshot"
3094 WHERE "issue_id" = "issue_id_p"
3095 AND "event" = 'periodic'
3096 LOOP
3097 UPDATE "direct_population_snapshot" SET
3098 "weight" = 1 +
3099 "weight_of_added_delegations_for_population_snapshot"(
3100 "issue_id_p",
3101 "member_id_v",
3102 '{}'
3104 WHERE "issue_id" = "issue_id_p"
3105 AND "event" = 'periodic'
3106 AND "member_id" = "member_id_v";
3107 END LOOP;
3108 RETURN;
3109 END;
3110 $$;
3112 COMMENT ON FUNCTION "create_population_snapshot"
3113 ( "issue"."id"%TYPE )
3114 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.';
3117 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3118 ( "issue_id_p" "issue"."id"%TYPE,
3119 "member_id_p" "member"."id"%TYPE,
3120 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3121 RETURNS "direct_interest_snapshot"."weight"%TYPE
3122 LANGUAGE 'plpgsql' VOLATILE AS $$
3123 DECLARE
3124 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3125 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3126 "weight_v" INT4;
3127 "sub_weight_v" INT4;
3128 BEGIN
3129 "weight_v" := 0;
3130 FOR "issue_delegation_row" IN
3131 SELECT * FROM "issue_delegation"
3132 WHERE "trustee_id" = "member_id_p"
3133 AND "issue_id" = "issue_id_p"
3134 LOOP
3135 IF NOT EXISTS (
3136 SELECT NULL FROM "direct_interest_snapshot"
3137 WHERE "issue_id" = "issue_id_p"
3138 AND "event" = 'periodic'
3139 AND "member_id" = "issue_delegation_row"."truster_id"
3140 ) AND NOT EXISTS (
3141 SELECT NULL FROM "delegating_interest_snapshot"
3142 WHERE "issue_id" = "issue_id_p"
3143 AND "event" = 'periodic'
3144 AND "member_id" = "issue_delegation_row"."truster_id"
3145 ) THEN
3146 "delegate_member_ids_v" :=
3147 "member_id_p" || "delegate_member_ids_p";
3148 INSERT INTO "delegating_interest_snapshot" (
3149 "issue_id",
3150 "event",
3151 "member_id",
3152 "scope",
3153 "delegate_member_ids"
3154 ) VALUES (
3155 "issue_id_p",
3156 'periodic',
3157 "issue_delegation_row"."truster_id",
3158 "issue_delegation_row"."scope",
3159 "delegate_member_ids_v"
3160 );
3161 "sub_weight_v" := 1 +
3162 "weight_of_added_delegations_for_interest_snapshot"(
3163 "issue_id_p",
3164 "issue_delegation_row"."truster_id",
3165 "delegate_member_ids_v"
3166 );
3167 UPDATE "delegating_interest_snapshot"
3168 SET "weight" = "sub_weight_v"
3169 WHERE "issue_id" = "issue_id_p"
3170 AND "event" = 'periodic'
3171 AND "member_id" = "issue_delegation_row"."truster_id";
3172 "weight_v" := "weight_v" + "sub_weight_v";
3173 END IF;
3174 END LOOP;
3175 RETURN "weight_v";
3176 END;
3177 $$;
3179 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3180 ( "issue"."id"%TYPE,
3181 "member"."id"%TYPE,
3182 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3183 IS 'Helper function for "create_interest_snapshot" function';
3186 CREATE FUNCTION "create_interest_snapshot"
3187 ( "issue_id_p" "issue"."id"%TYPE )
3188 RETURNS VOID
3189 LANGUAGE 'plpgsql' VOLATILE AS $$
3190 DECLARE
3191 "member_id_v" "member"."id"%TYPE;
3192 BEGIN
3193 DELETE FROM "direct_interest_snapshot"
3194 WHERE "issue_id" = "issue_id_p"
3195 AND "event" = 'periodic';
3196 DELETE FROM "delegating_interest_snapshot"
3197 WHERE "issue_id" = "issue_id_p"
3198 AND "event" = 'periodic';
3199 DELETE FROM "direct_supporter_snapshot"
3200 WHERE "issue_id" = "issue_id_p"
3201 AND "event" = 'periodic';
3202 INSERT INTO "direct_interest_snapshot"
3203 ("issue_id", "event", "member_id")
3204 SELECT
3205 "issue_id_p" AS "issue_id",
3206 'periodic' AS "event",
3207 "member"."id" AS "member_id"
3208 FROM "issue"
3209 JOIN "area" ON "issue"."area_id" = "area"."id"
3210 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3211 JOIN "member" ON "interest"."member_id" = "member"."id"
3212 JOIN "privilege"
3213 ON "privilege"."unit_id" = "area"."unit_id"
3214 AND "privilege"."member_id" = "member"."id"
3215 WHERE "issue"."id" = "issue_id_p"
3216 AND "member"."active" AND "privilege"."voting_right";
3217 FOR "member_id_v" IN
3218 SELECT "member_id" FROM "direct_interest_snapshot"
3219 WHERE "issue_id" = "issue_id_p"
3220 AND "event" = 'periodic'
3221 LOOP
3222 UPDATE "direct_interest_snapshot" SET
3223 "weight" = 1 +
3224 "weight_of_added_delegations_for_interest_snapshot"(
3225 "issue_id_p",
3226 "member_id_v",
3227 '{}'
3229 WHERE "issue_id" = "issue_id_p"
3230 AND "event" = 'periodic'
3231 AND "member_id" = "member_id_v";
3232 END LOOP;
3233 INSERT INTO "direct_supporter_snapshot"
3234 ( "issue_id", "initiative_id", "event", "member_id",
3235 "draft_id", "informed", "satisfied" )
3236 SELECT
3237 "issue_id_p" AS "issue_id",
3238 "initiative"."id" AS "initiative_id",
3239 'periodic' AS "event",
3240 "supporter"."member_id" AS "member_id",
3241 "supporter"."draft_id" AS "draft_id",
3242 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3243 NOT EXISTS (
3244 SELECT NULL FROM "critical_opinion"
3245 WHERE "initiative_id" = "initiative"."id"
3246 AND "member_id" = "supporter"."member_id"
3247 ) AS "satisfied"
3248 FROM "initiative"
3249 JOIN "supporter"
3250 ON "supporter"."initiative_id" = "initiative"."id"
3251 JOIN "current_draft"
3252 ON "initiative"."id" = "current_draft"."initiative_id"
3253 JOIN "direct_interest_snapshot"
3254 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3255 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3256 AND "event" = 'periodic'
3257 WHERE "initiative"."issue_id" = "issue_id_p";
3258 RETURN;
3259 END;
3260 $$;
3262 COMMENT ON FUNCTION "create_interest_snapshot"
3263 ( "issue"."id"%TYPE )
3264 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.';
3267 CREATE FUNCTION "create_snapshot"
3268 ( "issue_id_p" "issue"."id"%TYPE )
3269 RETURNS VOID
3270 LANGUAGE 'plpgsql' VOLATILE AS $$
3271 DECLARE
3272 "initiative_id_v" "initiative"."id"%TYPE;
3273 "suggestion_id_v" "suggestion"."id"%TYPE;
3274 BEGIN
3275 PERFORM "lock_issue"("issue_id_p");
3276 PERFORM "create_population_snapshot"("issue_id_p");
3277 PERFORM "create_interest_snapshot"("issue_id_p");
3278 UPDATE "issue" SET
3279 "snapshot" = now(),
3280 "latest_snapshot_event" = 'periodic',
3281 "population" = (
3282 SELECT coalesce(sum("weight"), 0)
3283 FROM "direct_population_snapshot"
3284 WHERE "issue_id" = "issue_id_p"
3285 AND "event" = 'periodic'
3287 WHERE "id" = "issue_id_p";
3288 FOR "initiative_id_v" IN
3289 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3290 LOOP
3291 UPDATE "initiative" SET
3292 "supporter_count" = (
3293 SELECT coalesce(sum("di"."weight"), 0)
3294 FROM "direct_interest_snapshot" AS "di"
3295 JOIN "direct_supporter_snapshot" AS "ds"
3296 ON "di"."member_id" = "ds"."member_id"
3297 WHERE "di"."issue_id" = "issue_id_p"
3298 AND "di"."event" = 'periodic'
3299 AND "ds"."initiative_id" = "initiative_id_v"
3300 AND "ds"."event" = 'periodic'
3301 ),
3302 "informed_supporter_count" = (
3303 SELECT coalesce(sum("di"."weight"), 0)
3304 FROM "direct_interest_snapshot" AS "di"
3305 JOIN "direct_supporter_snapshot" AS "ds"
3306 ON "di"."member_id" = "ds"."member_id"
3307 WHERE "di"."issue_id" = "issue_id_p"
3308 AND "di"."event" = 'periodic'
3309 AND "ds"."initiative_id" = "initiative_id_v"
3310 AND "ds"."event" = 'periodic'
3311 AND "ds"."informed"
3312 ),
3313 "satisfied_supporter_count" = (
3314 SELECT coalesce(sum("di"."weight"), 0)
3315 FROM "direct_interest_snapshot" AS "di"
3316 JOIN "direct_supporter_snapshot" AS "ds"
3317 ON "di"."member_id" = "ds"."member_id"
3318 WHERE "di"."issue_id" = "issue_id_p"
3319 AND "di"."event" = 'periodic'
3320 AND "ds"."initiative_id" = "initiative_id_v"
3321 AND "ds"."event" = 'periodic'
3322 AND "ds"."satisfied"
3323 ),
3324 "satisfied_informed_supporter_count" = (
3325 SELECT coalesce(sum("di"."weight"), 0)
3326 FROM "direct_interest_snapshot" AS "di"
3327 JOIN "direct_supporter_snapshot" AS "ds"
3328 ON "di"."member_id" = "ds"."member_id"
3329 WHERE "di"."issue_id" = "issue_id_p"
3330 AND "di"."event" = 'periodic'
3331 AND "ds"."initiative_id" = "initiative_id_v"
3332 AND "ds"."event" = 'periodic'
3333 AND "ds"."informed"
3334 AND "ds"."satisfied"
3336 WHERE "id" = "initiative_id_v";
3337 FOR "suggestion_id_v" IN
3338 SELECT "id" FROM "suggestion"
3339 WHERE "initiative_id" = "initiative_id_v"
3340 LOOP
3341 UPDATE "suggestion" SET
3342 "minus2_unfulfilled_count" = (
3343 SELECT coalesce(sum("snapshot"."weight"), 0)
3344 FROM "issue" CROSS JOIN "opinion"
3345 JOIN "direct_interest_snapshot" AS "snapshot"
3346 ON "snapshot"."issue_id" = "issue"."id"
3347 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3348 AND "snapshot"."member_id" = "opinion"."member_id"
3349 WHERE "issue"."id" = "issue_id_p"
3350 AND "opinion"."suggestion_id" = "suggestion_id_v"
3351 AND "opinion"."degree" = -2
3352 AND "opinion"."fulfilled" = FALSE
3353 ),
3354 "minus2_fulfilled_count" = (
3355 SELECT coalesce(sum("snapshot"."weight"), 0)
3356 FROM "issue" CROSS JOIN "opinion"
3357 JOIN "direct_interest_snapshot" AS "snapshot"
3358 ON "snapshot"."issue_id" = "issue"."id"
3359 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3360 AND "snapshot"."member_id" = "opinion"."member_id"
3361 WHERE "issue"."id" = "issue_id_p"
3362 AND "opinion"."suggestion_id" = "suggestion_id_v"
3363 AND "opinion"."degree" = -2
3364 AND "opinion"."fulfilled" = TRUE
3365 ),
3366 "minus1_unfulfilled_count" = (
3367 SELECT coalesce(sum("snapshot"."weight"), 0)
3368 FROM "issue" CROSS JOIN "opinion"
3369 JOIN "direct_interest_snapshot" AS "snapshot"
3370 ON "snapshot"."issue_id" = "issue"."id"
3371 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3372 AND "snapshot"."member_id" = "opinion"."member_id"
3373 WHERE "issue"."id" = "issue_id_p"
3374 AND "opinion"."suggestion_id" = "suggestion_id_v"
3375 AND "opinion"."degree" = -1
3376 AND "opinion"."fulfilled" = FALSE
3377 ),
3378 "minus1_fulfilled_count" = (
3379 SELECT coalesce(sum("snapshot"."weight"), 0)
3380 FROM "issue" CROSS JOIN "opinion"
3381 JOIN "direct_interest_snapshot" AS "snapshot"
3382 ON "snapshot"."issue_id" = "issue"."id"
3383 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3384 AND "snapshot"."member_id" = "opinion"."member_id"
3385 WHERE "issue"."id" = "issue_id_p"
3386 AND "opinion"."suggestion_id" = "suggestion_id_v"
3387 AND "opinion"."degree" = -1
3388 AND "opinion"."fulfilled" = TRUE
3389 ),
3390 "plus1_unfulfilled_count" = (
3391 SELECT coalesce(sum("snapshot"."weight"), 0)
3392 FROM "issue" CROSS JOIN "opinion"
3393 JOIN "direct_interest_snapshot" AS "snapshot"
3394 ON "snapshot"."issue_id" = "issue"."id"
3395 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3396 AND "snapshot"."member_id" = "opinion"."member_id"
3397 WHERE "issue"."id" = "issue_id_p"
3398 AND "opinion"."suggestion_id" = "suggestion_id_v"
3399 AND "opinion"."degree" = 1
3400 AND "opinion"."fulfilled" = FALSE
3401 ),
3402 "plus1_fulfilled_count" = (
3403 SELECT coalesce(sum("snapshot"."weight"), 0)
3404 FROM "issue" CROSS JOIN "opinion"
3405 JOIN "direct_interest_snapshot" AS "snapshot"
3406 ON "snapshot"."issue_id" = "issue"."id"
3407 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3408 AND "snapshot"."member_id" = "opinion"."member_id"
3409 WHERE "issue"."id" = "issue_id_p"
3410 AND "opinion"."suggestion_id" = "suggestion_id_v"
3411 AND "opinion"."degree" = 1
3412 AND "opinion"."fulfilled" = TRUE
3413 ),
3414 "plus2_unfulfilled_count" = (
3415 SELECT coalesce(sum("snapshot"."weight"), 0)
3416 FROM "issue" CROSS JOIN "opinion"
3417 JOIN "direct_interest_snapshot" AS "snapshot"
3418 ON "snapshot"."issue_id" = "issue"."id"
3419 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3420 AND "snapshot"."member_id" = "opinion"."member_id"
3421 WHERE "issue"."id" = "issue_id_p"
3422 AND "opinion"."suggestion_id" = "suggestion_id_v"
3423 AND "opinion"."degree" = 2
3424 AND "opinion"."fulfilled" = FALSE
3425 ),
3426 "plus2_fulfilled_count" = (
3427 SELECT coalesce(sum("snapshot"."weight"), 0)
3428 FROM "issue" CROSS JOIN "opinion"
3429 JOIN "direct_interest_snapshot" AS "snapshot"
3430 ON "snapshot"."issue_id" = "issue"."id"
3431 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3432 AND "snapshot"."member_id" = "opinion"."member_id"
3433 WHERE "issue"."id" = "issue_id_p"
3434 AND "opinion"."suggestion_id" = "suggestion_id_v"
3435 AND "opinion"."degree" = 2
3436 AND "opinion"."fulfilled" = TRUE
3438 WHERE "suggestion"."id" = "suggestion_id_v";
3439 END LOOP;
3440 END LOOP;
3441 RETURN;
3442 END;
3443 $$;
3445 COMMENT ON FUNCTION "create_snapshot"
3446 ( "issue"."id"%TYPE )
3447 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.';
3450 CREATE FUNCTION "set_snapshot_event"
3451 ( "issue_id_p" "issue"."id"%TYPE,
3452 "event_p" "snapshot_event" )
3453 RETURNS VOID
3454 LANGUAGE 'plpgsql' VOLATILE AS $$
3455 DECLARE
3456 "event_v" "issue"."latest_snapshot_event"%TYPE;
3457 BEGIN
3458 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3459 WHERE "id" = "issue_id_p" FOR UPDATE;
3460 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3461 WHERE "id" = "issue_id_p";
3462 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3463 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3464 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3465 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3466 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3467 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3468 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3469 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3470 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3471 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3472 RETURN;
3473 END;
3474 $$;
3476 COMMENT ON FUNCTION "set_snapshot_event"
3477 ( "issue"."id"%TYPE,
3478 "snapshot_event" )
3479 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3483 ---------------------
3484 -- Freezing issues --
3485 ---------------------
3487 CREATE FUNCTION "freeze_after_snapshot"
3488 ( "issue_id_p" "issue"."id"%TYPE )
3489 RETURNS VOID
3490 LANGUAGE 'plpgsql' VOLATILE AS $$
3491 DECLARE
3492 "issue_row" "issue"%ROWTYPE;
3493 "policy_row" "policy"%ROWTYPE;
3494 "initiative_row" "initiative"%ROWTYPE;
3495 BEGIN
3496 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3497 SELECT * INTO "policy_row"
3498 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3499 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3500 FOR "initiative_row" IN
3501 SELECT * FROM "initiative"
3502 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3503 LOOP
3504 IF
3505 "initiative_row"."satisfied_supporter_count" > 0 AND
3506 "initiative_row"."satisfied_supporter_count" *
3507 "policy_row"."initiative_quorum_den" >=
3508 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3509 THEN
3510 UPDATE "initiative" SET "admitted" = TRUE
3511 WHERE "id" = "initiative_row"."id";
3512 ELSE
3513 UPDATE "initiative" SET "admitted" = FALSE
3514 WHERE "id" = "initiative_row"."id";
3515 END IF;
3516 END LOOP;
3517 IF EXISTS (
3518 SELECT NULL FROM "initiative"
3519 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3520 ) THEN
3521 UPDATE "issue" SET
3522 "state" = 'voting',
3523 "accepted" = coalesce("accepted", now()),
3524 "half_frozen" = coalesce("half_frozen", now()),
3525 "fully_frozen" = now()
3526 WHERE "id" = "issue_id_p";
3527 ELSE
3528 UPDATE "issue" SET
3529 "state" = 'canceled_no_initiative_admitted',
3530 "accepted" = coalesce("accepted", now()),
3531 "half_frozen" = coalesce("half_frozen", now()),
3532 "fully_frozen" = now(),
3533 "closed" = now(),
3534 "ranks_available" = TRUE
3535 WHERE "id" = "issue_id_p";
3536 -- NOTE: The following DELETE statements have effect only when
3537 -- issue state has been manipulated
3538 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3539 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3540 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3541 END IF;
3542 RETURN;
3543 END;
3544 $$;
3546 COMMENT ON FUNCTION "freeze_after_snapshot"
3547 ( "issue"."id"%TYPE )
3548 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3551 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3552 RETURNS VOID
3553 LANGUAGE 'plpgsql' VOLATILE AS $$
3554 DECLARE
3555 "issue_row" "issue"%ROWTYPE;
3556 BEGIN
3557 PERFORM "create_snapshot"("issue_id_p");
3558 PERFORM "freeze_after_snapshot"("issue_id_p");
3559 RETURN;
3560 END;
3561 $$;
3563 COMMENT ON FUNCTION "manual_freeze"
3564 ( "issue"."id"%TYPE )
3565 IS 'Freeze an issue manually (fully) and start voting';
3569 -----------------------
3570 -- Counting of votes --
3571 -----------------------
3574 CREATE FUNCTION "weight_of_added_vote_delegations"
3575 ( "issue_id_p" "issue"."id"%TYPE,
3576 "member_id_p" "member"."id"%TYPE,
3577 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3578 RETURNS "direct_voter"."weight"%TYPE
3579 LANGUAGE 'plpgsql' VOLATILE AS $$
3580 DECLARE
3581 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3582 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3583 "weight_v" INT4;
3584 "sub_weight_v" INT4;
3585 BEGIN
3586 "weight_v" := 0;
3587 FOR "issue_delegation_row" IN
3588 SELECT * FROM "issue_delegation"
3589 WHERE "trustee_id" = "member_id_p"
3590 AND "issue_id" = "issue_id_p"
3591 LOOP
3592 IF NOT EXISTS (
3593 SELECT NULL FROM "direct_voter"
3594 WHERE "member_id" = "issue_delegation_row"."truster_id"
3595 AND "issue_id" = "issue_id_p"
3596 ) AND NOT EXISTS (
3597 SELECT NULL FROM "delegating_voter"
3598 WHERE "member_id" = "issue_delegation_row"."truster_id"
3599 AND "issue_id" = "issue_id_p"
3600 ) THEN
3601 "delegate_member_ids_v" :=
3602 "member_id_p" || "delegate_member_ids_p";
3603 INSERT INTO "delegating_voter" (
3604 "issue_id",
3605 "member_id",
3606 "scope",
3607 "delegate_member_ids"
3608 ) VALUES (
3609 "issue_id_p",
3610 "issue_delegation_row"."truster_id",
3611 "issue_delegation_row"."scope",
3612 "delegate_member_ids_v"
3613 );
3614 "sub_weight_v" := 1 +
3615 "weight_of_added_vote_delegations"(
3616 "issue_id_p",
3617 "issue_delegation_row"."truster_id",
3618 "delegate_member_ids_v"
3619 );
3620 UPDATE "delegating_voter"
3621 SET "weight" = "sub_weight_v"
3622 WHERE "issue_id" = "issue_id_p"
3623 AND "member_id" = "issue_delegation_row"."truster_id";
3624 "weight_v" := "weight_v" + "sub_weight_v";
3625 END IF;
3626 END LOOP;
3627 RETURN "weight_v";
3628 END;
3629 $$;
3631 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3632 ( "issue"."id"%TYPE,
3633 "member"."id"%TYPE,
3634 "delegating_voter"."delegate_member_ids"%TYPE )
3635 IS 'Helper function for "add_vote_delegations" function';
3638 CREATE FUNCTION "add_vote_delegations"
3639 ( "issue_id_p" "issue"."id"%TYPE )
3640 RETURNS VOID
3641 LANGUAGE 'plpgsql' VOLATILE AS $$
3642 DECLARE
3643 "member_id_v" "member"."id"%TYPE;
3644 BEGIN
3645 FOR "member_id_v" IN
3646 SELECT "member_id" FROM "direct_voter"
3647 WHERE "issue_id" = "issue_id_p"
3648 LOOP
3649 UPDATE "direct_voter" SET
3650 "weight" = "weight" + "weight_of_added_vote_delegations"(
3651 "issue_id_p",
3652 "member_id_v",
3653 '{}'
3655 WHERE "member_id" = "member_id_v"
3656 AND "issue_id" = "issue_id_p";
3657 END LOOP;
3658 RETURN;
3659 END;
3660 $$;
3662 COMMENT ON FUNCTION "add_vote_delegations"
3663 ( "issue_id_p" "issue"."id"%TYPE )
3664 IS 'Helper function for "close_voting" function';
3667 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3668 RETURNS VOID
3669 LANGUAGE 'plpgsql' VOLATILE AS $$
3670 DECLARE
3671 "area_id_v" "area"."id"%TYPE;
3672 "unit_id_v" "unit"."id"%TYPE;
3673 "member_id_v" "member"."id"%TYPE;
3674 BEGIN
3675 PERFORM "lock_issue"("issue_id_p");
3676 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3677 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3678 -- delete delegating votes (in cases of manual reset of issue state):
3679 DELETE FROM "delegating_voter"
3680 WHERE "issue_id" = "issue_id_p";
3681 -- delete votes from non-privileged voters:
3682 DELETE FROM "direct_voter"
3683 USING (
3684 SELECT
3685 "direct_voter"."member_id"
3686 FROM "direct_voter"
3687 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3688 LEFT JOIN "privilege"
3689 ON "privilege"."unit_id" = "unit_id_v"
3690 AND "privilege"."member_id" = "direct_voter"."member_id"
3691 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3692 "member"."active" = FALSE OR
3693 "privilege"."voting_right" ISNULL OR
3694 "privilege"."voting_right" = FALSE
3696 ) AS "subquery"
3697 WHERE "direct_voter"."issue_id" = "issue_id_p"
3698 AND "direct_voter"."member_id" = "subquery"."member_id";
3699 -- consider delegations:
3700 UPDATE "direct_voter" SET "weight" = 1
3701 WHERE "issue_id" = "issue_id_p";
3702 PERFORM "add_vote_delegations"("issue_id_p");
3703 -- set voter count and mark issue as being calculated:
3704 UPDATE "issue" SET
3705 "state" = 'calculation',
3706 "closed" = now(),
3707 "voter_count" = (
3708 SELECT coalesce(sum("weight"), 0)
3709 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3711 WHERE "id" = "issue_id_p";
3712 -- materialize battle_view:
3713 -- NOTE: "closed" column of issue must be set at this point
3714 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3715 INSERT INTO "battle" (
3716 "issue_id",
3717 "winning_initiative_id", "losing_initiative_id",
3718 "count"
3719 ) SELECT
3720 "issue_id",
3721 "winning_initiative_id", "losing_initiative_id",
3722 "count"
3723 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3724 -- copy "positive_votes" and "negative_votes" from "battle" table:
3725 UPDATE "initiative" SET
3726 "positive_votes" = "battle_win"."count",
3727 "negative_votes" = "battle_lose"."count"
3728 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3729 WHERE
3730 "battle_win"."issue_id" = "issue_id_p" AND
3731 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3732 "battle_win"."losing_initiative_id" ISNULL AND
3733 "battle_lose"."issue_id" = "issue_id_p" AND
3734 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3735 "battle_lose"."winning_initiative_id" ISNULL;
3736 END;
3737 $$;
3739 COMMENT ON FUNCTION "close_voting"
3740 ( "issue"."id"%TYPE )
3741 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.';
3744 CREATE FUNCTION "defeat_strength"
3745 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3746 RETURNS INT8
3747 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3748 BEGIN
3749 IF "positive_votes_p" > "negative_votes_p" THEN
3750 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3751 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3752 RETURN 0;
3753 ELSE
3754 RETURN -1;
3755 END IF;
3756 END;
3757 $$;
3759 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';
3762 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3763 RETURNS VOID
3764 LANGUAGE 'plpgsql' VOLATILE AS $$
3765 DECLARE
3766 "issue_row" "issue"%ROWTYPE;
3767 "policy_row" "policy"%ROWTYPE;
3768 "dimension_v" INTEGER;
3769 "vote_matrix" INT4[][]; -- absolute votes
3770 "matrix" INT8[][]; -- defeat strength / best paths
3771 "i" INTEGER;
3772 "j" INTEGER;
3773 "k" INTEGER;
3774 "battle_row" "battle"%ROWTYPE;
3775 "rank_ary" INT4[];
3776 "rank_v" INT4;
3777 "done_v" INTEGER;
3778 "winners_ary" INTEGER[];
3779 "initiative_id_v" "initiative"."id"%TYPE;
3780 BEGIN
3781 SELECT * INTO "issue_row"
3782 FROM "issue" WHERE "id" = "issue_id_p"
3783 FOR UPDATE;
3784 SELECT * INTO "policy_row"
3785 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3786 SELECT count(1) INTO "dimension_v"
3787 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3788 -- Create "vote_matrix" with absolute number of votes in pairwise
3789 -- comparison:
3790 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3791 "i" := 1;
3792 "j" := 2;
3793 FOR "battle_row" IN
3794 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3795 ORDER BY
3796 "winning_initiative_id" NULLS LAST,
3797 "losing_initiative_id" NULLS LAST
3798 LOOP
3799 "vote_matrix"["i"]["j"] := "battle_row"."count";
3800 IF "j" = "dimension_v" THEN
3801 "i" := "i" + 1;
3802 "j" := 1;
3803 ELSE
3804 "j" := "j" + 1;
3805 IF "j" = "i" THEN
3806 "j" := "j" + 1;
3807 END IF;
3808 END IF;
3809 END LOOP;
3810 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3811 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3812 END IF;
3813 -- Store defeat strengths in "matrix" using "defeat_strength"
3814 -- function:
3815 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3816 "i" := 1;
3817 LOOP
3818 "j" := 1;
3819 LOOP
3820 IF "i" != "j" THEN
3821 "matrix"["i"]["j"] := "defeat_strength"(
3822 "vote_matrix"["i"]["j"],
3823 "vote_matrix"["j"]["i"]
3824 );
3825 END IF;
3826 EXIT WHEN "j" = "dimension_v";
3827 "j" := "j" + 1;
3828 END LOOP;
3829 EXIT WHEN "i" = "dimension_v";
3830 "i" := "i" + 1;
3831 END LOOP;
3832 -- Find best paths:
3833 "i" := 1;
3834 LOOP
3835 "j" := 1;
3836 LOOP
3837 IF "i" != "j" THEN
3838 "k" := 1;
3839 LOOP
3840 IF "i" != "k" AND "j" != "k" THEN
3841 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3842 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3843 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3844 END IF;
3845 ELSE
3846 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3847 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3848 END IF;
3849 END IF;
3850 END IF;
3851 EXIT WHEN "k" = "dimension_v";
3852 "k" := "k" + 1;
3853 END LOOP;
3854 END IF;
3855 EXIT WHEN "j" = "dimension_v";
3856 "j" := "j" + 1;
3857 END LOOP;
3858 EXIT WHEN "i" = "dimension_v";
3859 "i" := "i" + 1;
3860 END LOOP;
3861 -- Determine order of winners:
3862 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3863 "rank_v" := 1;
3864 "done_v" := 0;
3865 LOOP
3866 "winners_ary" := '{}';
3867 "i" := 1;
3868 LOOP
3869 IF "rank_ary"["i"] ISNULL THEN
3870 "j" := 1;
3871 LOOP
3872 IF
3873 "i" != "j" AND
3874 "rank_ary"["j"] ISNULL AND
3875 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3876 THEN
3877 -- someone else is better
3878 EXIT;
3879 END IF;
3880 IF "j" = "dimension_v" THEN
3881 -- noone is better
3882 "winners_ary" := "winners_ary" || "i";
3883 EXIT;
3884 END IF;
3885 "j" := "j" + 1;
3886 END LOOP;
3887 END IF;
3888 EXIT WHEN "i" = "dimension_v";
3889 "i" := "i" + 1;
3890 END LOOP;
3891 "i" := 1;
3892 LOOP
3893 "rank_ary"["winners_ary"["i"]] := "rank_v";
3894 "done_v" := "done_v" + 1;
3895 EXIT WHEN "i" = array_upper("winners_ary", 1);
3896 "i" := "i" + 1;
3897 END LOOP;
3898 EXIT WHEN "done_v" = "dimension_v";
3899 "rank_v" := "rank_v" + 1;
3900 END LOOP;
3901 -- write preliminary results:
3902 "i" := 1;
3903 FOR "initiative_id_v" IN
3904 SELECT "id" FROM "initiative"
3905 WHERE "issue_id" = "issue_id_p" AND "admitted"
3906 ORDER BY "id"
3907 LOOP
3908 UPDATE "initiative" SET
3909 "direct_majority" =
3910 CASE WHEN "policy_row"."direct_majority_strict" THEN
3911 "positive_votes" * "policy_row"."direct_majority_den" >
3912 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3913 ELSE
3914 "positive_votes" * "policy_row"."direct_majority_den" >=
3915 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3916 END
3917 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3918 AND "issue_row"."voter_count"-"negative_votes" >=
3919 "policy_row"."direct_majority_non_negative",
3920 "indirect_majority" =
3921 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3922 "positive_votes" * "policy_row"."indirect_majority_den" >
3923 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3924 ELSE
3925 "positive_votes" * "policy_row"."indirect_majority_den" >=
3926 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3927 END
3928 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3929 AND "issue_row"."voter_count"-"negative_votes" >=
3930 "policy_row"."indirect_majority_non_negative",
3931 "schulze_rank" = "rank_ary"["i"],
3932 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3933 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3934 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3935 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3936 "eligible" = FALSE,
3937 "winner" = FALSE,
3938 "rank" = NULL -- NOTE: in cases of manual reset of issue state
3939 WHERE "id" = "initiative_id_v";
3940 "i" := "i" + 1;
3941 END LOOP;
3942 IF "i" != "dimension_v" THEN
3943 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3944 END IF;
3945 -- take indirect majorities into account:
3946 LOOP
3947 UPDATE "initiative" SET "indirect_majority" = TRUE
3948 FROM (
3949 SELECT "new_initiative"."id" AS "initiative_id"
3950 FROM "initiative" "old_initiative"
3951 JOIN "initiative" "new_initiative"
3952 ON "new_initiative"."issue_id" = "issue_id_p"
3953 AND "new_initiative"."indirect_majority" = FALSE
3954 JOIN "battle" "battle_win"
3955 ON "battle_win"."issue_id" = "issue_id_p"
3956 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3957 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3958 JOIN "battle" "battle_lose"
3959 ON "battle_lose"."issue_id" = "issue_id_p"
3960 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3961 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3962 WHERE "old_initiative"."issue_id" = "issue_id_p"
3963 AND "old_initiative"."indirect_majority" = TRUE
3964 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3965 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3966 "policy_row"."indirect_majority_num" *
3967 ("battle_win"."count"+"battle_lose"."count")
3968 ELSE
3969 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3970 "policy_row"."indirect_majority_num" *
3971 ("battle_win"."count"+"battle_lose"."count")
3972 END
3973 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3974 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3975 "policy_row"."indirect_majority_non_negative"
3976 ) AS "subquery"
3977 WHERE "id" = "subquery"."initiative_id";
3978 EXIT WHEN NOT FOUND;
3979 END LOOP;
3980 -- set "multistage_majority" for remaining matching initiatives:
3981 UPDATE "initiative" SET "multistage_majority" = TRUE
3982 FROM (
3983 SELECT "losing_initiative"."id" AS "initiative_id"
3984 FROM "initiative" "losing_initiative"
3985 JOIN "initiative" "winning_initiative"
3986 ON "winning_initiative"."issue_id" = "issue_id_p"
3987 AND "winning_initiative"."admitted"
3988 JOIN "battle" "battle_win"
3989 ON "battle_win"."issue_id" = "issue_id_p"
3990 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3991 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3992 JOIN "battle" "battle_lose"
3993 ON "battle_lose"."issue_id" = "issue_id_p"
3994 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3995 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3996 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3997 AND "losing_initiative"."admitted"
3998 AND "winning_initiative"."schulze_rank" <
3999 "losing_initiative"."schulze_rank"
4000 AND "battle_win"."count" > "battle_lose"."count"
4001 AND (
4002 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4003 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4004 ) AS "subquery"
4005 WHERE "id" = "subquery"."initiative_id";
4006 -- mark eligible initiatives:
4007 UPDATE "initiative" SET "eligible" = TRUE
4008 WHERE "issue_id" = "issue_id_p"
4009 AND "initiative"."direct_majority"
4010 AND "initiative"."indirect_majority"
4011 AND "initiative"."better_than_status_quo"
4012 AND (
4013 "policy_row"."no_multistage_majority" = FALSE OR
4014 "initiative"."multistage_majority" = FALSE )
4015 AND (
4016 "policy_row"."no_reverse_beat_path" = FALSE OR
4017 "initiative"."reverse_beat_path" = FALSE );
4018 -- mark final winner:
4019 UPDATE "initiative" SET "winner" = TRUE
4020 FROM (
4021 SELECT "id" AS "initiative_id"
4022 FROM "initiative"
4023 WHERE "issue_id" = "issue_id_p" AND "eligible"
4024 ORDER BY
4025 "schulze_rank",
4026 "id"
4027 LIMIT 1
4028 ) AS "subquery"
4029 WHERE "id" = "subquery"."initiative_id";
4030 -- write (final) ranks:
4031 "rank_v" := 1;
4032 FOR "initiative_id_v" IN
4033 SELECT "id"
4034 FROM "initiative"
4035 WHERE "issue_id" = "issue_id_p" AND "admitted"
4036 ORDER BY
4037 "winner" DESC,
4038 "eligible" DESC,
4039 "schulze_rank",
4040 "id"
4041 LOOP
4042 UPDATE "initiative" SET "rank" = "rank_v"
4043 WHERE "id" = "initiative_id_v";
4044 "rank_v" := "rank_v" + 1;
4045 END LOOP;
4046 -- set schulze rank of status quo and mark issue as finished:
4047 UPDATE "issue" SET
4048 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4049 "state" =
4050 CASE WHEN EXISTS (
4051 SELECT NULL FROM "initiative"
4052 WHERE "issue_id" = "issue_id_p" AND "winner"
4053 ) THEN
4054 'finished_with_winner'::"issue_state"
4055 ELSE
4056 'finished_without_winner'::"issue_state"
4057 END,
4058 "ranks_available" = TRUE
4059 WHERE "id" = "issue_id_p";
4060 RETURN;
4061 END;
4062 $$;
4064 COMMENT ON FUNCTION "calculate_ranks"
4065 ( "issue"."id"%TYPE )
4066 IS 'Determine ranking (Votes have to be counted first)';
4070 -----------------------------
4071 -- Automatic state changes --
4072 -----------------------------
4075 CREATE FUNCTION "check_issue"
4076 ( "issue_id_p" "issue"."id"%TYPE )
4077 RETURNS VOID
4078 LANGUAGE 'plpgsql' VOLATILE AS $$
4079 DECLARE
4080 "issue_row" "issue"%ROWTYPE;
4081 "policy_row" "policy"%ROWTYPE;
4082 BEGIN
4083 PERFORM "lock_issue"("issue_id_p");
4084 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4085 -- only process open issues:
4086 IF "issue_row"."closed" ISNULL THEN
4087 SELECT * INTO "policy_row" FROM "policy"
4088 WHERE "id" = "issue_row"."policy_id";
4089 -- create a snapshot, unless issue is already fully frozen:
4090 IF "issue_row"."fully_frozen" ISNULL THEN
4091 PERFORM "create_snapshot"("issue_id_p");
4092 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4093 END IF;
4094 -- eventually close or accept issues, which have not been accepted:
4095 IF "issue_row"."accepted" ISNULL THEN
4096 IF EXISTS (
4097 SELECT NULL FROM "initiative"
4098 WHERE "issue_id" = "issue_id_p"
4099 AND "supporter_count" > 0
4100 AND "supporter_count" * "policy_row"."issue_quorum_den"
4101 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4102 ) THEN
4103 -- accept issues, if supporter count is high enough
4104 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4105 -- NOTE: "issue_row" used later
4106 "issue_row"."state" := 'discussion';
4107 "issue_row"."accepted" := now();
4108 UPDATE "issue" SET
4109 "state" = "issue_row"."state",
4110 "accepted" = "issue_row"."accepted"
4111 WHERE "id" = "issue_row"."id";
4112 ELSIF
4113 now() >= "issue_row"."created" + "issue_row"."admission_time"
4114 THEN
4115 -- close issues, if admission time has expired
4116 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4117 UPDATE "issue" SET
4118 "state" = 'canceled_issue_not_accepted',
4119 "closed" = now()
4120 WHERE "id" = "issue_row"."id";
4121 END IF;
4122 END IF;
4123 -- eventually half freeze issues:
4124 IF
4125 -- NOTE: issue can't be closed at this point, if it has been accepted
4126 "issue_row"."accepted" NOTNULL AND
4127 "issue_row"."half_frozen" ISNULL
4128 THEN
4129 IF
4130 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4131 THEN
4132 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4133 -- NOTE: "issue_row" used later
4134 "issue_row"."state" := 'verification';
4135 "issue_row"."half_frozen" := now();
4136 UPDATE "issue" SET
4137 "state" = "issue_row"."state",
4138 "half_frozen" = "issue_row"."half_frozen"
4139 WHERE "id" = "issue_row"."id";
4140 END IF;
4141 END IF;
4142 -- close issues after some time, if all initiatives have been revoked:
4143 IF
4144 "issue_row"."closed" ISNULL AND
4145 NOT EXISTS (
4146 -- all initiatives are revoked
4147 SELECT NULL FROM "initiative"
4148 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4149 ) AND (
4150 -- and issue has not been accepted yet
4151 "issue_row"."accepted" ISNULL OR
4152 NOT EXISTS (
4153 -- or no initiatives have been revoked lately
4154 SELECT NULL FROM "initiative"
4155 WHERE "issue_id" = "issue_id_p"
4156 AND now() < "revoked" + "issue_row"."verification_time"
4157 ) OR (
4158 -- or verification time has elapsed
4159 "issue_row"."half_frozen" NOTNULL AND
4160 "issue_row"."fully_frozen" ISNULL AND
4161 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4164 THEN
4165 -- NOTE: "issue_row" used later
4166 IF "issue_row"."accepted" ISNULL THEN
4167 "issue_row"."state" := 'canceled_revoked_before_accepted';
4168 ELSIF "issue_row"."half_frozen" ISNULL THEN
4169 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4170 ELSE
4171 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4172 END IF;
4173 "issue_row"."closed" := now();
4174 UPDATE "issue" SET
4175 "state" = "issue_row"."state",
4176 "closed" = "issue_row"."closed"
4177 WHERE "id" = "issue_row"."id";
4178 END IF;
4179 -- fully freeze issue after verification time:
4180 IF
4181 "issue_row"."half_frozen" NOTNULL AND
4182 "issue_row"."fully_frozen" ISNULL AND
4183 "issue_row"."closed" ISNULL AND
4184 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4185 THEN
4186 PERFORM "freeze_after_snapshot"("issue_id_p");
4187 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4188 END IF;
4189 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4190 -- close issue by calling close_voting(...) after voting time:
4191 IF
4192 "issue_row"."closed" ISNULL AND
4193 "issue_row"."fully_frozen" NOTNULL AND
4194 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4195 THEN
4196 PERFORM "close_voting"("issue_id_p");
4197 -- calculate ranks will not consume much time and can be done now
4198 PERFORM "calculate_ranks"("issue_id_p");
4199 END IF;
4200 END IF;
4201 RETURN;
4202 END;
4203 $$;
4205 COMMENT ON FUNCTION "check_issue"
4206 ( "issue"."id"%TYPE )
4207 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.';
4210 CREATE FUNCTION "check_everything"()
4211 RETURNS VOID
4212 LANGUAGE 'plpgsql' VOLATILE AS $$
4213 DECLARE
4214 "issue_id_v" "issue"."id"%TYPE;
4215 BEGIN
4216 DELETE FROM "expired_session";
4217 PERFORM "check_activity"();
4218 PERFORM "calculate_member_counts"();
4219 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4220 PERFORM "check_issue"("issue_id_v");
4221 END LOOP;
4222 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4223 PERFORM "calculate_ranks"("issue_id_v");
4224 END LOOP;
4225 RETURN;
4226 END;
4227 $$;
4229 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.';
4233 ----------------------
4234 -- Deletion of data --
4235 ----------------------
4238 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4239 RETURNS VOID
4240 LANGUAGE 'plpgsql' VOLATILE AS $$
4241 DECLARE
4242 "issue_row" "issue"%ROWTYPE;
4243 BEGIN
4244 SELECT * INTO "issue_row"
4245 FROM "issue" WHERE "id" = "issue_id_p"
4246 FOR UPDATE;
4247 IF "issue_row"."cleaned" ISNULL THEN
4248 UPDATE "issue" SET
4249 "state" = 'voting',
4250 "closed" = NULL,
4251 "ranks_available" = FALSE
4252 WHERE "id" = "issue_id_p";
4253 DELETE FROM "issue_comment"
4254 WHERE "issue_id" = "issue_id_p";
4255 DELETE FROM "voting_comment"
4256 WHERE "issue_id" = "issue_id_p";
4257 DELETE FROM "delegating_voter"
4258 WHERE "issue_id" = "issue_id_p";
4259 DELETE FROM "direct_voter"
4260 WHERE "issue_id" = "issue_id_p";
4261 DELETE FROM "delegating_interest_snapshot"
4262 WHERE "issue_id" = "issue_id_p";
4263 DELETE FROM "direct_interest_snapshot"
4264 WHERE "issue_id" = "issue_id_p";
4265 DELETE FROM "delegating_population_snapshot"
4266 WHERE "issue_id" = "issue_id_p";
4267 DELETE FROM "direct_population_snapshot"
4268 WHERE "issue_id" = "issue_id_p";
4269 DELETE FROM "non_voter"
4270 WHERE "issue_id" = "issue_id_p";
4271 DELETE FROM "delegation"
4272 WHERE "issue_id" = "issue_id_p";
4273 DELETE FROM "supporter"
4274 WHERE "issue_id" = "issue_id_p";
4275 UPDATE "issue" SET
4276 "state" = "issue_row"."state",
4277 "closed" = "issue_row"."closed",
4278 "ranks_available" = "issue_row"."ranks_available",
4279 "cleaned" = now()
4280 WHERE "id" = "issue_id_p";
4281 END IF;
4282 RETURN;
4283 END;
4284 $$;
4286 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4289 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4290 RETURNS VOID
4291 LANGUAGE 'plpgsql' VOLATILE AS $$
4292 BEGIN
4293 UPDATE "member" SET
4294 "last_login" = NULL,
4295 "login" = NULL,
4296 "password" = NULL,
4297 "locked" = TRUE,
4298 "active" = FALSE,
4299 "notify_email" = NULL,
4300 "notify_email_unconfirmed" = NULL,
4301 "notify_email_secret" = NULL,
4302 "notify_email_secret_expiry" = NULL,
4303 "notify_email_lock_expiry" = NULL,
4304 "password_reset_secret" = NULL,
4305 "password_reset_secret_expiry" = NULL,
4306 "organizational_unit" = NULL,
4307 "internal_posts" = NULL,
4308 "realname" = NULL,
4309 "birthday" = NULL,
4310 "address" = NULL,
4311 "email" = NULL,
4312 "xmpp_address" = NULL,
4313 "website" = NULL,
4314 "phone" = NULL,
4315 "mobile_phone" = NULL,
4316 "profession" = NULL,
4317 "external_memberships" = NULL,
4318 "external_posts" = NULL,
4319 "statement" = NULL
4320 WHERE "id" = "member_id_p";
4321 -- "text_search_data" is updated by triggers
4322 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4323 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4324 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4325 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4326 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4327 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4328 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4329 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4330 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4331 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4332 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4333 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4334 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4335 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4336 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4337 DELETE FROM "direct_voter" USING "issue"
4338 WHERE "direct_voter"."issue_id" = "issue"."id"
4339 AND "issue"."closed" ISNULL
4340 AND "member_id" = "member_id_p";
4341 RETURN;
4342 END;
4343 $$;
4345 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)';
4348 CREATE FUNCTION "delete_private_data"()
4349 RETURNS VOID
4350 LANGUAGE 'plpgsql' VOLATILE AS $$
4351 BEGIN
4352 DELETE FROM "member" WHERE "activated" ISNULL;
4353 UPDATE "member" SET
4354 "invite_code" = NULL,
4355 "invite_code_expiry" = NULL,
4356 "admin_comment" = NULL,
4357 "last_login" = NULL,
4358 "login" = NULL,
4359 "password" = NULL,
4360 "lang" = NULL,
4361 "notify_email" = NULL,
4362 "notify_email_unconfirmed" = NULL,
4363 "notify_email_secret" = NULL,
4364 "notify_email_secret_expiry" = NULL,
4365 "notify_email_lock_expiry" = NULL,
4366 "notify_level" = NULL,
4367 "password_reset_secret" = NULL,
4368 "password_reset_secret_expiry" = NULL,
4369 "organizational_unit" = NULL,
4370 "internal_posts" = NULL,
4371 "realname" = NULL,
4372 "birthday" = NULL,
4373 "address" = NULL,
4374 "email" = NULL,
4375 "xmpp_address" = NULL,
4376 "website" = NULL,
4377 "phone" = NULL,
4378 "mobile_phone" = NULL,
4379 "profession" = NULL,
4380 "external_memberships" = NULL,
4381 "external_posts" = NULL,
4382 "formatting_engine" = NULL,
4383 "statement" = NULL;
4384 -- "text_search_data" is updated by triggers
4385 DELETE FROM "setting";
4386 DELETE FROM "setting_map";
4387 DELETE FROM "member_relation_setting";
4388 DELETE FROM "member_image";
4389 DELETE FROM "contact";
4390 DELETE FROM "ignored_member";
4391 DELETE FROM "session";
4392 DELETE FROM "area_setting";
4393 DELETE FROM "issue_setting";
4394 DELETE FROM "ignored_initiative";
4395 DELETE FROM "initiative_setting";
4396 DELETE FROM "suggestion_setting";
4397 DELETE FROM "non_voter";
4398 DELETE FROM "direct_voter" USING "issue"
4399 WHERE "direct_voter"."issue_id" = "issue"."id"
4400 AND "issue"."closed" ISNULL;
4401 RETURN;
4402 END;
4403 $$;
4405 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.';
4409 COMMIT;

Impressum / About Us