liquid_feedback_core

view core.sql @ 279:03897de17853

Work on tables for OAuth2
author jbe
date Wed Aug 15 01:13:44 2012 +0200 (2012-08-15)
parents 0a42a2600a2b
children 5a32f862b2dd
line source
2 -- Execute the following command manually for PostgreSQL prior version 9.0:
3 -- CREATE LANGUAGE plpgsql;
5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
7 BEGIN;
9 CREATE VIEW "liquid_feedback_version" AS
10 SELECT * FROM (VALUES ('2.1.0', 2, 1, 0))
11 AS "subquery"("string", "major", "minor", "revision");
15 ----------------------
16 -- Full text search --
17 ----------------------
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
21 RETURNS TSQUERY
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
23 BEGIN
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
25 END;
26 $$;
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
31 CREATE FUNCTION "highlight"
32 ( "body_p" TEXT,
33 "query_text_p" TEXT )
34 RETURNS TEXT
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
36 BEGIN
37 RETURN ts_headline(
38 'pg_catalog.simple',
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
40 "text_search_query"("query_text_p"),
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
42 END;
43 $$;
45 COMMENT ON FUNCTION "highlight"
46 ( "body_p" TEXT,
47 "query_text_p" TEXT )
48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
52 -------------------------
53 -- Tables and indicies --
54 -------------------------
57 CREATE TABLE "system_setting" (
58 "member_ttl" INTERVAL );
59 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
61 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
62 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
64 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
67 CREATE TABLE "contingent" (
68 "time_frame" INTERVAL PRIMARY KEY,
69 "text_entry_limit" INT4,
70 "initiative_limit" INT4 );
72 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
74 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
75 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
78 CREATE TYPE "notify_level" AS ENUM
79 ('none', 'voting', 'verification', 'discussion', 'all');
81 COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything';
84 CREATE TABLE "member" (
85 "id" SERIAL4 PRIMARY KEY,
86 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
87 "invite_code" TEXT UNIQUE,
88 "invite_code_expiry" TIMESTAMPTZ,
89 "admin_comment" TEXT,
90 "activated" TIMESTAMPTZ,
91 "last_activity" DATE,
92 "last_login" TIMESTAMPTZ,
93 "login" TEXT UNIQUE,
94 "password" TEXT,
95 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
96 "active" BOOLEAN NOT NULL DEFAULT FALSE,
97 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
98 "lang" TEXT,
99 "notify_email" TEXT,
100 "notify_email_unconfirmed" TEXT,
101 "notify_email_secret" TEXT UNIQUE,
102 "notify_email_secret_expiry" TIMESTAMPTZ,
103 "notify_email_lock_expiry" TIMESTAMPTZ,
104 "notify_level" "notify_level",
105 "password_reset_secret" TEXT UNIQUE,
106 "password_reset_secret_expiry" TIMESTAMPTZ,
107 "name" TEXT UNIQUE,
108 "identification" TEXT UNIQUE,
109 "authentication" TEXT,
110 "organizational_unit" TEXT,
111 "internal_posts" TEXT,
112 "realname" TEXT,
113 "birthday" DATE,
114 "address" TEXT,
115 "email" TEXT,
116 "xmpp_address" TEXT,
117 "website" TEXT,
118 "phone" TEXT,
119 "mobile_phone" TEXT,
120 "profession" TEXT,
121 "external_memberships" TEXT,
122 "external_posts" TEXT,
123 "formatting_engine" TEXT,
124 "statement" TEXT,
125 "text_search_data" TSVECTOR,
126 CONSTRAINT "active_requires_activated_and_last_activity"
127 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
128 CONSTRAINT "name_not_null_if_activated"
129 CHECK ("activated" ISNULL OR "name" NOTNULL) );
130 CREATE INDEX "member_active_idx" ON "member" ("active");
131 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
132 CREATE TRIGGER "update_text_search_data"
133 BEFORE INSERT OR UPDATE ON "member"
134 FOR EACH ROW EXECUTE PROCEDURE
135 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
136 "name", "identification", "organizational_unit", "internal_posts",
137 "realname", "external_memberships", "external_posts", "statement" );
139 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
141 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
142 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
143 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
144 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
145 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
146 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
147 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
148 COMMENT ON COLUMN "member"."login" IS 'Login name';
149 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
150 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
151 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
152 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
153 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
154 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
155 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
156 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
157 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
158 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
159 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address, may be NULL if member did not make any selection yet';
160 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
161 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
162 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
163 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
164 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
165 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
166 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
167 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
168 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
169 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
170 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
173 -- DEPRECATED API TABLES --
175 CREATE TYPE "application_access_level" AS ENUM
176 ('member', 'full', 'pseudonymous', 'anonymous');
178 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
181 CREATE TABLE "member_application" (
182 "id" SERIAL8 PRIMARY KEY,
183 UNIQUE ("member_id", "name"),
184 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
185 ON DELETE CASCADE ON UPDATE CASCADE,
186 "name" TEXT NOT NULL,
187 "comment" TEXT,
188 "access_level" "application_access_level" NOT NULL,
189 "key" TEXT NOT NULL UNIQUE,
190 "last_usage" TIMESTAMPTZ );
192 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
194 -- END OF DEPRECARED API TABLES --
197 -- NEW PRELIMINARY API TABLES --
199 CREATE TYPE "api_access_level" AS ENUM (
200 'none', 'anonymous', 'authors_pseudonymous', 'all_pseudonymous', 'everything', 'member' );
202 COMMENT ON TYPE "api_access_level" IS 'PRELIMINARY, SUBJECT TO CHANGE! Access scope for API consumers.';
205 CREATE TABLE "registered_client" (
206 UNIQUE ("client_identifier", "id"), -- index needed for foreign-key on table "authorized_client"
207 "id" SERIAL8 PRIMARY KEY,
208 "name" TEXT NOT NULL,
209 "client_identifier" TEXT NOT NULL,
210 "client_secret" TEXT,
211 "code_grant" BOOLEAN NOT NULL,
212 "implicit_grant" BOOLEAN NOT NULL,
213 "client_grant" BOOLEAN NOT NULL,
214 "access_level" "api_access_level",
215 "client_grant_access_level" "api_access_level",
216 "single_token" BOOLEAN NOT NULL DEFAULT FALSE,
217 "always_authorized" BOOLEAN NOT NULL DEFAULT FALSE,
218 "auth_duration" INTERVAL,
219 "login_duration" INTERVAL,
220 "refresh_duration" INTERVAL,
221 "access_duration" INTERVAL,
222 CONSTRAINT "code_or_implicit_grant_requires_access_level"
223 CHECK (("code_grant"=FALSE AND "implicit_grant"=FALSE) OR "access_level" NOTNULL),
224 CONSTRAINT "client_grant_requires_client_grant_access_level"
225 CHECK ("client_grant"=FALSE OR "client_grant_access_level" NOTNULL) );
227 COMMENT ON TABLE "registered_client" IS 'PRELIMINARY, SUBJECT TO CHANGE! OAuth2 client registered by administrator';
229 COMMENT ON COLUMN "registered_client"."name" IS 'Name of the registered client';
230 COMMENT ON COLUMN "registered_client"."client_identifier" IS 'OAuth2 client id, also used as redirection endpoint if "code_grant" or "implicit_grant" is set to TRUE';
231 COMMENT ON COLUMN "registered_client"."client_secret" IS 'Secret for client authentication';
232 COMMENT ON COLUMN "registered_client"."code_grant" IS 'Enable OAuth2 Authorization Code Grant';
233 COMMENT ON COLUMN "registered_client"."implicit_grant" IS 'Enable OAuth2 Implicit Grant';
234 COMMENT ON COLUMN "registered_client"."client_grant" IS 'Enable OAuth2 Client Credentials Grant';
235 COMMENT ON COLUMN "registered_client"."access_level" IS 'Maximum access level for OAuth2 Authorization Code Grant and Implicit Grant';
236 COMMENT ON COLUMN "registered_client"."client_grant_access_level" IS 'Maximum access level for OAuth2 Client Credentials Grant';
237 COMMENT ON COLUMN "registered_client"."single_token" IS 'Allow only one valid refresh token';
238 COMMENT ON COLUMN "registered_client"."always_authorized" IS 'Members do not need to authorize the client';
239 COMMENT ON COLUMN "registered_client"."auth_duration" IS 'Duration of authorization by member';
240 COMMENT ON COLUMN "registered_client"."login_duration" IS 'Life time of refresh code chain';
241 COMMENT ON COLUMN "registered_client"."refresh_duration" IS 'Life time of a refresh code';
242 COMMENT ON COLUMN "registered_client"."access_duration" IS 'Life time of an access code';
245 CREATE TABLE "authorized_client" (
246 "id" SERIAL8 PRIMARY KEY,
247 "registered_client_id" INT8 REFERENCES "registered_client" ("id")
248 ON DELETE CASCADE ON UPDATE CASCADE,
249 "client_identifier" TEXT NOT NULL,
250 FOREIGN KEY ("registered_client_id", "client_identifier")
251 REFERENCES "registered_client" ("id", "client_identifier")
252 ON DELETE CASCADE ON UPDATE CASCADE,
253 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
254 ON DELETE CASCADE ON UPDATE CASCADE,
255 "access_level" "api_access_level" NOT NULL,
256 "first_auth" TIMESTAMPTZ NOT NULL,
257 "last_auth" TIMESTAMPTZ NOT NULL,
258 UNIQUE ("client_identifier", "member_id") );
260 COMMENT ON TABLE "authorized_client" IS 'PRELIMINARY, SUBJECT TO CHANGE! OAuth2 client authorized by member, or automatically authorized for a member if "registered_client"."always_authorized" is set';
262 COMMENT ON COLUMN "authorized_client"."registered_client_id" IS 'Set, if client is a registered client';
263 COMMENT ON COLUMN "authorized_client"."client_identifier" IS 'OAuth2 client id, also used as redirection endpoint';
264 COMMENT ON COLUMN "authorized_client"."member_id" IS 'Member who authorized the client';
265 COMMENT ON COLUMN "authorized_client"."access_level" IS 'Authorized access level';
266 COMMENT ON COLUMN "authorized_client"."first_auth" IS 'Date/time of initial authorization';
267 COMMENT ON COLUMN "authorized_client"."last_auth" IS 'Date/time of last authorization refresh';
270 CREATE TABLE "authorized_client_token" (
271 "id" SERIAL8 PRIMARY KEY,
272 "authorized_client_id" INT8 NOT NULL REFERENCES "authorized_client"
273 ON DELETE CASCADE ON UPDATE CASCADE,
274 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
275 "authorization_code" TEXT,
276 "refreshed" TIMESTAMPTZ,
277 "refresh_token" TEXT,
278 "old_refresh_token" TEXT,
279 CONSTRAINT "one_of_authorization_code_and_refresh_token_set"
280 CHECK ("authorization_code" NOTNULL OR "refresh_token" NOTNULL),
281 CONSTRAINT "refresh_token_if_and_only_if_refreshed"
282 CHECK ("refreshed" NOTNULL = "refresh_token" NOTNULL),
283 CONSTRAINT "old_refresh_token_requires_current_refresh_token"
284 CHECK ("refresh_token" NOTNULL OR "old_refresh_token" ISNULL) );
286 COMMENT ON TABLE "authorized_client_token" IS 'PRELIMINARY, SUBJECT TO CHANGE! Issued OAuth2 authorization codes and refresh tokens';
288 COMMENT ON COLUMN "authorized_client_token"."created" IS 'Date/time when authorization code (or first refresh token when there is no authorization code) has been created';
289 COMMENT ON COLUMN "authorized_client_token"."authorization_code" IS 'OAuth2 authorization code (only valid for a very short time after it has been created)';
290 COMMENT ON COLUMN "authorized_client_token"."refreshed" IS 'Date/time of last refresh';
291 COMMENT ON COLUMN "authorized_client_token"."refresh_token" IS 'OAuth2 refresh token';
293 -- END OF NEW PRELIMINARY API TABLES --
296 CREATE TABLE "member_history" (
297 "id" SERIAL8 PRIMARY KEY,
298 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
299 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
300 "active" BOOLEAN NOT NULL,
301 "name" TEXT NOT NULL );
302 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
304 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
306 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
307 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
310 CREATE TABLE "rendered_member_statement" (
311 PRIMARY KEY ("member_id", "format"),
312 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
313 "format" TEXT,
314 "content" TEXT NOT NULL );
316 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)';
319 CREATE TABLE "setting" (
320 PRIMARY KEY ("member_id", "key"),
321 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
322 "key" TEXT NOT NULL,
323 "value" TEXT NOT NULL );
324 CREATE INDEX "setting_key_idx" ON "setting" ("key");
326 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
328 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
331 CREATE TABLE "setting_map" (
332 PRIMARY KEY ("member_id", "key", "subkey"),
333 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
334 "key" TEXT NOT NULL,
335 "subkey" TEXT NOT NULL,
336 "value" TEXT NOT NULL );
337 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
339 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
341 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
342 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
343 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
346 CREATE TABLE "member_relation_setting" (
347 PRIMARY KEY ("member_id", "key", "other_member_id"),
348 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
349 "key" TEXT NOT NULL,
350 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
351 "value" TEXT NOT NULL );
353 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
356 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
358 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
361 CREATE TABLE "member_image" (
362 PRIMARY KEY ("member_id", "image_type", "scaled"),
363 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
364 "image_type" "member_image_type",
365 "scaled" BOOLEAN,
366 "content_type" TEXT,
367 "data" BYTEA NOT NULL );
369 COMMENT ON TABLE "member_image" IS 'Images of members';
371 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
374 CREATE TABLE "member_count" (
375 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
376 "total_count" INT4 NOT NULL );
378 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';
380 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
381 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
384 CREATE TABLE "contact" (
385 PRIMARY KEY ("member_id", "other_member_id"),
386 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
387 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
388 "public" BOOLEAN NOT NULL DEFAULT FALSE,
389 CONSTRAINT "cant_save_yourself_as_contact"
390 CHECK ("member_id" != "other_member_id") );
391 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
393 COMMENT ON TABLE "contact" IS 'Contact lists';
395 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
396 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
397 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
400 CREATE TABLE "ignored_member" (
401 PRIMARY KEY ("member_id", "other_member_id"),
402 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
403 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
404 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
406 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
408 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
409 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
412 CREATE TABLE "session" (
413 "ident" TEXT PRIMARY KEY,
414 "additional_secret" TEXT,
415 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
416 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
417 "lang" TEXT );
418 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
420 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
422 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
423 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
424 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
425 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
428 CREATE TABLE "policy" (
429 "id" SERIAL4 PRIMARY KEY,
430 "index" INT4 NOT NULL,
431 "active" BOOLEAN NOT NULL DEFAULT TRUE,
432 "name" TEXT NOT NULL UNIQUE,
433 "description" TEXT NOT NULL DEFAULT '',
434 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
435 "admission_time" INTERVAL,
436 "discussion_time" INTERVAL,
437 "verification_time" INTERVAL,
438 "voting_time" INTERVAL,
439 "issue_quorum_num" INT4 NOT NULL,
440 "issue_quorum_den" INT4 NOT NULL,
441 "initiative_quorum_num" INT4 NOT NULL,
442 "initiative_quorum_den" INT4 NOT NULL,
443 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
444 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
445 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
446 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
447 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
448 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
449 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
450 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
451 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
452 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
453 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
454 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
455 CONSTRAINT "timing" CHECK (
456 ( "polling" = FALSE AND
457 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
458 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
459 ( "polling" = TRUE AND
460 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
461 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
462 ( "polling" = TRUE AND
463 "admission_time" ISNULL AND "discussion_time" ISNULL AND
464 "verification_time" ISNULL AND "voting_time" ISNULL ) ) );
465 CREATE INDEX "policy_active_idx" ON "policy" ("active");
467 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
469 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
470 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
471 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues, i.e. polls ("admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for issues)';
472 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
473 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
474 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"';
475 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'')';
476 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''';
477 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''';
478 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
479 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
480 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
481 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
482 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.';
483 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
484 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';
485 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';
486 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';
487 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.';
488 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';
489 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';
490 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
491 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
494 CREATE TABLE "unit" (
495 "id" SERIAL4 PRIMARY KEY,
496 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
497 "active" BOOLEAN NOT NULL DEFAULT TRUE,
498 "name" TEXT NOT NULL,
499 "description" TEXT NOT NULL DEFAULT '',
500 "member_count" INT4,
501 "text_search_data" TSVECTOR );
502 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
503 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
504 CREATE INDEX "unit_active_idx" ON "unit" ("active");
505 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
506 CREATE TRIGGER "update_text_search_data"
507 BEFORE INSERT OR UPDATE ON "unit"
508 FOR EACH ROW EXECUTE PROCEDURE
509 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
510 "name", "description" );
512 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
514 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
515 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
516 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
519 CREATE TABLE "unit_setting" (
520 PRIMARY KEY ("member_id", "key", "unit_id"),
521 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
522 "key" TEXT NOT NULL,
523 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
524 "value" TEXT NOT NULL );
526 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
529 CREATE TABLE "area" (
530 "id" SERIAL4 PRIMARY KEY,
531 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
532 "active" BOOLEAN NOT NULL DEFAULT TRUE,
533 "name" TEXT NOT NULL,
534 "description" TEXT NOT NULL DEFAULT '',
535 "direct_member_count" INT4,
536 "member_weight" INT4,
537 "text_search_data" TSVECTOR );
538 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
539 CREATE INDEX "area_active_idx" ON "area" ("active");
540 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
541 CREATE TRIGGER "update_text_search_data"
542 BEFORE INSERT OR UPDATE ON "area"
543 FOR EACH ROW EXECUTE PROCEDURE
544 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
545 "name", "description" );
547 COMMENT ON TABLE "area" IS 'Subject areas';
549 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
550 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"';
551 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
554 CREATE TABLE "area_setting" (
555 PRIMARY KEY ("member_id", "key", "area_id"),
556 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
557 "key" TEXT NOT NULL,
558 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
559 "value" TEXT NOT NULL );
561 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
564 CREATE TABLE "allowed_policy" (
565 PRIMARY KEY ("area_id", "policy_id"),
566 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
567 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
568 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
569 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
571 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
573 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
576 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
578 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';
581 CREATE TYPE "issue_state" AS ENUM (
582 'admission', 'discussion', 'verification', 'voting',
583 'canceled_revoked_before_accepted',
584 'canceled_issue_not_accepted',
585 'canceled_after_revocation_during_discussion',
586 'canceled_after_revocation_during_verification',
587 'calculation',
588 'canceled_no_initiative_admitted',
589 'finished_without_winner', 'finished_with_winner');
591 COMMENT ON TYPE "issue_state" IS 'State of issues';
594 CREATE TABLE "issue" (
595 "id" SERIAL4 PRIMARY KEY,
596 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
597 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
598 "state" "issue_state" NOT NULL DEFAULT 'admission',
599 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
600 "accepted" TIMESTAMPTZ,
601 "half_frozen" TIMESTAMPTZ,
602 "fully_frozen" TIMESTAMPTZ,
603 "closed" TIMESTAMPTZ,
604 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
605 "cleaned" TIMESTAMPTZ,
606 "admission_time" INTERVAL NOT NULL,
607 "discussion_time" INTERVAL NOT NULL,
608 "verification_time" INTERVAL NOT NULL,
609 "voting_time" INTERVAL NOT NULL,
610 "snapshot" TIMESTAMPTZ,
611 "latest_snapshot_event" "snapshot_event",
612 "population" INT4,
613 "voter_count" INT4,
614 "status_quo_schulze_rank" INT4,
615 CONSTRAINT "valid_state" CHECK ((
616 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
617 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
618 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
619 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
620 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
621 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
622 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
623 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
624 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
625 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
626 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
627 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
628 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
629 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
630 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
631 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
632 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
633 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
634 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
635 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
636 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
637 )),
638 CONSTRAINT "state_change_order" CHECK (
639 "created" <= "accepted" AND
640 "accepted" <= "half_frozen" AND
641 "half_frozen" <= "fully_frozen" AND
642 "fully_frozen" <= "closed" ),
643 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
644 "cleaned" ISNULL OR "closed" NOTNULL ),
645 CONSTRAINT "last_snapshot_on_full_freeze"
646 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
647 CONSTRAINT "freeze_requires_snapshot"
648 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
649 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
650 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
651 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
652 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
653 CREATE INDEX "issue_created_idx" ON "issue" ("created");
654 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
655 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
656 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
657 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
658 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
659 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
661 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
663 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
664 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.';
665 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.';
666 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.';
667 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
668 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
669 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
670 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
671 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
672 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
673 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
674 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';
675 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
676 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';
677 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
680 CREATE TABLE "issue_setting" (
681 PRIMARY KEY ("member_id", "key", "issue_id"),
682 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
683 "key" TEXT NOT NULL,
684 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
685 "value" TEXT NOT NULL );
687 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
690 CREATE TABLE "initiative" (
691 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
692 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
693 "id" SERIAL4 PRIMARY KEY,
694 "name" TEXT NOT NULL,
695 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
696 "discussion_url" TEXT,
697 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
698 "revoked" TIMESTAMPTZ,
699 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
700 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
701 "admitted" BOOLEAN,
702 "supporter_count" INT4,
703 "informed_supporter_count" INT4,
704 "satisfied_supporter_count" INT4,
705 "satisfied_informed_supporter_count" INT4,
706 "positive_votes" INT4,
707 "negative_votes" INT4,
708 "direct_majority" BOOLEAN,
709 "indirect_majority" BOOLEAN,
710 "schulze_rank" INT4,
711 "better_than_status_quo" BOOLEAN,
712 "worse_than_status_quo" BOOLEAN,
713 "reverse_beat_path" BOOLEAN,
714 "multistage_majority" BOOLEAN,
715 "eligible" BOOLEAN,
716 "winner" BOOLEAN,
717 "rank" INT4,
718 "text_search_data" TSVECTOR,
719 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
720 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
721 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
722 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
723 CONSTRAINT "revoked_initiatives_cant_be_admitted"
724 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
725 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
726 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
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 is an option for a poll (see "policy"."polling"), and does not need to pass the initiative quorum';
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"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
757 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
758 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
759 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
760 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
761 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
762 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
763 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"';
764 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
765 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
766 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
767 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
768 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';
769 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';
770 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"';
771 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
772 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';
775 CREATE TABLE "battle" (
776 "issue_id" INT4 NOT NULL,
777 "winning_initiative_id" INT4,
778 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
779 "losing_initiative_id" INT4,
780 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
781 "count" INT4 NOT NULL,
782 CONSTRAINT "initiative_ids_not_equal" CHECK (
783 "winning_initiative_id" != "losing_initiative_id" OR
784 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
785 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
786 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
787 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
788 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
790 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';
793 CREATE TABLE "ignored_initiative" (
794 PRIMARY KEY ("initiative_id", "member_id"),
795 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
796 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
797 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
799 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
802 CREATE TABLE "initiative_setting" (
803 PRIMARY KEY ("member_id", "key", "initiative_id"),
804 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
805 "key" TEXT NOT NULL,
806 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
807 "value" TEXT NOT NULL );
809 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
812 CREATE TABLE "draft" (
813 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
814 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
815 "id" SERIAL8 PRIMARY KEY,
816 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
817 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
818 "formatting_engine" TEXT,
819 "content" TEXT NOT NULL,
820 "text_search_data" TSVECTOR );
821 CREATE INDEX "draft_created_idx" ON "draft" ("created");
822 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
823 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
824 CREATE TRIGGER "update_text_search_data"
825 BEFORE INSERT OR UPDATE ON "draft"
826 FOR EACH ROW EXECUTE PROCEDURE
827 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
829 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.';
831 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
832 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
835 CREATE TABLE "rendered_draft" (
836 PRIMARY KEY ("draft_id", "format"),
837 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
838 "format" TEXT,
839 "content" TEXT NOT NULL );
841 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)';
844 CREATE TABLE "suggestion" (
845 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
846 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
847 "id" SERIAL8 PRIMARY KEY,
848 "draft_id" INT8 NOT NULL,
849 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
850 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
851 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
852 "name" TEXT NOT NULL,
853 "formatting_engine" TEXT,
854 "content" TEXT NOT NULL DEFAULT '',
855 "text_search_data" TSVECTOR,
856 "minus2_unfulfilled_count" INT4,
857 "minus2_fulfilled_count" INT4,
858 "minus1_unfulfilled_count" INT4,
859 "minus1_fulfilled_count" INT4,
860 "plus1_unfulfilled_count" INT4,
861 "plus1_fulfilled_count" INT4,
862 "plus2_unfulfilled_count" INT4,
863 "plus2_fulfilled_count" INT4 );
864 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
865 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
866 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
867 CREATE TRIGGER "update_text_search_data"
868 BEFORE INSERT OR UPDATE ON "suggestion"
869 FOR EACH ROW EXECUTE PROCEDURE
870 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
871 "name", "content");
873 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';
875 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")';
876 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
877 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
878 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
879 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
880 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
881 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
882 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
883 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
886 CREATE TABLE "rendered_suggestion" (
887 PRIMARY KEY ("suggestion_id", "format"),
888 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
889 "format" TEXT,
890 "content" TEXT NOT NULL );
892 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)';
895 CREATE TABLE "suggestion_setting" (
896 PRIMARY KEY ("member_id", "key", "suggestion_id"),
897 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
898 "key" TEXT NOT NULL,
899 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
900 "value" TEXT NOT NULL );
902 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
905 CREATE TABLE "privilege" (
906 PRIMARY KEY ("unit_id", "member_id"),
907 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
908 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
909 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
910 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
911 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
912 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
913 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
914 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
915 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
917 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
919 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
920 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
921 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
922 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
923 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
924 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
925 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create polls (see "policy"."polling" and "initiative"."polling")';
928 CREATE TABLE "membership" (
929 PRIMARY KEY ("area_id", "member_id"),
930 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
931 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
932 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
934 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
937 CREATE TABLE "interest" (
938 PRIMARY KEY ("issue_id", "member_id"),
939 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
940 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
941 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
943 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.';
946 CREATE TABLE "initiator" (
947 PRIMARY KEY ("initiative_id", "member_id"),
948 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
949 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
950 "accepted" BOOLEAN );
951 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
953 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.';
955 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.';
958 CREATE TABLE "supporter" (
959 "issue_id" INT4 NOT NULL,
960 PRIMARY KEY ("initiative_id", "member_id"),
961 "initiative_id" INT4,
962 "member_id" INT4,
963 "draft_id" INT8 NOT NULL,
964 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
965 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
966 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
968 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.';
970 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
971 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")';
974 CREATE TABLE "opinion" (
975 "initiative_id" INT4 NOT NULL,
976 PRIMARY KEY ("suggestion_id", "member_id"),
977 "suggestion_id" INT8,
978 "member_id" INT4,
979 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
980 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
981 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
982 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
983 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
985 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.';
987 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
990 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
992 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
995 CREATE TABLE "delegation" (
996 "id" SERIAL8 PRIMARY KEY,
997 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
998 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
999 "scope" "delegation_scope" NOT NULL,
1000 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1001 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1002 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1003 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1004 CONSTRAINT "no_unit_delegation_to_null"
1005 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1006 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1007 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1008 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1009 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1010 UNIQUE ("unit_id", "truster_id"),
1011 UNIQUE ("area_id", "truster_id"),
1012 UNIQUE ("issue_id", "truster_id") );
1013 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1014 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1016 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1018 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1019 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1020 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1023 CREATE TABLE "direct_population_snapshot" (
1024 PRIMARY KEY ("issue_id", "event", "member_id"),
1025 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1026 "event" "snapshot_event",
1027 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1028 "weight" INT4 );
1029 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
1031 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
1033 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1034 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
1037 CREATE TABLE "delegating_population_snapshot" (
1038 PRIMARY KEY ("issue_id", "event", "member_id"),
1039 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1040 "event" "snapshot_event",
1041 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1042 "weight" INT4,
1043 "scope" "delegation_scope" NOT NULL,
1044 "delegate_member_ids" INT4[] NOT NULL );
1045 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
1047 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
1049 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1050 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
1051 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
1052 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"';
1055 CREATE TABLE "direct_interest_snapshot" (
1056 PRIMARY KEY ("issue_id", "event", "member_id"),
1057 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1058 "event" "snapshot_event",
1059 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1060 "weight" INT4 );
1061 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1063 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
1065 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1066 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1069 CREATE TABLE "delegating_interest_snapshot" (
1070 PRIMARY KEY ("issue_id", "event", "member_id"),
1071 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1072 "event" "snapshot_event",
1073 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1074 "weight" INT4,
1075 "scope" "delegation_scope" NOT NULL,
1076 "delegate_member_ids" INT4[] NOT NULL );
1077 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1079 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
1081 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1082 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1083 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1084 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"';
1087 CREATE TABLE "direct_supporter_snapshot" (
1088 "issue_id" INT4 NOT NULL,
1089 PRIMARY KEY ("initiative_id", "event", "member_id"),
1090 "initiative_id" INT4,
1091 "event" "snapshot_event",
1092 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1093 "draft_id" INT8 NOT NULL,
1094 "informed" BOOLEAN NOT NULL,
1095 "satisfied" BOOLEAN NOT NULL,
1096 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1097 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1098 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1099 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1101 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1103 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';
1104 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1105 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1106 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1109 CREATE TABLE "non_voter" (
1110 PRIMARY KEY ("issue_id", "member_id"),
1111 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1112 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1113 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1115 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1118 CREATE TABLE "direct_voter" (
1119 PRIMARY KEY ("issue_id", "member_id"),
1120 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1121 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1122 "weight" INT4 );
1123 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1125 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.';
1127 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1130 CREATE TABLE "delegating_voter" (
1131 PRIMARY KEY ("issue_id", "member_id"),
1132 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1133 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1134 "weight" INT4,
1135 "scope" "delegation_scope" NOT NULL,
1136 "delegate_member_ids" INT4[] NOT NULL );
1137 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1139 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1141 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1142 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1143 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"';
1146 CREATE TABLE "vote" (
1147 "issue_id" INT4 NOT NULL,
1148 PRIMARY KEY ("initiative_id", "member_id"),
1149 "initiative_id" INT4,
1150 "member_id" INT4,
1151 "grade" INT4,
1152 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1153 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1154 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1156 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.';
1158 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1159 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.';
1162 CREATE TABLE "voting_comment" (
1163 PRIMARY KEY ("issue_id", "member_id"),
1164 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1165 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1166 "changed" TIMESTAMPTZ,
1167 "formatting_engine" TEXT,
1168 "content" TEXT NOT NULL,
1169 "text_search_data" TSVECTOR );
1170 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1171 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1172 CREATE TRIGGER "update_text_search_data"
1173 BEFORE INSERT OR UPDATE ON "voting_comment"
1174 FOR EACH ROW EXECUTE PROCEDURE
1175 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1177 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1179 COMMENT ON COLUMN "voting_comment"."changed" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
1182 CREATE TABLE "rendered_voting_comment" (
1183 PRIMARY KEY ("issue_id", "member_id", "format"),
1184 FOREIGN KEY ("issue_id", "member_id")
1185 REFERENCES "voting_comment" ("issue_id", "member_id")
1186 ON DELETE CASCADE ON UPDATE CASCADE,
1187 "issue_id" INT4,
1188 "member_id" INT4,
1189 "format" TEXT,
1190 "content" TEXT NOT NULL );
1192 COMMENT ON TABLE "rendered_voting_comment" IS 'This table may be used by frontends to cache "rendered" voting comments (e.g. HTML output generated from wiki text)';
1195 CREATE TYPE "event_type" AS ENUM (
1196 'issue_state_changed',
1197 'initiative_created_in_new_issue',
1198 'initiative_created_in_existing_issue',
1199 'initiative_revoked',
1200 'new_draft_created',
1201 'suggestion_created');
1203 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1206 CREATE TABLE "event" (
1207 "id" SERIAL8 PRIMARY KEY,
1208 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1209 "event" "event_type" NOT NULL,
1210 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1211 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1212 "state" "issue_state" CHECK ("state" != 'calculation'),
1213 "initiative_id" INT4,
1214 "draft_id" INT8,
1215 "suggestion_id" INT8,
1216 FOREIGN KEY ("issue_id", "initiative_id")
1217 REFERENCES "initiative" ("issue_id", "id")
1218 ON DELETE CASCADE ON UPDATE CASCADE,
1219 FOREIGN KEY ("initiative_id", "draft_id")
1220 REFERENCES "draft" ("initiative_id", "id")
1221 ON DELETE CASCADE ON UPDATE CASCADE,
1222 FOREIGN KEY ("initiative_id", "suggestion_id")
1223 REFERENCES "suggestion" ("initiative_id", "id")
1224 ON DELETE CASCADE ON UPDATE CASCADE,
1225 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1226 "event" != 'issue_state_changed' OR (
1227 "member_id" ISNULL AND
1228 "issue_id" NOTNULL AND
1229 "state" NOTNULL AND
1230 "initiative_id" ISNULL AND
1231 "draft_id" ISNULL AND
1232 "suggestion_id" ISNULL )),
1233 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1234 "event" NOT IN (
1235 'initiative_created_in_new_issue',
1236 'initiative_created_in_existing_issue',
1237 'initiative_revoked',
1238 'new_draft_created'
1239 ) OR (
1240 "member_id" NOTNULL AND
1241 "issue_id" NOTNULL AND
1242 "state" NOTNULL AND
1243 "initiative_id" NOTNULL AND
1244 "draft_id" NOTNULL AND
1245 "suggestion_id" ISNULL )),
1246 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1247 "event" != 'suggestion_created' OR (
1248 "member_id" NOTNULL AND
1249 "issue_id" NOTNULL AND
1250 "state" NOTNULL AND
1251 "initiative_id" NOTNULL AND
1252 "draft_id" ISNULL AND
1253 "suggestion_id" NOTNULL )) );
1254 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1256 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1258 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1259 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1260 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1261 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1264 CREATE TABLE "notification_sent" (
1265 "event_id" INT8 NOT NULL );
1266 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1268 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1269 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1273 ----------------------------------------------
1274 -- Writing of history entries and event log --
1275 ----------------------------------------------
1278 CREATE FUNCTION "write_member_history_trigger"()
1279 RETURNS TRIGGER
1280 LANGUAGE 'plpgsql' VOLATILE AS $$
1281 BEGIN
1282 IF
1283 ( NEW."active" != OLD."active" OR
1284 NEW."name" != OLD."name" ) AND
1285 OLD."activated" NOTNULL
1286 THEN
1287 INSERT INTO "member_history"
1288 ("member_id", "active", "name")
1289 VALUES (NEW."id", OLD."active", OLD."name");
1290 END IF;
1291 RETURN NULL;
1292 END;
1293 $$;
1295 CREATE TRIGGER "write_member_history"
1296 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1297 "write_member_history_trigger"();
1299 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1300 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1303 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1304 RETURNS TRIGGER
1305 LANGUAGE 'plpgsql' VOLATILE AS $$
1306 BEGIN
1307 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1308 INSERT INTO "event" ("event", "issue_id", "state")
1309 VALUES ('issue_state_changed', NEW."id", NEW."state");
1310 END IF;
1311 RETURN NULL;
1312 END;
1313 $$;
1315 CREATE TRIGGER "write_event_issue_state_changed"
1316 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1317 "write_event_issue_state_changed_trigger"();
1319 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1320 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1323 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1324 RETURNS TRIGGER
1325 LANGUAGE 'plpgsql' VOLATILE AS $$
1326 DECLARE
1327 "initiative_row" "initiative"%ROWTYPE;
1328 "issue_row" "issue"%ROWTYPE;
1329 "event_v" "event_type";
1330 BEGIN
1331 SELECT * INTO "initiative_row" FROM "initiative"
1332 WHERE "id" = NEW."initiative_id";
1333 SELECT * INTO "issue_row" FROM "issue"
1334 WHERE "id" = "initiative_row"."issue_id";
1335 IF EXISTS (
1336 SELECT NULL FROM "draft"
1337 WHERE "initiative_id" = NEW."initiative_id"
1338 AND "id" != NEW."id"
1339 ) THEN
1340 "event_v" := 'new_draft_created';
1341 ELSE
1342 IF EXISTS (
1343 SELECT NULL FROM "initiative"
1344 WHERE "issue_id" = "initiative_row"."issue_id"
1345 AND "id" != "initiative_row"."id"
1346 ) THEN
1347 "event_v" := 'initiative_created_in_existing_issue';
1348 ELSE
1349 "event_v" := 'initiative_created_in_new_issue';
1350 END IF;
1351 END IF;
1352 INSERT INTO "event" (
1353 "event", "member_id",
1354 "issue_id", "state", "initiative_id", "draft_id"
1355 ) VALUES (
1356 "event_v",
1357 NEW."author_id",
1358 "initiative_row"."issue_id",
1359 "issue_row"."state",
1360 "initiative_row"."id",
1361 NEW."id" );
1362 RETURN NULL;
1363 END;
1364 $$;
1366 CREATE TRIGGER "write_event_initiative_or_draft_created"
1367 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1368 "write_event_initiative_or_draft_created_trigger"();
1370 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1371 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1374 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1375 RETURNS TRIGGER
1376 LANGUAGE 'plpgsql' VOLATILE AS $$
1377 DECLARE
1378 "issue_row" "issue"%ROWTYPE;
1379 "draft_id_v" "draft"."id"%TYPE;
1380 BEGIN
1381 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1382 SELECT * INTO "issue_row" FROM "issue"
1383 WHERE "id" = NEW."issue_id";
1384 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1385 WHERE "initiative_id" = NEW."id";
1386 INSERT INTO "event" (
1387 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1388 ) VALUES (
1389 'initiative_revoked',
1390 NEW."revoked_by_member_id",
1391 NEW."issue_id",
1392 "issue_row"."state",
1393 NEW."id",
1394 "draft_id_v");
1395 END IF;
1396 RETURN NULL;
1397 END;
1398 $$;
1400 CREATE TRIGGER "write_event_initiative_revoked"
1401 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1402 "write_event_initiative_revoked_trigger"();
1404 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1405 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1408 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1409 RETURNS TRIGGER
1410 LANGUAGE 'plpgsql' VOLATILE AS $$
1411 DECLARE
1412 "initiative_row" "initiative"%ROWTYPE;
1413 "issue_row" "issue"%ROWTYPE;
1414 BEGIN
1415 SELECT * INTO "initiative_row" FROM "initiative"
1416 WHERE "id" = NEW."initiative_id";
1417 SELECT * INTO "issue_row" FROM "issue"
1418 WHERE "id" = "initiative_row"."issue_id";
1419 INSERT INTO "event" (
1420 "event", "member_id",
1421 "issue_id", "state", "initiative_id", "suggestion_id"
1422 ) VALUES (
1423 'suggestion_created',
1424 NEW."author_id",
1425 "initiative_row"."issue_id",
1426 "issue_row"."state",
1427 "initiative_row"."id",
1428 NEW."id" );
1429 RETURN NULL;
1430 END;
1431 $$;
1433 CREATE TRIGGER "write_event_suggestion_created"
1434 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1435 "write_event_suggestion_created_trigger"();
1437 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1438 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1442 ----------------------------
1443 -- Additional constraints --
1444 ----------------------------
1447 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1448 RETURNS TRIGGER
1449 LANGUAGE 'plpgsql' VOLATILE AS $$
1450 BEGIN
1451 IF NOT EXISTS (
1452 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1453 ) THEN
1454 --RAISE 'Cannot create issue without an initial initiative.' USING
1455 -- ERRCODE = 'integrity_constraint_violation',
1456 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1457 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1458 END IF;
1459 RETURN NULL;
1460 END;
1461 $$;
1463 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1464 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1465 FOR EACH ROW EXECUTE PROCEDURE
1466 "issue_requires_first_initiative_trigger"();
1468 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1469 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1472 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1473 RETURNS TRIGGER
1474 LANGUAGE 'plpgsql' VOLATILE AS $$
1475 DECLARE
1476 "reference_lost" BOOLEAN;
1477 BEGIN
1478 IF TG_OP = 'DELETE' THEN
1479 "reference_lost" := TRUE;
1480 ELSE
1481 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1482 END IF;
1483 IF
1484 "reference_lost" AND NOT EXISTS (
1485 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1487 THEN
1488 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1489 END IF;
1490 RETURN NULL;
1491 END;
1492 $$;
1494 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1495 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1496 FOR EACH ROW EXECUTE PROCEDURE
1497 "last_initiative_deletes_issue_trigger"();
1499 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1500 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1503 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1504 RETURNS TRIGGER
1505 LANGUAGE 'plpgsql' VOLATILE AS $$
1506 BEGIN
1507 IF NOT EXISTS (
1508 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1509 ) THEN
1510 --RAISE 'Cannot create initiative without an initial draft.' USING
1511 -- ERRCODE = 'integrity_constraint_violation',
1512 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1513 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1514 END IF;
1515 RETURN NULL;
1516 END;
1517 $$;
1519 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1520 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1521 FOR EACH ROW EXECUTE PROCEDURE
1522 "initiative_requires_first_draft_trigger"();
1524 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1525 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1528 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1529 RETURNS TRIGGER
1530 LANGUAGE 'plpgsql' VOLATILE AS $$
1531 DECLARE
1532 "reference_lost" BOOLEAN;
1533 BEGIN
1534 IF TG_OP = 'DELETE' THEN
1535 "reference_lost" := TRUE;
1536 ELSE
1537 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1538 END IF;
1539 IF
1540 "reference_lost" AND NOT EXISTS (
1541 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1543 THEN
1544 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1545 END IF;
1546 RETURN NULL;
1547 END;
1548 $$;
1550 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1551 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1552 FOR EACH ROW EXECUTE PROCEDURE
1553 "last_draft_deletes_initiative_trigger"();
1555 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1556 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1559 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1560 RETURNS TRIGGER
1561 LANGUAGE 'plpgsql' VOLATILE AS $$
1562 BEGIN
1563 IF NOT EXISTS (
1564 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1565 ) THEN
1566 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1567 END IF;
1568 RETURN NULL;
1569 END;
1570 $$;
1572 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1573 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1574 FOR EACH ROW EXECUTE PROCEDURE
1575 "suggestion_requires_first_opinion_trigger"();
1577 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1578 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1581 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1582 RETURNS TRIGGER
1583 LANGUAGE 'plpgsql' VOLATILE AS $$
1584 DECLARE
1585 "reference_lost" BOOLEAN;
1586 BEGIN
1587 IF TG_OP = 'DELETE' THEN
1588 "reference_lost" := TRUE;
1589 ELSE
1590 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1591 END IF;
1592 IF
1593 "reference_lost" AND NOT EXISTS (
1594 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1596 THEN
1597 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1598 END IF;
1599 RETURN NULL;
1600 END;
1601 $$;
1603 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1604 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1605 FOR EACH ROW EXECUTE PROCEDURE
1606 "last_opinion_deletes_suggestion_trigger"();
1608 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1609 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1613 ---------------------------------------------------------------
1614 -- Ensure that votes are not modified when issues are frozen --
1615 ---------------------------------------------------------------
1617 -- NOTE: Frontends should ensure this anyway, but in case of programming
1618 -- errors the following triggers ensure data integrity.
1621 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1622 RETURNS TRIGGER
1623 LANGUAGE 'plpgsql' VOLATILE AS $$
1624 DECLARE
1625 "issue_id_v" "issue"."id"%TYPE;
1626 "issue_row" "issue"%ROWTYPE;
1627 BEGIN
1628 IF TG_OP = 'DELETE' THEN
1629 "issue_id_v" := OLD."issue_id";
1630 ELSE
1631 "issue_id_v" := NEW."issue_id";
1632 END IF;
1633 SELECT INTO "issue_row" * FROM "issue"
1634 WHERE "id" = "issue_id_v" FOR SHARE;
1635 IF "issue_row"."closed" NOTNULL THEN
1636 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1637 END IF;
1638 RETURN NULL;
1639 END;
1640 $$;
1642 CREATE TRIGGER "forbid_changes_on_closed_issue"
1643 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1644 FOR EACH ROW EXECUTE PROCEDURE
1645 "forbid_changes_on_closed_issue_trigger"();
1647 CREATE TRIGGER "forbid_changes_on_closed_issue"
1648 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1649 FOR EACH ROW EXECUTE PROCEDURE
1650 "forbid_changes_on_closed_issue_trigger"();
1652 CREATE TRIGGER "forbid_changes_on_closed_issue"
1653 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1654 FOR EACH ROW EXECUTE PROCEDURE
1655 "forbid_changes_on_closed_issue_trigger"();
1657 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"';
1658 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';
1659 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';
1660 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';
1664 --------------------------------------------------------------------
1665 -- Auto-retrieval of fields only needed for referential integrity --
1666 --------------------------------------------------------------------
1669 CREATE FUNCTION "autofill_issue_id_trigger"()
1670 RETURNS TRIGGER
1671 LANGUAGE 'plpgsql' VOLATILE AS $$
1672 BEGIN
1673 IF NEW."issue_id" ISNULL THEN
1674 SELECT "issue_id" INTO NEW."issue_id"
1675 FROM "initiative" WHERE "id" = NEW."initiative_id";
1676 END IF;
1677 RETURN NEW;
1678 END;
1679 $$;
1681 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1682 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1684 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1685 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1687 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1688 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1689 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1692 CREATE FUNCTION "autofill_initiative_id_trigger"()
1693 RETURNS TRIGGER
1694 LANGUAGE 'plpgsql' VOLATILE AS $$
1695 BEGIN
1696 IF NEW."initiative_id" ISNULL THEN
1697 SELECT "initiative_id" INTO NEW."initiative_id"
1698 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1699 END IF;
1700 RETURN NEW;
1701 END;
1702 $$;
1704 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1705 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1707 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1708 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1712 -----------------------------------------------------
1713 -- Automatic calculation of certain default values --
1714 -----------------------------------------------------
1717 CREATE FUNCTION "copy_timings_trigger"()
1718 RETURNS TRIGGER
1719 LANGUAGE 'plpgsql' VOLATILE AS $$
1720 DECLARE
1721 "policy_row" "policy"%ROWTYPE;
1722 BEGIN
1723 SELECT * INTO "policy_row" FROM "policy"
1724 WHERE "id" = NEW."policy_id";
1725 IF NEW."admission_time" ISNULL THEN
1726 NEW."admission_time" := "policy_row"."admission_time";
1727 END IF;
1728 IF NEW."discussion_time" ISNULL THEN
1729 NEW."discussion_time" := "policy_row"."discussion_time";
1730 END IF;
1731 IF NEW."verification_time" ISNULL THEN
1732 NEW."verification_time" := "policy_row"."verification_time";
1733 END IF;
1734 IF NEW."voting_time" ISNULL THEN
1735 NEW."voting_time" := "policy_row"."voting_time";
1736 END IF;
1737 RETURN NEW;
1738 END;
1739 $$;
1741 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1742 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1744 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1745 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1748 CREATE FUNCTION "default_for_draft_id_trigger"()
1749 RETURNS TRIGGER
1750 LANGUAGE 'plpgsql' VOLATILE AS $$
1751 BEGIN
1752 IF NEW."draft_id" ISNULL THEN
1753 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1754 WHERE "initiative_id" = NEW."initiative_id";
1755 END IF;
1756 RETURN NEW;
1757 END;
1758 $$;
1760 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1761 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1762 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1763 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1765 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1766 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';
1767 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';
1771 ----------------------------------------
1772 -- Automatic creation of dependencies --
1773 ----------------------------------------
1776 CREATE FUNCTION "autocreate_interest_trigger"()
1777 RETURNS TRIGGER
1778 LANGUAGE 'plpgsql' VOLATILE AS $$
1779 BEGIN
1780 IF NOT EXISTS (
1781 SELECT NULL FROM "initiative" JOIN "interest"
1782 ON "initiative"."issue_id" = "interest"."issue_id"
1783 WHERE "initiative"."id" = NEW."initiative_id"
1784 AND "interest"."member_id" = NEW."member_id"
1785 ) THEN
1786 BEGIN
1787 INSERT INTO "interest" ("issue_id", "member_id")
1788 SELECT "issue_id", NEW."member_id"
1789 FROM "initiative" WHERE "id" = NEW."initiative_id";
1790 EXCEPTION WHEN unique_violation THEN END;
1791 END IF;
1792 RETURN NEW;
1793 END;
1794 $$;
1796 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1797 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1799 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1800 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';
1803 CREATE FUNCTION "autocreate_supporter_trigger"()
1804 RETURNS TRIGGER
1805 LANGUAGE 'plpgsql' VOLATILE AS $$
1806 BEGIN
1807 IF NOT EXISTS (
1808 SELECT NULL FROM "suggestion" JOIN "supporter"
1809 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1810 WHERE "suggestion"."id" = NEW."suggestion_id"
1811 AND "supporter"."member_id" = NEW."member_id"
1812 ) THEN
1813 BEGIN
1814 INSERT INTO "supporter" ("initiative_id", "member_id")
1815 SELECT "initiative_id", NEW."member_id"
1816 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1817 EXCEPTION WHEN unique_violation THEN END;
1818 END IF;
1819 RETURN NEW;
1820 END;
1821 $$;
1823 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1824 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1826 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1827 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.';
1831 ------------------------------------------
1832 -- Views and helper functions for views --
1833 ------------------------------------------
1836 CREATE VIEW "unit_delegation" AS
1837 SELECT
1838 "unit"."id" AS "unit_id",
1839 "delegation"."id",
1840 "delegation"."truster_id",
1841 "delegation"."trustee_id",
1842 "delegation"."scope"
1843 FROM "unit"
1844 JOIN "delegation"
1845 ON "delegation"."unit_id" = "unit"."id"
1846 JOIN "member"
1847 ON "delegation"."truster_id" = "member"."id"
1848 JOIN "privilege"
1849 ON "delegation"."unit_id" = "privilege"."unit_id"
1850 AND "delegation"."truster_id" = "privilege"."member_id"
1851 WHERE "member"."active" AND "privilege"."voting_right";
1853 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1856 CREATE VIEW "area_delegation" AS
1857 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1858 "area"."id" AS "area_id",
1859 "delegation"."id",
1860 "delegation"."truster_id",
1861 "delegation"."trustee_id",
1862 "delegation"."scope"
1863 FROM "area"
1864 JOIN "delegation"
1865 ON "delegation"."unit_id" = "area"."unit_id"
1866 OR "delegation"."area_id" = "area"."id"
1867 JOIN "member"
1868 ON "delegation"."truster_id" = "member"."id"
1869 JOIN "privilege"
1870 ON "area"."unit_id" = "privilege"."unit_id"
1871 AND "delegation"."truster_id" = "privilege"."member_id"
1872 WHERE "member"."active" AND "privilege"."voting_right"
1873 ORDER BY
1874 "area"."id",
1875 "delegation"."truster_id",
1876 "delegation"."scope" DESC;
1878 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1881 CREATE VIEW "issue_delegation" AS
1882 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1883 "issue"."id" AS "issue_id",
1884 "delegation"."id",
1885 "delegation"."truster_id",
1886 "delegation"."trustee_id",
1887 "delegation"."scope"
1888 FROM "issue"
1889 JOIN "area"
1890 ON "area"."id" = "issue"."area_id"
1891 JOIN "delegation"
1892 ON "delegation"."unit_id" = "area"."unit_id"
1893 OR "delegation"."area_id" = "area"."id"
1894 OR "delegation"."issue_id" = "issue"."id"
1895 JOIN "member"
1896 ON "delegation"."truster_id" = "member"."id"
1897 JOIN "privilege"
1898 ON "area"."unit_id" = "privilege"."unit_id"
1899 AND "delegation"."truster_id" = "privilege"."member_id"
1900 WHERE "member"."active" AND "privilege"."voting_right"
1901 ORDER BY
1902 "issue"."id",
1903 "delegation"."truster_id",
1904 "delegation"."scope" DESC;
1906 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1909 CREATE FUNCTION "membership_weight_with_skipping"
1910 ( "area_id_p" "area"."id"%TYPE,
1911 "member_id_p" "member"."id"%TYPE,
1912 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1913 RETURNS INT4
1914 LANGUAGE 'plpgsql' STABLE AS $$
1915 DECLARE
1916 "sum_v" INT4;
1917 "delegation_row" "area_delegation"%ROWTYPE;
1918 BEGIN
1919 "sum_v" := 1;
1920 FOR "delegation_row" IN
1921 SELECT "area_delegation".*
1922 FROM "area_delegation" LEFT JOIN "membership"
1923 ON "membership"."area_id" = "area_id_p"
1924 AND "membership"."member_id" = "area_delegation"."truster_id"
1925 WHERE "area_delegation"."area_id" = "area_id_p"
1926 AND "area_delegation"."trustee_id" = "member_id_p"
1927 AND "membership"."member_id" ISNULL
1928 LOOP
1929 IF NOT
1930 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1931 THEN
1932 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1933 "area_id_p",
1934 "delegation_row"."truster_id",
1935 "skip_member_ids_p" || "delegation_row"."truster_id"
1936 );
1937 END IF;
1938 END LOOP;
1939 RETURN "sum_v";
1940 END;
1941 $$;
1943 COMMENT ON FUNCTION "membership_weight_with_skipping"
1944 ( "area"."id"%TYPE,
1945 "member"."id"%TYPE,
1946 INT4[] )
1947 IS 'Helper function for "membership_weight" function';
1950 CREATE FUNCTION "membership_weight"
1951 ( "area_id_p" "area"."id"%TYPE,
1952 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1953 RETURNS INT4
1954 LANGUAGE 'plpgsql' STABLE AS $$
1955 BEGIN
1956 RETURN "membership_weight_with_skipping"(
1957 "area_id_p",
1958 "member_id_p",
1959 ARRAY["member_id_p"]
1960 );
1961 END;
1962 $$;
1964 COMMENT ON FUNCTION "membership_weight"
1965 ( "area"."id"%TYPE,
1966 "member"."id"%TYPE )
1967 IS 'Calculates the potential voting weight of a member in a given area';
1970 CREATE VIEW "member_count_view" AS
1971 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1973 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1976 CREATE VIEW "unit_member_count" AS
1977 SELECT
1978 "unit"."id" AS "unit_id",
1979 count("member"."id") AS "member_count"
1980 FROM "unit"
1981 LEFT JOIN "privilege"
1982 ON "privilege"."unit_id" = "unit"."id"
1983 AND "privilege"."voting_right"
1984 LEFT JOIN "member"
1985 ON "member"."id" = "privilege"."member_id"
1986 AND "member"."active"
1987 GROUP BY "unit"."id";
1989 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1992 CREATE VIEW "area_member_count" AS
1993 SELECT
1994 "area"."id" AS "area_id",
1995 count("member"."id") AS "direct_member_count",
1996 coalesce(
1997 sum(
1998 CASE WHEN "member"."id" NOTNULL THEN
1999 "membership_weight"("area"."id", "member"."id")
2000 ELSE 0 END
2002 ) AS "member_weight"
2003 FROM "area"
2004 LEFT JOIN "membership"
2005 ON "area"."id" = "membership"."area_id"
2006 LEFT JOIN "privilege"
2007 ON "privilege"."unit_id" = "area"."unit_id"
2008 AND "privilege"."member_id" = "membership"."member_id"
2009 AND "privilege"."voting_right"
2010 LEFT JOIN "member"
2011 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2012 AND "member"."active"
2013 GROUP BY "area"."id";
2015 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2018 CREATE VIEW "opening_draft" AS
2019 SELECT "draft".* FROM (
2020 SELECT
2021 "initiative"."id" AS "initiative_id",
2022 min("draft"."id") AS "draft_id"
2023 FROM "initiative" JOIN "draft"
2024 ON "initiative"."id" = "draft"."initiative_id"
2025 GROUP BY "initiative"."id"
2026 ) AS "subquery"
2027 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2029 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2032 CREATE VIEW "current_draft" AS
2033 SELECT "draft".* FROM (
2034 SELECT
2035 "initiative"."id" AS "initiative_id",
2036 max("draft"."id") AS "draft_id"
2037 FROM "initiative" JOIN "draft"
2038 ON "initiative"."id" = "draft"."initiative_id"
2039 GROUP BY "initiative"."id"
2040 ) AS "subquery"
2041 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2043 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2046 CREATE VIEW "critical_opinion" AS
2047 SELECT * FROM "opinion"
2048 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2049 OR ("degree" = -2 AND "fulfilled" = TRUE);
2051 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2054 CREATE VIEW "battle_participant" AS
2055 SELECT "initiative"."id", "initiative"."issue_id"
2056 FROM "issue" JOIN "initiative"
2057 ON "issue"."id" = "initiative"."issue_id"
2058 WHERE "initiative"."admitted"
2059 UNION ALL
2060 SELECT NULL, "id" AS "issue_id"
2061 FROM "issue";
2063 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2066 CREATE VIEW "battle_view" AS
2067 SELECT
2068 "issue"."id" AS "issue_id",
2069 "winning_initiative"."id" AS "winning_initiative_id",
2070 "losing_initiative"."id" AS "losing_initiative_id",
2071 sum(
2072 CASE WHEN
2073 coalesce("better_vote"."grade", 0) >
2074 coalesce("worse_vote"."grade", 0)
2075 THEN "direct_voter"."weight" ELSE 0 END
2076 ) AS "count"
2077 FROM "issue"
2078 LEFT JOIN "direct_voter"
2079 ON "issue"."id" = "direct_voter"."issue_id"
2080 JOIN "battle_participant" AS "winning_initiative"
2081 ON "issue"."id" = "winning_initiative"."issue_id"
2082 JOIN "battle_participant" AS "losing_initiative"
2083 ON "issue"."id" = "losing_initiative"."issue_id"
2084 LEFT JOIN "vote" AS "better_vote"
2085 ON "direct_voter"."member_id" = "better_vote"."member_id"
2086 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2087 LEFT JOIN "vote" AS "worse_vote"
2088 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2089 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2090 WHERE "issue"."closed" NOTNULL
2091 AND "issue"."cleaned" ISNULL
2092 AND (
2093 "winning_initiative"."id" != "losing_initiative"."id" OR
2094 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2095 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2096 GROUP BY
2097 "issue"."id",
2098 "winning_initiative"."id",
2099 "losing_initiative"."id";
2101 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';
2104 CREATE VIEW "expired_session" AS
2105 SELECT * FROM "session" WHERE now() > "expiry";
2107 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2108 DELETE FROM "session" WHERE "ident" = OLD."ident";
2110 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2111 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2114 CREATE VIEW "open_issue" AS
2115 SELECT * FROM "issue" WHERE "closed" ISNULL;
2117 COMMENT ON VIEW "open_issue" IS 'All open issues';
2120 CREATE VIEW "issue_with_ranks_missing" AS
2121 SELECT * FROM "issue"
2122 WHERE "fully_frozen" NOTNULL
2123 AND "closed" NOTNULL
2124 AND "ranks_available" = FALSE;
2126 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2129 CREATE VIEW "member_contingent" AS
2130 SELECT
2131 "member"."id" AS "member_id",
2132 "contingent"."time_frame",
2133 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2135 SELECT count(1) FROM "draft"
2136 WHERE "draft"."author_id" = "member"."id"
2137 AND "draft"."created" > now() - "contingent"."time_frame"
2138 ) + (
2139 SELECT count(1) FROM "suggestion"
2140 WHERE "suggestion"."author_id" = "member"."id"
2141 AND "suggestion"."created" > now() - "contingent"."time_frame"
2143 ELSE NULL END AS "text_entry_count",
2144 "contingent"."text_entry_limit",
2145 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2146 SELECT count(1) FROM "opening_draft"
2147 WHERE "opening_draft"."author_id" = "member"."id"
2148 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2149 ) ELSE NULL END AS "initiative_count",
2150 "contingent"."initiative_limit"
2151 FROM "member" CROSS JOIN "contingent";
2153 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2155 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2156 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2159 CREATE VIEW "member_contingent_left" AS
2160 SELECT
2161 "member_id",
2162 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2163 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2164 FROM "member_contingent" GROUP BY "member_id";
2166 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.';
2169 CREATE VIEW "event_seen_by_member" AS
2170 SELECT
2171 "member"."id" AS "seen_by_member_id",
2172 CASE WHEN "event"."state" IN (
2173 'voting',
2174 'finished_without_winner',
2175 'finished_with_winner'
2176 ) THEN
2177 'voting'::"notify_level"
2178 ELSE
2179 CASE WHEN "event"."state" IN (
2180 'verification',
2181 'canceled_after_revocation_during_verification',
2182 'canceled_no_initiative_admitted'
2183 ) THEN
2184 'verification'::"notify_level"
2185 ELSE
2186 CASE WHEN "event"."state" IN (
2187 'discussion',
2188 'canceled_after_revocation_during_discussion'
2189 ) THEN
2190 'discussion'::"notify_level"
2191 ELSE
2192 'all'::"notify_level"
2193 END
2194 END
2195 END AS "notify_level",
2196 "event".*
2197 FROM "member" CROSS JOIN "event"
2198 LEFT JOIN "issue"
2199 ON "event"."issue_id" = "issue"."id"
2200 LEFT JOIN "membership"
2201 ON "member"."id" = "membership"."member_id"
2202 AND "issue"."area_id" = "membership"."area_id"
2203 LEFT JOIN "interest"
2204 ON "member"."id" = "interest"."member_id"
2205 AND "event"."issue_id" = "interest"."issue_id"
2206 LEFT JOIN "supporter"
2207 ON "member"."id" = "supporter"."member_id"
2208 AND "event"."initiative_id" = "supporter"."initiative_id"
2209 LEFT JOIN "ignored_member"
2210 ON "member"."id" = "ignored_member"."member_id"
2211 AND "event"."member_id" = "ignored_member"."other_member_id"
2212 LEFT JOIN "ignored_initiative"
2213 ON "member"."id" = "ignored_initiative"."member_id"
2214 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2215 WHERE (
2216 "supporter"."member_id" NOTNULL OR
2217 "interest"."member_id" NOTNULL OR
2218 ( "membership"."member_id" NOTNULL AND
2219 "event"."event" IN (
2220 'issue_state_changed',
2221 'initiative_created_in_new_issue',
2222 'initiative_created_in_existing_issue',
2223 'initiative_revoked' ) ) )
2224 AND "ignored_member"."member_id" ISNULL
2225 AND "ignored_initiative"."member_id" ISNULL;
2227 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"';
2230 CREATE VIEW "selected_event_seen_by_member" AS
2231 SELECT
2232 "member"."id" AS "seen_by_member_id",
2233 CASE WHEN "event"."state" IN (
2234 'voting',
2235 'finished_without_winner',
2236 'finished_with_winner'
2237 ) THEN
2238 'voting'::"notify_level"
2239 ELSE
2240 CASE WHEN "event"."state" IN (
2241 'verification',
2242 'canceled_after_revocation_during_verification',
2243 'canceled_no_initiative_admitted'
2244 ) THEN
2245 'verification'::"notify_level"
2246 ELSE
2247 CASE WHEN "event"."state" IN (
2248 'discussion',
2249 'canceled_after_revocation_during_discussion'
2250 ) THEN
2251 'discussion'::"notify_level"
2252 ELSE
2253 'all'::"notify_level"
2254 END
2255 END
2256 END AS "notify_level",
2257 "event".*
2258 FROM "member" CROSS JOIN "event"
2259 LEFT JOIN "issue"
2260 ON "event"."issue_id" = "issue"."id"
2261 LEFT JOIN "membership"
2262 ON "member"."id" = "membership"."member_id"
2263 AND "issue"."area_id" = "membership"."area_id"
2264 LEFT JOIN "interest"
2265 ON "member"."id" = "interest"."member_id"
2266 AND "event"."issue_id" = "interest"."issue_id"
2267 LEFT JOIN "supporter"
2268 ON "member"."id" = "supporter"."member_id"
2269 AND "event"."initiative_id" = "supporter"."initiative_id"
2270 LEFT JOIN "ignored_member"
2271 ON "member"."id" = "ignored_member"."member_id"
2272 AND "event"."member_id" = "ignored_member"."other_member_id"
2273 LEFT JOIN "ignored_initiative"
2274 ON "member"."id" = "ignored_initiative"."member_id"
2275 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2276 WHERE (
2277 ( "member"."notify_level" >= 'all' ) OR
2278 ( "member"."notify_level" >= 'voting' AND
2279 "event"."state" IN (
2280 'voting',
2281 'finished_without_winner',
2282 'finished_with_winner' ) ) OR
2283 ( "member"."notify_level" >= 'verification' AND
2284 "event"."state" IN (
2285 'verification',
2286 'canceled_after_revocation_during_verification',
2287 'canceled_no_initiative_admitted' ) ) OR
2288 ( "member"."notify_level" >= 'discussion' AND
2289 "event"."state" IN (
2290 'discussion',
2291 'canceled_after_revocation_during_discussion' ) ) )
2292 AND (
2293 "supporter"."member_id" NOTNULL OR
2294 "interest"."member_id" NOTNULL OR
2295 ( "membership"."member_id" NOTNULL AND
2296 "event"."event" IN (
2297 'issue_state_changed',
2298 'initiative_created_in_new_issue',
2299 'initiative_created_in_existing_issue',
2300 'initiative_revoked' ) ) )
2301 AND "ignored_member"."member_id" ISNULL
2302 AND "ignored_initiative"."member_id" ISNULL;
2304 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"';
2307 CREATE TYPE "timeline_event" AS ENUM (
2308 'issue_created',
2309 'issue_canceled',
2310 'issue_accepted',
2311 'issue_half_frozen',
2312 'issue_finished_without_voting',
2313 'issue_voting_started',
2314 'issue_finished_after_voting',
2315 'initiative_created',
2316 'initiative_revoked',
2317 'draft_created',
2318 'suggestion_created');
2320 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2323 CREATE VIEW "timeline_issue" AS
2324 SELECT
2325 "created" AS "occurrence",
2326 'issue_created'::"timeline_event" AS "event",
2327 "id" AS "issue_id"
2328 FROM "issue"
2329 UNION ALL
2330 SELECT
2331 "closed" AS "occurrence",
2332 'issue_canceled'::"timeline_event" AS "event",
2333 "id" AS "issue_id"
2334 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2335 UNION ALL
2336 SELECT
2337 "accepted" AS "occurrence",
2338 'issue_accepted'::"timeline_event" AS "event",
2339 "id" AS "issue_id"
2340 FROM "issue" WHERE "accepted" NOTNULL
2341 UNION ALL
2342 SELECT
2343 "half_frozen" AS "occurrence",
2344 'issue_half_frozen'::"timeline_event" AS "event",
2345 "id" AS "issue_id"
2346 FROM "issue" WHERE "half_frozen" NOTNULL
2347 UNION ALL
2348 SELECT
2349 "fully_frozen" AS "occurrence",
2350 'issue_voting_started'::"timeline_event" AS "event",
2351 "id" AS "issue_id"
2352 FROM "issue"
2353 WHERE "fully_frozen" NOTNULL
2354 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2355 UNION ALL
2356 SELECT
2357 "closed" AS "occurrence",
2358 CASE WHEN "fully_frozen" = "closed" THEN
2359 'issue_finished_without_voting'::"timeline_event"
2360 ELSE
2361 'issue_finished_after_voting'::"timeline_event"
2362 END AS "event",
2363 "id" AS "issue_id"
2364 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2366 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2369 CREATE VIEW "timeline_initiative" AS
2370 SELECT
2371 "created" AS "occurrence",
2372 'initiative_created'::"timeline_event" AS "event",
2373 "id" AS "initiative_id"
2374 FROM "initiative"
2375 UNION ALL
2376 SELECT
2377 "revoked" AS "occurrence",
2378 'initiative_revoked'::"timeline_event" AS "event",
2379 "id" AS "initiative_id"
2380 FROM "initiative" WHERE "revoked" NOTNULL;
2382 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2385 CREATE VIEW "timeline_draft" AS
2386 SELECT
2387 "created" AS "occurrence",
2388 'draft_created'::"timeline_event" AS "event",
2389 "id" AS "draft_id"
2390 FROM "draft";
2392 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2395 CREATE VIEW "timeline_suggestion" AS
2396 SELECT
2397 "created" AS "occurrence",
2398 'suggestion_created'::"timeline_event" AS "event",
2399 "id" AS "suggestion_id"
2400 FROM "suggestion";
2402 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2405 CREATE VIEW "timeline" AS
2406 SELECT
2407 "occurrence",
2408 "event",
2409 "issue_id",
2410 NULL AS "initiative_id",
2411 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2412 NULL::INT8 AS "suggestion_id"
2413 FROM "timeline_issue"
2414 UNION ALL
2415 SELECT
2416 "occurrence",
2417 "event",
2418 NULL AS "issue_id",
2419 "initiative_id",
2420 NULL AS "draft_id",
2421 NULL AS "suggestion_id"
2422 FROM "timeline_initiative"
2423 UNION ALL
2424 SELECT
2425 "occurrence",
2426 "event",
2427 NULL AS "issue_id",
2428 NULL AS "initiative_id",
2429 "draft_id",
2430 NULL AS "suggestion_id"
2431 FROM "timeline_draft"
2432 UNION ALL
2433 SELECT
2434 "occurrence",
2435 "event",
2436 NULL AS "issue_id",
2437 NULL AS "initiative_id",
2438 NULL AS "draft_id",
2439 "suggestion_id"
2440 FROM "timeline_suggestion";
2442 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2446 ------------------------------------------------------
2447 -- Row set returning function for delegation chains --
2448 ------------------------------------------------------
2451 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2452 ('first', 'intermediate', 'last', 'repetition');
2454 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2457 CREATE TYPE "delegation_chain_row" AS (
2458 "index" INT4,
2459 "member_id" INT4,
2460 "member_valid" BOOLEAN,
2461 "participation" BOOLEAN,
2462 "overridden" BOOLEAN,
2463 "scope_in" "delegation_scope",
2464 "scope_out" "delegation_scope",
2465 "disabled_out" BOOLEAN,
2466 "loop" "delegation_chain_loop_tag" );
2468 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2470 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2471 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';
2472 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2473 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2474 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2475 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2476 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2479 CREATE FUNCTION "delegation_chain_for_closed_issue"
2480 ( "member_id_p" "member"."id"%TYPE,
2481 "issue_id_p" "issue"."id"%TYPE )
2482 RETURNS SETOF "delegation_chain_row"
2483 LANGUAGE 'plpgsql' STABLE AS $$
2484 DECLARE
2485 "output_row" "delegation_chain_row";
2486 "direct_voter_row" "direct_voter"%ROWTYPE;
2487 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2488 BEGIN
2489 "output_row"."index" := 0;
2490 "output_row"."member_id" := "member_id_p";
2491 "output_row"."member_valid" := TRUE;
2492 "output_row"."participation" := FALSE;
2493 "output_row"."overridden" := FALSE;
2494 "output_row"."disabled_out" := FALSE;
2495 LOOP
2496 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2497 WHERE "issue_id" = "issue_id_p"
2498 AND "member_id" = "output_row"."member_id";
2499 IF "direct_voter_row"."member_id" NOTNULL THEN
2500 "output_row"."participation" := TRUE;
2501 "output_row"."scope_out" := NULL;
2502 "output_row"."disabled_out" := NULL;
2503 RETURN NEXT "output_row";
2504 RETURN;
2505 END IF;
2506 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2507 WHERE "issue_id" = "issue_id_p"
2508 AND "member_id" = "output_row"."member_id";
2509 IF "delegating_voter_row"."member_id" ISNULL THEN
2510 RETURN;
2511 END IF;
2512 "output_row"."scope_out" := "delegating_voter_row"."scope";
2513 RETURN NEXT "output_row";
2514 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2515 "output_row"."scope_in" := "output_row"."scope_out";
2516 END LOOP;
2517 END;
2518 $$;
2520 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2521 ( "member"."id"%TYPE,
2522 "member"."id"%TYPE )
2523 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2526 CREATE FUNCTION "delegation_chain"
2527 ( "member_id_p" "member"."id"%TYPE,
2528 "unit_id_p" "unit"."id"%TYPE,
2529 "area_id_p" "area"."id"%TYPE,
2530 "issue_id_p" "issue"."id"%TYPE,
2531 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2532 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2533 RETURNS SETOF "delegation_chain_row"
2534 LANGUAGE 'plpgsql' STABLE AS $$
2535 DECLARE
2536 "scope_v" "delegation_scope";
2537 "unit_id_v" "unit"."id"%TYPE;
2538 "area_id_v" "area"."id"%TYPE;
2539 "issue_row" "issue"%ROWTYPE;
2540 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2541 "loop_member_id_v" "member"."id"%TYPE;
2542 "output_row" "delegation_chain_row";
2543 "output_rows" "delegation_chain_row"[];
2544 "simulate_v" BOOLEAN;
2545 "simulate_here_v" BOOLEAN;
2546 "delegation_row" "delegation"%ROWTYPE;
2547 "row_count" INT4;
2548 "i" INT4;
2549 "loop_v" BOOLEAN;
2550 BEGIN
2551 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2552 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2553 END IF;
2554 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2555 "simulate_v" := TRUE;
2556 ELSE
2557 "simulate_v" := FALSE;
2558 END IF;
2559 IF
2560 "unit_id_p" NOTNULL AND
2561 "area_id_p" ISNULL AND
2562 "issue_id_p" ISNULL
2563 THEN
2564 "scope_v" := 'unit';
2565 "unit_id_v" := "unit_id_p";
2566 ELSIF
2567 "unit_id_p" ISNULL AND
2568 "area_id_p" NOTNULL AND
2569 "issue_id_p" ISNULL
2570 THEN
2571 "scope_v" := 'area';
2572 "area_id_v" := "area_id_p";
2573 SELECT "unit_id" INTO "unit_id_v"
2574 FROM "area" WHERE "id" = "area_id_v";
2575 ELSIF
2576 "unit_id_p" ISNULL AND
2577 "area_id_p" ISNULL AND
2578 "issue_id_p" NOTNULL
2579 THEN
2580 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2581 IF "issue_row"."id" ISNULL THEN
2582 RETURN;
2583 END IF;
2584 IF "issue_row"."closed" NOTNULL THEN
2585 IF "simulate_v" THEN
2586 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2587 END IF;
2588 FOR "output_row" IN
2589 SELECT * FROM
2590 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2591 LOOP
2592 RETURN NEXT "output_row";
2593 END LOOP;
2594 RETURN;
2595 END IF;
2596 "scope_v" := 'issue';
2597 SELECT "area_id" INTO "area_id_v"
2598 FROM "issue" WHERE "id" = "issue_id_p";
2599 SELECT "unit_id" INTO "unit_id_v"
2600 FROM "area" WHERE "id" = "area_id_v";
2601 ELSE
2602 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2603 END IF;
2604 "visited_member_ids" := '{}';
2605 "loop_member_id_v" := NULL;
2606 "output_rows" := '{}';
2607 "output_row"."index" := 0;
2608 "output_row"."member_id" := "member_id_p";
2609 "output_row"."member_valid" := TRUE;
2610 "output_row"."participation" := FALSE;
2611 "output_row"."overridden" := FALSE;
2612 "output_row"."disabled_out" := FALSE;
2613 "output_row"."scope_out" := NULL;
2614 LOOP
2615 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2616 "loop_member_id_v" := "output_row"."member_id";
2617 ELSE
2618 "visited_member_ids" :=
2619 "visited_member_ids" || "output_row"."member_id";
2620 END IF;
2621 IF "output_row"."participation" ISNULL THEN
2622 "output_row"."overridden" := NULL;
2623 ELSIF "output_row"."participation" THEN
2624 "output_row"."overridden" := TRUE;
2625 END IF;
2626 "output_row"."scope_in" := "output_row"."scope_out";
2627 "output_row"."member_valid" := EXISTS (
2628 SELECT NULL FROM "member" JOIN "privilege"
2629 ON "privilege"."member_id" = "member"."id"
2630 AND "privilege"."unit_id" = "unit_id_v"
2631 WHERE "id" = "output_row"."member_id"
2632 AND "member"."active" AND "privilege"."voting_right"
2633 );
2634 "simulate_here_v" := (
2635 "simulate_v" AND
2636 "output_row"."member_id" = "member_id_p"
2637 );
2638 "delegation_row" := ROW(NULL);
2639 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2640 IF "scope_v" = 'unit' THEN
2641 IF NOT "simulate_here_v" THEN
2642 SELECT * INTO "delegation_row" FROM "delegation"
2643 WHERE "truster_id" = "output_row"."member_id"
2644 AND "unit_id" = "unit_id_v";
2645 END IF;
2646 ELSIF "scope_v" = 'area' THEN
2647 "output_row"."participation" := EXISTS (
2648 SELECT NULL FROM "membership"
2649 WHERE "area_id" = "area_id_p"
2650 AND "member_id" = "output_row"."member_id"
2651 );
2652 IF "simulate_here_v" THEN
2653 IF "simulate_trustee_id_p" ISNULL THEN
2654 SELECT * INTO "delegation_row" FROM "delegation"
2655 WHERE "truster_id" = "output_row"."member_id"
2656 AND "unit_id" = "unit_id_v";
2657 END IF;
2658 ELSE
2659 SELECT * INTO "delegation_row" FROM "delegation"
2660 WHERE "truster_id" = "output_row"."member_id"
2661 AND (
2662 "unit_id" = "unit_id_v" OR
2663 "area_id" = "area_id_v"
2665 ORDER BY "scope" DESC;
2666 END IF;
2667 ELSIF "scope_v" = 'issue' THEN
2668 IF "issue_row"."fully_frozen" ISNULL THEN
2669 "output_row"."participation" := EXISTS (
2670 SELECT NULL FROM "interest"
2671 WHERE "issue_id" = "issue_id_p"
2672 AND "member_id" = "output_row"."member_id"
2673 );
2674 ELSE
2675 IF "output_row"."member_id" = "member_id_p" THEN
2676 "output_row"."participation" := EXISTS (
2677 SELECT NULL FROM "direct_voter"
2678 WHERE "issue_id" = "issue_id_p"
2679 AND "member_id" = "output_row"."member_id"
2680 );
2681 ELSE
2682 "output_row"."participation" := NULL;
2683 END IF;
2684 END IF;
2685 IF "simulate_here_v" THEN
2686 IF "simulate_trustee_id_p" ISNULL THEN
2687 SELECT * INTO "delegation_row" FROM "delegation"
2688 WHERE "truster_id" = "output_row"."member_id"
2689 AND (
2690 "unit_id" = "unit_id_v" OR
2691 "area_id" = "area_id_v"
2693 ORDER BY "scope" DESC;
2694 END IF;
2695 ELSE
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" OR
2701 "issue_id" = "issue_id_p"
2703 ORDER BY "scope" DESC;
2704 END IF;
2705 END IF;
2706 ELSE
2707 "output_row"."participation" := FALSE;
2708 END IF;
2709 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2710 "output_row"."scope_out" := "scope_v";
2711 "output_rows" := "output_rows" || "output_row";
2712 "output_row"."member_id" := "simulate_trustee_id_p";
2713 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2714 "output_row"."scope_out" := "delegation_row"."scope";
2715 "output_rows" := "output_rows" || "output_row";
2716 "output_row"."member_id" := "delegation_row"."trustee_id";
2717 ELSIF "delegation_row"."scope" NOTNULL THEN
2718 "output_row"."scope_out" := "delegation_row"."scope";
2719 "output_row"."disabled_out" := TRUE;
2720 "output_rows" := "output_rows" || "output_row";
2721 EXIT;
2722 ELSE
2723 "output_row"."scope_out" := NULL;
2724 "output_rows" := "output_rows" || "output_row";
2725 EXIT;
2726 END IF;
2727 EXIT WHEN "loop_member_id_v" NOTNULL;
2728 "output_row"."index" := "output_row"."index" + 1;
2729 END LOOP;
2730 "row_count" := array_upper("output_rows", 1);
2731 "i" := 1;
2732 "loop_v" := FALSE;
2733 LOOP
2734 "output_row" := "output_rows"["i"];
2735 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2736 IF "loop_v" THEN
2737 IF "i" + 1 = "row_count" THEN
2738 "output_row"."loop" := 'last';
2739 ELSIF "i" = "row_count" THEN
2740 "output_row"."loop" := 'repetition';
2741 ELSE
2742 "output_row"."loop" := 'intermediate';
2743 END IF;
2744 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2745 "output_row"."loop" := 'first';
2746 "loop_v" := TRUE;
2747 END IF;
2748 IF "scope_v" = 'unit' THEN
2749 "output_row"."participation" := NULL;
2750 END IF;
2751 RETURN NEXT "output_row";
2752 "i" := "i" + 1;
2753 END LOOP;
2754 RETURN;
2755 END;
2756 $$;
2758 COMMENT ON FUNCTION "delegation_chain"
2759 ( "member"."id"%TYPE,
2760 "unit"."id"%TYPE,
2761 "area"."id"%TYPE,
2762 "issue"."id"%TYPE,
2763 "member"."id"%TYPE,
2764 BOOLEAN )
2765 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2769 ---------------------------------------------------------
2770 -- Single row returning function for delegation chains --
2771 ---------------------------------------------------------
2774 CREATE TYPE "delegation_info_loop_type" AS ENUM
2775 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2777 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''';
2780 CREATE TYPE "delegation_info_type" AS (
2781 "own_participation" BOOLEAN,
2782 "own_delegation_scope" "delegation_scope",
2783 "first_trustee_id" INT4,
2784 "first_trustee_participation" BOOLEAN,
2785 "first_trustee_ellipsis" BOOLEAN,
2786 "other_trustee_id" INT4,
2787 "other_trustee_participation" BOOLEAN,
2788 "other_trustee_ellipsis" BOOLEAN,
2789 "delegation_loop" "delegation_info_loop_type",
2790 "participating_member_id" INT4 );
2792 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';
2794 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2795 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2796 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2797 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2798 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2799 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2800 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)';
2801 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2802 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';
2803 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2806 CREATE FUNCTION "delegation_info"
2807 ( "member_id_p" "member"."id"%TYPE,
2808 "unit_id_p" "unit"."id"%TYPE,
2809 "area_id_p" "area"."id"%TYPE,
2810 "issue_id_p" "issue"."id"%TYPE,
2811 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2812 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2813 RETURNS "delegation_info_type"
2814 LANGUAGE 'plpgsql' STABLE AS $$
2815 DECLARE
2816 "current_row" "delegation_chain_row";
2817 "result" "delegation_info_type";
2818 BEGIN
2819 "result"."own_participation" := FALSE;
2820 FOR "current_row" IN
2821 SELECT * FROM "delegation_chain"(
2822 "member_id_p",
2823 "unit_id_p", "area_id_p", "issue_id_p",
2824 "simulate_trustee_id_p", "simulate_default_p")
2825 LOOP
2826 IF
2827 "result"."participating_member_id" ISNULL AND
2828 "current_row"."participation"
2829 THEN
2830 "result"."participating_member_id" := "current_row"."member_id";
2831 END IF;
2832 IF "current_row"."member_id" = "member_id_p" THEN
2833 "result"."own_participation" := "current_row"."participation";
2834 "result"."own_delegation_scope" := "current_row"."scope_out";
2835 IF "current_row"."loop" = 'first' THEN
2836 "result"."delegation_loop" := 'own';
2837 END IF;
2838 ELSIF
2839 "current_row"."member_valid" AND
2840 ( "current_row"."loop" ISNULL OR
2841 "current_row"."loop" != 'repetition' )
2842 THEN
2843 IF "result"."first_trustee_id" ISNULL THEN
2844 "result"."first_trustee_id" := "current_row"."member_id";
2845 "result"."first_trustee_participation" := "current_row"."participation";
2846 "result"."first_trustee_ellipsis" := FALSE;
2847 IF "current_row"."loop" = 'first' THEN
2848 "result"."delegation_loop" := 'first';
2849 END IF;
2850 ELSIF "result"."other_trustee_id" ISNULL THEN
2851 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2852 "result"."other_trustee_id" := "current_row"."member_id";
2853 "result"."other_trustee_participation" := TRUE;
2854 "result"."other_trustee_ellipsis" := FALSE;
2855 IF "current_row"."loop" = 'first' THEN
2856 "result"."delegation_loop" := 'other';
2857 END IF;
2858 ELSE
2859 "result"."first_trustee_ellipsis" := TRUE;
2860 IF "current_row"."loop" = 'first' THEN
2861 "result"."delegation_loop" := 'first_ellipsis';
2862 END IF;
2863 END IF;
2864 ELSE
2865 "result"."other_trustee_ellipsis" := TRUE;
2866 IF "current_row"."loop" = 'first' THEN
2867 "result"."delegation_loop" := 'other_ellipsis';
2868 END IF;
2869 END IF;
2870 END IF;
2871 END LOOP;
2872 RETURN "result";
2873 END;
2874 $$;
2876 COMMENT ON FUNCTION "delegation_info"
2877 ( "member"."id"%TYPE,
2878 "unit"."id"%TYPE,
2879 "area"."id"%TYPE,
2880 "issue"."id"%TYPE,
2881 "member"."id"%TYPE,
2882 BOOLEAN )
2883 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2887 ------------------------------
2888 -- Comparison by vote count --
2889 ------------------------------
2891 CREATE FUNCTION "vote_ratio"
2892 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2893 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2894 RETURNS FLOAT8
2895 LANGUAGE 'plpgsql' STABLE AS $$
2896 BEGIN
2897 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2898 RETURN
2899 "positive_votes_p"::FLOAT8 /
2900 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2901 ELSIF "positive_votes_p" > 0 THEN
2902 RETURN "positive_votes_p";
2903 ELSIF "negative_votes_p" > 0 THEN
2904 RETURN 1 - "negative_votes_p";
2905 ELSE
2906 RETURN 0.5;
2907 END IF;
2908 END;
2909 $$;
2911 COMMENT ON FUNCTION "vote_ratio"
2912 ( "initiative"."positive_votes"%TYPE,
2913 "initiative"."negative_votes"%TYPE )
2914 IS 'Returns a number, which can be used for comparison of initiatives based on count of approvals and disapprovals. Greater numbers indicate a better result. This function is NOT injective.';
2918 ------------------------------------------------
2919 -- Locking for snapshots and voting procedure --
2920 ------------------------------------------------
2923 CREATE FUNCTION "share_row_lock_issue_trigger"()
2924 RETURNS TRIGGER
2925 LANGUAGE 'plpgsql' VOLATILE AS $$
2926 BEGIN
2927 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2928 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2929 END IF;
2930 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2931 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2932 RETURN NEW;
2933 ELSE
2934 RETURN OLD;
2935 END IF;
2936 END;
2937 $$;
2939 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2942 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2943 RETURNS TRIGGER
2944 LANGUAGE 'plpgsql' VOLATILE AS $$
2945 BEGIN
2946 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2947 PERFORM NULL FROM "issue"
2948 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2949 WHERE "initiative"."id" = OLD."initiative_id"
2950 FOR SHARE OF "issue";
2951 END IF;
2952 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2953 PERFORM NULL FROM "issue"
2954 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2955 WHERE "initiative"."id" = NEW."initiative_id"
2956 FOR SHARE OF "issue";
2957 RETURN NEW;
2958 ELSE
2959 RETURN OLD;
2960 END IF;
2961 END;
2962 $$;
2964 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2967 CREATE TRIGGER "share_row_lock_issue"
2968 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2969 FOR EACH ROW EXECUTE PROCEDURE
2970 "share_row_lock_issue_trigger"();
2972 CREATE TRIGGER "share_row_lock_issue"
2973 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2974 FOR EACH ROW EXECUTE PROCEDURE
2975 "share_row_lock_issue_trigger"();
2977 CREATE TRIGGER "share_row_lock_issue"
2978 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2979 FOR EACH ROW EXECUTE PROCEDURE
2980 "share_row_lock_issue_trigger"();
2982 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2983 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2984 FOR EACH ROW EXECUTE PROCEDURE
2985 "share_row_lock_issue_via_initiative_trigger"();
2987 CREATE TRIGGER "share_row_lock_issue"
2988 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2989 FOR EACH ROW EXECUTE PROCEDURE
2990 "share_row_lock_issue_trigger"();
2992 CREATE TRIGGER "share_row_lock_issue"
2993 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2994 FOR EACH ROW EXECUTE PROCEDURE
2995 "share_row_lock_issue_trigger"();
2997 CREATE TRIGGER "share_row_lock_issue"
2998 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2999 FOR EACH ROW EXECUTE PROCEDURE
3000 "share_row_lock_issue_trigger"();
3002 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
3003 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
3004 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
3005 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
3006 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
3007 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
3008 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
3011 CREATE FUNCTION "lock_issue"
3012 ( "issue_id_p" "issue"."id"%TYPE )
3013 RETURNS VOID
3014 LANGUAGE 'plpgsql' VOLATILE AS $$
3015 BEGIN
3016 LOCK TABLE "member" IN SHARE MODE;
3017 LOCK TABLE "privilege" IN SHARE MODE;
3018 LOCK TABLE "membership" IN SHARE MODE;
3019 LOCK TABLE "policy" IN SHARE MODE;
3020 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
3021 -- NOTE: The row-level exclusive lock in combination with the
3022 -- share_row_lock_issue(_via_initiative)_trigger functions (which
3023 -- acquire a row-level share lock on the issue) ensure that no data
3024 -- is changed, which could affect calculation of snapshots or
3025 -- counting of votes. Table "delegation" must be table-level-locked,
3026 -- as it also contains issue- and global-scope delegations.
3027 LOCK TABLE "delegation" IN SHARE MODE;
3028 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
3029 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
3030 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
3031 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
3032 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
3033 RETURN;
3034 END;
3035 $$;
3037 COMMENT ON FUNCTION "lock_issue"
3038 ( "issue"."id"%TYPE )
3039 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
3043 ------------------------------------------------------------------------
3044 -- Regular tasks, except calculcation of snapshots and voting results --
3045 ------------------------------------------------------------------------
3047 CREATE FUNCTION "check_activity"()
3048 RETURNS VOID
3049 LANGUAGE 'plpgsql' VOLATILE AS $$
3050 DECLARE
3051 "system_setting_row" "system_setting"%ROWTYPE;
3052 BEGIN
3053 SELECT * INTO "system_setting_row" FROM "system_setting";
3054 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
3055 IF "system_setting_row"."member_ttl" NOTNULL THEN
3056 UPDATE "member" SET "active" = FALSE
3057 WHERE "active" = TRUE
3058 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
3059 END IF;
3060 RETURN;
3061 END;
3062 $$;
3064 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
3067 CREATE FUNCTION "calculate_member_counts"()
3068 RETURNS VOID
3069 LANGUAGE 'plpgsql' VOLATILE AS $$
3070 BEGIN
3071 LOCK TABLE "member" IN SHARE MODE;
3072 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
3073 LOCK TABLE "unit" IN EXCLUSIVE MODE;
3074 LOCK TABLE "area" IN EXCLUSIVE MODE;
3075 LOCK TABLE "privilege" IN SHARE MODE;
3076 LOCK TABLE "membership" IN SHARE MODE;
3077 DELETE FROM "member_count";
3078 INSERT INTO "member_count" ("total_count")
3079 SELECT "total_count" FROM "member_count_view";
3080 UPDATE "unit" SET "member_count" = "view"."member_count"
3081 FROM "unit_member_count" AS "view"
3082 WHERE "view"."unit_id" = "unit"."id";
3083 UPDATE "area" SET
3084 "direct_member_count" = "view"."direct_member_count",
3085 "member_weight" = "view"."member_weight"
3086 FROM "area_member_count" AS "view"
3087 WHERE "view"."area_id" = "area"."id";
3088 RETURN;
3089 END;
3090 $$;
3092 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"';
3096 ------------------------------
3097 -- Calculation of snapshots --
3098 ------------------------------
3100 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3101 ( "issue_id_p" "issue"."id"%TYPE,
3102 "member_id_p" "member"."id"%TYPE,
3103 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3104 RETURNS "direct_population_snapshot"."weight"%TYPE
3105 LANGUAGE 'plpgsql' VOLATILE AS $$
3106 DECLARE
3107 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3108 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3109 "weight_v" INT4;
3110 "sub_weight_v" INT4;
3111 BEGIN
3112 "weight_v" := 0;
3113 FOR "issue_delegation_row" IN
3114 SELECT * FROM "issue_delegation"
3115 WHERE "trustee_id" = "member_id_p"
3116 AND "issue_id" = "issue_id_p"
3117 LOOP
3118 IF NOT EXISTS (
3119 SELECT NULL FROM "direct_population_snapshot"
3120 WHERE "issue_id" = "issue_id_p"
3121 AND "event" = 'periodic'
3122 AND "member_id" = "issue_delegation_row"."truster_id"
3123 ) AND NOT EXISTS (
3124 SELECT NULL FROM "delegating_population_snapshot"
3125 WHERE "issue_id" = "issue_id_p"
3126 AND "event" = 'periodic'
3127 AND "member_id" = "issue_delegation_row"."truster_id"
3128 ) THEN
3129 "delegate_member_ids_v" :=
3130 "member_id_p" || "delegate_member_ids_p";
3131 INSERT INTO "delegating_population_snapshot" (
3132 "issue_id",
3133 "event",
3134 "member_id",
3135 "scope",
3136 "delegate_member_ids"
3137 ) VALUES (
3138 "issue_id_p",
3139 'periodic',
3140 "issue_delegation_row"."truster_id",
3141 "issue_delegation_row"."scope",
3142 "delegate_member_ids_v"
3143 );
3144 "sub_weight_v" := 1 +
3145 "weight_of_added_delegations_for_population_snapshot"(
3146 "issue_id_p",
3147 "issue_delegation_row"."truster_id",
3148 "delegate_member_ids_v"
3149 );
3150 UPDATE "delegating_population_snapshot"
3151 SET "weight" = "sub_weight_v"
3152 WHERE "issue_id" = "issue_id_p"
3153 AND "event" = 'periodic'
3154 AND "member_id" = "issue_delegation_row"."truster_id";
3155 "weight_v" := "weight_v" + "sub_weight_v";
3156 END IF;
3157 END LOOP;
3158 RETURN "weight_v";
3159 END;
3160 $$;
3162 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3163 ( "issue"."id"%TYPE,
3164 "member"."id"%TYPE,
3165 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3166 IS 'Helper function for "create_population_snapshot" function';
3169 CREATE FUNCTION "create_population_snapshot"
3170 ( "issue_id_p" "issue"."id"%TYPE )
3171 RETURNS VOID
3172 LANGUAGE 'plpgsql' VOLATILE AS $$
3173 DECLARE
3174 "member_id_v" "member"."id"%TYPE;
3175 BEGIN
3176 DELETE FROM "direct_population_snapshot"
3177 WHERE "issue_id" = "issue_id_p"
3178 AND "event" = 'periodic';
3179 DELETE FROM "delegating_population_snapshot"
3180 WHERE "issue_id" = "issue_id_p"
3181 AND "event" = 'periodic';
3182 INSERT INTO "direct_population_snapshot"
3183 ("issue_id", "event", "member_id")
3184 SELECT
3185 "issue_id_p" AS "issue_id",
3186 'periodic'::"snapshot_event" AS "event",
3187 "member"."id" AS "member_id"
3188 FROM "issue"
3189 JOIN "area" ON "issue"."area_id" = "area"."id"
3190 JOIN "membership" ON "area"."id" = "membership"."area_id"
3191 JOIN "member" ON "membership"."member_id" = "member"."id"
3192 JOIN "privilege"
3193 ON "privilege"."unit_id" = "area"."unit_id"
3194 AND "privilege"."member_id" = "member"."id"
3195 WHERE "issue"."id" = "issue_id_p"
3196 AND "member"."active" AND "privilege"."voting_right"
3197 UNION
3198 SELECT
3199 "issue_id_p" AS "issue_id",
3200 'periodic'::"snapshot_event" AS "event",
3201 "member"."id" AS "member_id"
3202 FROM "issue"
3203 JOIN "area" ON "issue"."area_id" = "area"."id"
3204 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3205 JOIN "member" ON "interest"."member_id" = "member"."id"
3206 JOIN "privilege"
3207 ON "privilege"."unit_id" = "area"."unit_id"
3208 AND "privilege"."member_id" = "member"."id"
3209 WHERE "issue"."id" = "issue_id_p"
3210 AND "member"."active" AND "privilege"."voting_right";
3211 FOR "member_id_v" IN
3212 SELECT "member_id" FROM "direct_population_snapshot"
3213 WHERE "issue_id" = "issue_id_p"
3214 AND "event" = 'periodic'
3215 LOOP
3216 UPDATE "direct_population_snapshot" SET
3217 "weight" = 1 +
3218 "weight_of_added_delegations_for_population_snapshot"(
3219 "issue_id_p",
3220 "member_id_v",
3221 '{}'
3223 WHERE "issue_id" = "issue_id_p"
3224 AND "event" = 'periodic'
3225 AND "member_id" = "member_id_v";
3226 END LOOP;
3227 RETURN;
3228 END;
3229 $$;
3231 COMMENT ON FUNCTION "create_population_snapshot"
3232 ( "issue"."id"%TYPE )
3233 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.';
3236 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3237 ( "issue_id_p" "issue"."id"%TYPE,
3238 "member_id_p" "member"."id"%TYPE,
3239 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3240 RETURNS "direct_interest_snapshot"."weight"%TYPE
3241 LANGUAGE 'plpgsql' VOLATILE AS $$
3242 DECLARE
3243 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3244 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3245 "weight_v" INT4;
3246 "sub_weight_v" INT4;
3247 BEGIN
3248 "weight_v" := 0;
3249 FOR "issue_delegation_row" IN
3250 SELECT * FROM "issue_delegation"
3251 WHERE "trustee_id" = "member_id_p"
3252 AND "issue_id" = "issue_id_p"
3253 LOOP
3254 IF NOT EXISTS (
3255 SELECT NULL FROM "direct_interest_snapshot"
3256 WHERE "issue_id" = "issue_id_p"
3257 AND "event" = 'periodic'
3258 AND "member_id" = "issue_delegation_row"."truster_id"
3259 ) AND NOT EXISTS (
3260 SELECT NULL FROM "delegating_interest_snapshot"
3261 WHERE "issue_id" = "issue_id_p"
3262 AND "event" = 'periodic'
3263 AND "member_id" = "issue_delegation_row"."truster_id"
3264 ) THEN
3265 "delegate_member_ids_v" :=
3266 "member_id_p" || "delegate_member_ids_p";
3267 INSERT INTO "delegating_interest_snapshot" (
3268 "issue_id",
3269 "event",
3270 "member_id",
3271 "scope",
3272 "delegate_member_ids"
3273 ) VALUES (
3274 "issue_id_p",
3275 'periodic',
3276 "issue_delegation_row"."truster_id",
3277 "issue_delegation_row"."scope",
3278 "delegate_member_ids_v"
3279 );
3280 "sub_weight_v" := 1 +
3281 "weight_of_added_delegations_for_interest_snapshot"(
3282 "issue_id_p",
3283 "issue_delegation_row"."truster_id",
3284 "delegate_member_ids_v"
3285 );
3286 UPDATE "delegating_interest_snapshot"
3287 SET "weight" = "sub_weight_v"
3288 WHERE "issue_id" = "issue_id_p"
3289 AND "event" = 'periodic'
3290 AND "member_id" = "issue_delegation_row"."truster_id";
3291 "weight_v" := "weight_v" + "sub_weight_v";
3292 END IF;
3293 END LOOP;
3294 RETURN "weight_v";
3295 END;
3296 $$;
3298 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3299 ( "issue"."id"%TYPE,
3300 "member"."id"%TYPE,
3301 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3302 IS 'Helper function for "create_interest_snapshot" function';
3305 CREATE FUNCTION "create_interest_snapshot"
3306 ( "issue_id_p" "issue"."id"%TYPE )
3307 RETURNS VOID
3308 LANGUAGE 'plpgsql' VOLATILE AS $$
3309 DECLARE
3310 "member_id_v" "member"."id"%TYPE;
3311 BEGIN
3312 DELETE FROM "direct_interest_snapshot"
3313 WHERE "issue_id" = "issue_id_p"
3314 AND "event" = 'periodic';
3315 DELETE FROM "delegating_interest_snapshot"
3316 WHERE "issue_id" = "issue_id_p"
3317 AND "event" = 'periodic';
3318 DELETE FROM "direct_supporter_snapshot"
3319 WHERE "issue_id" = "issue_id_p"
3320 AND "event" = 'periodic';
3321 INSERT INTO "direct_interest_snapshot"
3322 ("issue_id", "event", "member_id")
3323 SELECT
3324 "issue_id_p" AS "issue_id",
3325 'periodic' AS "event",
3326 "member"."id" AS "member_id"
3327 FROM "issue"
3328 JOIN "area" ON "issue"."area_id" = "area"."id"
3329 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3330 JOIN "member" ON "interest"."member_id" = "member"."id"
3331 JOIN "privilege"
3332 ON "privilege"."unit_id" = "area"."unit_id"
3333 AND "privilege"."member_id" = "member"."id"
3334 WHERE "issue"."id" = "issue_id_p"
3335 AND "member"."active" AND "privilege"."voting_right";
3336 FOR "member_id_v" IN
3337 SELECT "member_id" FROM "direct_interest_snapshot"
3338 WHERE "issue_id" = "issue_id_p"
3339 AND "event" = 'periodic'
3340 LOOP
3341 UPDATE "direct_interest_snapshot" SET
3342 "weight" = 1 +
3343 "weight_of_added_delegations_for_interest_snapshot"(
3344 "issue_id_p",
3345 "member_id_v",
3346 '{}'
3348 WHERE "issue_id" = "issue_id_p"
3349 AND "event" = 'periodic'
3350 AND "member_id" = "member_id_v";
3351 END LOOP;
3352 INSERT INTO "direct_supporter_snapshot"
3353 ( "issue_id", "initiative_id", "event", "member_id",
3354 "draft_id", "informed", "satisfied" )
3355 SELECT
3356 "issue_id_p" AS "issue_id",
3357 "initiative"."id" AS "initiative_id",
3358 'periodic' AS "event",
3359 "supporter"."member_id" AS "member_id",
3360 "supporter"."draft_id" AS "draft_id",
3361 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3362 NOT EXISTS (
3363 SELECT NULL FROM "critical_opinion"
3364 WHERE "initiative_id" = "initiative"."id"
3365 AND "member_id" = "supporter"."member_id"
3366 ) AS "satisfied"
3367 FROM "initiative"
3368 JOIN "supporter"
3369 ON "supporter"."initiative_id" = "initiative"."id"
3370 JOIN "current_draft"
3371 ON "initiative"."id" = "current_draft"."initiative_id"
3372 JOIN "direct_interest_snapshot"
3373 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3374 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3375 AND "event" = 'periodic'
3376 WHERE "initiative"."issue_id" = "issue_id_p";
3377 RETURN;
3378 END;
3379 $$;
3381 COMMENT ON FUNCTION "create_interest_snapshot"
3382 ( "issue"."id"%TYPE )
3383 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.';
3386 CREATE FUNCTION "create_snapshot"
3387 ( "issue_id_p" "issue"."id"%TYPE )
3388 RETURNS VOID
3389 LANGUAGE 'plpgsql' VOLATILE AS $$
3390 DECLARE
3391 "initiative_id_v" "initiative"."id"%TYPE;
3392 "suggestion_id_v" "suggestion"."id"%TYPE;
3393 BEGIN
3394 PERFORM "lock_issue"("issue_id_p");
3395 PERFORM "create_population_snapshot"("issue_id_p");
3396 PERFORM "create_interest_snapshot"("issue_id_p");
3397 UPDATE "issue" SET
3398 "snapshot" = now(),
3399 "latest_snapshot_event" = 'periodic',
3400 "population" = (
3401 SELECT coalesce(sum("weight"), 0)
3402 FROM "direct_population_snapshot"
3403 WHERE "issue_id" = "issue_id_p"
3404 AND "event" = 'periodic'
3406 WHERE "id" = "issue_id_p";
3407 FOR "initiative_id_v" IN
3408 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3409 LOOP
3410 UPDATE "initiative" SET
3411 "supporter_count" = (
3412 SELECT coalesce(sum("di"."weight"), 0)
3413 FROM "direct_interest_snapshot" AS "di"
3414 JOIN "direct_supporter_snapshot" AS "ds"
3415 ON "di"."member_id" = "ds"."member_id"
3416 WHERE "di"."issue_id" = "issue_id_p"
3417 AND "di"."event" = 'periodic'
3418 AND "ds"."initiative_id" = "initiative_id_v"
3419 AND "ds"."event" = 'periodic'
3420 ),
3421 "informed_supporter_count" = (
3422 SELECT coalesce(sum("di"."weight"), 0)
3423 FROM "direct_interest_snapshot" AS "di"
3424 JOIN "direct_supporter_snapshot" AS "ds"
3425 ON "di"."member_id" = "ds"."member_id"
3426 WHERE "di"."issue_id" = "issue_id_p"
3427 AND "di"."event" = 'periodic'
3428 AND "ds"."initiative_id" = "initiative_id_v"
3429 AND "ds"."event" = 'periodic'
3430 AND "ds"."informed"
3431 ),
3432 "satisfied_supporter_count" = (
3433 SELECT coalesce(sum("di"."weight"), 0)
3434 FROM "direct_interest_snapshot" AS "di"
3435 JOIN "direct_supporter_snapshot" AS "ds"
3436 ON "di"."member_id" = "ds"."member_id"
3437 WHERE "di"."issue_id" = "issue_id_p"
3438 AND "di"."event" = 'periodic'
3439 AND "ds"."initiative_id" = "initiative_id_v"
3440 AND "ds"."event" = 'periodic'
3441 AND "ds"."satisfied"
3442 ),
3443 "satisfied_informed_supporter_count" = (
3444 SELECT coalesce(sum("di"."weight"), 0)
3445 FROM "direct_interest_snapshot" AS "di"
3446 JOIN "direct_supporter_snapshot" AS "ds"
3447 ON "di"."member_id" = "ds"."member_id"
3448 WHERE "di"."issue_id" = "issue_id_p"
3449 AND "di"."event" = 'periodic'
3450 AND "ds"."initiative_id" = "initiative_id_v"
3451 AND "ds"."event" = 'periodic'
3452 AND "ds"."informed"
3453 AND "ds"."satisfied"
3455 WHERE "id" = "initiative_id_v";
3456 FOR "suggestion_id_v" IN
3457 SELECT "id" FROM "suggestion"
3458 WHERE "initiative_id" = "initiative_id_v"
3459 LOOP
3460 UPDATE "suggestion" SET
3461 "minus2_unfulfilled_count" = (
3462 SELECT coalesce(sum("snapshot"."weight"), 0)
3463 FROM "issue" CROSS JOIN "opinion"
3464 JOIN "direct_interest_snapshot" AS "snapshot"
3465 ON "snapshot"."issue_id" = "issue"."id"
3466 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3467 AND "snapshot"."member_id" = "opinion"."member_id"
3468 WHERE "issue"."id" = "issue_id_p"
3469 AND "opinion"."suggestion_id" = "suggestion_id_v"
3470 AND "opinion"."degree" = -2
3471 AND "opinion"."fulfilled" = FALSE
3472 ),
3473 "minus2_fulfilled_count" = (
3474 SELECT coalesce(sum("snapshot"."weight"), 0)
3475 FROM "issue" CROSS JOIN "opinion"
3476 JOIN "direct_interest_snapshot" AS "snapshot"
3477 ON "snapshot"."issue_id" = "issue"."id"
3478 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3479 AND "snapshot"."member_id" = "opinion"."member_id"
3480 WHERE "issue"."id" = "issue_id_p"
3481 AND "opinion"."suggestion_id" = "suggestion_id_v"
3482 AND "opinion"."degree" = -2
3483 AND "opinion"."fulfilled" = TRUE
3484 ),
3485 "minus1_unfulfilled_count" = (
3486 SELECT coalesce(sum("snapshot"."weight"), 0)
3487 FROM "issue" CROSS JOIN "opinion"
3488 JOIN "direct_interest_snapshot" AS "snapshot"
3489 ON "snapshot"."issue_id" = "issue"."id"
3490 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3491 AND "snapshot"."member_id" = "opinion"."member_id"
3492 WHERE "issue"."id" = "issue_id_p"
3493 AND "opinion"."suggestion_id" = "suggestion_id_v"
3494 AND "opinion"."degree" = -1
3495 AND "opinion"."fulfilled" = FALSE
3496 ),
3497 "minus1_fulfilled_count" = (
3498 SELECT coalesce(sum("snapshot"."weight"), 0)
3499 FROM "issue" CROSS JOIN "opinion"
3500 JOIN "direct_interest_snapshot" AS "snapshot"
3501 ON "snapshot"."issue_id" = "issue"."id"
3502 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3503 AND "snapshot"."member_id" = "opinion"."member_id"
3504 WHERE "issue"."id" = "issue_id_p"
3505 AND "opinion"."suggestion_id" = "suggestion_id_v"
3506 AND "opinion"."degree" = -1
3507 AND "opinion"."fulfilled" = TRUE
3508 ),
3509 "plus1_unfulfilled_count" = (
3510 SELECT coalesce(sum("snapshot"."weight"), 0)
3511 FROM "issue" CROSS JOIN "opinion"
3512 JOIN "direct_interest_snapshot" AS "snapshot"
3513 ON "snapshot"."issue_id" = "issue"."id"
3514 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3515 AND "snapshot"."member_id" = "opinion"."member_id"
3516 WHERE "issue"."id" = "issue_id_p"
3517 AND "opinion"."suggestion_id" = "suggestion_id_v"
3518 AND "opinion"."degree" = 1
3519 AND "opinion"."fulfilled" = FALSE
3520 ),
3521 "plus1_fulfilled_count" = (
3522 SELECT coalesce(sum("snapshot"."weight"), 0)
3523 FROM "issue" CROSS JOIN "opinion"
3524 JOIN "direct_interest_snapshot" AS "snapshot"
3525 ON "snapshot"."issue_id" = "issue"."id"
3526 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3527 AND "snapshot"."member_id" = "opinion"."member_id"
3528 WHERE "issue"."id" = "issue_id_p"
3529 AND "opinion"."suggestion_id" = "suggestion_id_v"
3530 AND "opinion"."degree" = 1
3531 AND "opinion"."fulfilled" = TRUE
3532 ),
3533 "plus2_unfulfilled_count" = (
3534 SELECT coalesce(sum("snapshot"."weight"), 0)
3535 FROM "issue" CROSS JOIN "opinion"
3536 JOIN "direct_interest_snapshot" AS "snapshot"
3537 ON "snapshot"."issue_id" = "issue"."id"
3538 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3539 AND "snapshot"."member_id" = "opinion"."member_id"
3540 WHERE "issue"."id" = "issue_id_p"
3541 AND "opinion"."suggestion_id" = "suggestion_id_v"
3542 AND "opinion"."degree" = 2
3543 AND "opinion"."fulfilled" = FALSE
3544 ),
3545 "plus2_fulfilled_count" = (
3546 SELECT coalesce(sum("snapshot"."weight"), 0)
3547 FROM "issue" CROSS JOIN "opinion"
3548 JOIN "direct_interest_snapshot" AS "snapshot"
3549 ON "snapshot"."issue_id" = "issue"."id"
3550 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3551 AND "snapshot"."member_id" = "opinion"."member_id"
3552 WHERE "issue"."id" = "issue_id_p"
3553 AND "opinion"."suggestion_id" = "suggestion_id_v"
3554 AND "opinion"."degree" = 2
3555 AND "opinion"."fulfilled" = TRUE
3557 WHERE "suggestion"."id" = "suggestion_id_v";
3558 END LOOP;
3559 END LOOP;
3560 RETURN;
3561 END;
3562 $$;
3564 COMMENT ON FUNCTION "create_snapshot"
3565 ( "issue"."id"%TYPE )
3566 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.';
3569 CREATE FUNCTION "set_snapshot_event"
3570 ( "issue_id_p" "issue"."id"%TYPE,
3571 "event_p" "snapshot_event" )
3572 RETURNS VOID
3573 LANGUAGE 'plpgsql' VOLATILE AS $$
3574 DECLARE
3575 "event_v" "issue"."latest_snapshot_event"%TYPE;
3576 BEGIN
3577 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3578 WHERE "id" = "issue_id_p" FOR UPDATE;
3579 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3580 WHERE "id" = "issue_id_p";
3581 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3582 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3583 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3584 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3585 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3586 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3587 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3588 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3589 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3590 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3591 RETURN;
3592 END;
3593 $$;
3595 COMMENT ON FUNCTION "set_snapshot_event"
3596 ( "issue"."id"%TYPE,
3597 "snapshot_event" )
3598 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3602 ---------------------
3603 -- Freezing issues --
3604 ---------------------
3606 CREATE FUNCTION "freeze_after_snapshot"
3607 ( "issue_id_p" "issue"."id"%TYPE )
3608 RETURNS VOID
3609 LANGUAGE 'plpgsql' VOLATILE AS $$
3610 DECLARE
3611 "issue_row" "issue"%ROWTYPE;
3612 "policy_row" "policy"%ROWTYPE;
3613 "initiative_row" "initiative"%ROWTYPE;
3614 BEGIN
3615 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3616 SELECT * INTO "policy_row"
3617 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3618 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3619 FOR "initiative_row" IN
3620 SELECT * FROM "initiative"
3621 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3622 LOOP
3623 IF
3624 "initiative_row"."polling" OR (
3625 "initiative_row"."satisfied_supporter_count" > 0 AND
3626 "initiative_row"."satisfied_supporter_count" *
3627 "policy_row"."initiative_quorum_den" >=
3628 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3630 THEN
3631 UPDATE "initiative" SET "admitted" = TRUE
3632 WHERE "id" = "initiative_row"."id";
3633 ELSE
3634 UPDATE "initiative" SET "admitted" = FALSE
3635 WHERE "id" = "initiative_row"."id";
3636 END IF;
3637 END LOOP;
3638 IF EXISTS (
3639 SELECT NULL FROM "initiative"
3640 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3641 ) THEN
3642 UPDATE "issue" SET
3643 "state" = 'voting',
3644 "accepted" = coalesce("accepted", now()),
3645 "half_frozen" = coalesce("half_frozen", now()),
3646 "fully_frozen" = now()
3647 WHERE "id" = "issue_id_p";
3648 ELSE
3649 UPDATE "issue" SET
3650 "state" = 'canceled_no_initiative_admitted',
3651 "accepted" = coalesce("accepted", now()),
3652 "half_frozen" = coalesce("half_frozen", now()),
3653 "fully_frozen" = now(),
3654 "closed" = now(),
3655 "ranks_available" = TRUE
3656 WHERE "id" = "issue_id_p";
3657 -- NOTE: The following DELETE statements have effect only when
3658 -- issue state has been manipulated
3659 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3660 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3661 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3662 END IF;
3663 RETURN;
3664 END;
3665 $$;
3667 COMMENT ON FUNCTION "freeze_after_snapshot"
3668 ( "issue"."id"%TYPE )
3669 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3672 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3673 RETURNS VOID
3674 LANGUAGE 'plpgsql' VOLATILE AS $$
3675 DECLARE
3676 "issue_row" "issue"%ROWTYPE;
3677 BEGIN
3678 PERFORM "create_snapshot"("issue_id_p");
3679 PERFORM "freeze_after_snapshot"("issue_id_p");
3680 RETURN;
3681 END;
3682 $$;
3684 COMMENT ON FUNCTION "manual_freeze"
3685 ( "issue"."id"%TYPE )
3686 IS 'Freeze an issue manually (fully) and start voting';
3690 -----------------------
3691 -- Counting of votes --
3692 -----------------------
3695 CREATE FUNCTION "weight_of_added_vote_delegations"
3696 ( "issue_id_p" "issue"."id"%TYPE,
3697 "member_id_p" "member"."id"%TYPE,
3698 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3699 RETURNS "direct_voter"."weight"%TYPE
3700 LANGUAGE 'plpgsql' VOLATILE AS $$
3701 DECLARE
3702 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3703 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3704 "weight_v" INT4;
3705 "sub_weight_v" INT4;
3706 BEGIN
3707 "weight_v" := 0;
3708 FOR "issue_delegation_row" IN
3709 SELECT * FROM "issue_delegation"
3710 WHERE "trustee_id" = "member_id_p"
3711 AND "issue_id" = "issue_id_p"
3712 LOOP
3713 IF NOT EXISTS (
3714 SELECT NULL FROM "direct_voter"
3715 WHERE "member_id" = "issue_delegation_row"."truster_id"
3716 AND "issue_id" = "issue_id_p"
3717 ) AND NOT EXISTS (
3718 SELECT NULL FROM "delegating_voter"
3719 WHERE "member_id" = "issue_delegation_row"."truster_id"
3720 AND "issue_id" = "issue_id_p"
3721 ) THEN
3722 "delegate_member_ids_v" :=
3723 "member_id_p" || "delegate_member_ids_p";
3724 INSERT INTO "delegating_voter" (
3725 "issue_id",
3726 "member_id",
3727 "scope",
3728 "delegate_member_ids"
3729 ) VALUES (
3730 "issue_id_p",
3731 "issue_delegation_row"."truster_id",
3732 "issue_delegation_row"."scope",
3733 "delegate_member_ids_v"
3734 );
3735 "sub_weight_v" := 1 +
3736 "weight_of_added_vote_delegations"(
3737 "issue_id_p",
3738 "issue_delegation_row"."truster_id",
3739 "delegate_member_ids_v"
3740 );
3741 UPDATE "delegating_voter"
3742 SET "weight" = "sub_weight_v"
3743 WHERE "issue_id" = "issue_id_p"
3744 AND "member_id" = "issue_delegation_row"."truster_id";
3745 "weight_v" := "weight_v" + "sub_weight_v";
3746 END IF;
3747 END LOOP;
3748 RETURN "weight_v";
3749 END;
3750 $$;
3752 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3753 ( "issue"."id"%TYPE,
3754 "member"."id"%TYPE,
3755 "delegating_voter"."delegate_member_ids"%TYPE )
3756 IS 'Helper function for "add_vote_delegations" function';
3759 CREATE FUNCTION "add_vote_delegations"
3760 ( "issue_id_p" "issue"."id"%TYPE )
3761 RETURNS VOID
3762 LANGUAGE 'plpgsql' VOLATILE AS $$
3763 DECLARE
3764 "member_id_v" "member"."id"%TYPE;
3765 BEGIN
3766 FOR "member_id_v" IN
3767 SELECT "member_id" FROM "direct_voter"
3768 WHERE "issue_id" = "issue_id_p"
3769 LOOP
3770 UPDATE "direct_voter" SET
3771 "weight" = "weight" + "weight_of_added_vote_delegations"(
3772 "issue_id_p",
3773 "member_id_v",
3774 '{}'
3776 WHERE "member_id" = "member_id_v"
3777 AND "issue_id" = "issue_id_p";
3778 END LOOP;
3779 RETURN;
3780 END;
3781 $$;
3783 COMMENT ON FUNCTION "add_vote_delegations"
3784 ( "issue_id_p" "issue"."id"%TYPE )
3785 IS 'Helper function for "close_voting" function';
3788 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3789 RETURNS VOID
3790 LANGUAGE 'plpgsql' VOLATILE AS $$
3791 DECLARE
3792 "area_id_v" "area"."id"%TYPE;
3793 "unit_id_v" "unit"."id"%TYPE;
3794 "member_id_v" "member"."id"%TYPE;
3795 BEGIN
3796 PERFORM "lock_issue"("issue_id_p");
3797 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3798 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3799 -- delete delegating votes (in cases of manual reset of issue state):
3800 DELETE FROM "delegating_voter"
3801 WHERE "issue_id" = "issue_id_p";
3802 -- delete votes from non-privileged voters:
3803 DELETE FROM "direct_voter"
3804 USING (
3805 SELECT
3806 "direct_voter"."member_id"
3807 FROM "direct_voter"
3808 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3809 LEFT JOIN "privilege"
3810 ON "privilege"."unit_id" = "unit_id_v"
3811 AND "privilege"."member_id" = "direct_voter"."member_id"
3812 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3813 "member"."active" = FALSE OR
3814 "privilege"."voting_right" ISNULL OR
3815 "privilege"."voting_right" = FALSE
3817 ) AS "subquery"
3818 WHERE "direct_voter"."issue_id" = "issue_id_p"
3819 AND "direct_voter"."member_id" = "subquery"."member_id";
3820 -- consider delegations:
3821 UPDATE "direct_voter" SET "weight" = 1
3822 WHERE "issue_id" = "issue_id_p";
3823 PERFORM "add_vote_delegations"("issue_id_p");
3824 -- set voter count and mark issue as being calculated:
3825 UPDATE "issue" SET
3826 "state" = 'calculation',
3827 "closed" = now(),
3828 "voter_count" = (
3829 SELECT coalesce(sum("weight"), 0)
3830 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3832 WHERE "id" = "issue_id_p";
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 -- copy "positive_votes" and "negative_votes" from "battle" table:
3846 UPDATE "initiative" SET
3847 "positive_votes" = "battle_win"."count",
3848 "negative_votes" = "battle_lose"."count"
3849 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3850 WHERE
3851 "battle_win"."issue_id" = "issue_id_p" AND
3852 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3853 "battle_win"."losing_initiative_id" ISNULL AND
3854 "battle_lose"."issue_id" = "issue_id_p" AND
3855 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3856 "battle_lose"."winning_initiative_id" ISNULL;
3857 END;
3858 $$;
3860 COMMENT ON FUNCTION "close_voting"
3861 ( "issue"."id"%TYPE )
3862 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.';
3865 CREATE FUNCTION "defeat_strength"
3866 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3867 RETURNS INT8
3868 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3869 BEGIN
3870 IF "positive_votes_p" > "negative_votes_p" THEN
3871 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3872 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3873 RETURN 0;
3874 ELSE
3875 RETURN -1;
3876 END IF;
3877 END;
3878 $$;
3880 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4) IS 'Calculates defeat strength (INT8!) of a pairwise defeat primarily by the absolute number of votes for the winner and secondarily by the absolute number of votes for the loser';
3883 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3884 RETURNS VOID
3885 LANGUAGE 'plpgsql' VOLATILE AS $$
3886 DECLARE
3887 "issue_row" "issue"%ROWTYPE;
3888 "policy_row" "policy"%ROWTYPE;
3889 "dimension_v" INTEGER;
3890 "vote_matrix" INT4[][]; -- absolute votes
3891 "matrix" INT8[][]; -- defeat strength / best paths
3892 "i" INTEGER;
3893 "j" INTEGER;
3894 "k" INTEGER;
3895 "battle_row" "battle"%ROWTYPE;
3896 "rank_ary" INT4[];
3897 "rank_v" INT4;
3898 "done_v" INTEGER;
3899 "winners_ary" INTEGER[];
3900 "initiative_id_v" "initiative"."id"%TYPE;
3901 BEGIN
3902 SELECT * INTO "issue_row"
3903 FROM "issue" WHERE "id" = "issue_id_p"
3904 FOR UPDATE;
3905 SELECT * INTO "policy_row"
3906 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3907 SELECT count(1) INTO "dimension_v"
3908 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3909 -- Create "vote_matrix" with absolute number of votes in pairwise
3910 -- comparison:
3911 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3912 "i" := 1;
3913 "j" := 2;
3914 FOR "battle_row" IN
3915 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3916 ORDER BY
3917 "winning_initiative_id" NULLS LAST,
3918 "losing_initiative_id" NULLS LAST
3919 LOOP
3920 "vote_matrix"["i"]["j"] := "battle_row"."count";
3921 IF "j" = "dimension_v" THEN
3922 "i" := "i" + 1;
3923 "j" := 1;
3924 ELSE
3925 "j" := "j" + 1;
3926 IF "j" = "i" THEN
3927 "j" := "j" + 1;
3928 END IF;
3929 END IF;
3930 END LOOP;
3931 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3932 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3933 END IF;
3934 -- Store defeat strengths in "matrix" using "defeat_strength"
3935 -- function:
3936 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3937 "i" := 1;
3938 LOOP
3939 "j" := 1;
3940 LOOP
3941 IF "i" != "j" THEN
3942 "matrix"["i"]["j"] := "defeat_strength"(
3943 "vote_matrix"["i"]["j"],
3944 "vote_matrix"["j"]["i"]
3945 );
3946 END IF;
3947 EXIT WHEN "j" = "dimension_v";
3948 "j" := "j" + 1;
3949 END LOOP;
3950 EXIT WHEN "i" = "dimension_v";
3951 "i" := "i" + 1;
3952 END LOOP;
3953 -- Find best paths:
3954 "i" := 1;
3955 LOOP
3956 "j" := 1;
3957 LOOP
3958 IF "i" != "j" THEN
3959 "k" := 1;
3960 LOOP
3961 IF "i" != "k" AND "j" != "k" THEN
3962 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3963 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3964 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3965 END IF;
3966 ELSE
3967 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3968 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3969 END IF;
3970 END IF;
3971 END IF;
3972 EXIT WHEN "k" = "dimension_v";
3973 "k" := "k" + 1;
3974 END LOOP;
3975 END IF;
3976 EXIT WHEN "j" = "dimension_v";
3977 "j" := "j" + 1;
3978 END LOOP;
3979 EXIT WHEN "i" = "dimension_v";
3980 "i" := "i" + 1;
3981 END LOOP;
3982 -- Determine order of winners:
3983 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3984 "rank_v" := 1;
3985 "done_v" := 0;
3986 LOOP
3987 "winners_ary" := '{}';
3988 "i" := 1;
3989 LOOP
3990 IF "rank_ary"["i"] ISNULL THEN
3991 "j" := 1;
3992 LOOP
3993 IF
3994 "i" != "j" AND
3995 "rank_ary"["j"] ISNULL AND
3996 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3997 THEN
3998 -- someone else is better
3999 EXIT;
4000 END IF;
4001 IF "j" = "dimension_v" THEN
4002 -- noone is better
4003 "winners_ary" := "winners_ary" || "i";
4004 EXIT;
4005 END IF;
4006 "j" := "j" + 1;
4007 END LOOP;
4008 END IF;
4009 EXIT WHEN "i" = "dimension_v";
4010 "i" := "i" + 1;
4011 END LOOP;
4012 "i" := 1;
4013 LOOP
4014 "rank_ary"["winners_ary"["i"]] := "rank_v";
4015 "done_v" := "done_v" + 1;
4016 EXIT WHEN "i" = array_upper("winners_ary", 1);
4017 "i" := "i" + 1;
4018 END LOOP;
4019 EXIT WHEN "done_v" = "dimension_v";
4020 "rank_v" := "rank_v" + 1;
4021 END LOOP;
4022 -- write preliminary results:
4023 "i" := 1;
4024 FOR "initiative_id_v" IN
4025 SELECT "id" FROM "initiative"
4026 WHERE "issue_id" = "issue_id_p" AND "admitted"
4027 ORDER BY "id"
4028 LOOP
4029 UPDATE "initiative" SET
4030 "direct_majority" =
4031 CASE WHEN "policy_row"."direct_majority_strict" THEN
4032 "positive_votes" * "policy_row"."direct_majority_den" >
4033 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4034 ELSE
4035 "positive_votes" * "policy_row"."direct_majority_den" >=
4036 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4037 END
4038 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4039 AND "issue_row"."voter_count"-"negative_votes" >=
4040 "policy_row"."direct_majority_non_negative",
4041 "indirect_majority" =
4042 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4043 "positive_votes" * "policy_row"."indirect_majority_den" >
4044 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4045 ELSE
4046 "positive_votes" * "policy_row"."indirect_majority_den" >=
4047 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4048 END
4049 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4050 AND "issue_row"."voter_count"-"negative_votes" >=
4051 "policy_row"."indirect_majority_non_negative",
4052 "schulze_rank" = "rank_ary"["i"],
4053 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
4054 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
4055 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
4056 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
4057 "eligible" = FALSE,
4058 "winner" = FALSE,
4059 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4060 WHERE "id" = "initiative_id_v";
4061 "i" := "i" + 1;
4062 END LOOP;
4063 IF "i" != "dimension_v" THEN
4064 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4065 END IF;
4066 -- take indirect majorities into account:
4067 LOOP
4068 UPDATE "initiative" SET "indirect_majority" = TRUE
4069 FROM (
4070 SELECT "new_initiative"."id" AS "initiative_id"
4071 FROM "initiative" "old_initiative"
4072 JOIN "initiative" "new_initiative"
4073 ON "new_initiative"."issue_id" = "issue_id_p"
4074 AND "new_initiative"."indirect_majority" = FALSE
4075 JOIN "battle" "battle_win"
4076 ON "battle_win"."issue_id" = "issue_id_p"
4077 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4078 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4079 JOIN "battle" "battle_lose"
4080 ON "battle_lose"."issue_id" = "issue_id_p"
4081 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4082 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4083 WHERE "old_initiative"."issue_id" = "issue_id_p"
4084 AND "old_initiative"."indirect_majority" = TRUE
4085 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4086 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4087 "policy_row"."indirect_majority_num" *
4088 ("battle_win"."count"+"battle_lose"."count")
4089 ELSE
4090 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4091 "policy_row"."indirect_majority_num" *
4092 ("battle_win"."count"+"battle_lose"."count")
4093 END
4094 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4095 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4096 "policy_row"."indirect_majority_non_negative"
4097 ) AS "subquery"
4098 WHERE "id" = "subquery"."initiative_id";
4099 EXIT WHEN NOT FOUND;
4100 END LOOP;
4101 -- set "multistage_majority" for remaining matching initiatives:
4102 UPDATE "initiative" SET "multistage_majority" = TRUE
4103 FROM (
4104 SELECT "losing_initiative"."id" AS "initiative_id"
4105 FROM "initiative" "losing_initiative"
4106 JOIN "initiative" "winning_initiative"
4107 ON "winning_initiative"."issue_id" = "issue_id_p"
4108 AND "winning_initiative"."admitted"
4109 JOIN "battle" "battle_win"
4110 ON "battle_win"."issue_id" = "issue_id_p"
4111 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4112 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4113 JOIN "battle" "battle_lose"
4114 ON "battle_lose"."issue_id" = "issue_id_p"
4115 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4116 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4117 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4118 AND "losing_initiative"."admitted"
4119 AND "winning_initiative"."schulze_rank" <
4120 "losing_initiative"."schulze_rank"
4121 AND "battle_win"."count" > "battle_lose"."count"
4122 AND (
4123 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4124 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4125 ) AS "subquery"
4126 WHERE "id" = "subquery"."initiative_id";
4127 -- mark eligible initiatives:
4128 UPDATE "initiative" SET "eligible" = TRUE
4129 WHERE "issue_id" = "issue_id_p"
4130 AND "initiative"."direct_majority"
4131 AND "initiative"."indirect_majority"
4132 AND "initiative"."better_than_status_quo"
4133 AND (
4134 "policy_row"."no_multistage_majority" = FALSE OR
4135 "initiative"."multistage_majority" = FALSE )
4136 AND (
4137 "policy_row"."no_reverse_beat_path" = FALSE OR
4138 "initiative"."reverse_beat_path" = FALSE );
4139 -- mark final winner:
4140 UPDATE "initiative" SET "winner" = TRUE
4141 FROM (
4142 SELECT "id" AS "initiative_id"
4143 FROM "initiative"
4144 WHERE "issue_id" = "issue_id_p" AND "eligible"
4145 ORDER BY
4146 "schulze_rank",
4147 "vote_ratio"("positive_votes", "negative_votes"),
4148 "id"
4149 LIMIT 1
4150 ) AS "subquery"
4151 WHERE "id" = "subquery"."initiative_id";
4152 -- write (final) ranks:
4153 "rank_v" := 1;
4154 FOR "initiative_id_v" IN
4155 SELECT "id"
4156 FROM "initiative"
4157 WHERE "issue_id" = "issue_id_p" AND "admitted"
4158 ORDER BY
4159 "winner" DESC,
4160 "eligible" DESC,
4161 "schulze_rank",
4162 "vote_ratio"("positive_votes", "negative_votes"),
4163 "id"
4164 LOOP
4165 UPDATE "initiative" SET "rank" = "rank_v"
4166 WHERE "id" = "initiative_id_v";
4167 "rank_v" := "rank_v" + 1;
4168 END LOOP;
4169 -- set schulze rank of status quo and mark issue as finished:
4170 UPDATE "issue" SET
4171 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4172 "state" =
4173 CASE WHEN EXISTS (
4174 SELECT NULL FROM "initiative"
4175 WHERE "issue_id" = "issue_id_p" AND "winner"
4176 ) THEN
4177 'finished_with_winner'::"issue_state"
4178 ELSE
4179 'finished_without_winner'::"issue_state"
4180 END,
4181 "ranks_available" = TRUE
4182 WHERE "id" = "issue_id_p";
4183 RETURN;
4184 END;
4185 $$;
4187 COMMENT ON FUNCTION "calculate_ranks"
4188 ( "issue"."id"%TYPE )
4189 IS 'Determine ranking (Votes have to be counted first)';
4193 -----------------------------
4194 -- Automatic state changes --
4195 -----------------------------
4198 CREATE FUNCTION "check_issue"
4199 ( "issue_id_p" "issue"."id"%TYPE )
4200 RETURNS VOID
4201 LANGUAGE 'plpgsql' VOLATILE AS $$
4202 DECLARE
4203 "issue_row" "issue"%ROWTYPE;
4204 "policy_row" "policy"%ROWTYPE;
4205 BEGIN
4206 PERFORM "lock_issue"("issue_id_p");
4207 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4208 -- only process open issues:
4209 IF "issue_row"."closed" ISNULL THEN
4210 SELECT * INTO "policy_row" FROM "policy"
4211 WHERE "id" = "issue_row"."policy_id";
4212 -- create a snapshot, unless issue is already fully frozen:
4213 IF "issue_row"."fully_frozen" ISNULL THEN
4214 PERFORM "create_snapshot"("issue_id_p");
4215 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4216 END IF;
4217 -- eventually close or accept issues, which have not been accepted:
4218 IF "issue_row"."accepted" ISNULL THEN
4219 IF EXISTS (
4220 SELECT NULL FROM "initiative"
4221 WHERE "issue_id" = "issue_id_p"
4222 AND "supporter_count" > 0
4223 AND "supporter_count" * "policy_row"."issue_quorum_den"
4224 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4225 ) THEN
4226 -- accept issues, if supporter count is high enough
4227 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4228 -- NOTE: "issue_row" used later
4229 "issue_row"."state" := 'discussion';
4230 "issue_row"."accepted" := now();
4231 UPDATE "issue" SET
4232 "state" = "issue_row"."state",
4233 "accepted" = "issue_row"."accepted"
4234 WHERE "id" = "issue_row"."id";
4235 ELSIF
4236 now() >= "issue_row"."created" + "issue_row"."admission_time"
4237 THEN
4238 -- close issues, if admission time has expired
4239 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4240 UPDATE "issue" SET
4241 "state" = 'canceled_issue_not_accepted',
4242 "closed" = now()
4243 WHERE "id" = "issue_row"."id";
4244 END IF;
4245 END IF;
4246 -- eventually half freeze issues:
4247 IF
4248 -- NOTE: issue can't be closed at this point, if it has been accepted
4249 "issue_row"."accepted" NOTNULL AND
4250 "issue_row"."half_frozen" ISNULL
4251 THEN
4252 IF
4253 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4254 THEN
4255 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4256 -- NOTE: "issue_row" used later
4257 "issue_row"."state" := 'verification';
4258 "issue_row"."half_frozen" := now();
4259 UPDATE "issue" SET
4260 "state" = "issue_row"."state",
4261 "half_frozen" = "issue_row"."half_frozen"
4262 WHERE "id" = "issue_row"."id";
4263 END IF;
4264 END IF;
4265 -- close issues after some time, if all initiatives have been revoked:
4266 IF
4267 "issue_row"."closed" ISNULL AND
4268 NOT EXISTS (
4269 -- all initiatives are revoked
4270 SELECT NULL FROM "initiative"
4271 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4272 ) AND (
4273 -- and issue has not been accepted yet
4274 "issue_row"."accepted" ISNULL OR
4275 NOT EXISTS (
4276 -- or no initiatives have been revoked lately
4277 SELECT NULL FROM "initiative"
4278 WHERE "issue_id" = "issue_id_p"
4279 AND now() < "revoked" + "issue_row"."verification_time"
4280 ) OR (
4281 -- or verification time has elapsed
4282 "issue_row"."half_frozen" NOTNULL AND
4283 "issue_row"."fully_frozen" ISNULL AND
4284 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4287 THEN
4288 -- NOTE: "issue_row" used later
4289 IF "issue_row"."accepted" ISNULL THEN
4290 "issue_row"."state" := 'canceled_revoked_before_accepted';
4291 ELSIF "issue_row"."half_frozen" ISNULL THEN
4292 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4293 ELSE
4294 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4295 END IF;
4296 "issue_row"."closed" := now();
4297 UPDATE "issue" SET
4298 "state" = "issue_row"."state",
4299 "closed" = "issue_row"."closed"
4300 WHERE "id" = "issue_row"."id";
4301 END IF;
4302 -- fully freeze issue after verification time:
4303 IF
4304 "issue_row"."half_frozen" NOTNULL AND
4305 "issue_row"."fully_frozen" ISNULL AND
4306 "issue_row"."closed" ISNULL AND
4307 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4308 THEN
4309 PERFORM "freeze_after_snapshot"("issue_id_p");
4310 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4311 END IF;
4312 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4313 -- close issue by calling close_voting(...) after voting time:
4314 IF
4315 "issue_row"."closed" ISNULL AND
4316 "issue_row"."fully_frozen" NOTNULL AND
4317 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4318 THEN
4319 PERFORM "close_voting"("issue_id_p");
4320 -- calculate ranks will not consume much time and can be done now
4321 PERFORM "calculate_ranks"("issue_id_p");
4322 END IF;
4323 END IF;
4324 RETURN;
4325 END;
4326 $$;
4328 COMMENT ON FUNCTION "check_issue"
4329 ( "issue"."id"%TYPE )
4330 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required; At end of voting the ranking is not calculated by this function, but must be calculated in a seperate transaction using the "calculate_ranks" function.';
4333 CREATE FUNCTION "check_everything"()
4334 RETURNS VOID
4335 LANGUAGE 'plpgsql' VOLATILE AS $$
4336 DECLARE
4337 "issue_id_v" "issue"."id"%TYPE;
4338 BEGIN
4339 DELETE FROM "expired_session";
4340 PERFORM "check_activity"();
4341 PERFORM "calculate_member_counts"();
4342 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4343 PERFORM "check_issue"("issue_id_v");
4344 END LOOP;
4345 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4346 PERFORM "calculate_ranks"("issue_id_v");
4347 END LOOP;
4348 RETURN;
4349 END;
4350 $$;
4352 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue, and if possible, automatically calculates ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result. In productive environments you should call the lf_update program instead.';
4356 ----------------------
4357 -- Deletion of data --
4358 ----------------------
4361 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4362 RETURNS VOID
4363 LANGUAGE 'plpgsql' VOLATILE AS $$
4364 DECLARE
4365 "issue_row" "issue"%ROWTYPE;
4366 BEGIN
4367 SELECT * INTO "issue_row"
4368 FROM "issue" WHERE "id" = "issue_id_p"
4369 FOR UPDATE;
4370 IF "issue_row"."cleaned" ISNULL THEN
4371 UPDATE "issue" SET
4372 "state" = 'voting',
4373 "closed" = NULL,
4374 "ranks_available" = FALSE
4375 WHERE "id" = "issue_id_p";
4376 DELETE FROM "voting_comment"
4377 WHERE "issue_id" = "issue_id_p";
4378 DELETE FROM "delegating_voter"
4379 WHERE "issue_id" = "issue_id_p";
4380 DELETE FROM "direct_voter"
4381 WHERE "issue_id" = "issue_id_p";
4382 DELETE FROM "delegating_interest_snapshot"
4383 WHERE "issue_id" = "issue_id_p";
4384 DELETE FROM "direct_interest_snapshot"
4385 WHERE "issue_id" = "issue_id_p";
4386 DELETE FROM "delegating_population_snapshot"
4387 WHERE "issue_id" = "issue_id_p";
4388 DELETE FROM "direct_population_snapshot"
4389 WHERE "issue_id" = "issue_id_p";
4390 DELETE FROM "non_voter"
4391 WHERE "issue_id" = "issue_id_p";
4392 DELETE FROM "delegation"
4393 WHERE "issue_id" = "issue_id_p";
4394 DELETE FROM "supporter"
4395 WHERE "issue_id" = "issue_id_p";
4396 UPDATE "issue" SET
4397 "state" = "issue_row"."state",
4398 "closed" = "issue_row"."closed",
4399 "ranks_available" = "issue_row"."ranks_available",
4400 "cleaned" = now()
4401 WHERE "id" = "issue_id_p";
4402 END IF;
4403 RETURN;
4404 END;
4405 $$;
4407 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4410 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4411 RETURNS VOID
4412 LANGUAGE 'plpgsql' VOLATILE AS $$
4413 BEGIN
4414 UPDATE "member" SET
4415 "last_login" = NULL,
4416 "login" = NULL,
4417 "password" = NULL,
4418 "locked" = TRUE,
4419 "active" = FALSE,
4420 "notify_email" = NULL,
4421 "notify_email_unconfirmed" = NULL,
4422 "notify_email_secret" = NULL,
4423 "notify_email_secret_expiry" = NULL,
4424 "notify_email_lock_expiry" = NULL,
4425 "password_reset_secret" = NULL,
4426 "password_reset_secret_expiry" = NULL,
4427 "organizational_unit" = NULL,
4428 "internal_posts" = NULL,
4429 "realname" = NULL,
4430 "birthday" = NULL,
4431 "address" = NULL,
4432 "email" = NULL,
4433 "xmpp_address" = NULL,
4434 "website" = NULL,
4435 "phone" = NULL,
4436 "mobile_phone" = NULL,
4437 "profession" = NULL,
4438 "external_memberships" = NULL,
4439 "external_posts" = NULL,
4440 "statement" = NULL
4441 WHERE "id" = "member_id_p";
4442 -- "text_search_data" is updated by triggers
4443 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4444 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4445 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4446 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4447 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4448 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4449 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4450 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4451 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4452 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4453 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4454 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4455 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4456 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4457 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4458 DELETE FROM "direct_voter" USING "issue"
4459 WHERE "direct_voter"."issue_id" = "issue"."id"
4460 AND "issue"."closed" ISNULL
4461 AND "member_id" = "member_id_p";
4462 RETURN;
4463 END;
4464 $$;
4466 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)';
4469 CREATE FUNCTION "delete_private_data"()
4470 RETURNS VOID
4471 LANGUAGE 'plpgsql' VOLATILE AS $$
4472 BEGIN
4473 DELETE FROM "member" WHERE "activated" ISNULL;
4474 UPDATE "member" SET
4475 "invite_code" = NULL,
4476 "invite_code_expiry" = NULL,
4477 "admin_comment" = NULL,
4478 "last_login" = NULL,
4479 "login" = NULL,
4480 "password" = NULL,
4481 "lang" = NULL,
4482 "notify_email" = NULL,
4483 "notify_email_unconfirmed" = NULL,
4484 "notify_email_secret" = NULL,
4485 "notify_email_secret_expiry" = NULL,
4486 "notify_email_lock_expiry" = NULL,
4487 "notify_level" = NULL,
4488 "password_reset_secret" = NULL,
4489 "password_reset_secret_expiry" = NULL,
4490 "organizational_unit" = NULL,
4491 "internal_posts" = NULL,
4492 "realname" = NULL,
4493 "birthday" = NULL,
4494 "address" = NULL,
4495 "email" = NULL,
4496 "xmpp_address" = NULL,
4497 "website" = NULL,
4498 "phone" = NULL,
4499 "mobile_phone" = NULL,
4500 "profession" = NULL,
4501 "external_memberships" = NULL,
4502 "external_posts" = NULL,
4503 "formatting_engine" = NULL,
4504 "statement" = NULL;
4505 -- "text_search_data" is updated by triggers
4506 DELETE FROM "setting";
4507 DELETE FROM "setting_map";
4508 DELETE FROM "member_relation_setting";
4509 DELETE FROM "member_image";
4510 DELETE FROM "contact";
4511 DELETE FROM "ignored_member";
4512 DELETE FROM "session";
4513 DELETE FROM "area_setting";
4514 DELETE FROM "issue_setting";
4515 DELETE FROM "ignored_initiative";
4516 DELETE FROM "initiative_setting";
4517 DELETE FROM "suggestion_setting";
4518 DELETE FROM "non_voter";
4519 DELETE FROM "direct_voter" USING "issue"
4520 WHERE "direct_voter"."issue_id" = "issue"."id"
4521 AND "issue"."closed" ISNULL;
4522 RETURN;
4523 END;
4524 $$;
4526 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.';
4530 COMMIT;

Impressum / About Us