liquid_feedback_core

view core.sql @ 448:8730552eee9d

Re-added removed deprecated API tables (already accidentally removed in previous commit)
author jbe
date Tue Dec 01 16:56:29 2015 +0100 (2015-12-01)
parents 78e9a2071b0c
children 6cef981cdcdf
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 ('3.0.5', 3, 0, 5))
11 AS "subquery"("string", "major", "minor", "revision");
15 ----------------------
16 -- Full text search --
17 ----------------------
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
21 RETURNS TSQUERY
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
23 BEGIN
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
25 END;
26 $$;
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
31 CREATE FUNCTION "highlight"
32 ( "body_p" TEXT,
33 "query_text_p" TEXT )
34 RETURNS TEXT
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
36 BEGIN
37 RETURN ts_headline(
38 'pg_catalog.simple',
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
40 "text_search_query"("query_text_p"),
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
42 END;
43 $$;
45 COMMENT ON FUNCTION "highlight"
46 ( "body_p" TEXT,
47 "query_text_p" TEXT )
48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
52 -------------------------
53 -- Tables and indicies --
54 -------------------------
57 CREATE TABLE "temporary_transaction_data" (
58 PRIMARY KEY ("txid", "key"),
59 "txid" INT8 DEFAULT txid_current(),
60 "key" TEXT,
61 "value" TEXT NOT NULL );
63 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
65 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
68 CREATE TABLE "system_setting" (
69 "member_ttl" INTERVAL );
70 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
72 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
73 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
75 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.';
78 CREATE TABLE "contingent" (
79 PRIMARY KEY ("polling", "time_frame"),
80 "polling" BOOLEAN,
81 "time_frame" INTERVAL,
82 "text_entry_limit" INT4,
83 "initiative_limit" INT4 );
85 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.';
87 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
88 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';
89 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
92 CREATE TYPE "notify_level" AS ENUM
93 ('none', 'voting', 'verification', 'discussion', 'all');
95 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';
98 CREATE TABLE "member" (
99 "id" SERIAL4 PRIMARY KEY,
100 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
101 "invite_code" TEXT UNIQUE,
102 "invite_code_expiry" TIMESTAMPTZ,
103 "admin_comment" TEXT,
104 "activated" TIMESTAMPTZ,
105 "last_activity" DATE,
106 "last_login" TIMESTAMPTZ,
107 "last_delegation_check" TIMESTAMPTZ,
108 "login" TEXT UNIQUE,
109 "password" TEXT,
110 "authority" TEXT,
111 "authority_uid" TEXT,
112 "authority_login" TEXT,
113 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
114 "active" BOOLEAN NOT NULL DEFAULT FALSE,
115 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
116 "lang" TEXT,
117 "notify_email" TEXT,
118 "notify_email_unconfirmed" TEXT,
119 "notify_email_secret" TEXT UNIQUE,
120 "notify_email_secret_expiry" TIMESTAMPTZ,
121 "notify_email_lock_expiry" TIMESTAMPTZ,
122 "notify_level" "notify_level",
123 "login_recovery_expiry" TIMESTAMPTZ,
124 "password_reset_secret" TEXT UNIQUE,
125 "password_reset_secret_expiry" TIMESTAMPTZ,
126 "name" TEXT UNIQUE,
127 "identification" TEXT UNIQUE,
128 "authentication" TEXT,
129 "organizational_unit" TEXT,
130 "internal_posts" TEXT,
131 "realname" TEXT,
132 "birthday" DATE,
133 "address" TEXT,
134 "email" TEXT,
135 "xmpp_address" TEXT,
136 "website" TEXT,
137 "phone" TEXT,
138 "mobile_phone" TEXT,
139 "profession" TEXT,
140 "external_memberships" TEXT,
141 "external_posts" TEXT,
142 "formatting_engine" TEXT,
143 "statement" TEXT,
144 "text_search_data" TSVECTOR,
145 CONSTRAINT "active_requires_activated_and_last_activity"
146 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
147 CONSTRAINT "authority_requires_uid_and_vice_versa"
148 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
149 CONSTRAINT "authority_uid_unique_per_authority"
150 UNIQUE ("authority", "authority_uid"),
151 CONSTRAINT "authority_login_requires_authority"
152 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
153 CONSTRAINT "name_not_null_if_activated"
154 CHECK ("activated" ISNULL OR "name" NOTNULL) );
155 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
156 CREATE INDEX "member_active_idx" ON "member" ("active");
157 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
158 CREATE TRIGGER "update_text_search_data"
159 BEFORE INSERT OR UPDATE ON "member"
160 FOR EACH ROW EXECUTE PROCEDURE
161 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
162 "name", "identification", "organizational_unit", "internal_posts",
163 "realname", "external_memberships", "external_posts", "statement" );
165 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
167 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
168 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
169 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
170 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
171 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';
172 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
173 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
174 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
175 COMMENT ON COLUMN "member"."login" IS 'Login name';
176 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
177 COMMENT ON COLUMN "member"."authority" IS 'NULL if LiquidFeedback Core is authoritative for the member account; otherwise a string that indicates the source/authority of the external account (e.g. ''LDAP'' for an LDAP account)';
178 COMMENT ON COLUMN "member"."authority_uid" IS 'Unique identifier (unique per "authority") that allows to identify an external account (e.g. even if the login name changes)';
179 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
180 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
181 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".';
182 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
183 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
184 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
185 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
186 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
187 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
188 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
189 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';
190 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
191 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
192 COMMENT ON COLUMN "member"."password_reset_secret_expiry" IS 'Date/time until the password recovery secret is valid, and date/time after which another password recovery attempt is allowed';
193 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
194 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
195 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
196 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
197 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
198 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
199 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
200 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
201 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
202 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
203 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
206 -- DEPRECATED API TABLES --
208 CREATE TYPE "application_access_level" AS ENUM
209 ('member', 'full', 'pseudonymous', 'anonymous');
211 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
214 CREATE TABLE "member_application" (
215 "id" SERIAL8 PRIMARY KEY,
216 UNIQUE ("member_id", "name"),
217 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
218 ON DELETE CASCADE ON UPDATE CASCADE,
219 "name" TEXT NOT NULL,
220 "comment" TEXT,
221 "access_level" "application_access_level" NOT NULL,
222 "key" TEXT NOT NULL UNIQUE,
223 "last_usage" TIMESTAMPTZ );
225 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
227 -- END OF DEPRECARED API TABLES --
230 CREATE TABLE "member_history" (
231 "id" SERIAL8 PRIMARY KEY,
232 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
233 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
234 "active" BOOLEAN NOT NULL,
235 "name" TEXT NOT NULL );
236 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
238 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
240 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
241 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
244 CREATE TABLE "rendered_member_statement" (
245 PRIMARY KEY ("member_id", "format"),
246 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
247 "format" TEXT,
248 "content" TEXT NOT NULL );
250 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)';
253 CREATE TABLE "setting" (
254 PRIMARY KEY ("member_id", "key"),
255 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
256 "key" TEXT NOT NULL,
257 "value" TEXT NOT NULL );
258 CREATE INDEX "setting_key_idx" ON "setting" ("key");
260 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
262 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
265 CREATE TABLE "setting_map" (
266 PRIMARY KEY ("member_id", "key", "subkey"),
267 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
268 "key" TEXT NOT NULL,
269 "subkey" TEXT NOT NULL,
270 "value" TEXT NOT NULL );
271 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
273 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
275 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
276 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
277 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
280 CREATE TABLE "member_relation_setting" (
281 PRIMARY KEY ("member_id", "key", "other_member_id"),
282 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
283 "key" TEXT NOT NULL,
284 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
285 "value" TEXT NOT NULL );
287 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
290 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
292 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
295 CREATE TABLE "member_image" (
296 PRIMARY KEY ("member_id", "image_type", "scaled"),
297 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
298 "image_type" "member_image_type",
299 "scaled" BOOLEAN,
300 "content_type" TEXT,
301 "data" BYTEA NOT NULL );
303 COMMENT ON TABLE "member_image" IS 'Images of members';
305 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
308 CREATE TABLE "member_count" (
309 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
310 "total_count" INT4 NOT NULL );
312 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';
314 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
315 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
318 CREATE TABLE "contact" (
319 PRIMARY KEY ("member_id", "other_member_id"),
320 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
321 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
322 "public" BOOLEAN NOT NULL DEFAULT FALSE,
323 CONSTRAINT "cant_save_yourself_as_contact"
324 CHECK ("member_id" != "other_member_id") );
325 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
327 COMMENT ON TABLE "contact" IS 'Contact lists';
329 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
330 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
331 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
334 CREATE TABLE "ignored_member" (
335 PRIMARY KEY ("member_id", "other_member_id"),
336 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
337 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
338 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
340 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
342 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
343 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
346 CREATE TABLE "session" (
347 "ident" TEXT PRIMARY KEY,
348 "additional_secret" TEXT,
349 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
350 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
351 "authority" TEXT,
352 "authority_uid" TEXT,
353 "authority_login" TEXT,
354 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
355 "lang" TEXT );
356 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
358 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
360 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
361 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
362 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
363 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
364 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
365 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
366 COMMENT ON COLUMN "session"."needs_delegation_check" IS 'Set to TRUE, if member must perform a delegation check to proceed with login; see column "last_delegation_check" in "member" table';
367 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
370 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
372 COMMENT ON TYPE "defeat_strength" IS 'How pairwise defeats are measured for the Schulze method: ''simple'' = only the number of winning votes, ''tuple'' = primarily the number of winning votes, secondarily the number of losing votes';
375 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
377 COMMENT ON TYPE "tie_breaking" IS 'Tie-breaker for the Schulze method: ''simple'' = only initiative ids are used, ''variant1'' = use initiative ids in variant 1 for tie breaking of the links (TBRL) and sequentially forbid shared links, ''variant2'' = use initiative ids in variant 2 for tie breaking of the links (TBRL) and sequentially forbid shared links';
381 CREATE TABLE "policy" (
382 "id" SERIAL4 PRIMARY KEY,
383 "index" INT4 NOT NULL,
384 "active" BOOLEAN NOT NULL DEFAULT TRUE,
385 "name" TEXT NOT NULL UNIQUE,
386 "description" TEXT NOT NULL DEFAULT '',
387 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
388 "min_admission_time" INTERVAL,
389 "max_admission_time" INTERVAL,
390 "discussion_time" INTERVAL,
391 "verification_time" INTERVAL,
392 "voting_time" INTERVAL,
393 "issue_quorum_num" INT4,
394 "issue_quorum_den" INT4,
395 "initiative_quorum_num" INT4 NOT NULL,
396 "initiative_quorum_den" INT4 NOT NULL,
397 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
398 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
399 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
400 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
401 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
402 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
403 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
404 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
405 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
406 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
407 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
408 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
409 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
410 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
411 CONSTRAINT "timing" CHECK (
412 ( "polling" = FALSE AND
413 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
414 "discussion_time" NOTNULL AND
415 "verification_time" NOTNULL AND
416 "voting_time" NOTNULL ) OR
417 ( "polling" = TRUE AND
418 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
419 "discussion_time" NOTNULL AND
420 "verification_time" NOTNULL AND
421 "voting_time" NOTNULL ) OR
422 ( "polling" = TRUE AND
423 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
424 "discussion_time" ISNULL AND
425 "verification_time" ISNULL AND
426 "voting_time" ISNULL ) ),
427 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
428 "polling" = ("issue_quorum_num" ISNULL) AND
429 "polling" = ("issue_quorum_den" ISNULL) ),
430 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
431 "defeat_strength" = 'tuple'::"defeat_strength" OR
432 "no_reverse_beat_path" = FALSE ) );
433 CREATE INDEX "policy_active_idx" ON "policy" ("active");
435 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
437 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
438 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
439 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "min_admission_time" and "max_admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
440 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open';
441 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
442 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
443 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"';
444 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'')';
445 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''';
446 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''';
447 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
448 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
449 COMMENT ON COLUMN "policy"."defeat_strength" IS 'How pairwise defeats are measured for the Schulze method; see type "defeat_strength"; ''tuple'' is the recommended setting';
450 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
451 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
452 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
453 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.';
454 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
455 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';
456 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';
457 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';
458 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.';
459 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';
460 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';
461 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: 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.';
462 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: 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").';
465 CREATE TABLE "unit" (
466 "id" SERIAL4 PRIMARY KEY,
467 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
468 "active" BOOLEAN NOT NULL DEFAULT TRUE,
469 "name" TEXT NOT NULL,
470 "description" TEXT NOT NULL DEFAULT '',
471 "external_reference" TEXT,
472 "member_count" INT4,
473 "text_search_data" TSVECTOR );
474 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
475 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
476 CREATE INDEX "unit_active_idx" ON "unit" ("active");
477 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
478 CREATE TRIGGER "update_text_search_data"
479 BEFORE INSERT OR UPDATE ON "unit"
480 FOR EACH ROW EXECUTE PROCEDURE
481 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
482 "name", "description" );
484 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
486 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
487 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
488 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
489 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
492 CREATE TABLE "unit_setting" (
493 PRIMARY KEY ("member_id", "key", "unit_id"),
494 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
495 "key" TEXT NOT NULL,
496 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
497 "value" TEXT NOT NULL );
499 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
502 CREATE TABLE "area" (
503 "id" SERIAL4 PRIMARY KEY,
504 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
505 "active" BOOLEAN NOT NULL DEFAULT TRUE,
506 "name" TEXT NOT NULL,
507 "description" TEXT NOT NULL DEFAULT '',
508 "external_reference" TEXT,
509 "direct_member_count" INT4,
510 "member_weight" INT4,
511 "text_search_data" TSVECTOR );
512 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
513 CREATE INDEX "area_active_idx" ON "area" ("active");
514 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
515 CREATE TRIGGER "update_text_search_data"
516 BEFORE INSERT OR UPDATE ON "area"
517 FOR EACH ROW EXECUTE PROCEDURE
518 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
519 "name", "description" );
521 COMMENT ON TABLE "area" IS 'Subject areas';
523 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
524 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
525 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"';
526 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
529 CREATE TABLE "area_setting" (
530 PRIMARY KEY ("member_id", "key", "area_id"),
531 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
532 "key" TEXT NOT NULL,
533 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
534 "value" TEXT NOT NULL );
536 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
539 CREATE TABLE "allowed_policy" (
540 PRIMARY KEY ("area_id", "policy_id"),
541 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
542 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
543 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
544 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
546 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
548 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
551 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
553 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';
556 CREATE TYPE "issue_state" AS ENUM (
557 'admission', 'discussion', 'verification', 'voting',
558 'canceled_by_admin',
559 'canceled_revoked_before_accepted',
560 'canceled_issue_not_accepted',
561 'canceled_after_revocation_during_discussion',
562 'canceled_after_revocation_during_verification',
563 'canceled_no_initiative_admitted',
564 'finished_without_winner', 'finished_with_winner');
566 COMMENT ON TYPE "issue_state" IS 'State of issues';
569 CREATE TABLE "issue" (
570 "id" SERIAL4 PRIMARY KEY,
571 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
572 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
573 "admin_notice" TEXT,
574 "external_reference" TEXT,
575 "state" "issue_state" NOT NULL DEFAULT 'admission',
576 "phase_finished" TIMESTAMPTZ,
577 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
578 "accepted" TIMESTAMPTZ,
579 "half_frozen" TIMESTAMPTZ,
580 "fully_frozen" TIMESTAMPTZ,
581 "closed" TIMESTAMPTZ,
582 "cleaned" TIMESTAMPTZ,
583 "min_admission_time" INTERVAL,
584 "max_admission_time" INTERVAL,
585 "discussion_time" INTERVAL NOT NULL,
586 "verification_time" INTERVAL NOT NULL,
587 "voting_time" INTERVAL NOT NULL,
588 "snapshot" TIMESTAMPTZ,
589 "latest_snapshot_event" "snapshot_event",
590 "population" INT4,
591 "voter_count" INT4,
592 "status_quo_schulze_rank" INT4,
593 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
594 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
595 "min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created") ),
596 CONSTRAINT "valid_state" CHECK (
597 (
598 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
599 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
600 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
601 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
602 ) AND (
603 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
604 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
605 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
606 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
607 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
608 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
609 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
610 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
611 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
612 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
613 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
614 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
615 )),
616 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
617 "phase_finished" ISNULL OR "closed" ISNULL ),
618 CONSTRAINT "state_change_order" CHECK (
619 "created" <= "accepted" AND
620 "accepted" <= "half_frozen" AND
621 "half_frozen" <= "fully_frozen" AND
622 "fully_frozen" <= "closed" ),
623 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
624 "cleaned" ISNULL OR "closed" NOTNULL ),
625 CONSTRAINT "last_snapshot_on_full_freeze"
626 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
627 CONSTRAINT "freeze_requires_snapshot"
628 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
629 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
630 CHECK (("snapshot" NOTNULL) = ("latest_snapshot_event" NOTNULL)) );
631 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
632 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
633 CREATE INDEX "issue_created_idx" ON "issue" ("created");
634 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
635 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
636 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
637 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
638 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
639 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
641 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
643 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
644 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
645 COMMENT ON COLUMN "issue"."phase_finished" IS 'Set to a value NOTNULL, if the current phase has finished, but calculations are pending; No changes in this issue shall be made by the frontend or API when this value is set';
646 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
647 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.';
648 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.';
649 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "max_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.';
650 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
651 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
652 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
653 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
654 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
655 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
656 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
657 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';
658 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
659 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';
660 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
663 CREATE TABLE "issue_order_in_admission_state" (
664 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
665 "order_in_area" INT4,
666 "order_in_unit" INT4 );
668 COMMENT ON TABLE "issue_order_in_admission_state" IS 'Ordering information for issues that are not stored in the "issue" table to avoid locking of multiple issues at once; Filled/updated by "lf_update_issue_order"';
670 COMMENT ON COLUMN "issue_order_in_admission_state"."id" IS 'References "issue" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
671 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_area" IS 'Order of issues in admission state within a single area; NULL values sort last';
672 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_unit" IS 'Order of issues in admission state within all areas of a unit; NULL values sort last';
675 CREATE TABLE "issue_setting" (
676 PRIMARY KEY ("member_id", "key", "issue_id"),
677 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
678 "key" TEXT NOT NULL,
679 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
680 "value" TEXT NOT NULL );
682 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
685 CREATE TABLE "initiative" (
686 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
687 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
688 "id" SERIAL4 PRIMARY KEY,
689 "name" TEXT NOT NULL,
690 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
691 "discussion_url" TEXT,
692 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
693 "revoked" TIMESTAMPTZ,
694 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
695 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
696 "external_reference" TEXT,
697 "admitted" BOOLEAN,
698 "supporter_count" INT4,
699 "informed_supporter_count" INT4,
700 "satisfied_supporter_count" INT4,
701 "satisfied_informed_supporter_count" INT4,
702 "harmonic_weight" NUMERIC(12, 3),
703 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
704 "first_preference_votes" INT4,
705 "positive_votes" INT4,
706 "negative_votes" INT4,
707 "direct_majority" BOOLEAN,
708 "indirect_majority" BOOLEAN,
709 "schulze_rank" INT4,
710 "better_than_status_quo" BOOLEAN,
711 "worse_than_status_quo" BOOLEAN,
712 "reverse_beat_path" BOOLEAN,
713 "multistage_majority" BOOLEAN,
714 "eligible" BOOLEAN,
715 "winner" BOOLEAN,
716 "rank" INT4,
717 "text_search_data" TSVECTOR,
718 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
719 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
720 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
721 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
722 CONSTRAINT "revoked_initiatives_cant_be_admitted"
723 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
724 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
725 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
726 ( "first_preference_votes" ISNULL AND
727 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
728 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
729 "schulze_rank" ISNULL AND
730 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
731 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
732 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
733 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
734 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
735 "eligible" = FALSE OR
736 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
737 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
738 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
739 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
740 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
741 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
742 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
743 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
744 CREATE TRIGGER "update_text_search_data"
745 BEFORE INSERT OR UPDATE ON "initiative"
746 FOR EACH ROW EXECUTE PROCEDURE
747 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
748 "name", "discussion_url");
750 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.';
752 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
753 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
754 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
755 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
756 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
757 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
758 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
759 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
760 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
761 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
762 COMMENT ON COLUMN "initiative"."harmonic_weight" IS 'Indicates the relevancy of the initiative, calculated from the potential supporters weighted with the harmonic series to avoid a large number of clones affecting other initiative''s sorting positions too much; shall be used as secondary sorting key after "admitted" as primary sorting key';
763 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
764 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
765 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
766 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
767 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"';
768 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
769 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
770 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
771 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (DEPRECATED, since schulze-ranking is unique per issue; use "better_than_status_quo"=FALSE)';
772 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; set to NULL if "policy"."defeat_strength" is set to ''simple''';
773 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';
774 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"';
775 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
776 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';
779 CREATE TABLE "battle" (
780 "issue_id" INT4 NOT NULL,
781 "winning_initiative_id" INT4,
782 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
783 "losing_initiative_id" INT4,
784 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
785 "count" INT4 NOT NULL,
786 CONSTRAINT "initiative_ids_not_equal" CHECK (
787 "winning_initiative_id" != "losing_initiative_id" OR
788 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
789 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
790 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
791 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
792 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
794 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';
797 CREATE TABLE "ignored_initiative" (
798 PRIMARY KEY ("initiative_id", "member_id"),
799 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
800 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
801 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
803 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
806 CREATE TABLE "initiative_setting" (
807 PRIMARY KEY ("member_id", "key", "initiative_id"),
808 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
809 "key" TEXT NOT NULL,
810 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
811 "value" TEXT NOT NULL );
813 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
816 CREATE TABLE "draft" (
817 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
818 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
819 "id" SERIAL8 PRIMARY KEY,
820 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
821 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
822 "formatting_engine" TEXT,
823 "content" TEXT NOT NULL,
824 "external_reference" TEXT,
825 "text_search_data" TSVECTOR );
826 CREATE INDEX "draft_created_idx" ON "draft" ("created");
827 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
828 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
829 CREATE TRIGGER "update_text_search_data"
830 BEFORE INSERT OR UPDATE ON "draft"
831 FOR EACH ROW EXECUTE PROCEDURE
832 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
834 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.';
836 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
837 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
838 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
841 CREATE TABLE "rendered_draft" (
842 PRIMARY KEY ("draft_id", "format"),
843 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
844 "format" TEXT,
845 "content" TEXT NOT NULL );
847 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)';
850 CREATE TABLE "suggestion" (
851 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
852 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
853 "id" SERIAL8 PRIMARY KEY,
854 "draft_id" INT8 NOT NULL,
855 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
856 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
857 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
858 "name" TEXT NOT NULL,
859 "formatting_engine" TEXT,
860 "content" TEXT NOT NULL DEFAULT '',
861 "external_reference" TEXT,
862 "text_search_data" TSVECTOR,
863 "minus2_unfulfilled_count" INT4,
864 "minus2_fulfilled_count" INT4,
865 "minus1_unfulfilled_count" INT4,
866 "minus1_fulfilled_count" INT4,
867 "plus1_unfulfilled_count" INT4,
868 "plus1_fulfilled_count" INT4,
869 "plus2_unfulfilled_count" INT4,
870 "plus2_fulfilled_count" INT4,
871 "proportional_order" INT4 );
872 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
873 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
874 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
875 CREATE TRIGGER "update_text_search_data"
876 BEFORE INSERT OR UPDATE ON "suggestion"
877 FOR EACH ROW EXECUTE PROCEDURE
878 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
879 "name", "content");
881 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';
883 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")';
884 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
885 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
886 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
887 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
888 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
889 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
890 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
891 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
892 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
893 COMMENT ON COLUMN "suggestion"."proportional_order" IS 'To be used for sorting suggestions within an initiative; NULL values sort last; updated by "lf_update_suggestion_order"';
896 CREATE TABLE "rendered_suggestion" (
897 PRIMARY KEY ("suggestion_id", "format"),
898 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
899 "format" TEXT,
900 "content" TEXT NOT NULL );
902 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)';
905 CREATE TABLE "suggestion_setting" (
906 PRIMARY KEY ("member_id", "key", "suggestion_id"),
907 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
908 "key" TEXT NOT NULL,
909 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
910 "value" TEXT NOT NULL );
912 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
915 CREATE TABLE "privilege" (
916 PRIMARY KEY ("unit_id", "member_id"),
917 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
918 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
919 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
920 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
921 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
922 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
923 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
924 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
925 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
927 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
929 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
930 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
931 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
932 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
933 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
934 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
935 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues';
938 CREATE TABLE "membership" (
939 PRIMARY KEY ("area_id", "member_id"),
940 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
941 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
942 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
944 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
947 CREATE TABLE "interest" (
948 PRIMARY KEY ("issue_id", "member_id"),
949 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
950 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
951 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
953 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.';
956 CREATE TABLE "initiator" (
957 PRIMARY KEY ("initiative_id", "member_id"),
958 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
959 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
960 "accepted" BOOLEAN );
961 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
963 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.';
965 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.';
968 CREATE TABLE "supporter" (
969 "issue_id" INT4 NOT NULL,
970 PRIMARY KEY ("initiative_id", "member_id"),
971 "initiative_id" INT4,
972 "member_id" INT4,
973 "draft_id" INT8 NOT NULL,
974 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
975 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
976 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
978 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.';
980 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
981 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")';
984 CREATE TABLE "opinion" (
985 "initiative_id" INT4 NOT NULL,
986 PRIMARY KEY ("suggestion_id", "member_id"),
987 "suggestion_id" INT8,
988 "member_id" INT4,
989 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
990 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
991 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
992 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
993 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
995 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.';
997 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1000 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1002 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1005 CREATE TABLE "delegation" (
1006 "id" SERIAL8 PRIMARY KEY,
1007 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1008 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1009 "scope" "delegation_scope" NOT NULL,
1010 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1011 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1012 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1013 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1014 CONSTRAINT "no_unit_delegation_to_null"
1015 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1016 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1017 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1018 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1019 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1020 UNIQUE ("unit_id", "truster_id"),
1021 UNIQUE ("area_id", "truster_id"),
1022 UNIQUE ("issue_id", "truster_id") );
1023 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1024 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1026 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1028 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1029 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1030 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1033 CREATE TABLE "direct_population_snapshot" (
1034 PRIMARY KEY ("issue_id", "event", "member_id"),
1035 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1036 "event" "snapshot_event",
1037 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1038 "weight" INT4 );
1039 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
1041 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
1043 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1044 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
1047 CREATE TABLE "delegating_population_snapshot" (
1048 PRIMARY KEY ("issue_id", "event", "member_id"),
1049 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1050 "event" "snapshot_event",
1051 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1052 "weight" INT4,
1053 "scope" "delegation_scope" NOT NULL,
1054 "delegate_member_ids" INT4[] NOT NULL );
1055 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
1057 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
1059 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1060 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
1061 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
1062 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"';
1065 CREATE TABLE "direct_interest_snapshot" (
1066 PRIMARY KEY ("issue_id", "event", "member_id"),
1067 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1068 "event" "snapshot_event",
1069 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1070 "weight" INT4 );
1071 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1073 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
1075 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1076 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1079 CREATE TABLE "delegating_interest_snapshot" (
1080 PRIMARY KEY ("issue_id", "event", "member_id"),
1081 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1082 "event" "snapshot_event",
1083 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1084 "weight" INT4,
1085 "scope" "delegation_scope" NOT NULL,
1086 "delegate_member_ids" INT4[] NOT NULL );
1087 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1089 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
1091 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1092 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1093 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1094 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"';
1097 CREATE TABLE "direct_supporter_snapshot" (
1098 "issue_id" INT4 NOT NULL,
1099 PRIMARY KEY ("initiative_id", "event", "member_id"),
1100 "initiative_id" INT4,
1101 "event" "snapshot_event",
1102 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1103 "draft_id" INT8 NOT NULL,
1104 "informed" BOOLEAN NOT NULL,
1105 "satisfied" BOOLEAN NOT NULL,
1106 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1107 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1108 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1109 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1111 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot"); for corrections refer to column "issue_notice" of "issue" table';
1113 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';
1114 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1115 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1116 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1119 CREATE TABLE "non_voter" (
1120 PRIMARY KEY ("issue_id", "member_id"),
1121 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1122 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1123 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1125 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1128 CREATE TABLE "direct_voter" (
1129 PRIMARY KEY ("issue_id", "member_id"),
1130 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1131 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1132 "weight" INT4,
1133 "comment_changed" TIMESTAMPTZ,
1134 "formatting_engine" TEXT,
1135 "comment" TEXT,
1136 "text_search_data" TSVECTOR );
1137 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1138 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1139 CREATE TRIGGER "update_text_search_data"
1140 BEFORE INSERT OR UPDATE ON "direct_voter"
1141 FOR EACH ROW EXECUTE PROCEDURE
1142 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1144 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; for corrections refer to column "issue_notice" of "issue" table';
1146 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1147 COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL';
1148 COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL';
1149 COMMENT ON COLUMN "direct_voter"."comment" 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.';
1152 CREATE TABLE "rendered_voter_comment" (
1153 PRIMARY KEY ("issue_id", "member_id", "format"),
1154 FOREIGN KEY ("issue_id", "member_id")
1155 REFERENCES "direct_voter" ("issue_id", "member_id")
1156 ON DELETE CASCADE ON UPDATE CASCADE,
1157 "issue_id" INT4,
1158 "member_id" INT4,
1159 "format" TEXT,
1160 "content" TEXT NOT NULL );
1162 COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)';
1165 CREATE TABLE "delegating_voter" (
1166 PRIMARY KEY ("issue_id", "member_id"),
1167 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1168 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1169 "weight" INT4,
1170 "scope" "delegation_scope" NOT NULL,
1171 "delegate_member_ids" INT4[] NOT NULL );
1172 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1174 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table; for corrections refer to column "issue_notice" of "issue" table';
1176 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1177 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1178 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"';
1181 CREATE TABLE "vote" (
1182 "issue_id" INT4 NOT NULL,
1183 PRIMARY KEY ("initiative_id", "member_id"),
1184 "initiative_id" INT4,
1185 "member_id" INT4,
1186 "grade" INT4 NOT NULL,
1187 "first_preference" BOOLEAN,
1188 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1189 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1190 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1191 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1192 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1194 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; for corrections refer to column "issue_notice" of "issue" table';
1196 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1197 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.';
1198 COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.';
1201 CREATE TYPE "event_type" AS ENUM (
1202 'issue_state_changed',
1203 'initiative_created_in_new_issue',
1204 'initiative_created_in_existing_issue',
1205 'initiative_revoked',
1206 'new_draft_created',
1207 'suggestion_created');
1209 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1212 CREATE TABLE "event" (
1213 "id" SERIAL8 PRIMARY KEY,
1214 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1215 "event" "event_type" NOT NULL,
1216 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1217 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1218 "state" "issue_state",
1219 "initiative_id" INT4,
1220 "draft_id" INT8,
1221 "suggestion_id" INT8,
1222 FOREIGN KEY ("issue_id", "initiative_id")
1223 REFERENCES "initiative" ("issue_id", "id")
1224 ON DELETE CASCADE ON UPDATE CASCADE,
1225 FOREIGN KEY ("initiative_id", "draft_id")
1226 REFERENCES "draft" ("initiative_id", "id")
1227 ON DELETE CASCADE ON UPDATE CASCADE,
1228 FOREIGN KEY ("initiative_id", "suggestion_id")
1229 REFERENCES "suggestion" ("initiative_id", "id")
1230 ON DELETE CASCADE ON UPDATE CASCADE,
1231 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1232 "event" != 'issue_state_changed' OR (
1233 "member_id" ISNULL AND
1234 "issue_id" NOTNULL AND
1235 "state" NOTNULL AND
1236 "initiative_id" ISNULL AND
1237 "draft_id" ISNULL AND
1238 "suggestion_id" ISNULL )),
1239 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1240 "event" NOT IN (
1241 'initiative_created_in_new_issue',
1242 'initiative_created_in_existing_issue',
1243 'initiative_revoked',
1244 'new_draft_created'
1245 ) OR (
1246 "member_id" NOTNULL AND
1247 "issue_id" NOTNULL AND
1248 "state" NOTNULL AND
1249 "initiative_id" NOTNULL AND
1250 "draft_id" NOTNULL AND
1251 "suggestion_id" ISNULL )),
1252 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1253 "event" != 'suggestion_created' OR (
1254 "member_id" NOTNULL AND
1255 "issue_id" NOTNULL AND
1256 "state" NOTNULL AND
1257 "initiative_id" NOTNULL AND
1258 "draft_id" ISNULL AND
1259 "suggestion_id" NOTNULL )) );
1260 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1262 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1264 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1265 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1266 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1267 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1270 CREATE TABLE "notification_sent" (
1271 "event_id" INT8 NOT NULL );
1272 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1274 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1275 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1279 ----------------------------------------------
1280 -- Writing of history entries and event log --
1281 ----------------------------------------------
1284 CREATE FUNCTION "write_member_history_trigger"()
1285 RETURNS TRIGGER
1286 LANGUAGE 'plpgsql' VOLATILE AS $$
1287 BEGIN
1288 IF
1289 ( NEW."active" != OLD."active" OR
1290 NEW."name" != OLD."name" ) AND
1291 OLD."activated" NOTNULL
1292 THEN
1293 INSERT INTO "member_history"
1294 ("member_id", "active", "name")
1295 VALUES (NEW."id", OLD."active", OLD."name");
1296 END IF;
1297 RETURN NULL;
1298 END;
1299 $$;
1301 CREATE TRIGGER "write_member_history"
1302 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1303 "write_member_history_trigger"();
1305 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1306 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1309 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1310 RETURNS TRIGGER
1311 LANGUAGE 'plpgsql' VOLATILE AS $$
1312 BEGIN
1313 IF NEW."state" != OLD."state" THEN
1314 INSERT INTO "event" ("event", "issue_id", "state")
1315 VALUES ('issue_state_changed', NEW."id", NEW."state");
1316 END IF;
1317 RETURN NULL;
1318 END;
1319 $$;
1321 CREATE TRIGGER "write_event_issue_state_changed"
1322 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1323 "write_event_issue_state_changed_trigger"();
1325 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1326 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1329 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1330 RETURNS TRIGGER
1331 LANGUAGE 'plpgsql' VOLATILE AS $$
1332 DECLARE
1333 "initiative_row" "initiative"%ROWTYPE;
1334 "issue_row" "issue"%ROWTYPE;
1335 "event_v" "event_type";
1336 BEGIN
1337 SELECT * INTO "initiative_row" FROM "initiative"
1338 WHERE "id" = NEW."initiative_id";
1339 SELECT * INTO "issue_row" FROM "issue"
1340 WHERE "id" = "initiative_row"."issue_id";
1341 IF EXISTS (
1342 SELECT NULL FROM "draft"
1343 WHERE "initiative_id" = NEW."initiative_id"
1344 AND "id" != NEW."id"
1345 ) THEN
1346 "event_v" := 'new_draft_created';
1347 ELSE
1348 IF EXISTS (
1349 SELECT NULL FROM "initiative"
1350 WHERE "issue_id" = "initiative_row"."issue_id"
1351 AND "id" != "initiative_row"."id"
1352 ) THEN
1353 "event_v" := 'initiative_created_in_existing_issue';
1354 ELSE
1355 "event_v" := 'initiative_created_in_new_issue';
1356 END IF;
1357 END IF;
1358 INSERT INTO "event" (
1359 "event", "member_id",
1360 "issue_id", "state", "initiative_id", "draft_id"
1361 ) VALUES (
1362 "event_v",
1363 NEW."author_id",
1364 "initiative_row"."issue_id",
1365 "issue_row"."state",
1366 "initiative_row"."id",
1367 NEW."id" );
1368 RETURN NULL;
1369 END;
1370 $$;
1372 CREATE TRIGGER "write_event_initiative_or_draft_created"
1373 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1374 "write_event_initiative_or_draft_created_trigger"();
1376 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1377 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1380 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1381 RETURNS TRIGGER
1382 LANGUAGE 'plpgsql' VOLATILE AS $$
1383 DECLARE
1384 "issue_row" "issue"%ROWTYPE;
1385 "draft_id_v" "draft"."id"%TYPE;
1386 BEGIN
1387 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1388 SELECT * INTO "issue_row" FROM "issue"
1389 WHERE "id" = NEW."issue_id";
1390 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1391 WHERE "initiative_id" = NEW."id";
1392 INSERT INTO "event" (
1393 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1394 ) VALUES (
1395 'initiative_revoked',
1396 NEW."revoked_by_member_id",
1397 NEW."issue_id",
1398 "issue_row"."state",
1399 NEW."id",
1400 "draft_id_v");
1401 END IF;
1402 RETURN NULL;
1403 END;
1404 $$;
1406 CREATE TRIGGER "write_event_initiative_revoked"
1407 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1408 "write_event_initiative_revoked_trigger"();
1410 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1411 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1414 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1415 RETURNS TRIGGER
1416 LANGUAGE 'plpgsql' VOLATILE AS $$
1417 DECLARE
1418 "initiative_row" "initiative"%ROWTYPE;
1419 "issue_row" "issue"%ROWTYPE;
1420 BEGIN
1421 SELECT * INTO "initiative_row" FROM "initiative"
1422 WHERE "id" = NEW."initiative_id";
1423 SELECT * INTO "issue_row" FROM "issue"
1424 WHERE "id" = "initiative_row"."issue_id";
1425 INSERT INTO "event" (
1426 "event", "member_id",
1427 "issue_id", "state", "initiative_id", "suggestion_id"
1428 ) VALUES (
1429 'suggestion_created',
1430 NEW."author_id",
1431 "initiative_row"."issue_id",
1432 "issue_row"."state",
1433 "initiative_row"."id",
1434 NEW."id" );
1435 RETURN NULL;
1436 END;
1437 $$;
1439 CREATE TRIGGER "write_event_suggestion_created"
1440 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1441 "write_event_suggestion_created_trigger"();
1443 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1444 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1448 ----------------------------
1449 -- Additional constraints --
1450 ----------------------------
1453 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1454 RETURNS TRIGGER
1455 LANGUAGE 'plpgsql' VOLATILE AS $$
1456 BEGIN
1457 IF NOT EXISTS (
1458 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1459 ) THEN
1460 --RAISE 'Cannot create issue without an initial initiative.' USING
1461 -- ERRCODE = 'integrity_constraint_violation',
1462 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1463 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1464 END IF;
1465 RETURN NULL;
1466 END;
1467 $$;
1469 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1470 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1471 FOR EACH ROW EXECUTE PROCEDURE
1472 "issue_requires_first_initiative_trigger"();
1474 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1475 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1478 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1479 RETURNS TRIGGER
1480 LANGUAGE 'plpgsql' VOLATILE AS $$
1481 DECLARE
1482 "reference_lost" BOOLEAN;
1483 BEGIN
1484 IF TG_OP = 'DELETE' THEN
1485 "reference_lost" := TRUE;
1486 ELSE
1487 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1488 END IF;
1489 IF
1490 "reference_lost" AND NOT EXISTS (
1491 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1493 THEN
1494 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1495 END IF;
1496 RETURN NULL;
1497 END;
1498 $$;
1500 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1501 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1502 FOR EACH ROW EXECUTE PROCEDURE
1503 "last_initiative_deletes_issue_trigger"();
1505 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1506 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1509 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1510 RETURNS TRIGGER
1511 LANGUAGE 'plpgsql' VOLATILE AS $$
1512 BEGIN
1513 IF NOT EXISTS (
1514 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1515 ) THEN
1516 --RAISE 'Cannot create initiative without an initial draft.' USING
1517 -- ERRCODE = 'integrity_constraint_violation',
1518 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1519 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1520 END IF;
1521 RETURN NULL;
1522 END;
1523 $$;
1525 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1526 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1527 FOR EACH ROW EXECUTE PROCEDURE
1528 "initiative_requires_first_draft_trigger"();
1530 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1531 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1534 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1535 RETURNS TRIGGER
1536 LANGUAGE 'plpgsql' VOLATILE AS $$
1537 DECLARE
1538 "reference_lost" BOOLEAN;
1539 BEGIN
1540 IF TG_OP = 'DELETE' THEN
1541 "reference_lost" := TRUE;
1542 ELSE
1543 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1544 END IF;
1545 IF
1546 "reference_lost" AND NOT EXISTS (
1547 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1549 THEN
1550 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1551 END IF;
1552 RETURN NULL;
1553 END;
1554 $$;
1556 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1557 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1558 FOR EACH ROW EXECUTE PROCEDURE
1559 "last_draft_deletes_initiative_trigger"();
1561 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1562 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1565 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1566 RETURNS TRIGGER
1567 LANGUAGE 'plpgsql' VOLATILE AS $$
1568 BEGIN
1569 IF NOT EXISTS (
1570 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1571 ) THEN
1572 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1573 END IF;
1574 RETURN NULL;
1575 END;
1576 $$;
1578 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1579 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1580 FOR EACH ROW EXECUTE PROCEDURE
1581 "suggestion_requires_first_opinion_trigger"();
1583 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1584 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1587 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1588 RETURNS TRIGGER
1589 LANGUAGE 'plpgsql' VOLATILE AS $$
1590 DECLARE
1591 "reference_lost" BOOLEAN;
1592 BEGIN
1593 IF TG_OP = 'DELETE' THEN
1594 "reference_lost" := TRUE;
1595 ELSE
1596 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1597 END IF;
1598 IF
1599 "reference_lost" AND NOT EXISTS (
1600 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1602 THEN
1603 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1604 END IF;
1605 RETURN NULL;
1606 END;
1607 $$;
1609 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1610 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1611 FOR EACH ROW EXECUTE PROCEDURE
1612 "last_opinion_deletes_suggestion_trigger"();
1614 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1615 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1618 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
1619 RETURNS TRIGGER
1620 LANGUAGE 'plpgsql' VOLATILE AS $$
1621 BEGIN
1622 DELETE FROM "direct_voter"
1623 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1624 RETURN NULL;
1625 END;
1626 $$;
1628 CREATE TRIGGER "non_voter_deletes_direct_voter"
1629 AFTER INSERT OR UPDATE ON "non_voter"
1630 FOR EACH ROW EXECUTE PROCEDURE
1631 "non_voter_deletes_direct_voter_trigger"();
1633 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
1634 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
1637 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
1638 RETURNS TRIGGER
1639 LANGUAGE 'plpgsql' VOLATILE AS $$
1640 BEGIN
1641 DELETE FROM "non_voter"
1642 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
1643 RETURN NULL;
1644 END;
1645 $$;
1647 CREATE TRIGGER "direct_voter_deletes_non_voter"
1648 AFTER INSERT OR UPDATE ON "direct_voter"
1649 FOR EACH ROW EXECUTE PROCEDURE
1650 "direct_voter_deletes_non_voter_trigger"();
1652 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
1653 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
1656 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
1657 RETURNS TRIGGER
1658 LANGUAGE 'plpgsql' VOLATILE AS $$
1659 BEGIN
1660 IF NEW."comment" ISNULL THEN
1661 NEW."comment_changed" := NULL;
1662 NEW."formatting_engine" := NULL;
1663 END IF;
1664 RETURN NEW;
1665 END;
1666 $$;
1668 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
1669 BEFORE INSERT OR UPDATE ON "direct_voter"
1670 FOR EACH ROW EXECUTE PROCEDURE
1671 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
1673 COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"';
1674 COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.';
1677 ---------------------------------------------------------------
1678 -- Ensure that votes are not modified when issues are closed --
1679 ---------------------------------------------------------------
1681 -- NOTE: Frontends should ensure this anyway, but in case of programming
1682 -- errors the following triggers ensure data integrity.
1685 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1686 RETURNS TRIGGER
1687 LANGUAGE 'plpgsql' VOLATILE AS $$
1688 DECLARE
1689 "issue_id_v" "issue"."id"%TYPE;
1690 "issue_row" "issue"%ROWTYPE;
1691 BEGIN
1692 IF EXISTS (
1693 SELECT NULL FROM "temporary_transaction_data"
1694 WHERE "txid" = txid_current()
1695 AND "key" = 'override_protection_triggers'
1696 AND "value" = TRUE::TEXT
1697 ) THEN
1698 RETURN NULL;
1699 END IF;
1700 IF TG_OP = 'DELETE' THEN
1701 "issue_id_v" := OLD."issue_id";
1702 ELSE
1703 "issue_id_v" := NEW."issue_id";
1704 END IF;
1705 SELECT INTO "issue_row" * FROM "issue"
1706 WHERE "id" = "issue_id_v" FOR SHARE;
1707 IF (
1708 "issue_row"."closed" NOTNULL OR (
1709 "issue_row"."state" = 'voting' AND
1710 "issue_row"."phase_finished" NOTNULL
1712 ) THEN
1713 IF
1714 TG_RELID = 'direct_voter'::regclass AND
1715 TG_OP = 'UPDATE'
1716 THEN
1717 IF
1718 OLD."issue_id" = NEW."issue_id" AND
1719 OLD."member_id" = NEW."member_id" AND
1720 OLD."weight" = NEW."weight"
1721 THEN
1722 RETURN NULL; -- allows changing of voter comment
1723 END IF;
1724 END IF;
1725 RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
1726 END IF;
1727 RETURN NULL;
1728 END;
1729 $$;
1731 CREATE TRIGGER "forbid_changes_on_closed_issue"
1732 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1733 FOR EACH ROW EXECUTE PROCEDURE
1734 "forbid_changes_on_closed_issue_trigger"();
1736 CREATE TRIGGER "forbid_changes_on_closed_issue"
1737 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1738 FOR EACH ROW EXECUTE PROCEDURE
1739 "forbid_changes_on_closed_issue_trigger"();
1741 CREATE TRIGGER "forbid_changes_on_closed_issue"
1742 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1743 FOR EACH ROW EXECUTE PROCEDURE
1744 "forbid_changes_on_closed_issue_trigger"();
1746 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"';
1747 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';
1748 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';
1749 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';
1753 --------------------------------------------------------------------
1754 -- Auto-retrieval of fields only needed for referential integrity --
1755 --------------------------------------------------------------------
1758 CREATE FUNCTION "autofill_issue_id_trigger"()
1759 RETURNS TRIGGER
1760 LANGUAGE 'plpgsql' VOLATILE AS $$
1761 BEGIN
1762 IF NEW."issue_id" ISNULL THEN
1763 SELECT "issue_id" INTO NEW."issue_id"
1764 FROM "initiative" WHERE "id" = NEW."initiative_id";
1765 END IF;
1766 RETURN NEW;
1767 END;
1768 $$;
1770 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1771 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1773 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1774 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1776 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1777 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1778 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1781 CREATE FUNCTION "autofill_initiative_id_trigger"()
1782 RETURNS TRIGGER
1783 LANGUAGE 'plpgsql' VOLATILE AS $$
1784 BEGIN
1785 IF NEW."initiative_id" ISNULL THEN
1786 SELECT "initiative_id" INTO NEW."initiative_id"
1787 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1788 END IF;
1789 RETURN NEW;
1790 END;
1791 $$;
1793 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1794 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1796 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1797 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1801 -----------------------------------------------------
1802 -- Automatic calculation of certain default values --
1803 -----------------------------------------------------
1806 CREATE FUNCTION "copy_timings_trigger"()
1807 RETURNS TRIGGER
1808 LANGUAGE 'plpgsql' VOLATILE AS $$
1809 DECLARE
1810 "policy_row" "policy"%ROWTYPE;
1811 BEGIN
1812 SELECT * INTO "policy_row" FROM "policy"
1813 WHERE "id" = NEW."policy_id";
1814 IF NEW."min_admission_time" ISNULL THEN
1815 NEW."min_admission_time" := "policy_row"."min_admission_time";
1816 END IF;
1817 IF NEW."max_admission_time" ISNULL THEN
1818 NEW."max_admission_time" := "policy_row"."max_admission_time";
1819 END IF;
1820 IF NEW."discussion_time" ISNULL THEN
1821 NEW."discussion_time" := "policy_row"."discussion_time";
1822 END IF;
1823 IF NEW."verification_time" ISNULL THEN
1824 NEW."verification_time" := "policy_row"."verification_time";
1825 END IF;
1826 IF NEW."voting_time" ISNULL THEN
1827 NEW."voting_time" := "policy_row"."voting_time";
1828 END IF;
1829 RETURN NEW;
1830 END;
1831 $$;
1833 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1834 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1836 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1837 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1840 CREATE FUNCTION "default_for_draft_id_trigger"()
1841 RETURNS TRIGGER
1842 LANGUAGE 'plpgsql' VOLATILE AS $$
1843 BEGIN
1844 IF NEW."draft_id" ISNULL THEN
1845 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1846 WHERE "initiative_id" = NEW."initiative_id";
1847 END IF;
1848 RETURN NEW;
1849 END;
1850 $$;
1852 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1853 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1854 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1855 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1857 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1858 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';
1859 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';
1863 ----------------------------------------
1864 -- Automatic creation of dependencies --
1865 ----------------------------------------
1868 CREATE FUNCTION "autocreate_interest_trigger"()
1869 RETURNS TRIGGER
1870 LANGUAGE 'plpgsql' VOLATILE AS $$
1871 BEGIN
1872 IF NOT EXISTS (
1873 SELECT NULL FROM "initiative" JOIN "interest"
1874 ON "initiative"."issue_id" = "interest"."issue_id"
1875 WHERE "initiative"."id" = NEW."initiative_id"
1876 AND "interest"."member_id" = NEW."member_id"
1877 ) THEN
1878 BEGIN
1879 INSERT INTO "interest" ("issue_id", "member_id")
1880 SELECT "issue_id", NEW."member_id"
1881 FROM "initiative" WHERE "id" = NEW."initiative_id";
1882 EXCEPTION WHEN unique_violation THEN END;
1883 END IF;
1884 RETURN NEW;
1885 END;
1886 $$;
1888 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1889 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1891 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1892 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';
1895 CREATE FUNCTION "autocreate_supporter_trigger"()
1896 RETURNS TRIGGER
1897 LANGUAGE 'plpgsql' VOLATILE AS $$
1898 BEGIN
1899 IF NOT EXISTS (
1900 SELECT NULL FROM "suggestion" JOIN "supporter"
1901 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1902 WHERE "suggestion"."id" = NEW."suggestion_id"
1903 AND "supporter"."member_id" = NEW."member_id"
1904 ) THEN
1905 BEGIN
1906 INSERT INTO "supporter" ("initiative_id", "member_id")
1907 SELECT "initiative_id", NEW."member_id"
1908 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1909 EXCEPTION WHEN unique_violation THEN END;
1910 END IF;
1911 RETURN NEW;
1912 END;
1913 $$;
1915 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1916 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1918 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1919 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.';
1923 ------------------------------------------
1924 -- Views and helper functions for views --
1925 ------------------------------------------
1928 CREATE VIEW "unit_delegation" AS
1929 SELECT
1930 "unit"."id" AS "unit_id",
1931 "delegation"."id",
1932 "delegation"."truster_id",
1933 "delegation"."trustee_id",
1934 "delegation"."scope"
1935 FROM "unit"
1936 JOIN "delegation"
1937 ON "delegation"."unit_id" = "unit"."id"
1938 JOIN "member"
1939 ON "delegation"."truster_id" = "member"."id"
1940 JOIN "privilege"
1941 ON "delegation"."unit_id" = "privilege"."unit_id"
1942 AND "delegation"."truster_id" = "privilege"."member_id"
1943 WHERE "member"."active" AND "privilege"."voting_right";
1945 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1948 CREATE VIEW "area_delegation" AS
1949 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1950 "area"."id" AS "area_id",
1951 "delegation"."id",
1952 "delegation"."truster_id",
1953 "delegation"."trustee_id",
1954 "delegation"."scope"
1955 FROM "area"
1956 JOIN "delegation"
1957 ON "delegation"."unit_id" = "area"."unit_id"
1958 OR "delegation"."area_id" = "area"."id"
1959 JOIN "member"
1960 ON "delegation"."truster_id" = "member"."id"
1961 JOIN "privilege"
1962 ON "area"."unit_id" = "privilege"."unit_id"
1963 AND "delegation"."truster_id" = "privilege"."member_id"
1964 WHERE "member"."active" AND "privilege"."voting_right"
1965 ORDER BY
1966 "area"."id",
1967 "delegation"."truster_id",
1968 "delegation"."scope" DESC;
1970 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1973 CREATE VIEW "issue_delegation" AS
1974 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1975 "issue"."id" AS "issue_id",
1976 "delegation"."id",
1977 "delegation"."truster_id",
1978 "delegation"."trustee_id",
1979 "delegation"."scope"
1980 FROM "issue"
1981 JOIN "area"
1982 ON "area"."id" = "issue"."area_id"
1983 JOIN "delegation"
1984 ON "delegation"."unit_id" = "area"."unit_id"
1985 OR "delegation"."area_id" = "area"."id"
1986 OR "delegation"."issue_id" = "issue"."id"
1987 JOIN "member"
1988 ON "delegation"."truster_id" = "member"."id"
1989 JOIN "privilege"
1990 ON "area"."unit_id" = "privilege"."unit_id"
1991 AND "delegation"."truster_id" = "privilege"."member_id"
1992 WHERE "member"."active" AND "privilege"."voting_right"
1993 ORDER BY
1994 "issue"."id",
1995 "delegation"."truster_id",
1996 "delegation"."scope" DESC;
1998 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
2001 CREATE FUNCTION "membership_weight_with_skipping"
2002 ( "area_id_p" "area"."id"%TYPE,
2003 "member_id_p" "member"."id"%TYPE,
2004 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
2005 RETURNS INT4
2006 LANGUAGE 'plpgsql' STABLE AS $$
2007 DECLARE
2008 "sum_v" INT4;
2009 "delegation_row" "area_delegation"%ROWTYPE;
2010 BEGIN
2011 "sum_v" := 1;
2012 FOR "delegation_row" IN
2013 SELECT "area_delegation".*
2014 FROM "area_delegation" LEFT JOIN "membership"
2015 ON "membership"."area_id" = "area_id_p"
2016 AND "membership"."member_id" = "area_delegation"."truster_id"
2017 WHERE "area_delegation"."area_id" = "area_id_p"
2018 AND "area_delegation"."trustee_id" = "member_id_p"
2019 AND "membership"."member_id" ISNULL
2020 LOOP
2021 IF NOT
2022 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
2023 THEN
2024 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
2025 "area_id_p",
2026 "delegation_row"."truster_id",
2027 "skip_member_ids_p" || "delegation_row"."truster_id"
2028 );
2029 END IF;
2030 END LOOP;
2031 RETURN "sum_v";
2032 END;
2033 $$;
2035 COMMENT ON FUNCTION "membership_weight_with_skipping"
2036 ( "area"."id"%TYPE,
2037 "member"."id"%TYPE,
2038 INT4[] )
2039 IS 'Helper function for "membership_weight" function';
2042 CREATE FUNCTION "membership_weight"
2043 ( "area_id_p" "area"."id"%TYPE,
2044 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
2045 RETURNS INT4
2046 LANGUAGE 'plpgsql' STABLE AS $$
2047 BEGIN
2048 RETURN "membership_weight_with_skipping"(
2049 "area_id_p",
2050 "member_id_p",
2051 ARRAY["member_id_p"]
2052 );
2053 END;
2054 $$;
2056 COMMENT ON FUNCTION "membership_weight"
2057 ( "area"."id"%TYPE,
2058 "member"."id"%TYPE )
2059 IS 'Calculates the potential voting weight of a member in a given area';
2062 CREATE VIEW "member_count_view" AS
2063 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
2065 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
2068 CREATE VIEW "unit_member_count" AS
2069 SELECT
2070 "unit"."id" AS "unit_id",
2071 count("member"."id") AS "member_count"
2072 FROM "unit"
2073 LEFT JOIN "privilege"
2074 ON "privilege"."unit_id" = "unit"."id"
2075 AND "privilege"."voting_right"
2076 LEFT JOIN "member"
2077 ON "member"."id" = "privilege"."member_id"
2078 AND "member"."active"
2079 GROUP BY "unit"."id";
2081 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
2084 CREATE VIEW "area_member_count" AS
2085 SELECT
2086 "area"."id" AS "area_id",
2087 count("member"."id") AS "direct_member_count",
2088 coalesce(
2089 sum(
2090 CASE WHEN "member"."id" NOTNULL THEN
2091 "membership_weight"("area"."id", "member"."id")
2092 ELSE 0 END
2094 ) AS "member_weight"
2095 FROM "area"
2096 LEFT JOIN "membership"
2097 ON "area"."id" = "membership"."area_id"
2098 LEFT JOIN "privilege"
2099 ON "privilege"."unit_id" = "area"."unit_id"
2100 AND "privilege"."member_id" = "membership"."member_id"
2101 AND "privilege"."voting_right"
2102 LEFT JOIN "member"
2103 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2104 AND "member"."active"
2105 GROUP BY "area"."id";
2107 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2110 CREATE VIEW "opening_draft" AS
2111 SELECT "draft".* FROM (
2112 SELECT
2113 "initiative"."id" AS "initiative_id",
2114 min("draft"."id") AS "draft_id"
2115 FROM "initiative" JOIN "draft"
2116 ON "initiative"."id" = "draft"."initiative_id"
2117 GROUP BY "initiative"."id"
2118 ) AS "subquery"
2119 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2121 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2124 CREATE VIEW "current_draft" AS
2125 SELECT "draft".* FROM (
2126 SELECT
2127 "initiative"."id" AS "initiative_id",
2128 max("draft"."id") AS "draft_id"
2129 FROM "initiative" JOIN "draft"
2130 ON "initiative"."id" = "draft"."initiative_id"
2131 GROUP BY "initiative"."id"
2132 ) AS "subquery"
2133 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2135 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2138 CREATE VIEW "critical_opinion" AS
2139 SELECT * FROM "opinion"
2140 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2141 OR ("degree" = -2 AND "fulfilled" = TRUE);
2143 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2146 CREATE VIEW "issue_supporter_in_admission_state" AS
2147 SELECT DISTINCT
2148 "area"."unit_id",
2149 "issue"."area_id",
2150 "issue"."id" AS "issue_id",
2151 "supporter"."member_id",
2152 "direct_interest_snapshot"."weight"
2153 FROM "issue"
2154 JOIN "area" ON "area"."id" = "issue"."area_id"
2155 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
2156 JOIN "direct_interest_snapshot"
2157 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2158 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2159 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
2160 WHERE "issue"."state" = 'admission'::"issue_state";
2162 COMMENT ON VIEW "issue_supporter_in_admission_state" IS 'Helper view for "lf_update_issue_order" to allow a (proportional) ordering of issues within an area';
2165 CREATE VIEW "initiative_suggestion_order_calculation" AS
2166 SELECT
2167 "initiative"."id" AS "initiative_id",
2168 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
2169 FROM "initiative" JOIN "issue"
2170 ON "initiative"."issue_id" = "issue"."id"
2171 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
2172 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
2174 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
2176 COMMENT ON COLUMN "initiative_suggestion_order_calculation"."final" IS 'Set to TRUE, if the issue is fully frozen or closed, and the calculation has to be done only once for one last time';
2179 CREATE VIEW "individual_suggestion_ranking" AS
2180 SELECT
2181 "opinion"."initiative_id",
2182 "opinion"."member_id",
2183 "direct_interest_snapshot"."weight",
2184 CASE WHEN
2185 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
2186 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
2187 THEN 1 ELSE
2188 CASE WHEN
2189 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
2190 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
2191 THEN 2 ELSE
2192 CASE WHEN
2193 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
2194 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
2195 THEN 3 ELSE 4 END
2196 END
2197 END AS "preference",
2198 "opinion"."suggestion_id"
2199 FROM "opinion"
2200 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
2201 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
2202 JOIN "direct_interest_snapshot"
2203 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
2204 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
2205 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
2207 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
2210 CREATE VIEW "battle_participant" AS
2211 SELECT "initiative"."id", "initiative"."issue_id"
2212 FROM "issue" JOIN "initiative"
2213 ON "issue"."id" = "initiative"."issue_id"
2214 WHERE "initiative"."admitted"
2215 UNION ALL
2216 SELECT NULL, "id" AS "issue_id"
2217 FROM "issue";
2219 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2222 CREATE VIEW "battle_view" AS
2223 SELECT
2224 "issue"."id" AS "issue_id",
2225 "winning_initiative"."id" AS "winning_initiative_id",
2226 "losing_initiative"."id" AS "losing_initiative_id",
2227 sum(
2228 CASE WHEN
2229 coalesce("better_vote"."grade", 0) >
2230 coalesce("worse_vote"."grade", 0)
2231 THEN "direct_voter"."weight" ELSE 0 END
2232 ) AS "count"
2233 FROM "issue"
2234 LEFT JOIN "direct_voter"
2235 ON "issue"."id" = "direct_voter"."issue_id"
2236 JOIN "battle_participant" AS "winning_initiative"
2237 ON "issue"."id" = "winning_initiative"."issue_id"
2238 JOIN "battle_participant" AS "losing_initiative"
2239 ON "issue"."id" = "losing_initiative"."issue_id"
2240 LEFT JOIN "vote" AS "better_vote"
2241 ON "direct_voter"."member_id" = "better_vote"."member_id"
2242 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2243 LEFT JOIN "vote" AS "worse_vote"
2244 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2245 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2246 WHERE "issue"."state" = 'voting'
2247 AND "issue"."phase_finished" NOTNULL
2248 AND (
2249 "winning_initiative"."id" != "losing_initiative"."id" OR
2250 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2251 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2252 GROUP BY
2253 "issue"."id",
2254 "winning_initiative"."id",
2255 "losing_initiative"."id";
2257 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';
2260 CREATE VIEW "expired_session" AS
2261 SELECT * FROM "session" WHERE now() > "expiry";
2263 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2264 DELETE FROM "session" WHERE "ident" = OLD."ident";
2266 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2267 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2270 CREATE VIEW "open_issue" AS
2271 SELECT * FROM "issue" WHERE "closed" ISNULL;
2273 COMMENT ON VIEW "open_issue" IS 'All open issues';
2276 CREATE VIEW "member_contingent" AS
2277 SELECT
2278 "member"."id" AS "member_id",
2279 "contingent"."polling",
2280 "contingent"."time_frame",
2281 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2283 SELECT count(1) FROM "draft"
2284 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2285 WHERE "draft"."author_id" = "member"."id"
2286 AND "initiative"."polling" = "contingent"."polling"
2287 AND "draft"."created" > now() - "contingent"."time_frame"
2288 ) + (
2289 SELECT count(1) FROM "suggestion"
2290 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
2291 WHERE "suggestion"."author_id" = "member"."id"
2292 AND "contingent"."polling" = FALSE
2293 AND "suggestion"."created" > now() - "contingent"."time_frame"
2295 ELSE NULL END AS "text_entry_count",
2296 "contingent"."text_entry_limit",
2297 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2298 SELECT count(1) FROM "opening_draft" AS "draft"
2299 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
2300 WHERE "draft"."author_id" = "member"."id"
2301 AND "initiative"."polling" = "contingent"."polling"
2302 AND "draft"."created" > now() - "contingent"."time_frame"
2303 ) ELSE NULL END AS "initiative_count",
2304 "contingent"."initiative_limit"
2305 FROM "member" CROSS JOIN "contingent";
2307 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2309 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2310 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2313 CREATE VIEW "member_contingent_left" AS
2314 SELECT
2315 "member_id",
2316 "polling",
2317 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2318 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2319 FROM "member_contingent" GROUP BY "member_id", "polling";
2321 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.';
2324 CREATE VIEW "event_seen_by_member" AS
2325 SELECT
2326 "member"."id" AS "seen_by_member_id",
2327 CASE WHEN "event"."state" IN (
2328 'voting',
2329 'finished_without_winner',
2330 'finished_with_winner'
2331 ) THEN
2332 'voting'::"notify_level"
2333 ELSE
2334 CASE WHEN "event"."state" IN (
2335 'verification',
2336 'canceled_after_revocation_during_verification',
2337 'canceled_no_initiative_admitted'
2338 ) THEN
2339 'verification'::"notify_level"
2340 ELSE
2341 CASE WHEN "event"."state" IN (
2342 'discussion',
2343 'canceled_after_revocation_during_discussion'
2344 ) THEN
2345 'discussion'::"notify_level"
2346 ELSE
2347 'all'::"notify_level"
2348 END
2349 END
2350 END AS "notify_level",
2351 "event".*
2352 FROM "member" CROSS JOIN "event"
2353 LEFT JOIN "issue"
2354 ON "event"."issue_id" = "issue"."id"
2355 LEFT JOIN "membership"
2356 ON "member"."id" = "membership"."member_id"
2357 AND "issue"."area_id" = "membership"."area_id"
2358 LEFT JOIN "interest"
2359 ON "member"."id" = "interest"."member_id"
2360 AND "event"."issue_id" = "interest"."issue_id"
2361 LEFT JOIN "ignored_member"
2362 ON "member"."id" = "ignored_member"."member_id"
2363 AND "event"."member_id" = "ignored_member"."other_member_id"
2364 LEFT JOIN "ignored_initiative"
2365 ON "member"."id" = "ignored_initiative"."member_id"
2366 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2367 WHERE (
2368 "interest"."member_id" NOTNULL OR
2369 ( "membership"."member_id" NOTNULL AND
2370 "event"."event" IN (
2371 'issue_state_changed',
2372 'initiative_created_in_new_issue',
2373 'initiative_created_in_existing_issue',
2374 'initiative_revoked' ) ) )
2375 AND "ignored_member"."member_id" ISNULL
2376 AND "ignored_initiative"."member_id" ISNULL;
2378 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"';
2381 CREATE VIEW "selected_event_seen_by_member" AS
2382 SELECT
2383 "member"."id" AS "seen_by_member_id",
2384 CASE WHEN "event"."state" IN (
2385 'voting',
2386 'finished_without_winner',
2387 'finished_with_winner'
2388 ) THEN
2389 'voting'::"notify_level"
2390 ELSE
2391 CASE WHEN "event"."state" IN (
2392 'verification',
2393 'canceled_after_revocation_during_verification',
2394 'canceled_no_initiative_admitted'
2395 ) THEN
2396 'verification'::"notify_level"
2397 ELSE
2398 CASE WHEN "event"."state" IN (
2399 'discussion',
2400 'canceled_after_revocation_during_discussion'
2401 ) THEN
2402 'discussion'::"notify_level"
2403 ELSE
2404 'all'::"notify_level"
2405 END
2406 END
2407 END AS "notify_level",
2408 "event".*
2409 FROM "member" CROSS JOIN "event"
2410 LEFT JOIN "issue"
2411 ON "event"."issue_id" = "issue"."id"
2412 LEFT JOIN "membership"
2413 ON "member"."id" = "membership"."member_id"
2414 AND "issue"."area_id" = "membership"."area_id"
2415 LEFT JOIN "interest"
2416 ON "member"."id" = "interest"."member_id"
2417 AND "event"."issue_id" = "interest"."issue_id"
2418 LEFT JOIN "ignored_member"
2419 ON "member"."id" = "ignored_member"."member_id"
2420 AND "event"."member_id" = "ignored_member"."other_member_id"
2421 LEFT JOIN "ignored_initiative"
2422 ON "member"."id" = "ignored_initiative"."member_id"
2423 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2424 WHERE (
2425 ( "member"."notify_level" >= 'all' ) OR
2426 ( "member"."notify_level" >= 'voting' AND
2427 "event"."state" IN (
2428 'voting',
2429 'finished_without_winner',
2430 'finished_with_winner' ) ) OR
2431 ( "member"."notify_level" >= 'verification' AND
2432 "event"."state" IN (
2433 'verification',
2434 'canceled_after_revocation_during_verification',
2435 'canceled_no_initiative_admitted' ) ) OR
2436 ( "member"."notify_level" >= 'discussion' AND
2437 "event"."state" IN (
2438 'discussion',
2439 'canceled_after_revocation_during_discussion' ) ) )
2440 AND (
2441 "interest"."member_id" NOTNULL OR
2442 ( "membership"."member_id" NOTNULL AND
2443 "event"."event" IN (
2444 'issue_state_changed',
2445 'initiative_created_in_new_issue',
2446 'initiative_created_in_existing_issue',
2447 'initiative_revoked' ) ) )
2448 AND "ignored_member"."member_id" ISNULL
2449 AND "ignored_initiative"."member_id" ISNULL;
2451 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"';
2455 ------------------------------------------------------
2456 -- Row set returning function for delegation chains --
2457 ------------------------------------------------------
2460 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2461 ('first', 'intermediate', 'last', 'repetition');
2463 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2466 CREATE TYPE "delegation_chain_row" AS (
2467 "index" INT4,
2468 "member_id" INT4,
2469 "member_valid" BOOLEAN,
2470 "participation" BOOLEAN,
2471 "overridden" BOOLEAN,
2472 "scope_in" "delegation_scope",
2473 "scope_out" "delegation_scope",
2474 "disabled_out" BOOLEAN,
2475 "loop" "delegation_chain_loop_tag" );
2477 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2479 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2480 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';
2481 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2482 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2483 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2484 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2485 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2488 CREATE FUNCTION "delegation_chain_for_closed_issue"
2489 ( "member_id_p" "member"."id"%TYPE,
2490 "issue_id_p" "issue"."id"%TYPE )
2491 RETURNS SETOF "delegation_chain_row"
2492 LANGUAGE 'plpgsql' STABLE AS $$
2493 DECLARE
2494 "output_row" "delegation_chain_row";
2495 "direct_voter_row" "direct_voter"%ROWTYPE;
2496 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2497 BEGIN
2498 "output_row"."index" := 0;
2499 "output_row"."member_id" := "member_id_p";
2500 "output_row"."member_valid" := TRUE;
2501 "output_row"."participation" := FALSE;
2502 "output_row"."overridden" := FALSE;
2503 "output_row"."disabled_out" := FALSE;
2504 LOOP
2505 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2506 WHERE "issue_id" = "issue_id_p"
2507 AND "member_id" = "output_row"."member_id";
2508 IF "direct_voter_row"."member_id" NOTNULL THEN
2509 "output_row"."participation" := TRUE;
2510 "output_row"."scope_out" := NULL;
2511 "output_row"."disabled_out" := NULL;
2512 RETURN NEXT "output_row";
2513 RETURN;
2514 END IF;
2515 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2516 WHERE "issue_id" = "issue_id_p"
2517 AND "member_id" = "output_row"."member_id";
2518 IF "delegating_voter_row"."member_id" ISNULL THEN
2519 RETURN;
2520 END IF;
2521 "output_row"."scope_out" := "delegating_voter_row"."scope";
2522 RETURN NEXT "output_row";
2523 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2524 "output_row"."scope_in" := "output_row"."scope_out";
2525 END LOOP;
2526 END;
2527 $$;
2529 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2530 ( "member"."id"%TYPE,
2531 "member"."id"%TYPE )
2532 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2535 CREATE FUNCTION "delegation_chain"
2536 ( "member_id_p" "member"."id"%TYPE,
2537 "unit_id_p" "unit"."id"%TYPE,
2538 "area_id_p" "area"."id"%TYPE,
2539 "issue_id_p" "issue"."id"%TYPE,
2540 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2541 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2542 RETURNS SETOF "delegation_chain_row"
2543 LANGUAGE 'plpgsql' STABLE AS $$
2544 DECLARE
2545 "scope_v" "delegation_scope";
2546 "unit_id_v" "unit"."id"%TYPE;
2547 "area_id_v" "area"."id"%TYPE;
2548 "issue_row" "issue"%ROWTYPE;
2549 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2550 "loop_member_id_v" "member"."id"%TYPE;
2551 "output_row" "delegation_chain_row";
2552 "output_rows" "delegation_chain_row"[];
2553 "simulate_v" BOOLEAN;
2554 "simulate_here_v" BOOLEAN;
2555 "delegation_row" "delegation"%ROWTYPE;
2556 "row_count" INT4;
2557 "i" INT4;
2558 "loop_v" BOOLEAN;
2559 BEGIN
2560 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2561 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2562 END IF;
2563 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2564 "simulate_v" := TRUE;
2565 ELSE
2566 "simulate_v" := FALSE;
2567 END IF;
2568 IF
2569 "unit_id_p" NOTNULL AND
2570 "area_id_p" ISNULL AND
2571 "issue_id_p" ISNULL
2572 THEN
2573 "scope_v" := 'unit';
2574 "unit_id_v" := "unit_id_p";
2575 ELSIF
2576 "unit_id_p" ISNULL AND
2577 "area_id_p" NOTNULL AND
2578 "issue_id_p" ISNULL
2579 THEN
2580 "scope_v" := 'area';
2581 "area_id_v" := "area_id_p";
2582 SELECT "unit_id" INTO "unit_id_v"
2583 FROM "area" WHERE "id" = "area_id_v";
2584 ELSIF
2585 "unit_id_p" ISNULL AND
2586 "area_id_p" ISNULL AND
2587 "issue_id_p" NOTNULL
2588 THEN
2589 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2590 IF "issue_row"."id" ISNULL THEN
2591 RETURN;
2592 END IF;
2593 IF "issue_row"."closed" NOTNULL THEN
2594 IF "simulate_v" THEN
2595 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2596 END IF;
2597 FOR "output_row" IN
2598 SELECT * FROM
2599 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2600 LOOP
2601 RETURN NEXT "output_row";
2602 END LOOP;
2603 RETURN;
2604 END IF;
2605 "scope_v" := 'issue';
2606 SELECT "area_id" INTO "area_id_v"
2607 FROM "issue" WHERE "id" = "issue_id_p";
2608 SELECT "unit_id" INTO "unit_id_v"
2609 FROM "area" WHERE "id" = "area_id_v";
2610 ELSE
2611 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2612 END IF;
2613 "visited_member_ids" := '{}';
2614 "loop_member_id_v" := NULL;
2615 "output_rows" := '{}';
2616 "output_row"."index" := 0;
2617 "output_row"."member_id" := "member_id_p";
2618 "output_row"."member_valid" := TRUE;
2619 "output_row"."participation" := FALSE;
2620 "output_row"."overridden" := FALSE;
2621 "output_row"."disabled_out" := FALSE;
2622 "output_row"."scope_out" := NULL;
2623 LOOP
2624 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2625 "loop_member_id_v" := "output_row"."member_id";
2626 ELSE
2627 "visited_member_ids" :=
2628 "visited_member_ids" || "output_row"."member_id";
2629 END IF;
2630 IF "output_row"."participation" ISNULL THEN
2631 "output_row"."overridden" := NULL;
2632 ELSIF "output_row"."participation" THEN
2633 "output_row"."overridden" := TRUE;
2634 END IF;
2635 "output_row"."scope_in" := "output_row"."scope_out";
2636 "output_row"."member_valid" := EXISTS (
2637 SELECT NULL FROM "member" JOIN "privilege"
2638 ON "privilege"."member_id" = "member"."id"
2639 AND "privilege"."unit_id" = "unit_id_v"
2640 WHERE "id" = "output_row"."member_id"
2641 AND "member"."active" AND "privilege"."voting_right"
2642 );
2643 "simulate_here_v" := (
2644 "simulate_v" AND
2645 "output_row"."member_id" = "member_id_p"
2646 );
2647 "delegation_row" := ROW(NULL);
2648 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2649 IF "scope_v" = 'unit' THEN
2650 IF NOT "simulate_here_v" THEN
2651 SELECT * INTO "delegation_row" FROM "delegation"
2652 WHERE "truster_id" = "output_row"."member_id"
2653 AND "unit_id" = "unit_id_v";
2654 END IF;
2655 ELSIF "scope_v" = 'area' THEN
2656 "output_row"."participation" := EXISTS (
2657 SELECT NULL FROM "membership"
2658 WHERE "area_id" = "area_id_p"
2659 AND "member_id" = "output_row"."member_id"
2660 );
2661 IF "simulate_here_v" THEN
2662 IF "simulate_trustee_id_p" ISNULL THEN
2663 SELECT * INTO "delegation_row" FROM "delegation"
2664 WHERE "truster_id" = "output_row"."member_id"
2665 AND "unit_id" = "unit_id_v";
2666 END IF;
2667 ELSE
2668 SELECT * INTO "delegation_row" FROM "delegation"
2669 WHERE "truster_id" = "output_row"."member_id"
2670 AND (
2671 "unit_id" = "unit_id_v" OR
2672 "area_id" = "area_id_v"
2674 ORDER BY "scope" DESC;
2675 END IF;
2676 ELSIF "scope_v" = 'issue' THEN
2677 IF "issue_row"."fully_frozen" ISNULL THEN
2678 "output_row"."participation" := EXISTS (
2679 SELECT NULL FROM "interest"
2680 WHERE "issue_id" = "issue_id_p"
2681 AND "member_id" = "output_row"."member_id"
2682 );
2683 ELSE
2684 IF "output_row"."member_id" = "member_id_p" THEN
2685 "output_row"."participation" := EXISTS (
2686 SELECT NULL FROM "direct_voter"
2687 WHERE "issue_id" = "issue_id_p"
2688 AND "member_id" = "output_row"."member_id"
2689 );
2690 ELSE
2691 "output_row"."participation" := NULL;
2692 END IF;
2693 END IF;
2694 IF "simulate_here_v" THEN
2695 IF "simulate_trustee_id_p" ISNULL THEN
2696 SELECT * INTO "delegation_row" FROM "delegation"
2697 WHERE "truster_id" = "output_row"."member_id"
2698 AND (
2699 "unit_id" = "unit_id_v" OR
2700 "area_id" = "area_id_v"
2702 ORDER BY "scope" DESC;
2703 END IF;
2704 ELSE
2705 SELECT * INTO "delegation_row" FROM "delegation"
2706 WHERE "truster_id" = "output_row"."member_id"
2707 AND (
2708 "unit_id" = "unit_id_v" OR
2709 "area_id" = "area_id_v" OR
2710 "issue_id" = "issue_id_p"
2712 ORDER BY "scope" DESC;
2713 END IF;
2714 END IF;
2715 ELSE
2716 "output_row"."participation" := FALSE;
2717 END IF;
2718 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2719 "output_row"."scope_out" := "scope_v";
2720 "output_rows" := "output_rows" || "output_row";
2721 "output_row"."member_id" := "simulate_trustee_id_p";
2722 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2723 "output_row"."scope_out" := "delegation_row"."scope";
2724 "output_rows" := "output_rows" || "output_row";
2725 "output_row"."member_id" := "delegation_row"."trustee_id";
2726 ELSIF "delegation_row"."scope" NOTNULL THEN
2727 "output_row"."scope_out" := "delegation_row"."scope";
2728 "output_row"."disabled_out" := TRUE;
2729 "output_rows" := "output_rows" || "output_row";
2730 EXIT;
2731 ELSE
2732 "output_row"."scope_out" := NULL;
2733 "output_rows" := "output_rows" || "output_row";
2734 EXIT;
2735 END IF;
2736 EXIT WHEN "loop_member_id_v" NOTNULL;
2737 "output_row"."index" := "output_row"."index" + 1;
2738 END LOOP;
2739 "row_count" := array_upper("output_rows", 1);
2740 "i" := 1;
2741 "loop_v" := FALSE;
2742 LOOP
2743 "output_row" := "output_rows"["i"];
2744 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2745 IF "loop_v" THEN
2746 IF "i" + 1 = "row_count" THEN
2747 "output_row"."loop" := 'last';
2748 ELSIF "i" = "row_count" THEN
2749 "output_row"."loop" := 'repetition';
2750 ELSE
2751 "output_row"."loop" := 'intermediate';
2752 END IF;
2753 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2754 "output_row"."loop" := 'first';
2755 "loop_v" := TRUE;
2756 END IF;
2757 IF "scope_v" = 'unit' THEN
2758 "output_row"."participation" := NULL;
2759 END IF;
2760 RETURN NEXT "output_row";
2761 "i" := "i" + 1;
2762 END LOOP;
2763 RETURN;
2764 END;
2765 $$;
2767 COMMENT ON FUNCTION "delegation_chain"
2768 ( "member"."id"%TYPE,
2769 "unit"."id"%TYPE,
2770 "area"."id"%TYPE,
2771 "issue"."id"%TYPE,
2772 "member"."id"%TYPE,
2773 BOOLEAN )
2774 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2778 ---------------------------------------------------------
2779 -- Single row returning function for delegation chains --
2780 ---------------------------------------------------------
2783 CREATE TYPE "delegation_info_loop_type" AS ENUM
2784 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2786 COMMENT ON TYPE "delegation_info_loop_type" IS 'Type of "delegation_loop" in "delegation_info_type"; ''own'' means loop to self, ''first'' means loop to first trustee, ''first_ellipsis'' means loop to ellipsis after first trustee, ''other'' means loop to other trustee, ''other_ellipsis'' means loop to ellipsis after other trustee''';
2789 CREATE TYPE "delegation_info_type" AS (
2790 "own_participation" BOOLEAN,
2791 "own_delegation_scope" "delegation_scope",
2792 "first_trustee_id" INT4,
2793 "first_trustee_participation" BOOLEAN,
2794 "first_trustee_ellipsis" BOOLEAN,
2795 "other_trustee_id" INT4,
2796 "other_trustee_participation" BOOLEAN,
2797 "other_trustee_ellipsis" BOOLEAN,
2798 "delegation_loop" "delegation_info_loop_type",
2799 "participating_member_id" INT4 );
2801 COMMENT ON TYPE "delegation_info_type" IS 'Type of result returned by "delegation_info" function; For meaning of "participation" check comment on "delegation_chain_row" type';
2803 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2804 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2805 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2806 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2807 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2808 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2809 COMMENT ON COLUMN "delegation_info_type"."other_trustee_participation" IS 'Another trustee is participating (redundant field: if "other_trustee_id" is set, then "other_trustee_participation" is always TRUE, else "other_trustee_participation" is NULL)';
2810 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2811 COMMENT ON COLUMN "delegation_info_type"."delegation_loop" IS 'Non-NULL value, if delegation chain contains a circle; See comment on "delegation_info_loop_type" for details';
2812 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2815 CREATE FUNCTION "delegation_info"
2816 ( "member_id_p" "member"."id"%TYPE,
2817 "unit_id_p" "unit"."id"%TYPE,
2818 "area_id_p" "area"."id"%TYPE,
2819 "issue_id_p" "issue"."id"%TYPE,
2820 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2821 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2822 RETURNS "delegation_info_type"
2823 LANGUAGE 'plpgsql' STABLE AS $$
2824 DECLARE
2825 "current_row" "delegation_chain_row";
2826 "result" "delegation_info_type";
2827 BEGIN
2828 "result"."own_participation" := FALSE;
2829 FOR "current_row" IN
2830 SELECT * FROM "delegation_chain"(
2831 "member_id_p",
2832 "unit_id_p", "area_id_p", "issue_id_p",
2833 "simulate_trustee_id_p", "simulate_default_p")
2834 LOOP
2835 IF
2836 "result"."participating_member_id" ISNULL AND
2837 "current_row"."participation"
2838 THEN
2839 "result"."participating_member_id" := "current_row"."member_id";
2840 END IF;
2841 IF "current_row"."member_id" = "member_id_p" THEN
2842 "result"."own_participation" := "current_row"."participation";
2843 "result"."own_delegation_scope" := "current_row"."scope_out";
2844 IF "current_row"."loop" = 'first' THEN
2845 "result"."delegation_loop" := 'own';
2846 END IF;
2847 ELSIF
2848 "current_row"."member_valid" AND
2849 ( "current_row"."loop" ISNULL OR
2850 "current_row"."loop" != 'repetition' )
2851 THEN
2852 IF "result"."first_trustee_id" ISNULL THEN
2853 "result"."first_trustee_id" := "current_row"."member_id";
2854 "result"."first_trustee_participation" := "current_row"."participation";
2855 "result"."first_trustee_ellipsis" := FALSE;
2856 IF "current_row"."loop" = 'first' THEN
2857 "result"."delegation_loop" := 'first';
2858 END IF;
2859 ELSIF "result"."other_trustee_id" ISNULL THEN
2860 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2861 "result"."other_trustee_id" := "current_row"."member_id";
2862 "result"."other_trustee_participation" := TRUE;
2863 "result"."other_trustee_ellipsis" := FALSE;
2864 IF "current_row"."loop" = 'first' THEN
2865 "result"."delegation_loop" := 'other';
2866 END IF;
2867 ELSE
2868 "result"."first_trustee_ellipsis" := TRUE;
2869 IF "current_row"."loop" = 'first' THEN
2870 "result"."delegation_loop" := 'first_ellipsis';
2871 END IF;
2872 END IF;
2873 ELSE
2874 "result"."other_trustee_ellipsis" := TRUE;
2875 IF "current_row"."loop" = 'first' THEN
2876 "result"."delegation_loop" := 'other_ellipsis';
2877 END IF;
2878 END IF;
2879 END IF;
2880 END LOOP;
2881 RETURN "result";
2882 END;
2883 $$;
2885 COMMENT ON FUNCTION "delegation_info"
2886 ( "member"."id"%TYPE,
2887 "unit"."id"%TYPE,
2888 "area"."id"%TYPE,
2889 "issue"."id"%TYPE,
2890 "member"."id"%TYPE,
2891 BOOLEAN )
2892 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2896 ---------------------------
2897 -- Transaction isolation --
2898 ---------------------------
2901 CREATE FUNCTION "require_transaction_isolation"()
2902 RETURNS VOID
2903 LANGUAGE 'plpgsql' VOLATILE AS $$
2904 BEGIN
2905 IF
2906 current_setting('transaction_isolation') NOT IN
2907 ('repeatable read', 'serializable')
2908 THEN
2909 RAISE EXCEPTION 'Insufficient transaction isolation level';
2910 END IF;
2911 RETURN;
2912 END;
2913 $$;
2915 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
2918 CREATE FUNCTION "dont_require_transaction_isolation"()
2919 RETURNS VOID
2920 LANGUAGE 'plpgsql' VOLATILE AS $$
2921 BEGIN
2922 IF
2923 current_setting('transaction_isolation') IN
2924 ('repeatable read', 'serializable')
2925 THEN
2926 RAISE WARNING 'Unneccessary transaction isolation level: %',
2927 current_setting('transaction_isolation');
2928 END IF;
2929 RETURN;
2930 END;
2931 $$;
2933 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
2937 ------------------------------------------------------------------------
2938 -- Regular tasks, except calculcation of snapshots and voting results --
2939 ------------------------------------------------------------------------
2942 CREATE FUNCTION "check_activity"()
2943 RETURNS VOID
2944 LANGUAGE 'plpgsql' VOLATILE AS $$
2945 DECLARE
2946 "system_setting_row" "system_setting"%ROWTYPE;
2947 BEGIN
2948 PERFORM "dont_require_transaction_isolation"();
2949 SELECT * INTO "system_setting_row" FROM "system_setting";
2950 IF "system_setting_row"."member_ttl" NOTNULL THEN
2951 UPDATE "member" SET "active" = FALSE
2952 WHERE "active" = TRUE
2953 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
2954 END IF;
2955 RETURN;
2956 END;
2957 $$;
2959 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
2962 CREATE FUNCTION "calculate_member_counts"()
2963 RETURNS VOID
2964 LANGUAGE 'plpgsql' VOLATILE AS $$
2965 BEGIN
2966 PERFORM "require_transaction_isolation"();
2967 DELETE FROM "member_count";
2968 INSERT INTO "member_count" ("total_count")
2969 SELECT "total_count" FROM "member_count_view";
2970 UPDATE "unit" SET "member_count" = "view"."member_count"
2971 FROM "unit_member_count" AS "view"
2972 WHERE "view"."unit_id" = "unit"."id";
2973 UPDATE "area" SET
2974 "direct_member_count" = "view"."direct_member_count",
2975 "member_weight" = "view"."member_weight"
2976 FROM "area_member_count" AS "view"
2977 WHERE "view"."area_id" = "area"."id";
2978 RETURN;
2979 END;
2980 $$;
2982 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"';
2986 ------------------------------------
2987 -- Calculation of harmonic weight --
2988 ------------------------------------
2991 CREATE VIEW "remaining_harmonic_supporter_weight" AS
2992 SELECT
2993 "direct_interest_snapshot"."issue_id",
2994 "direct_interest_snapshot"."event",
2995 "direct_interest_snapshot"."member_id",
2996 "direct_interest_snapshot"."weight" AS "weight_num",
2997 count("initiative"."id") AS "weight_den"
2998 FROM "issue"
2999 JOIN "direct_interest_snapshot"
3000 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
3001 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
3002 JOIN "initiative"
3003 ON "issue"."id" = "initiative"."issue_id"
3004 AND "initiative"."harmonic_weight" ISNULL
3005 JOIN "direct_supporter_snapshot"
3006 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
3007 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
3008 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
3009 AND (
3010 "direct_supporter_snapshot"."satisfied" = TRUE OR
3011 coalesce("initiative"."admitted", FALSE) = FALSE
3013 GROUP BY
3014 "direct_interest_snapshot"."issue_id",
3015 "direct_interest_snapshot"."event",
3016 "direct_interest_snapshot"."member_id",
3017 "direct_interest_snapshot"."weight";
3019 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
3022 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
3023 SELECT
3024 "initiative"."issue_id",
3025 "initiative"."id" AS "initiative_id",
3026 "initiative"."admitted",
3027 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
3028 "remaining_harmonic_supporter_weight"."weight_den"
3029 FROM "remaining_harmonic_supporter_weight"
3030 JOIN "initiative"
3031 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
3032 AND "initiative"."harmonic_weight" ISNULL
3033 JOIN "direct_supporter_snapshot"
3034 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
3035 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
3036 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
3037 AND (
3038 "direct_supporter_snapshot"."satisfied" = TRUE OR
3039 coalesce("initiative"."admitted", FALSE) = FALSE
3041 GROUP BY
3042 "initiative"."issue_id",
3043 "initiative"."id",
3044 "initiative"."admitted",
3045 "remaining_harmonic_supporter_weight"."weight_den";
3047 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
3050 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
3051 SELECT
3052 "issue_id",
3053 "id" AS "initiative_id",
3054 "admitted",
3055 0 AS "weight_num",
3056 1 AS "weight_den"
3057 FROM "initiative"
3058 WHERE "harmonic_weight" ISNULL;
3060 COMMENT ON VIEW "remaining_harmonic_initiative_weight_dummies" IS 'Helper view for function "set_harmonic_initiative_weights" providing dummy weights of zero value, which are needed for corner cases where there are no supporters for an initiative at all';
3063 CREATE FUNCTION "set_harmonic_initiative_weights"
3064 ( "issue_id_p" "issue"."id"%TYPE )
3065 RETURNS VOID
3066 LANGUAGE 'plpgsql' VOLATILE AS $$
3067 DECLARE
3068 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
3069 "i" INT4;
3070 "count_v" INT4;
3071 "summand_v" FLOAT;
3072 "id_ary" INT4[];
3073 "weight_ary" FLOAT[];
3074 "min_weight_v" FLOAT;
3075 BEGIN
3076 PERFORM "require_transaction_isolation"();
3077 UPDATE "initiative" SET "harmonic_weight" = NULL
3078 WHERE "issue_id" = "issue_id_p";
3079 LOOP
3080 "min_weight_v" := NULL;
3081 "i" := 0;
3082 "count_v" := 0;
3083 FOR "weight_row" IN
3084 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
3085 WHERE "issue_id" = "issue_id_p"
3086 AND (
3087 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3088 SELECT NULL FROM "initiative"
3089 WHERE "issue_id" = "issue_id_p"
3090 AND "harmonic_weight" ISNULL
3091 AND coalesce("admitted", FALSE) = FALSE
3094 UNION ALL -- needed for corner cases
3095 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
3096 WHERE "issue_id" = "issue_id_p"
3097 AND (
3098 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
3099 SELECT NULL FROM "initiative"
3100 WHERE "issue_id" = "issue_id_p"
3101 AND "harmonic_weight" ISNULL
3102 AND coalesce("admitted", FALSE) = FALSE
3105 ORDER BY "initiative_id" DESC, "weight_den" DESC
3106 -- NOTE: non-admitted initiatives placed first (at last positions),
3107 -- latest initiatives treated worse in case of tie
3108 LOOP
3109 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
3110 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
3111 "i" := "i" + 1;
3112 "count_v" := "i";
3113 "id_ary"["i"] := "weight_row"."initiative_id";
3114 "weight_ary"["i"] := "summand_v";
3115 ELSE
3116 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
3117 END IF;
3118 END LOOP;
3119 EXIT WHEN "count_v" = 0;
3120 "i" := 1;
3121 LOOP
3122 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
3123 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
3124 "min_weight_v" := "weight_ary"["i"];
3125 END IF;
3126 "i" := "i" + 1;
3127 EXIT WHEN "i" > "count_v";
3128 END LOOP;
3129 "i" := 1;
3130 LOOP
3131 IF "weight_ary"["i"] = "min_weight_v" THEN
3132 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
3133 WHERE "id" = "id_ary"["i"];
3134 EXIT;
3135 END IF;
3136 "i" := "i" + 1;
3137 END LOOP;
3138 END LOOP;
3139 UPDATE "initiative" SET "harmonic_weight" = 0
3140 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
3141 END;
3142 $$;
3144 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
3145 ( "issue"."id"%TYPE )
3146 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
3150 ------------------------------
3151 -- Calculation of snapshots --
3152 ------------------------------
3155 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3156 ( "issue_id_p" "issue"."id"%TYPE,
3157 "member_id_p" "member"."id"%TYPE,
3158 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3159 RETURNS "direct_population_snapshot"."weight"%TYPE
3160 LANGUAGE 'plpgsql' VOLATILE AS $$
3161 DECLARE
3162 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3163 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3164 "weight_v" INT4;
3165 "sub_weight_v" INT4;
3166 BEGIN
3167 PERFORM "require_transaction_isolation"();
3168 "weight_v" := 0;
3169 FOR "issue_delegation_row" IN
3170 SELECT * FROM "issue_delegation"
3171 WHERE "trustee_id" = "member_id_p"
3172 AND "issue_id" = "issue_id_p"
3173 LOOP
3174 IF NOT EXISTS (
3175 SELECT NULL FROM "direct_population_snapshot"
3176 WHERE "issue_id" = "issue_id_p"
3177 AND "event" = 'periodic'
3178 AND "member_id" = "issue_delegation_row"."truster_id"
3179 ) AND NOT EXISTS (
3180 SELECT NULL FROM "delegating_population_snapshot"
3181 WHERE "issue_id" = "issue_id_p"
3182 AND "event" = 'periodic'
3183 AND "member_id" = "issue_delegation_row"."truster_id"
3184 ) THEN
3185 "delegate_member_ids_v" :=
3186 "member_id_p" || "delegate_member_ids_p";
3187 INSERT INTO "delegating_population_snapshot" (
3188 "issue_id",
3189 "event",
3190 "member_id",
3191 "scope",
3192 "delegate_member_ids"
3193 ) VALUES (
3194 "issue_id_p",
3195 'periodic',
3196 "issue_delegation_row"."truster_id",
3197 "issue_delegation_row"."scope",
3198 "delegate_member_ids_v"
3199 );
3200 "sub_weight_v" := 1 +
3201 "weight_of_added_delegations_for_population_snapshot"(
3202 "issue_id_p",
3203 "issue_delegation_row"."truster_id",
3204 "delegate_member_ids_v"
3205 );
3206 UPDATE "delegating_population_snapshot"
3207 SET "weight" = "sub_weight_v"
3208 WHERE "issue_id" = "issue_id_p"
3209 AND "event" = 'periodic'
3210 AND "member_id" = "issue_delegation_row"."truster_id";
3211 "weight_v" := "weight_v" + "sub_weight_v";
3212 END IF;
3213 END LOOP;
3214 RETURN "weight_v";
3215 END;
3216 $$;
3218 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3219 ( "issue"."id"%TYPE,
3220 "member"."id"%TYPE,
3221 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3222 IS 'Helper function for "create_population_snapshot" function';
3225 CREATE FUNCTION "create_population_snapshot"
3226 ( "issue_id_p" "issue"."id"%TYPE )
3227 RETURNS VOID
3228 LANGUAGE 'plpgsql' VOLATILE AS $$
3229 DECLARE
3230 "member_id_v" "member"."id"%TYPE;
3231 BEGIN
3232 PERFORM "require_transaction_isolation"();
3233 DELETE FROM "direct_population_snapshot"
3234 WHERE "issue_id" = "issue_id_p"
3235 AND "event" = 'periodic';
3236 DELETE FROM "delegating_population_snapshot"
3237 WHERE "issue_id" = "issue_id_p"
3238 AND "event" = 'periodic';
3239 INSERT INTO "direct_population_snapshot"
3240 ("issue_id", "event", "member_id")
3241 SELECT
3242 "issue_id_p" AS "issue_id",
3243 'periodic'::"snapshot_event" AS "event",
3244 "member"."id" AS "member_id"
3245 FROM "issue"
3246 JOIN "area" ON "issue"."area_id" = "area"."id"
3247 JOIN "membership" ON "area"."id" = "membership"."area_id"
3248 JOIN "member" ON "membership"."member_id" = "member"."id"
3249 JOIN "privilege"
3250 ON "privilege"."unit_id" = "area"."unit_id"
3251 AND "privilege"."member_id" = "member"."id"
3252 WHERE "issue"."id" = "issue_id_p"
3253 AND "member"."active" AND "privilege"."voting_right"
3254 UNION
3255 SELECT
3256 "issue_id_p" AS "issue_id",
3257 'periodic'::"snapshot_event" AS "event",
3258 "member"."id" AS "member_id"
3259 FROM "issue"
3260 JOIN "area" ON "issue"."area_id" = "area"."id"
3261 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3262 JOIN "member" ON "interest"."member_id" = "member"."id"
3263 JOIN "privilege"
3264 ON "privilege"."unit_id" = "area"."unit_id"
3265 AND "privilege"."member_id" = "member"."id"
3266 WHERE "issue"."id" = "issue_id_p"
3267 AND "member"."active" AND "privilege"."voting_right";
3268 FOR "member_id_v" IN
3269 SELECT "member_id" FROM "direct_population_snapshot"
3270 WHERE "issue_id" = "issue_id_p"
3271 AND "event" = 'periodic'
3272 LOOP
3273 UPDATE "direct_population_snapshot" SET
3274 "weight" = 1 +
3275 "weight_of_added_delegations_for_population_snapshot"(
3276 "issue_id_p",
3277 "member_id_v",
3278 '{}'
3280 WHERE "issue_id" = "issue_id_p"
3281 AND "event" = 'periodic'
3282 AND "member_id" = "member_id_v";
3283 END LOOP;
3284 RETURN;
3285 END;
3286 $$;
3288 COMMENT ON FUNCTION "create_population_snapshot"
3289 ( "issue"."id"%TYPE )
3290 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.';
3293 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3294 ( "issue_id_p" "issue"."id"%TYPE,
3295 "member_id_p" "member"."id"%TYPE,
3296 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3297 RETURNS "direct_interest_snapshot"."weight"%TYPE
3298 LANGUAGE 'plpgsql' VOLATILE AS $$
3299 DECLARE
3300 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3301 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3302 "weight_v" INT4;
3303 "sub_weight_v" INT4;
3304 BEGIN
3305 PERFORM "require_transaction_isolation"();
3306 "weight_v" := 0;
3307 FOR "issue_delegation_row" IN
3308 SELECT * FROM "issue_delegation"
3309 WHERE "trustee_id" = "member_id_p"
3310 AND "issue_id" = "issue_id_p"
3311 LOOP
3312 IF NOT EXISTS (
3313 SELECT NULL FROM "direct_interest_snapshot"
3314 WHERE "issue_id" = "issue_id_p"
3315 AND "event" = 'periodic'
3316 AND "member_id" = "issue_delegation_row"."truster_id"
3317 ) AND NOT EXISTS (
3318 SELECT NULL FROM "delegating_interest_snapshot"
3319 WHERE "issue_id" = "issue_id_p"
3320 AND "event" = 'periodic'
3321 AND "member_id" = "issue_delegation_row"."truster_id"
3322 ) THEN
3323 "delegate_member_ids_v" :=
3324 "member_id_p" || "delegate_member_ids_p";
3325 INSERT INTO "delegating_interest_snapshot" (
3326 "issue_id",
3327 "event",
3328 "member_id",
3329 "scope",
3330 "delegate_member_ids"
3331 ) VALUES (
3332 "issue_id_p",
3333 'periodic',
3334 "issue_delegation_row"."truster_id",
3335 "issue_delegation_row"."scope",
3336 "delegate_member_ids_v"
3337 );
3338 "sub_weight_v" := 1 +
3339 "weight_of_added_delegations_for_interest_snapshot"(
3340 "issue_id_p",
3341 "issue_delegation_row"."truster_id",
3342 "delegate_member_ids_v"
3343 );
3344 UPDATE "delegating_interest_snapshot"
3345 SET "weight" = "sub_weight_v"
3346 WHERE "issue_id" = "issue_id_p"
3347 AND "event" = 'periodic'
3348 AND "member_id" = "issue_delegation_row"."truster_id";
3349 "weight_v" := "weight_v" + "sub_weight_v";
3350 END IF;
3351 END LOOP;
3352 RETURN "weight_v";
3353 END;
3354 $$;
3356 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3357 ( "issue"."id"%TYPE,
3358 "member"."id"%TYPE,
3359 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3360 IS 'Helper function for "create_interest_snapshot" function';
3363 CREATE FUNCTION "create_interest_snapshot"
3364 ( "issue_id_p" "issue"."id"%TYPE )
3365 RETURNS VOID
3366 LANGUAGE 'plpgsql' VOLATILE AS $$
3367 DECLARE
3368 "member_id_v" "member"."id"%TYPE;
3369 BEGIN
3370 PERFORM "require_transaction_isolation"();
3371 DELETE FROM "direct_interest_snapshot"
3372 WHERE "issue_id" = "issue_id_p"
3373 AND "event" = 'periodic';
3374 DELETE FROM "delegating_interest_snapshot"
3375 WHERE "issue_id" = "issue_id_p"
3376 AND "event" = 'periodic';
3377 DELETE FROM "direct_supporter_snapshot"
3378 USING "initiative" -- NOTE: due to missing index on issue_id
3379 WHERE "initiative"."issue_id" = "issue_id_p"
3380 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3381 AND "direct_supporter_snapshot"."event" = 'periodic';
3382 INSERT INTO "direct_interest_snapshot"
3383 ("issue_id", "event", "member_id")
3384 SELECT
3385 "issue_id_p" AS "issue_id",
3386 'periodic' AS "event",
3387 "member"."id" AS "member_id"
3388 FROM "issue"
3389 JOIN "area" ON "issue"."area_id" = "area"."id"
3390 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3391 JOIN "member" ON "interest"."member_id" = "member"."id"
3392 JOIN "privilege"
3393 ON "privilege"."unit_id" = "area"."unit_id"
3394 AND "privilege"."member_id" = "member"."id"
3395 WHERE "issue"."id" = "issue_id_p"
3396 AND "member"."active" AND "privilege"."voting_right";
3397 FOR "member_id_v" IN
3398 SELECT "member_id" FROM "direct_interest_snapshot"
3399 WHERE "issue_id" = "issue_id_p"
3400 AND "event" = 'periodic'
3401 LOOP
3402 UPDATE "direct_interest_snapshot" SET
3403 "weight" = 1 +
3404 "weight_of_added_delegations_for_interest_snapshot"(
3405 "issue_id_p",
3406 "member_id_v",
3407 '{}'
3409 WHERE "issue_id" = "issue_id_p"
3410 AND "event" = 'periodic'
3411 AND "member_id" = "member_id_v";
3412 END LOOP;
3413 INSERT INTO "direct_supporter_snapshot"
3414 ( "issue_id", "initiative_id", "event", "member_id",
3415 "draft_id", "informed", "satisfied" )
3416 SELECT
3417 "issue_id_p" AS "issue_id",
3418 "initiative"."id" AS "initiative_id",
3419 'periodic' AS "event",
3420 "supporter"."member_id" AS "member_id",
3421 "supporter"."draft_id" AS "draft_id",
3422 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3423 NOT EXISTS (
3424 SELECT NULL FROM "critical_opinion"
3425 WHERE "initiative_id" = "initiative"."id"
3426 AND "member_id" = "supporter"."member_id"
3427 ) AS "satisfied"
3428 FROM "initiative"
3429 JOIN "supporter"
3430 ON "supporter"."initiative_id" = "initiative"."id"
3431 JOIN "current_draft"
3432 ON "initiative"."id" = "current_draft"."initiative_id"
3433 JOIN "direct_interest_snapshot"
3434 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3435 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3436 AND "event" = 'periodic'
3437 WHERE "initiative"."issue_id" = "issue_id_p";
3438 RETURN;
3439 END;
3440 $$;
3442 COMMENT ON FUNCTION "create_interest_snapshot"
3443 ( "issue"."id"%TYPE )
3444 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.';
3447 CREATE FUNCTION "create_snapshot"
3448 ( "issue_id_p" "issue"."id"%TYPE )
3449 RETURNS VOID
3450 LANGUAGE 'plpgsql' VOLATILE AS $$
3451 DECLARE
3452 "initiative_id_v" "initiative"."id"%TYPE;
3453 "suggestion_id_v" "suggestion"."id"%TYPE;
3454 BEGIN
3455 PERFORM "require_transaction_isolation"();
3456 PERFORM "create_population_snapshot"("issue_id_p");
3457 PERFORM "create_interest_snapshot"("issue_id_p");
3458 UPDATE "issue" SET
3459 "snapshot" = coalesce("phase_finished", now()),
3460 "latest_snapshot_event" = 'periodic',
3461 "population" = (
3462 SELECT coalesce(sum("weight"), 0)
3463 FROM "direct_population_snapshot"
3464 WHERE "issue_id" = "issue_id_p"
3465 AND "event" = 'periodic'
3467 WHERE "id" = "issue_id_p";
3468 FOR "initiative_id_v" IN
3469 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3470 LOOP
3471 UPDATE "initiative" SET
3472 "supporter_count" = (
3473 SELECT coalesce(sum("di"."weight"), 0)
3474 FROM "direct_interest_snapshot" AS "di"
3475 JOIN "direct_supporter_snapshot" AS "ds"
3476 ON "di"."member_id" = "ds"."member_id"
3477 WHERE "di"."issue_id" = "issue_id_p"
3478 AND "di"."event" = 'periodic'
3479 AND "ds"."initiative_id" = "initiative_id_v"
3480 AND "ds"."event" = 'periodic'
3481 ),
3482 "informed_supporter_count" = (
3483 SELECT coalesce(sum("di"."weight"), 0)
3484 FROM "direct_interest_snapshot" AS "di"
3485 JOIN "direct_supporter_snapshot" AS "ds"
3486 ON "di"."member_id" = "ds"."member_id"
3487 WHERE "di"."issue_id" = "issue_id_p"
3488 AND "di"."event" = 'periodic'
3489 AND "ds"."initiative_id" = "initiative_id_v"
3490 AND "ds"."event" = 'periodic'
3491 AND "ds"."informed"
3492 ),
3493 "satisfied_supporter_count" = (
3494 SELECT coalesce(sum("di"."weight"), 0)
3495 FROM "direct_interest_snapshot" AS "di"
3496 JOIN "direct_supporter_snapshot" AS "ds"
3497 ON "di"."member_id" = "ds"."member_id"
3498 WHERE "di"."issue_id" = "issue_id_p"
3499 AND "di"."event" = 'periodic'
3500 AND "ds"."initiative_id" = "initiative_id_v"
3501 AND "ds"."event" = 'periodic'
3502 AND "ds"."satisfied"
3503 ),
3504 "satisfied_informed_supporter_count" = (
3505 SELECT coalesce(sum("di"."weight"), 0)
3506 FROM "direct_interest_snapshot" AS "di"
3507 JOIN "direct_supporter_snapshot" AS "ds"
3508 ON "di"."member_id" = "ds"."member_id"
3509 WHERE "di"."issue_id" = "issue_id_p"
3510 AND "di"."event" = 'periodic'
3511 AND "ds"."initiative_id" = "initiative_id_v"
3512 AND "ds"."event" = 'periodic'
3513 AND "ds"."informed"
3514 AND "ds"."satisfied"
3516 WHERE "id" = "initiative_id_v";
3517 FOR "suggestion_id_v" IN
3518 SELECT "id" FROM "suggestion"
3519 WHERE "initiative_id" = "initiative_id_v"
3520 LOOP
3521 UPDATE "suggestion" SET
3522 "minus2_unfulfilled_count" = (
3523 SELECT coalesce(sum("snapshot"."weight"), 0)
3524 FROM "issue" CROSS JOIN "opinion"
3525 JOIN "direct_interest_snapshot" AS "snapshot"
3526 ON "snapshot"."issue_id" = "issue"."id"
3527 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3528 AND "snapshot"."member_id" = "opinion"."member_id"
3529 WHERE "issue"."id" = "issue_id_p"
3530 AND "opinion"."suggestion_id" = "suggestion_id_v"
3531 AND "opinion"."degree" = -2
3532 AND "opinion"."fulfilled" = FALSE
3533 ),
3534 "minus2_fulfilled_count" = (
3535 SELECT coalesce(sum("snapshot"."weight"), 0)
3536 FROM "issue" CROSS JOIN "opinion"
3537 JOIN "direct_interest_snapshot" AS "snapshot"
3538 ON "snapshot"."issue_id" = "issue"."id"
3539 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3540 AND "snapshot"."member_id" = "opinion"."member_id"
3541 WHERE "issue"."id" = "issue_id_p"
3542 AND "opinion"."suggestion_id" = "suggestion_id_v"
3543 AND "opinion"."degree" = -2
3544 AND "opinion"."fulfilled" = TRUE
3545 ),
3546 "minus1_unfulfilled_count" = (
3547 SELECT coalesce(sum("snapshot"."weight"), 0)
3548 FROM "issue" CROSS JOIN "opinion"
3549 JOIN "direct_interest_snapshot" AS "snapshot"
3550 ON "snapshot"."issue_id" = "issue"."id"
3551 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3552 AND "snapshot"."member_id" = "opinion"."member_id"
3553 WHERE "issue"."id" = "issue_id_p"
3554 AND "opinion"."suggestion_id" = "suggestion_id_v"
3555 AND "opinion"."degree" = -1
3556 AND "opinion"."fulfilled" = FALSE
3557 ),
3558 "minus1_fulfilled_count" = (
3559 SELECT coalesce(sum("snapshot"."weight"), 0)
3560 FROM "issue" CROSS JOIN "opinion"
3561 JOIN "direct_interest_snapshot" AS "snapshot"
3562 ON "snapshot"."issue_id" = "issue"."id"
3563 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3564 AND "snapshot"."member_id" = "opinion"."member_id"
3565 WHERE "issue"."id" = "issue_id_p"
3566 AND "opinion"."suggestion_id" = "suggestion_id_v"
3567 AND "opinion"."degree" = -1
3568 AND "opinion"."fulfilled" = TRUE
3569 ),
3570 "plus1_unfulfilled_count" = (
3571 SELECT coalesce(sum("snapshot"."weight"), 0)
3572 FROM "issue" CROSS JOIN "opinion"
3573 JOIN "direct_interest_snapshot" AS "snapshot"
3574 ON "snapshot"."issue_id" = "issue"."id"
3575 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3576 AND "snapshot"."member_id" = "opinion"."member_id"
3577 WHERE "issue"."id" = "issue_id_p"
3578 AND "opinion"."suggestion_id" = "suggestion_id_v"
3579 AND "opinion"."degree" = 1
3580 AND "opinion"."fulfilled" = FALSE
3581 ),
3582 "plus1_fulfilled_count" = (
3583 SELECT coalesce(sum("snapshot"."weight"), 0)
3584 FROM "issue" CROSS JOIN "opinion"
3585 JOIN "direct_interest_snapshot" AS "snapshot"
3586 ON "snapshot"."issue_id" = "issue"."id"
3587 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3588 AND "snapshot"."member_id" = "opinion"."member_id"
3589 WHERE "issue"."id" = "issue_id_p"
3590 AND "opinion"."suggestion_id" = "suggestion_id_v"
3591 AND "opinion"."degree" = 1
3592 AND "opinion"."fulfilled" = TRUE
3593 ),
3594 "plus2_unfulfilled_count" = (
3595 SELECT coalesce(sum("snapshot"."weight"), 0)
3596 FROM "issue" CROSS JOIN "opinion"
3597 JOIN "direct_interest_snapshot" AS "snapshot"
3598 ON "snapshot"."issue_id" = "issue"."id"
3599 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3600 AND "snapshot"."member_id" = "opinion"."member_id"
3601 WHERE "issue"."id" = "issue_id_p"
3602 AND "opinion"."suggestion_id" = "suggestion_id_v"
3603 AND "opinion"."degree" = 2
3604 AND "opinion"."fulfilled" = FALSE
3605 ),
3606 "plus2_fulfilled_count" = (
3607 SELECT coalesce(sum("snapshot"."weight"), 0)
3608 FROM "issue" CROSS JOIN "opinion"
3609 JOIN "direct_interest_snapshot" AS "snapshot"
3610 ON "snapshot"."issue_id" = "issue"."id"
3611 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3612 AND "snapshot"."member_id" = "opinion"."member_id"
3613 WHERE "issue"."id" = "issue_id_p"
3614 AND "opinion"."suggestion_id" = "suggestion_id_v"
3615 AND "opinion"."degree" = 2
3616 AND "opinion"."fulfilled" = TRUE
3618 WHERE "suggestion"."id" = "suggestion_id_v";
3619 END LOOP;
3620 END LOOP;
3621 RETURN;
3622 END;
3623 $$;
3625 COMMENT ON FUNCTION "create_snapshot"
3626 ( "issue"."id"%TYPE )
3627 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.';
3630 CREATE FUNCTION "set_snapshot_event"
3631 ( "issue_id_p" "issue"."id"%TYPE,
3632 "event_p" "snapshot_event" )
3633 RETURNS VOID
3634 LANGUAGE 'plpgsql' VOLATILE AS $$
3635 DECLARE
3636 "event_v" "issue"."latest_snapshot_event"%TYPE;
3637 BEGIN
3638 PERFORM "require_transaction_isolation"();
3639 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3640 WHERE "id" = "issue_id_p" FOR UPDATE;
3641 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3642 WHERE "id" = "issue_id_p";
3643 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3644 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3645 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3646 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3647 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3648 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3649 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3650 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3651 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3652 FROM "initiative" -- NOTE: due to missing index on issue_id
3653 WHERE "initiative"."issue_id" = "issue_id_p"
3654 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
3655 AND "direct_supporter_snapshot"."event" = "event_v";
3656 RETURN;
3657 END;
3658 $$;
3660 COMMENT ON FUNCTION "set_snapshot_event"
3661 ( "issue"."id"%TYPE,
3662 "snapshot_event" )
3663 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3667 -----------------------
3668 -- Counting of votes --
3669 -----------------------
3672 CREATE FUNCTION "weight_of_added_vote_delegations"
3673 ( "issue_id_p" "issue"."id"%TYPE,
3674 "member_id_p" "member"."id"%TYPE,
3675 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3676 RETURNS "direct_voter"."weight"%TYPE
3677 LANGUAGE 'plpgsql' VOLATILE AS $$
3678 DECLARE
3679 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3680 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3681 "weight_v" INT4;
3682 "sub_weight_v" INT4;
3683 BEGIN
3684 PERFORM "require_transaction_isolation"();
3685 "weight_v" := 0;
3686 FOR "issue_delegation_row" IN
3687 SELECT * FROM "issue_delegation"
3688 WHERE "trustee_id" = "member_id_p"
3689 AND "issue_id" = "issue_id_p"
3690 LOOP
3691 IF NOT EXISTS (
3692 SELECT NULL FROM "direct_voter"
3693 WHERE "member_id" = "issue_delegation_row"."truster_id"
3694 AND "issue_id" = "issue_id_p"
3695 ) AND NOT EXISTS (
3696 SELECT NULL FROM "delegating_voter"
3697 WHERE "member_id" = "issue_delegation_row"."truster_id"
3698 AND "issue_id" = "issue_id_p"
3699 ) THEN
3700 "delegate_member_ids_v" :=
3701 "member_id_p" || "delegate_member_ids_p";
3702 INSERT INTO "delegating_voter" (
3703 "issue_id",
3704 "member_id",
3705 "scope",
3706 "delegate_member_ids"
3707 ) VALUES (
3708 "issue_id_p",
3709 "issue_delegation_row"."truster_id",
3710 "issue_delegation_row"."scope",
3711 "delegate_member_ids_v"
3712 );
3713 "sub_weight_v" := 1 +
3714 "weight_of_added_vote_delegations"(
3715 "issue_id_p",
3716 "issue_delegation_row"."truster_id",
3717 "delegate_member_ids_v"
3718 );
3719 UPDATE "delegating_voter"
3720 SET "weight" = "sub_weight_v"
3721 WHERE "issue_id" = "issue_id_p"
3722 AND "member_id" = "issue_delegation_row"."truster_id";
3723 "weight_v" := "weight_v" + "sub_weight_v";
3724 END IF;
3725 END LOOP;
3726 RETURN "weight_v";
3727 END;
3728 $$;
3730 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3731 ( "issue"."id"%TYPE,
3732 "member"."id"%TYPE,
3733 "delegating_voter"."delegate_member_ids"%TYPE )
3734 IS 'Helper function for "add_vote_delegations" function';
3737 CREATE FUNCTION "add_vote_delegations"
3738 ( "issue_id_p" "issue"."id"%TYPE )
3739 RETURNS VOID
3740 LANGUAGE 'plpgsql' VOLATILE AS $$
3741 DECLARE
3742 "member_id_v" "member"."id"%TYPE;
3743 BEGIN
3744 PERFORM "require_transaction_isolation"();
3745 FOR "member_id_v" IN
3746 SELECT "member_id" FROM "direct_voter"
3747 WHERE "issue_id" = "issue_id_p"
3748 LOOP
3749 UPDATE "direct_voter" SET
3750 "weight" = "weight" + "weight_of_added_vote_delegations"(
3751 "issue_id_p",
3752 "member_id_v",
3753 '{}'
3755 WHERE "member_id" = "member_id_v"
3756 AND "issue_id" = "issue_id_p";
3757 END LOOP;
3758 RETURN;
3759 END;
3760 $$;
3762 COMMENT ON FUNCTION "add_vote_delegations"
3763 ( "issue_id_p" "issue"."id"%TYPE )
3764 IS 'Helper function for "close_voting" function';
3767 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3768 RETURNS VOID
3769 LANGUAGE 'plpgsql' VOLATILE AS $$
3770 DECLARE
3771 "area_id_v" "area"."id"%TYPE;
3772 "unit_id_v" "unit"."id"%TYPE;
3773 "member_id_v" "member"."id"%TYPE;
3774 BEGIN
3775 PERFORM "require_transaction_isolation"();
3776 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3777 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3778 -- override protection triggers:
3779 INSERT INTO "temporary_transaction_data" ("key", "value")
3780 VALUES ('override_protection_triggers', TRUE::TEXT);
3781 -- delete timestamp of voting comment:
3782 UPDATE "direct_voter" SET "comment_changed" = NULL
3783 WHERE "issue_id" = "issue_id_p";
3784 -- delete delegating votes (in cases of manual reset of issue state):
3785 DELETE FROM "delegating_voter"
3786 WHERE "issue_id" = "issue_id_p";
3787 -- delete votes from non-privileged voters:
3788 DELETE FROM "direct_voter"
3789 USING (
3790 SELECT
3791 "direct_voter"."member_id"
3792 FROM "direct_voter"
3793 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3794 LEFT JOIN "privilege"
3795 ON "privilege"."unit_id" = "unit_id_v"
3796 AND "privilege"."member_id" = "direct_voter"."member_id"
3797 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3798 "member"."active" = FALSE OR
3799 "privilege"."voting_right" ISNULL OR
3800 "privilege"."voting_right" = FALSE
3802 ) AS "subquery"
3803 WHERE "direct_voter"."issue_id" = "issue_id_p"
3804 AND "direct_voter"."member_id" = "subquery"."member_id";
3805 -- consider delegations:
3806 UPDATE "direct_voter" SET "weight" = 1
3807 WHERE "issue_id" = "issue_id_p";
3808 PERFORM "add_vote_delegations"("issue_id_p");
3809 -- mark first preferences:
3810 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
3811 FROM (
3812 SELECT
3813 "vote"."initiative_id",
3814 "vote"."member_id",
3815 CASE WHEN "vote"."grade" > 0 THEN
3816 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
3817 ELSE NULL
3818 END AS "first_preference"
3819 FROM "vote"
3820 JOIN "initiative" -- NOTE: due to missing index on issue_id
3821 ON "vote"."issue_id" = "initiative"."issue_id"
3822 JOIN "vote" AS "agg"
3823 ON "initiative"."id" = "agg"."initiative_id"
3824 AND "vote"."member_id" = "agg"."member_id"
3825 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
3826 ) AS "subquery"
3827 WHERE "vote"."issue_id" = "issue_id_p"
3828 AND "vote"."initiative_id" = "subquery"."initiative_id"
3829 AND "vote"."member_id" = "subquery"."member_id";
3830 -- finish overriding protection triggers (avoids garbage):
3831 DELETE FROM "temporary_transaction_data"
3832 WHERE "key" = 'override_protection_triggers';
3833 -- materialize battle_view:
3834 -- NOTE: "closed" column of issue must be set at this point
3835 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3836 INSERT INTO "battle" (
3837 "issue_id",
3838 "winning_initiative_id", "losing_initiative_id",
3839 "count"
3840 ) SELECT
3841 "issue_id",
3842 "winning_initiative_id", "losing_initiative_id",
3843 "count"
3844 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3845 -- set voter count:
3846 UPDATE "issue" SET
3847 "voter_count" = (
3848 SELECT coalesce(sum("weight"), 0)
3849 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3851 WHERE "id" = "issue_id_p";
3852 -- copy "positive_votes" and "negative_votes" from "battle" table:
3853 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
3854 UPDATE "initiative" SET
3855 "first_preference_votes" = 0,
3856 "positive_votes" = "battle_win"."count",
3857 "negative_votes" = "battle_lose"."count"
3858 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3859 WHERE
3860 "battle_win"."issue_id" = "issue_id_p" AND
3861 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3862 "battle_win"."losing_initiative_id" ISNULL AND
3863 "battle_lose"."issue_id" = "issue_id_p" AND
3864 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3865 "battle_lose"."winning_initiative_id" ISNULL;
3866 -- calculate "first_preference_votes":
3867 -- NOTE: will only set values not equal to zero
3868 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
3869 FROM (
3870 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
3871 FROM "vote" JOIN "direct_voter"
3872 ON "vote"."issue_id" = "direct_voter"."issue_id"
3873 AND "vote"."member_id" = "direct_voter"."member_id"
3874 WHERE "vote"."first_preference"
3875 GROUP BY "vote"."initiative_id"
3876 ) AS "subquery"
3877 WHERE "initiative"."issue_id" = "issue_id_p"
3878 AND "initiative"."admitted"
3879 AND "initiative"."id" = "subquery"."initiative_id";
3880 END;
3881 $$;
3883 COMMENT ON FUNCTION "close_voting"
3884 ( "issue"."id"%TYPE )
3885 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.';
3888 CREATE FUNCTION "defeat_strength"
3889 ( "positive_votes_p" INT4,
3890 "negative_votes_p" INT4,
3891 "defeat_strength_p" "defeat_strength" )
3892 RETURNS INT8
3893 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3894 BEGIN
3895 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
3896 IF "positive_votes_p" > "negative_votes_p" THEN
3897 RETURN "positive_votes_p";
3898 ELSE
3899 RETURN 0;
3900 END IF;
3901 ELSE
3902 IF "positive_votes_p" > "negative_votes_p" THEN
3903 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3904 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3905 RETURN 0;
3906 ELSE
3907 RETURN -1;
3908 END IF;
3909 END IF;
3910 END;
3911 $$;
3913 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4, "defeat_strength") IS 'Calculates defeat strength (INT8!) according to the "defeat_strength" option (see comment on type "defeat_strength")';
3916 CREATE FUNCTION "secondary_link_strength"
3917 ( "initiative1_ord_p" INT4,
3918 "initiative2_ord_p" INT4,
3919 "tie_breaking_p" "tie_breaking" )
3920 RETURNS INT8
3921 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3922 BEGIN
3923 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
3924 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
3925 END IF;
3926 RETURN (
3927 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
3929 ELSE
3930 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
3931 1::INT8 << 62
3932 ELSE 0 END
3934 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
3935 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
3936 ELSE
3937 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
3938 END
3939 END
3940 );
3941 END;
3942 $$;
3944 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
3947 CREATE TYPE "link_strength" AS (
3948 "primary" INT8,
3949 "secondary" INT8 );
3951 COMMENT ON TYPE "link_strength" IS 'Type to store the defeat strength of a link between two candidates plus a secondary criterion to create unique link strengths between the candidates (needed for tie-breaking ''variant1'' and ''variant2'')';
3954 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
3955 RETURNS "link_strength"[][]
3956 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3957 DECLARE
3958 "dimension_v" INT4;
3959 "matrix_p" "link_strength"[][];
3960 "i" INT4;
3961 "j" INT4;
3962 "k" INT4;
3963 BEGIN
3964 "dimension_v" := array_upper("matrix_d", 1);
3965 "matrix_p" := "matrix_d";
3966 "i" := 1;
3967 LOOP
3968 "j" := 1;
3969 LOOP
3970 IF "i" != "j" THEN
3971 "k" := 1;
3972 LOOP
3973 IF "i" != "k" AND "j" != "k" THEN
3974 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
3975 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
3976 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
3977 END IF;
3978 ELSE
3979 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
3980 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
3981 END IF;
3982 END IF;
3983 END IF;
3984 EXIT WHEN "k" = "dimension_v";
3985 "k" := "k" + 1;
3986 END LOOP;
3987 END IF;
3988 EXIT WHEN "j" = "dimension_v";
3989 "j" := "j" + 1;
3990 END LOOP;
3991 EXIT WHEN "i" = "dimension_v";
3992 "i" := "i" + 1;
3993 END LOOP;
3994 RETURN "matrix_p";
3995 END;
3996 $$;
3998 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
4001 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
4002 RETURNS VOID
4003 LANGUAGE 'plpgsql' VOLATILE AS $$
4004 DECLARE
4005 "issue_row" "issue"%ROWTYPE;
4006 "policy_row" "policy"%ROWTYPE;
4007 "dimension_v" INT4;
4008 "matrix_a" INT4[][]; -- absolute votes
4009 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
4010 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
4011 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
4012 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
4013 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
4014 "i" INT4;
4015 "j" INT4;
4016 "m" INT4;
4017 "n" INT4;
4018 "battle_row" "battle"%ROWTYPE;
4019 "rank_ary" INT4[];
4020 "rank_v" INT4;
4021 "initiative_id_v" "initiative"."id"%TYPE;
4022 BEGIN
4023 PERFORM "require_transaction_isolation"();
4024 SELECT * INTO "issue_row"
4025 FROM "issue" WHERE "id" = "issue_id_p";
4026 SELECT * INTO "policy_row"
4027 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4028 SELECT count(1) INTO "dimension_v"
4029 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
4030 -- create "matrix_a" with absolute number of votes in pairwise
4031 -- comparison:
4032 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
4033 "i" := 1;
4034 "j" := 2;
4035 FOR "battle_row" IN
4036 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
4037 ORDER BY
4038 "winning_initiative_id" NULLS FIRST,
4039 "losing_initiative_id" NULLS FIRST
4040 LOOP
4041 "matrix_a"["i"]["j"] := "battle_row"."count";
4042 IF "j" = "dimension_v" THEN
4043 "i" := "i" + 1;
4044 "j" := 1;
4045 ELSE
4046 "j" := "j" + 1;
4047 IF "j" = "i" THEN
4048 "j" := "j" + 1;
4049 END IF;
4050 END IF;
4051 END LOOP;
4052 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
4053 RAISE EXCEPTION 'Wrong battle count (should not happen)';
4054 END IF;
4055 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
4056 -- and "secondary_link_strength" functions:
4057 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
4058 "i" := 1;
4059 LOOP
4060 "j" := 1;
4061 LOOP
4062 IF "i" != "j" THEN
4063 "matrix_d"["i"]["j"] := (
4064 "defeat_strength"(
4065 "matrix_a"["i"]["j"],
4066 "matrix_a"["j"]["i"],
4067 "policy_row"."defeat_strength"
4068 ),
4069 "secondary_link_strength"(
4070 "i",
4071 "j",
4072 "policy_row"."tie_breaking"
4074 )::"link_strength";
4075 END IF;
4076 EXIT WHEN "j" = "dimension_v";
4077 "j" := "j" + 1;
4078 END LOOP;
4079 EXIT WHEN "i" = "dimension_v";
4080 "i" := "i" + 1;
4081 END LOOP;
4082 -- find best paths:
4083 "matrix_p" := "find_best_paths"("matrix_d");
4084 -- create partial order:
4085 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
4086 "i" := 1;
4087 LOOP
4088 "j" := "i" + 1;
4089 LOOP
4090 IF "i" != "j" THEN
4091 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
4092 "matrix_b"["i"]["j"] := TRUE;
4093 "matrix_b"["j"]["i"] := FALSE;
4094 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
4095 "matrix_b"["i"]["j"] := FALSE;
4096 "matrix_b"["j"]["i"] := TRUE;
4097 END IF;
4098 END IF;
4099 EXIT WHEN "j" = "dimension_v";
4100 "j" := "j" + 1;
4101 END LOOP;
4102 EXIT WHEN "i" = "dimension_v" - 1;
4103 "i" := "i" + 1;
4104 END LOOP;
4105 -- tie-breaking by forbidding shared weakest links in beat-paths
4106 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
4107 -- is performed later by initiative id):
4108 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
4109 "m" := 1;
4110 LOOP
4111 "n" := "m" + 1;
4112 LOOP
4113 -- only process those candidates m and n, which are tied:
4114 IF "matrix_b"["m"]["n"] ISNULL THEN
4115 -- start with beat-paths prior tie-breaking:
4116 "matrix_t" := "matrix_p";
4117 -- start with all links allowed:
4118 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
4119 LOOP
4120 -- determine (and forbid) that link that is the weakest link
4121 -- in both the best path from candidate m to candidate n and
4122 -- from candidate n to candidate m:
4123 "i" := 1;
4124 <<forbid_one_link>>
4125 LOOP
4126 "j" := 1;
4127 LOOP
4128 IF "i" != "j" THEN
4129 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
4130 "matrix_f"["i"]["j"] := TRUE;
4131 -- exit for performance reasons,
4132 -- as exactly one link will be found:
4133 EXIT forbid_one_link;
4134 END IF;
4135 END IF;
4136 EXIT WHEN "j" = "dimension_v";
4137 "j" := "j" + 1;
4138 END LOOP;
4139 IF "i" = "dimension_v" THEN
4140 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
4141 END IF;
4142 "i" := "i" + 1;
4143 END LOOP;
4144 -- calculate best beat-paths while ignoring forbidden links:
4145 "i" := 1;
4146 LOOP
4147 "j" := 1;
4148 LOOP
4149 IF "i" != "j" THEN
4150 "matrix_t"["i"]["j"] := CASE
4151 WHEN "matrix_f"["i"]["j"]
4152 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
4153 ELSE "matrix_d"["i"]["j"] END;
4154 END IF;
4155 EXIT WHEN "j" = "dimension_v";
4156 "j" := "j" + 1;
4157 END LOOP;
4158 EXIT WHEN "i" = "dimension_v";
4159 "i" := "i" + 1;
4160 END LOOP;
4161 "matrix_t" := "find_best_paths"("matrix_t");
4162 -- extend partial order, if tie-breaking was successful:
4163 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
4164 "matrix_b"["m"]["n"] := TRUE;
4165 "matrix_b"["n"]["m"] := FALSE;
4166 EXIT;
4167 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
4168 "matrix_b"["m"]["n"] := FALSE;
4169 "matrix_b"["n"]["m"] := TRUE;
4170 EXIT;
4171 END IF;
4172 END LOOP;
4173 END IF;
4174 EXIT WHEN "n" = "dimension_v";
4175 "n" := "n" + 1;
4176 END LOOP;
4177 EXIT WHEN "m" = "dimension_v" - 1;
4178 "m" := "m" + 1;
4179 END LOOP;
4180 END IF;
4181 -- store a unique ranking in "rank_ary":
4182 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
4183 "rank_v" := 1;
4184 LOOP
4185 "i" := 1;
4186 <<assign_next_rank>>
4187 LOOP
4188 IF "rank_ary"["i"] ISNULL THEN
4189 "j" := 1;
4190 LOOP
4191 IF
4192 "i" != "j" AND
4193 "rank_ary"["j"] ISNULL AND
4194 ( "matrix_b"["j"]["i"] OR
4195 -- tie-breaking by "id"
4196 ( "matrix_b"["j"]["i"] ISNULL AND
4197 "j" < "i" ) )
4198 THEN
4199 -- someone else is better
4200 EXIT;
4201 END IF;
4202 IF "j" = "dimension_v" THEN
4203 -- noone is better
4204 "rank_ary"["i"] := "rank_v";
4205 EXIT assign_next_rank;
4206 END IF;
4207 "j" := "j" + 1;
4208 END LOOP;
4209 END IF;
4210 "i" := "i" + 1;
4211 IF "i" > "dimension_v" THEN
4212 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
4213 END IF;
4214 END LOOP;
4215 EXIT WHEN "rank_v" = "dimension_v";
4216 "rank_v" := "rank_v" + 1;
4217 END LOOP;
4218 -- write preliminary results:
4219 "i" := 2; -- omit status quo with "i" = 1
4220 FOR "initiative_id_v" IN
4221 SELECT "id" FROM "initiative"
4222 WHERE "issue_id" = "issue_id_p" AND "admitted"
4223 ORDER BY "id"
4224 LOOP
4225 UPDATE "initiative" SET
4226 "direct_majority" =
4227 CASE WHEN "policy_row"."direct_majority_strict" THEN
4228 "positive_votes" * "policy_row"."direct_majority_den" >
4229 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4230 ELSE
4231 "positive_votes" * "policy_row"."direct_majority_den" >=
4232 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4233 END
4234 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4235 AND "issue_row"."voter_count"-"negative_votes" >=
4236 "policy_row"."direct_majority_non_negative",
4237 "indirect_majority" =
4238 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4239 "positive_votes" * "policy_row"."indirect_majority_den" >
4240 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4241 ELSE
4242 "positive_votes" * "policy_row"."indirect_majority_den" >=
4243 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4244 END
4245 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4246 AND "issue_row"."voter_count"-"negative_votes" >=
4247 "policy_row"."indirect_majority_non_negative",
4248 "schulze_rank" = "rank_ary"["i"],
4249 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
4250 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
4251 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
4252 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
4253 THEN NULL
4254 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
4255 "eligible" = FALSE,
4256 "winner" = FALSE,
4257 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4258 WHERE "id" = "initiative_id_v";
4259 "i" := "i" + 1;
4260 END LOOP;
4261 IF "i" != "dimension_v" + 1 THEN
4262 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4263 END IF;
4264 -- take indirect majorities into account:
4265 LOOP
4266 UPDATE "initiative" SET "indirect_majority" = TRUE
4267 FROM (
4268 SELECT "new_initiative"."id" AS "initiative_id"
4269 FROM "initiative" "old_initiative"
4270 JOIN "initiative" "new_initiative"
4271 ON "new_initiative"."issue_id" = "issue_id_p"
4272 AND "new_initiative"."indirect_majority" = FALSE
4273 JOIN "battle" "battle_win"
4274 ON "battle_win"."issue_id" = "issue_id_p"
4275 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4276 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4277 JOIN "battle" "battle_lose"
4278 ON "battle_lose"."issue_id" = "issue_id_p"
4279 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4280 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4281 WHERE "old_initiative"."issue_id" = "issue_id_p"
4282 AND "old_initiative"."indirect_majority" = TRUE
4283 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4284 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4285 "policy_row"."indirect_majority_num" *
4286 ("battle_win"."count"+"battle_lose"."count")
4287 ELSE
4288 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4289 "policy_row"."indirect_majority_num" *
4290 ("battle_win"."count"+"battle_lose"."count")
4291 END
4292 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4293 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4294 "policy_row"."indirect_majority_non_negative"
4295 ) AS "subquery"
4296 WHERE "id" = "subquery"."initiative_id";
4297 EXIT WHEN NOT FOUND;
4298 END LOOP;
4299 -- set "multistage_majority" for remaining matching initiatives:
4300 UPDATE "initiative" SET "multistage_majority" = TRUE
4301 FROM (
4302 SELECT "losing_initiative"."id" AS "initiative_id"
4303 FROM "initiative" "losing_initiative"
4304 JOIN "initiative" "winning_initiative"
4305 ON "winning_initiative"."issue_id" = "issue_id_p"
4306 AND "winning_initiative"."admitted"
4307 JOIN "battle" "battle_win"
4308 ON "battle_win"."issue_id" = "issue_id_p"
4309 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4310 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4311 JOIN "battle" "battle_lose"
4312 ON "battle_lose"."issue_id" = "issue_id_p"
4313 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4314 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4315 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4316 AND "losing_initiative"."admitted"
4317 AND "winning_initiative"."schulze_rank" <
4318 "losing_initiative"."schulze_rank"
4319 AND "battle_win"."count" > "battle_lose"."count"
4320 AND (
4321 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4322 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4323 ) AS "subquery"
4324 WHERE "id" = "subquery"."initiative_id";
4325 -- mark eligible initiatives:
4326 UPDATE "initiative" SET "eligible" = TRUE
4327 WHERE "issue_id" = "issue_id_p"
4328 AND "initiative"."direct_majority"
4329 AND "initiative"."indirect_majority"
4330 AND "initiative"."better_than_status_quo"
4331 AND (
4332 "policy_row"."no_multistage_majority" = FALSE OR
4333 "initiative"."multistage_majority" = FALSE )
4334 AND (
4335 "policy_row"."no_reverse_beat_path" = FALSE OR
4336 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
4337 -- mark final winner:
4338 UPDATE "initiative" SET "winner" = TRUE
4339 FROM (
4340 SELECT "id" AS "initiative_id"
4341 FROM "initiative"
4342 WHERE "issue_id" = "issue_id_p" AND "eligible"
4343 ORDER BY
4344 "schulze_rank",
4345 "id"
4346 LIMIT 1
4347 ) AS "subquery"
4348 WHERE "id" = "subquery"."initiative_id";
4349 -- write (final) ranks:
4350 "rank_v" := 1;
4351 FOR "initiative_id_v" IN
4352 SELECT "id"
4353 FROM "initiative"
4354 WHERE "issue_id" = "issue_id_p" AND "admitted"
4355 ORDER BY
4356 "winner" DESC,
4357 "eligible" DESC,
4358 "schulze_rank",
4359 "id"
4360 LOOP
4361 UPDATE "initiative" SET "rank" = "rank_v"
4362 WHERE "id" = "initiative_id_v";
4363 "rank_v" := "rank_v" + 1;
4364 END LOOP;
4365 -- set schulze rank of status quo and mark issue as finished:
4366 UPDATE "issue" SET
4367 "status_quo_schulze_rank" = "rank_ary"[1],
4368 "state" =
4369 CASE WHEN EXISTS (
4370 SELECT NULL FROM "initiative"
4371 WHERE "issue_id" = "issue_id_p" AND "winner"
4372 ) THEN
4373 'finished_with_winner'::"issue_state"
4374 ELSE
4375 'finished_without_winner'::"issue_state"
4376 END,
4377 "closed" = "phase_finished",
4378 "phase_finished" = NULL
4379 WHERE "id" = "issue_id_p";
4380 RETURN;
4381 END;
4382 $$;
4384 COMMENT ON FUNCTION "calculate_ranks"
4385 ( "issue"."id"%TYPE )
4386 IS 'Determine ranking (Votes have to be counted first)';
4390 -----------------------------
4391 -- Automatic state changes --
4392 -----------------------------
4395 CREATE TYPE "check_issue_persistence" AS (
4396 "state" "issue_state",
4397 "phase_finished" BOOLEAN,
4398 "issue_revoked" BOOLEAN,
4399 "snapshot_created" BOOLEAN,
4400 "harmonic_weights_set" BOOLEAN,
4401 "closed_voting" BOOLEAN );
4403 COMMENT ON TYPE "check_issue_persistence" IS 'Type of data returned by "check_issue" function, to be passed to subsequent calls of the same function';
4406 CREATE FUNCTION "check_issue"
4407 ( "issue_id_p" "issue"."id"%TYPE,
4408 "persist" "check_issue_persistence" )
4409 RETURNS "check_issue_persistence"
4410 LANGUAGE 'plpgsql' VOLATILE AS $$
4411 DECLARE
4412 "issue_row" "issue"%ROWTYPE;
4413 "policy_row" "policy"%ROWTYPE;
4414 "initiative_row" "initiative"%ROWTYPE;
4415 "state_v" "issue_state";
4416 BEGIN
4417 PERFORM "require_transaction_isolation"();
4418 IF "persist" ISNULL THEN
4419 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4420 FOR UPDATE;
4421 IF "issue_row"."closed" NOTNULL THEN
4422 RETURN NULL;
4423 END IF;
4424 "persist"."state" := "issue_row"."state";
4425 IF
4426 ( "issue_row"."state" = 'admission' AND now() >=
4427 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
4428 ( "issue_row"."state" = 'discussion' AND now() >=
4429 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
4430 ( "issue_row"."state" = 'verification' AND now() >=
4431 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
4432 ( "issue_row"."state" = 'voting' AND now() >=
4433 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
4434 THEN
4435 "persist"."phase_finished" := TRUE;
4436 ELSE
4437 "persist"."phase_finished" := FALSE;
4438 END IF;
4439 IF
4440 NOT EXISTS (
4441 -- all initiatives are revoked
4442 SELECT NULL FROM "initiative"
4443 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4444 ) AND (
4445 -- and issue has not been accepted yet
4446 "persist"."state" = 'admission' OR
4447 -- or verification time has elapsed
4448 ( "persist"."state" = 'verification' AND
4449 "persist"."phase_finished" ) OR
4450 -- or no initiatives have been revoked lately
4451 NOT EXISTS (
4452 SELECT NULL FROM "initiative"
4453 WHERE "issue_id" = "issue_id_p"
4454 AND now() < "revoked" + "issue_row"."verification_time"
4457 THEN
4458 "persist"."issue_revoked" := TRUE;
4459 ELSE
4460 "persist"."issue_revoked" := FALSE;
4461 END IF;
4462 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
4463 UPDATE "issue" SET "phase_finished" = now()
4464 WHERE "id" = "issue_row"."id";
4465 RETURN "persist";
4466 ELSIF
4467 "persist"."state" IN ('admission', 'discussion', 'verification')
4468 THEN
4469 RETURN "persist";
4470 ELSE
4471 RETURN NULL;
4472 END IF;
4473 END IF;
4474 IF
4475 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4476 coalesce("persist"."snapshot_created", FALSE) = FALSE
4477 THEN
4478 PERFORM "create_snapshot"("issue_id_p");
4479 "persist"."snapshot_created" = TRUE;
4480 IF "persist"."phase_finished" THEN
4481 IF "persist"."state" = 'admission' THEN
4482 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4483 ELSIF "persist"."state" = 'discussion' THEN
4484 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4485 ELSIF "persist"."state" = 'verification' THEN
4486 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
4487 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4488 SELECT * INTO "policy_row" FROM "policy"
4489 WHERE "id" = "issue_row"."policy_id";
4490 FOR "initiative_row" IN
4491 SELECT * FROM "initiative"
4492 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4493 FOR UPDATE
4494 LOOP
4495 IF
4496 "initiative_row"."polling" OR (
4497 "initiative_row"."satisfied_supporter_count" > 0 AND
4498 "initiative_row"."satisfied_supporter_count" *
4499 "policy_row"."initiative_quorum_den" >=
4500 "issue_row"."population" * "policy_row"."initiative_quorum_num"
4502 THEN
4503 UPDATE "initiative" SET "admitted" = TRUE
4504 WHERE "id" = "initiative_row"."id";
4505 ELSE
4506 UPDATE "initiative" SET "admitted" = FALSE
4507 WHERE "id" = "initiative_row"."id";
4508 END IF;
4509 END LOOP;
4510 END IF;
4511 END IF;
4512 RETURN "persist";
4513 END IF;
4514 IF
4515 "persist"."state" IN ('admission', 'discussion', 'verification') AND
4516 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
4517 THEN
4518 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
4519 "persist"."harmonic_weights_set" = TRUE;
4520 IF
4521 "persist"."phase_finished" OR
4522 "persist"."issue_revoked" OR
4523 "persist"."state" = 'admission'
4524 THEN
4525 RETURN "persist";
4526 ELSE
4527 RETURN NULL;
4528 END IF;
4529 END IF;
4530 IF "persist"."issue_revoked" THEN
4531 IF "persist"."state" = 'admission' THEN
4532 "state_v" := 'canceled_revoked_before_accepted';
4533 ELSIF "persist"."state" = 'discussion' THEN
4534 "state_v" := 'canceled_after_revocation_during_discussion';
4535 ELSIF "persist"."state" = 'verification' THEN
4536 "state_v" := 'canceled_after_revocation_during_verification';
4537 END IF;
4538 UPDATE "issue" SET
4539 "state" = "state_v",
4540 "closed" = "phase_finished",
4541 "phase_finished" = NULL
4542 WHERE "id" = "issue_id_p";
4543 RETURN NULL;
4544 END IF;
4545 IF "persist"."state" = 'admission' THEN
4546 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4547 FOR UPDATE;
4548 SELECT * INTO "policy_row"
4549 FROM "policy" WHERE "id" = "issue_row"."policy_id";
4550 IF
4551 ( now() >=
4552 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
4553 EXISTS (
4554 SELECT NULL FROM "initiative"
4555 WHERE "issue_id" = "issue_id_p"
4556 AND "supporter_count" > 0
4557 AND "supporter_count" * "policy_row"."issue_quorum_den"
4558 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4560 THEN
4561 UPDATE "issue" SET
4562 "state" = 'discussion',
4563 "accepted" = coalesce("phase_finished", now()),
4564 "phase_finished" = NULL
4565 WHERE "id" = "issue_id_p";
4566 ELSIF "issue_row"."phase_finished" NOTNULL THEN
4567 UPDATE "issue" SET
4568 "state" = 'canceled_issue_not_accepted',
4569 "closed" = "phase_finished",
4570 "phase_finished" = NULL
4571 WHERE "id" = "issue_id_p";
4572 END IF;
4573 RETURN NULL;
4574 END IF;
4575 IF "persist"."phase_finished" THEN
4576 IF "persist"."state" = 'discussion' THEN
4577 UPDATE "issue" SET
4578 "state" = 'verification',
4579 "half_frozen" = "phase_finished",
4580 "phase_finished" = NULL
4581 WHERE "id" = "issue_id_p";
4582 RETURN NULL;
4583 END IF;
4584 IF "persist"."state" = 'verification' THEN
4585 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
4586 FOR UPDATE;
4587 SELECT * INTO "policy_row" FROM "policy"
4588 WHERE "id" = "issue_row"."policy_id";
4589 IF EXISTS (
4590 SELECT NULL FROM "initiative"
4591 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
4592 ) THEN
4593 UPDATE "issue" SET
4594 "state" = 'voting',
4595 "fully_frozen" = "phase_finished",
4596 "phase_finished" = NULL
4597 WHERE "id" = "issue_id_p";
4598 ELSE
4599 UPDATE "issue" SET
4600 "state" = 'canceled_no_initiative_admitted',
4601 "fully_frozen" = "phase_finished",
4602 "closed" = "phase_finished",
4603 "phase_finished" = NULL
4604 WHERE "id" = "issue_id_p";
4605 -- NOTE: The following DELETE statements have effect only when
4606 -- issue state has been manipulated
4607 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
4608 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
4609 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
4610 END IF;
4611 RETURN NULL;
4612 END IF;
4613 IF "persist"."state" = 'voting' THEN
4614 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
4615 PERFORM "close_voting"("issue_id_p");
4616 "persist"."closed_voting" = TRUE;
4617 RETURN "persist";
4618 END IF;
4619 PERFORM "calculate_ranks"("issue_id_p");
4620 RETURN NULL;
4621 END IF;
4622 END IF;
4623 RAISE WARNING 'should not happen';
4624 RETURN NULL;
4625 END;
4626 $$;
4628 COMMENT ON FUNCTION "check_issue"
4629 ( "issue"."id"%TYPE,
4630 "check_issue_persistence" )
4631 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required, and perform the status change when necessary; Function must be called multiple times with the previous result as second parameter, until the result is NULL (see source code of function "check_everything")';
4634 CREATE FUNCTION "check_everything"()
4635 RETURNS VOID
4636 LANGUAGE 'plpgsql' VOLATILE AS $$
4637 DECLARE
4638 "issue_id_v" "issue"."id"%TYPE;
4639 "persist_v" "check_issue_persistence";
4640 BEGIN
4641 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
4642 DELETE FROM "expired_session";
4643 PERFORM "check_activity"();
4644 PERFORM "calculate_member_counts"();
4645 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4646 "persist_v" := NULL;
4647 LOOP
4648 "persist_v" := "check_issue"("issue_id_v", "persist_v");
4649 EXIT WHEN "persist_v" ISNULL;
4650 END LOOP;
4651 END LOOP;
4652 RETURN;
4653 END;
4654 $$;
4656 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue. Use this function only for development and debugging purposes, as you may run into locking and/or serialization problems in productive environments.';
4660 ----------------------
4661 -- Deletion of data --
4662 ----------------------
4665 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4666 RETURNS VOID
4667 LANGUAGE 'plpgsql' VOLATILE AS $$
4668 BEGIN
4669 IF EXISTS (
4670 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
4671 ) THEN
4672 -- override protection triggers:
4673 INSERT INTO "temporary_transaction_data" ("key", "value")
4674 VALUES ('override_protection_triggers', TRUE::TEXT);
4675 -- clean data:
4676 DELETE FROM "delegating_voter"
4677 WHERE "issue_id" = "issue_id_p";
4678 DELETE FROM "direct_voter"
4679 WHERE "issue_id" = "issue_id_p";
4680 DELETE FROM "delegating_interest_snapshot"
4681 WHERE "issue_id" = "issue_id_p";
4682 DELETE FROM "direct_interest_snapshot"
4683 WHERE "issue_id" = "issue_id_p";
4684 DELETE FROM "delegating_population_snapshot"
4685 WHERE "issue_id" = "issue_id_p";
4686 DELETE FROM "direct_population_snapshot"
4687 WHERE "issue_id" = "issue_id_p";
4688 DELETE FROM "non_voter"
4689 WHERE "issue_id" = "issue_id_p";
4690 DELETE FROM "delegation"
4691 WHERE "issue_id" = "issue_id_p";
4692 DELETE FROM "supporter"
4693 USING "initiative" -- NOTE: due to missing index on issue_id
4694 WHERE "initiative"."issue_id" = "issue_id_p"
4695 AND "supporter"."initiative_id" = "initiative_id";
4696 -- mark issue as cleaned:
4697 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
4698 -- finish overriding protection triggers (avoids garbage):
4699 DELETE FROM "temporary_transaction_data"
4700 WHERE "key" = 'override_protection_triggers';
4701 END IF;
4702 RETURN;
4703 END;
4704 $$;
4706 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4709 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4710 RETURNS VOID
4711 LANGUAGE 'plpgsql' VOLATILE AS $$
4712 BEGIN
4713 UPDATE "member" SET
4714 "last_login" = NULL,
4715 "last_delegation_check" = NULL,
4716 "login" = NULL,
4717 "password" = NULL,
4718 "authority" = NULL,
4719 "authority_uid" = NULL,
4720 "authority_login" = NULL,
4721 "locked" = TRUE,
4722 "active" = FALSE,
4723 "notify_email" = NULL,
4724 "notify_email_unconfirmed" = NULL,
4725 "notify_email_secret" = NULL,
4726 "notify_email_secret_expiry" = NULL,
4727 "notify_email_lock_expiry" = NULL,
4728 "login_recovery_expiry" = NULL,
4729 "password_reset_secret" = NULL,
4730 "password_reset_secret_expiry" = NULL,
4731 "organizational_unit" = NULL,
4732 "internal_posts" = NULL,
4733 "realname" = NULL,
4734 "birthday" = NULL,
4735 "address" = NULL,
4736 "email" = NULL,
4737 "xmpp_address" = NULL,
4738 "website" = NULL,
4739 "phone" = NULL,
4740 "mobile_phone" = NULL,
4741 "profession" = NULL,
4742 "external_memberships" = NULL,
4743 "external_posts" = NULL,
4744 "statement" = NULL
4745 WHERE "id" = "member_id_p";
4746 -- "text_search_data" is updated by triggers
4747 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4748 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4749 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4750 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4751 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4752 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4753 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4754 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4755 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4756 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4757 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4758 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4759 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4760 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4761 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4762 DELETE FROM "direct_voter" USING "issue"
4763 WHERE "direct_voter"."issue_id" = "issue"."id"
4764 AND "issue"."closed" ISNULL
4765 AND "member_id" = "member_id_p";
4766 RETURN;
4767 END;
4768 $$;
4770 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)';
4773 CREATE FUNCTION "delete_private_data"()
4774 RETURNS VOID
4775 LANGUAGE 'plpgsql' VOLATILE AS $$
4776 BEGIN
4777 DELETE FROM "temporary_transaction_data";
4778 DELETE FROM "member" WHERE "activated" ISNULL;
4779 UPDATE "member" SET
4780 "invite_code" = NULL,
4781 "invite_code_expiry" = NULL,
4782 "admin_comment" = NULL,
4783 "last_login" = NULL,
4784 "last_delegation_check" = NULL,
4785 "login" = NULL,
4786 "password" = NULL,
4787 "authority" = NULL,
4788 "authority_uid" = NULL,
4789 "authority_login" = NULL,
4790 "lang" = NULL,
4791 "notify_email" = NULL,
4792 "notify_email_unconfirmed" = NULL,
4793 "notify_email_secret" = NULL,
4794 "notify_email_secret_expiry" = NULL,
4795 "notify_email_lock_expiry" = NULL,
4796 "notify_level" = NULL,
4797 "login_recovery_expiry" = NULL,
4798 "password_reset_secret" = NULL,
4799 "password_reset_secret_expiry" = NULL,
4800 "organizational_unit" = NULL,
4801 "internal_posts" = NULL,
4802 "realname" = NULL,
4803 "birthday" = NULL,
4804 "address" = NULL,
4805 "email" = NULL,
4806 "xmpp_address" = NULL,
4807 "website" = NULL,
4808 "phone" = NULL,
4809 "mobile_phone" = NULL,
4810 "profession" = NULL,
4811 "external_memberships" = NULL,
4812 "external_posts" = NULL,
4813 "formatting_engine" = NULL,
4814 "statement" = NULL;
4815 -- "text_search_data" is updated by triggers
4816 DELETE FROM "setting";
4817 DELETE FROM "setting_map";
4818 DELETE FROM "member_relation_setting";
4819 DELETE FROM "member_image";
4820 DELETE FROM "contact";
4821 DELETE FROM "ignored_member";
4822 DELETE FROM "session";
4823 DELETE FROM "area_setting";
4824 DELETE FROM "issue_setting";
4825 DELETE FROM "ignored_initiative";
4826 DELETE FROM "initiative_setting";
4827 DELETE FROM "suggestion_setting";
4828 DELETE FROM "non_voter";
4829 DELETE FROM "direct_voter" USING "issue"
4830 WHERE "direct_voter"."issue_id" = "issue"."id"
4831 AND "issue"."closed" ISNULL;
4832 RETURN;
4833 END;
4834 $$;
4836 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. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
4840 COMMIT;

Impressum / About Us