liquid_feedback_core

view core.sql @ 241:8d2d92e83605

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

Impressum / About Us