liquid_feedback_core

view core.sql @ 281:2fd3ac2f8323

URL for registered (web) API clients
author jbe
date Wed Aug 15 11:08:13 2012 +0200 (2012-08-15)
parents 5a32f862b2dd
children 3ac4a5664f5c
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 "id" SERIAL8 PRIMARY KEY,
207 "name" TEXT NOT NULL,
208 "url" TEXT,
209 "client_identifier" TEXT NOT NULL UNIQUE,
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"."url" IS 'Optional URL for web clients';
231 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';
232 COMMENT ON COLUMN "registered_client"."client_secret" IS 'Secret for client authentication';
233 COMMENT ON COLUMN "registered_client"."code_grant" IS 'Enable OAuth2 Authorization Code Grant';
234 COMMENT ON COLUMN "registered_client"."implicit_grant" IS 'Enable OAuth2 Implicit Grant';
235 COMMENT ON COLUMN "registered_client"."client_grant" IS 'Enable OAuth2 Client Credentials Grant';
236 COMMENT ON COLUMN "registered_client"."access_level" IS 'Maximum access level for OAuth2 Authorization Code Grant and Implicit Grant';
237 COMMENT ON COLUMN "registered_client"."client_grant_access_level" IS 'Maximum access level for OAuth2 Client Credentials Grant';
238 COMMENT ON COLUMN "registered_client"."single_token" IS 'Allow only one valid refresh token';
239 COMMENT ON COLUMN "registered_client"."always_authorized" IS 'Members do not need to authorize the client';
240 COMMENT ON COLUMN "registered_client"."auth_duration" IS 'Duration of authorization by member';
241 COMMENT ON COLUMN "registered_client"."login_duration" IS 'Life time of refresh code chain';
242 COMMENT ON COLUMN "registered_client"."refresh_duration" IS 'Life time of a refresh code';
243 COMMENT ON COLUMN "registered_client"."access_duration" IS 'Life time of an access code';
246 CREATE TABLE "authorized_client" (
247 "id" SERIAL8 PRIMARY KEY,
248 UNIQUE ("client_identifier", "member_id"),
249 "client_identifier" TEXT NOT NULL,
250 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
251 ON DELETE CASCADE ON UPDATE CASCADE,
252 "access_level" "api_access_level" NOT NULL,
253 "first_auth" TIMESTAMPTZ NOT NULL,
254 "last_auth" TIMESTAMPTZ NOT NULL,
255 UNIQUE ("client_identifier", "member_id") );
257 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';
259 COMMENT ON COLUMN "authorized_client"."client_identifier" IS 'OAuth2 client id, also used as redirection endpoint';
260 COMMENT ON COLUMN "authorized_client"."member_id" IS 'Member who authorized the client';
261 COMMENT ON COLUMN "authorized_client"."access_level" IS 'Authorized access level';
262 COMMENT ON COLUMN "authorized_client"."first_auth" IS 'Date/time of initial authorization';
263 COMMENT ON COLUMN "authorized_client"."last_auth" IS 'Date/time of last authorization refresh';
266 CREATE TABLE "authorized_client_token" (
267 "id" SERIAL8 PRIMARY KEY,
268 "authorized_client_id" INT8 NOT NULL REFERENCES "authorized_client"
269 ON DELETE CASCADE ON UPDATE CASCADE,
270 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
271 "authorization_code" TEXT,
272 "refreshed" TIMESTAMPTZ,
273 "refresh_token" TEXT,
274 "old_refresh_token" TEXT,
275 CONSTRAINT "one_of_authorization_code_and_refresh_token_set"
276 CHECK ("authorization_code" NOTNULL OR "refresh_token" NOTNULL),
277 CONSTRAINT "refresh_token_if_and_only_if_refreshed"
278 CHECK ("refreshed" NOTNULL = "refresh_token" NOTNULL),
279 CONSTRAINT "old_refresh_token_requires_current_refresh_token"
280 CHECK ("refresh_token" NOTNULL OR "old_refresh_token" ISNULL) );
282 COMMENT ON TABLE "authorized_client_token" IS 'PRELIMINARY, SUBJECT TO CHANGE! Issued OAuth2 authorization codes and refresh tokens';
284 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';
285 COMMENT ON COLUMN "authorized_client_token"."authorization_code" IS 'OAuth2 authorization code (only valid for a very short time after it has been created)';
286 COMMENT ON COLUMN "authorized_client_token"."refreshed" IS 'Date/time of last refresh';
287 COMMENT ON COLUMN "authorized_client_token"."refresh_token" IS 'OAuth2 refresh token';
289 -- END OF NEW PRELIMINARY API TABLES --
292 CREATE TABLE "member_history" (
293 "id" SERIAL8 PRIMARY KEY,
294 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
295 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
296 "active" BOOLEAN NOT NULL,
297 "name" TEXT NOT NULL );
298 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
300 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
302 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
303 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
306 CREATE TABLE "rendered_member_statement" (
307 PRIMARY KEY ("member_id", "format"),
308 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
309 "format" TEXT,
310 "content" TEXT NOT NULL );
312 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)';
315 CREATE TABLE "setting" (
316 PRIMARY KEY ("member_id", "key"),
317 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
318 "key" TEXT NOT NULL,
319 "value" TEXT NOT NULL );
320 CREATE INDEX "setting_key_idx" ON "setting" ("key");
322 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
324 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
327 CREATE TABLE "setting_map" (
328 PRIMARY KEY ("member_id", "key", "subkey"),
329 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
330 "key" TEXT NOT NULL,
331 "subkey" TEXT NOT NULL,
332 "value" TEXT NOT NULL );
333 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
335 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
337 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
338 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
339 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
342 CREATE TABLE "member_relation_setting" (
343 PRIMARY KEY ("member_id", "key", "other_member_id"),
344 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
345 "key" TEXT NOT NULL,
346 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
347 "value" TEXT NOT NULL );
349 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
352 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
354 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
357 CREATE TABLE "member_image" (
358 PRIMARY KEY ("member_id", "image_type", "scaled"),
359 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
360 "image_type" "member_image_type",
361 "scaled" BOOLEAN,
362 "content_type" TEXT,
363 "data" BYTEA NOT NULL );
365 COMMENT ON TABLE "member_image" IS 'Images of members';
367 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
370 CREATE TABLE "member_count" (
371 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
372 "total_count" INT4 NOT NULL );
374 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';
376 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
377 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
380 CREATE TABLE "contact" (
381 PRIMARY KEY ("member_id", "other_member_id"),
382 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
383 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
384 "public" BOOLEAN NOT NULL DEFAULT FALSE,
385 CONSTRAINT "cant_save_yourself_as_contact"
386 CHECK ("member_id" != "other_member_id") );
387 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
389 COMMENT ON TABLE "contact" IS 'Contact lists';
391 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
392 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
393 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
396 CREATE TABLE "ignored_member" (
397 PRIMARY KEY ("member_id", "other_member_id"),
398 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
399 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
400 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
402 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
404 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
405 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
408 CREATE TABLE "session" (
409 "ident" TEXT PRIMARY KEY,
410 "additional_secret" TEXT,
411 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
412 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
413 "lang" TEXT );
414 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
416 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
418 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
419 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
420 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
421 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
424 CREATE TABLE "policy" (
425 "id" SERIAL4 PRIMARY KEY,
426 "index" INT4 NOT NULL,
427 "active" BOOLEAN NOT NULL DEFAULT TRUE,
428 "name" TEXT NOT NULL UNIQUE,
429 "description" TEXT NOT NULL DEFAULT '',
430 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
431 "admission_time" INTERVAL,
432 "discussion_time" INTERVAL,
433 "verification_time" INTERVAL,
434 "voting_time" INTERVAL,
435 "issue_quorum_num" INT4 NOT NULL,
436 "issue_quorum_den" INT4 NOT NULL,
437 "initiative_quorum_num" INT4 NOT NULL,
438 "initiative_quorum_den" INT4 NOT NULL,
439 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
440 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
441 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
442 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
443 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
444 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
445 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
446 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
447 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
448 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
449 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
450 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
451 CONSTRAINT "timing" CHECK (
452 ( "polling" = FALSE AND
453 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
454 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
455 ( "polling" = TRUE AND
456 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
457 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
458 ( "polling" = TRUE AND
459 "admission_time" ISNULL AND "discussion_time" ISNULL AND
460 "verification_time" ISNULL AND "voting_time" ISNULL ) ) );
461 CREATE INDEX "policy_active_idx" ON "policy" ("active");
463 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
465 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
466 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
467 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)';
468 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
469 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
470 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"';
471 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'')';
472 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''';
473 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''';
474 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
475 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
476 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
477 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
478 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.';
479 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
480 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';
481 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';
482 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';
483 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.';
484 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';
485 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';
486 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.';
487 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").';
490 CREATE TABLE "unit" (
491 "id" SERIAL4 PRIMARY KEY,
492 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
493 "active" BOOLEAN NOT NULL DEFAULT TRUE,
494 "name" TEXT NOT NULL,
495 "description" TEXT NOT NULL DEFAULT '',
496 "member_count" INT4,
497 "text_search_data" TSVECTOR );
498 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
499 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
500 CREATE INDEX "unit_active_idx" ON "unit" ("active");
501 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
502 CREATE TRIGGER "update_text_search_data"
503 BEFORE INSERT OR UPDATE ON "unit"
504 FOR EACH ROW EXECUTE PROCEDURE
505 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
506 "name", "description" );
508 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
510 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
511 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
512 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
515 CREATE TABLE "unit_setting" (
516 PRIMARY KEY ("member_id", "key", "unit_id"),
517 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
518 "key" TEXT NOT NULL,
519 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
520 "value" TEXT NOT NULL );
522 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
525 CREATE TABLE "area" (
526 "id" SERIAL4 PRIMARY KEY,
527 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
528 "active" BOOLEAN NOT NULL DEFAULT TRUE,
529 "name" TEXT NOT NULL,
530 "description" TEXT NOT NULL DEFAULT '',
531 "direct_member_count" INT4,
532 "member_weight" INT4,
533 "text_search_data" TSVECTOR );
534 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
535 CREATE INDEX "area_active_idx" ON "area" ("active");
536 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
537 CREATE TRIGGER "update_text_search_data"
538 BEFORE INSERT OR UPDATE ON "area"
539 FOR EACH ROW EXECUTE PROCEDURE
540 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
541 "name", "description" );
543 COMMENT ON TABLE "area" IS 'Subject areas';
545 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
546 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"';
547 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
550 CREATE TABLE "area_setting" (
551 PRIMARY KEY ("member_id", "key", "area_id"),
552 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
553 "key" TEXT NOT NULL,
554 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
555 "value" TEXT NOT NULL );
557 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
560 CREATE TABLE "allowed_policy" (
561 PRIMARY KEY ("area_id", "policy_id"),
562 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
563 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
564 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
565 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
567 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
569 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
572 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
574 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';
577 CREATE TYPE "issue_state" AS ENUM (
578 'admission', 'discussion', 'verification', 'voting',
579 'canceled_revoked_before_accepted',
580 'canceled_issue_not_accepted',
581 'canceled_after_revocation_during_discussion',
582 'canceled_after_revocation_during_verification',
583 'calculation',
584 'canceled_no_initiative_admitted',
585 'finished_without_winner', 'finished_with_winner');
587 COMMENT ON TYPE "issue_state" IS 'State of issues';
590 CREATE TABLE "issue" (
591 "id" SERIAL4 PRIMARY KEY,
592 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
593 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
594 "state" "issue_state" NOT NULL DEFAULT 'admission',
595 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
596 "accepted" TIMESTAMPTZ,
597 "half_frozen" TIMESTAMPTZ,
598 "fully_frozen" TIMESTAMPTZ,
599 "closed" TIMESTAMPTZ,
600 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
601 "cleaned" TIMESTAMPTZ,
602 "admission_time" INTERVAL NOT NULL,
603 "discussion_time" INTERVAL NOT NULL,
604 "verification_time" INTERVAL NOT NULL,
605 "voting_time" INTERVAL NOT NULL,
606 "snapshot" TIMESTAMPTZ,
607 "latest_snapshot_event" "snapshot_event",
608 "population" INT4,
609 "voter_count" INT4,
610 "status_quo_schulze_rank" INT4,
611 CONSTRAINT "valid_state" CHECK ((
612 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
613 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
614 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
615 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
616 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
617 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
618 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
619 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
620 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
621 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
622 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
623 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
624 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
625 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
626 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
627 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
628 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
629 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
630 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
631 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
632 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
633 )),
634 CONSTRAINT "state_change_order" CHECK (
635 "created" <= "accepted" AND
636 "accepted" <= "half_frozen" AND
637 "half_frozen" <= "fully_frozen" AND
638 "fully_frozen" <= "closed" ),
639 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
640 "cleaned" ISNULL OR "closed" NOTNULL ),
641 CONSTRAINT "last_snapshot_on_full_freeze"
642 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
643 CONSTRAINT "freeze_requires_snapshot"
644 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
645 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
646 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
647 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
648 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
649 CREATE INDEX "issue_created_idx" ON "issue" ("created");
650 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
651 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
652 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
653 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
654 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
655 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
657 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
659 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
660 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.';
661 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.';
662 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.';
663 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
664 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
665 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
666 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
667 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
668 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
669 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
670 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';
671 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
672 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';
673 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
676 CREATE TABLE "issue_setting" (
677 PRIMARY KEY ("member_id", "key", "issue_id"),
678 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
679 "key" TEXT NOT NULL,
680 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
681 "value" TEXT NOT NULL );
683 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
686 CREATE TABLE "initiative" (
687 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
688 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
689 "id" SERIAL4 PRIMARY KEY,
690 "name" TEXT NOT NULL,
691 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
692 "discussion_url" TEXT,
693 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
694 "revoked" TIMESTAMPTZ,
695 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
696 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
697 "admitted" BOOLEAN,
698 "supporter_count" INT4,
699 "informed_supporter_count" INT4,
700 "satisfied_supporter_count" INT4,
701 "satisfied_informed_supporter_count" INT4,
702 "positive_votes" INT4,
703 "negative_votes" INT4,
704 "direct_majority" BOOLEAN,
705 "indirect_majority" BOOLEAN,
706 "schulze_rank" INT4,
707 "better_than_status_quo" BOOLEAN,
708 "worse_than_status_quo" BOOLEAN,
709 "reverse_beat_path" BOOLEAN,
710 "multistage_majority" BOOLEAN,
711 "eligible" BOOLEAN,
712 "winner" BOOLEAN,
713 "rank" INT4,
714 "text_search_data" TSVECTOR,
715 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
716 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
717 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
718 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
719 CONSTRAINT "revoked_initiatives_cant_be_admitted"
720 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
721 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
722 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
723 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
724 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
725 "schulze_rank" ISNULL AND
726 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
727 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
728 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
729 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
730 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
731 "eligible" = FALSE OR
732 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
733 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
734 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
735 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
736 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
737 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
738 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
739 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
740 CREATE TRIGGER "update_text_search_data"
741 BEFORE INSERT OR UPDATE ON "initiative"
742 FOR EACH ROW EXECUTE PROCEDURE
743 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
744 "name", "discussion_url");
746 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.';
748 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';
749 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
750 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
751 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
752 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
753 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
754 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
755 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
756 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
757 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
758 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
759 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"';
760 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
761 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
762 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
763 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
764 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';
765 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';
766 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"';
767 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
768 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';
771 CREATE TABLE "battle" (
772 "issue_id" INT4 NOT NULL,
773 "winning_initiative_id" INT4,
774 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
775 "losing_initiative_id" INT4,
776 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
777 "count" INT4 NOT NULL,
778 CONSTRAINT "initiative_ids_not_equal" CHECK (
779 "winning_initiative_id" != "losing_initiative_id" OR
780 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
781 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
782 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
783 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
784 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
786 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';
789 CREATE TABLE "ignored_initiative" (
790 PRIMARY KEY ("initiative_id", "member_id"),
791 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
792 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
793 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
795 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
798 CREATE TABLE "initiative_setting" (
799 PRIMARY KEY ("member_id", "key", "initiative_id"),
800 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "key" TEXT NOT NULL,
802 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
803 "value" TEXT NOT NULL );
805 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
808 CREATE TABLE "draft" (
809 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
810 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
811 "id" SERIAL8 PRIMARY KEY,
812 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
813 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
814 "formatting_engine" TEXT,
815 "content" TEXT NOT NULL,
816 "text_search_data" TSVECTOR );
817 CREATE INDEX "draft_created_idx" ON "draft" ("created");
818 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
819 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
820 CREATE TRIGGER "update_text_search_data"
821 BEFORE INSERT OR UPDATE ON "draft"
822 FOR EACH ROW EXECUTE PROCEDURE
823 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
825 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.';
827 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
828 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
831 CREATE TABLE "rendered_draft" (
832 PRIMARY KEY ("draft_id", "format"),
833 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
834 "format" TEXT,
835 "content" TEXT NOT NULL );
837 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)';
840 CREATE TABLE "suggestion" (
841 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
842 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
843 "id" SERIAL8 PRIMARY KEY,
844 "draft_id" INT8 NOT NULL,
845 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
846 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
847 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
848 "name" TEXT NOT NULL,
849 "formatting_engine" TEXT,
850 "content" TEXT NOT NULL DEFAULT '',
851 "text_search_data" TSVECTOR,
852 "minus2_unfulfilled_count" INT4,
853 "minus2_fulfilled_count" INT4,
854 "minus1_unfulfilled_count" INT4,
855 "minus1_fulfilled_count" INT4,
856 "plus1_unfulfilled_count" INT4,
857 "plus1_fulfilled_count" INT4,
858 "plus2_unfulfilled_count" INT4,
859 "plus2_fulfilled_count" INT4 );
860 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
861 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
862 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
863 CREATE TRIGGER "update_text_search_data"
864 BEFORE INSERT OR UPDATE ON "suggestion"
865 FOR EACH ROW EXECUTE PROCEDURE
866 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
867 "name", "content");
869 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';
871 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")';
872 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
873 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
874 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
875 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
876 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
877 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
878 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
879 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
882 CREATE TABLE "rendered_suggestion" (
883 PRIMARY KEY ("suggestion_id", "format"),
884 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
885 "format" TEXT,
886 "content" TEXT NOT NULL );
888 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)';
891 CREATE TABLE "suggestion_setting" (
892 PRIMARY KEY ("member_id", "key", "suggestion_id"),
893 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
894 "key" TEXT NOT NULL,
895 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
896 "value" TEXT NOT NULL );
898 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
901 CREATE TABLE "privilege" (
902 PRIMARY KEY ("unit_id", "member_id"),
903 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
904 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
905 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
906 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
907 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
908 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
909 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
910 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
911 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
913 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
915 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
916 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
917 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
918 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
919 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
920 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
921 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create polls (see "policy"."polling" and "initiative"."polling")';
924 CREATE TABLE "membership" (
925 PRIMARY KEY ("area_id", "member_id"),
926 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
927 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
928 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
930 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
933 CREATE TABLE "interest" (
934 PRIMARY KEY ("issue_id", "member_id"),
935 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
936 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
937 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
939 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.';
942 CREATE TABLE "initiator" (
943 PRIMARY KEY ("initiative_id", "member_id"),
944 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
945 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
946 "accepted" BOOLEAN );
947 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
949 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.';
951 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.';
954 CREATE TABLE "supporter" (
955 "issue_id" INT4 NOT NULL,
956 PRIMARY KEY ("initiative_id", "member_id"),
957 "initiative_id" INT4,
958 "member_id" INT4,
959 "draft_id" INT8 NOT NULL,
960 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
961 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
962 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
964 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.';
966 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
967 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")';
970 CREATE TABLE "opinion" (
971 "initiative_id" INT4 NOT NULL,
972 PRIMARY KEY ("suggestion_id", "member_id"),
973 "suggestion_id" INT8,
974 "member_id" INT4,
975 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
976 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
977 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
978 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
979 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
981 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.';
983 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
986 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
988 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
991 CREATE TABLE "delegation" (
992 "id" SERIAL8 PRIMARY KEY,
993 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
994 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
995 "scope" "delegation_scope" NOT NULL,
996 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
997 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
998 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
999 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1000 CONSTRAINT "no_unit_delegation_to_null"
1001 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1002 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1003 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1004 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1005 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1006 UNIQUE ("unit_id", "truster_id"),
1007 UNIQUE ("area_id", "truster_id"),
1008 UNIQUE ("issue_id", "truster_id") );
1009 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1010 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1012 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1014 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1015 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1016 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1019 CREATE TABLE "direct_population_snapshot" (
1020 PRIMARY KEY ("issue_id", "event", "member_id"),
1021 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1022 "event" "snapshot_event",
1023 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1024 "weight" INT4 );
1025 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
1027 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
1029 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1030 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
1033 CREATE TABLE "delegating_population_snapshot" (
1034 PRIMARY KEY ("issue_id", "event", "member_id"),
1035 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1036 "event" "snapshot_event",
1037 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1038 "weight" INT4,
1039 "scope" "delegation_scope" NOT NULL,
1040 "delegate_member_ids" INT4[] NOT NULL );
1041 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
1043 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
1045 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1046 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
1047 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
1048 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"';
1051 CREATE TABLE "direct_interest_snapshot" (
1052 PRIMARY KEY ("issue_id", "event", "member_id"),
1053 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1054 "event" "snapshot_event",
1055 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1056 "weight" INT4 );
1057 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1059 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
1061 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1062 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1065 CREATE TABLE "delegating_interest_snapshot" (
1066 PRIMARY KEY ("issue_id", "event", "member_id"),
1067 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1068 "event" "snapshot_event",
1069 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1070 "weight" INT4,
1071 "scope" "delegation_scope" NOT NULL,
1072 "delegate_member_ids" INT4[] NOT NULL );
1073 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1075 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
1077 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1078 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1079 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1080 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"';
1083 CREATE TABLE "direct_supporter_snapshot" (
1084 "issue_id" INT4 NOT NULL,
1085 PRIMARY KEY ("initiative_id", "event", "member_id"),
1086 "initiative_id" INT4,
1087 "event" "snapshot_event",
1088 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1089 "draft_id" INT8 NOT NULL,
1090 "informed" BOOLEAN NOT NULL,
1091 "satisfied" BOOLEAN NOT NULL,
1092 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1093 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1094 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1095 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1097 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
1099 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';
1100 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
1101 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1102 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1105 CREATE TABLE "non_voter" (
1106 PRIMARY KEY ("issue_id", "member_id"),
1107 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1108 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1109 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
1111 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1114 CREATE TABLE "direct_voter" (
1115 PRIMARY KEY ("issue_id", "member_id"),
1116 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1117 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1118 "weight" INT4 );
1119 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1121 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.';
1123 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1126 CREATE TABLE "delegating_voter" (
1127 PRIMARY KEY ("issue_id", "member_id"),
1128 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1129 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1130 "weight" INT4,
1131 "scope" "delegation_scope" NOT NULL,
1132 "delegate_member_ids" INT4[] NOT NULL );
1133 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1135 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
1137 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1138 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1139 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"';
1142 CREATE TABLE "vote" (
1143 "issue_id" INT4 NOT NULL,
1144 PRIMARY KEY ("initiative_id", "member_id"),
1145 "initiative_id" INT4,
1146 "member_id" INT4,
1147 "grade" INT4,
1148 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1149 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1150 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1152 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.';
1154 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1155 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.';
1158 CREATE TABLE "voting_comment" (
1159 PRIMARY KEY ("issue_id", "member_id"),
1160 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1161 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1162 "changed" TIMESTAMPTZ,
1163 "formatting_engine" TEXT,
1164 "content" TEXT NOT NULL,
1165 "text_search_data" TSVECTOR );
1166 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1167 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1168 CREATE TRIGGER "update_text_search_data"
1169 BEFORE INSERT OR UPDATE ON "voting_comment"
1170 FOR EACH ROW EXECUTE PROCEDURE
1171 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1173 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1175 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.';
1178 CREATE TABLE "rendered_voting_comment" (
1179 PRIMARY KEY ("issue_id", "member_id", "format"),
1180 FOREIGN KEY ("issue_id", "member_id")
1181 REFERENCES "voting_comment" ("issue_id", "member_id")
1182 ON DELETE CASCADE ON UPDATE CASCADE,
1183 "issue_id" INT4,
1184 "member_id" INT4,
1185 "format" TEXT,
1186 "content" TEXT NOT NULL );
1188 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)';
1191 CREATE TYPE "event_type" AS ENUM (
1192 'issue_state_changed',
1193 'initiative_created_in_new_issue',
1194 'initiative_created_in_existing_issue',
1195 'initiative_revoked',
1196 'new_draft_created',
1197 'suggestion_created');
1199 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1202 CREATE TABLE "event" (
1203 "id" SERIAL8 PRIMARY KEY,
1204 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1205 "event" "event_type" NOT NULL,
1206 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1207 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1208 "state" "issue_state" CHECK ("state" != 'calculation'),
1209 "initiative_id" INT4,
1210 "draft_id" INT8,
1211 "suggestion_id" INT8,
1212 FOREIGN KEY ("issue_id", "initiative_id")
1213 REFERENCES "initiative" ("issue_id", "id")
1214 ON DELETE CASCADE ON UPDATE CASCADE,
1215 FOREIGN KEY ("initiative_id", "draft_id")
1216 REFERENCES "draft" ("initiative_id", "id")
1217 ON DELETE CASCADE ON UPDATE CASCADE,
1218 FOREIGN KEY ("initiative_id", "suggestion_id")
1219 REFERENCES "suggestion" ("initiative_id", "id")
1220 ON DELETE CASCADE ON UPDATE CASCADE,
1221 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1222 "event" != 'issue_state_changed' OR (
1223 "member_id" ISNULL AND
1224 "issue_id" NOTNULL AND
1225 "state" NOTNULL AND
1226 "initiative_id" ISNULL AND
1227 "draft_id" ISNULL AND
1228 "suggestion_id" ISNULL )),
1229 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1230 "event" NOT IN (
1231 'initiative_created_in_new_issue',
1232 'initiative_created_in_existing_issue',
1233 'initiative_revoked',
1234 'new_draft_created'
1235 ) OR (
1236 "member_id" NOTNULL AND
1237 "issue_id" NOTNULL AND
1238 "state" NOTNULL AND
1239 "initiative_id" NOTNULL AND
1240 "draft_id" NOTNULL AND
1241 "suggestion_id" ISNULL )),
1242 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1243 "event" != 'suggestion_created' OR (
1244 "member_id" NOTNULL AND
1245 "issue_id" NOTNULL AND
1246 "state" NOTNULL AND
1247 "initiative_id" NOTNULL AND
1248 "draft_id" ISNULL AND
1249 "suggestion_id" NOTNULL )) );
1250 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1252 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1254 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1255 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1256 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1257 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1260 CREATE TABLE "notification_sent" (
1261 "event_id" INT8 NOT NULL );
1262 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
1264 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
1265 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
1269 ----------------------------------------------
1270 -- Writing of history entries and event log --
1271 ----------------------------------------------
1274 CREATE FUNCTION "write_member_history_trigger"()
1275 RETURNS TRIGGER
1276 LANGUAGE 'plpgsql' VOLATILE AS $$
1277 BEGIN
1278 IF
1279 ( NEW."active" != OLD."active" OR
1280 NEW."name" != OLD."name" ) AND
1281 OLD."activated" NOTNULL
1282 THEN
1283 INSERT INTO "member_history"
1284 ("member_id", "active", "name")
1285 VALUES (NEW."id", OLD."active", OLD."name");
1286 END IF;
1287 RETURN NULL;
1288 END;
1289 $$;
1291 CREATE TRIGGER "write_member_history"
1292 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1293 "write_member_history_trigger"();
1295 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1296 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1299 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1300 RETURNS TRIGGER
1301 LANGUAGE 'plpgsql' VOLATILE AS $$
1302 BEGIN
1303 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1304 INSERT INTO "event" ("event", "issue_id", "state")
1305 VALUES ('issue_state_changed', NEW."id", NEW."state");
1306 END IF;
1307 RETURN NULL;
1308 END;
1309 $$;
1311 CREATE TRIGGER "write_event_issue_state_changed"
1312 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1313 "write_event_issue_state_changed_trigger"();
1315 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1316 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1319 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1320 RETURNS TRIGGER
1321 LANGUAGE 'plpgsql' VOLATILE AS $$
1322 DECLARE
1323 "initiative_row" "initiative"%ROWTYPE;
1324 "issue_row" "issue"%ROWTYPE;
1325 "event_v" "event_type";
1326 BEGIN
1327 SELECT * INTO "initiative_row" FROM "initiative"
1328 WHERE "id" = NEW."initiative_id";
1329 SELECT * INTO "issue_row" FROM "issue"
1330 WHERE "id" = "initiative_row"."issue_id";
1331 IF EXISTS (
1332 SELECT NULL FROM "draft"
1333 WHERE "initiative_id" = NEW."initiative_id"
1334 AND "id" != NEW."id"
1335 ) THEN
1336 "event_v" := 'new_draft_created';
1337 ELSE
1338 IF EXISTS (
1339 SELECT NULL FROM "initiative"
1340 WHERE "issue_id" = "initiative_row"."issue_id"
1341 AND "id" != "initiative_row"."id"
1342 ) THEN
1343 "event_v" := 'initiative_created_in_existing_issue';
1344 ELSE
1345 "event_v" := 'initiative_created_in_new_issue';
1346 END IF;
1347 END IF;
1348 INSERT INTO "event" (
1349 "event", "member_id",
1350 "issue_id", "state", "initiative_id", "draft_id"
1351 ) VALUES (
1352 "event_v",
1353 NEW."author_id",
1354 "initiative_row"."issue_id",
1355 "issue_row"."state",
1356 "initiative_row"."id",
1357 NEW."id" );
1358 RETURN NULL;
1359 END;
1360 $$;
1362 CREATE TRIGGER "write_event_initiative_or_draft_created"
1363 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1364 "write_event_initiative_or_draft_created_trigger"();
1366 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1367 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1370 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1371 RETURNS TRIGGER
1372 LANGUAGE 'plpgsql' VOLATILE AS $$
1373 DECLARE
1374 "issue_row" "issue"%ROWTYPE;
1375 "draft_id_v" "draft"."id"%TYPE;
1376 BEGIN
1377 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1378 SELECT * INTO "issue_row" FROM "issue"
1379 WHERE "id" = NEW."issue_id";
1380 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1381 WHERE "initiative_id" = NEW."id";
1382 INSERT INTO "event" (
1383 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
1384 ) VALUES (
1385 'initiative_revoked',
1386 NEW."revoked_by_member_id",
1387 NEW."issue_id",
1388 "issue_row"."state",
1389 NEW."id",
1390 "draft_id_v");
1391 END IF;
1392 RETURN NULL;
1393 END;
1394 $$;
1396 CREATE TRIGGER "write_event_initiative_revoked"
1397 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1398 "write_event_initiative_revoked_trigger"();
1400 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1401 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1404 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1405 RETURNS TRIGGER
1406 LANGUAGE 'plpgsql' VOLATILE AS $$
1407 DECLARE
1408 "initiative_row" "initiative"%ROWTYPE;
1409 "issue_row" "issue"%ROWTYPE;
1410 BEGIN
1411 SELECT * INTO "initiative_row" FROM "initiative"
1412 WHERE "id" = NEW."initiative_id";
1413 SELECT * INTO "issue_row" FROM "issue"
1414 WHERE "id" = "initiative_row"."issue_id";
1415 INSERT INTO "event" (
1416 "event", "member_id",
1417 "issue_id", "state", "initiative_id", "suggestion_id"
1418 ) VALUES (
1419 'suggestion_created',
1420 NEW."author_id",
1421 "initiative_row"."issue_id",
1422 "issue_row"."state",
1423 "initiative_row"."id",
1424 NEW."id" );
1425 RETURN NULL;
1426 END;
1427 $$;
1429 CREATE TRIGGER "write_event_suggestion_created"
1430 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1431 "write_event_suggestion_created_trigger"();
1433 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1434 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1438 ----------------------------
1439 -- Additional constraints --
1440 ----------------------------
1443 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1444 RETURNS TRIGGER
1445 LANGUAGE 'plpgsql' VOLATILE AS $$
1446 BEGIN
1447 IF NOT EXISTS (
1448 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1449 ) THEN
1450 --RAISE 'Cannot create issue without an initial initiative.' USING
1451 -- ERRCODE = 'integrity_constraint_violation',
1452 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1453 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1454 END IF;
1455 RETURN NULL;
1456 END;
1457 $$;
1459 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1460 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1461 FOR EACH ROW EXECUTE PROCEDURE
1462 "issue_requires_first_initiative_trigger"();
1464 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1465 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1468 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1469 RETURNS TRIGGER
1470 LANGUAGE 'plpgsql' VOLATILE AS $$
1471 DECLARE
1472 "reference_lost" BOOLEAN;
1473 BEGIN
1474 IF TG_OP = 'DELETE' THEN
1475 "reference_lost" := TRUE;
1476 ELSE
1477 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1478 END IF;
1479 IF
1480 "reference_lost" AND NOT EXISTS (
1481 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1483 THEN
1484 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1485 END IF;
1486 RETURN NULL;
1487 END;
1488 $$;
1490 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1491 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1492 FOR EACH ROW EXECUTE PROCEDURE
1493 "last_initiative_deletes_issue_trigger"();
1495 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1496 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1499 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1500 RETURNS TRIGGER
1501 LANGUAGE 'plpgsql' VOLATILE AS $$
1502 BEGIN
1503 IF NOT EXISTS (
1504 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1505 ) THEN
1506 --RAISE 'Cannot create initiative without an initial draft.' USING
1507 -- ERRCODE = 'integrity_constraint_violation',
1508 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1509 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1510 END IF;
1511 RETURN NULL;
1512 END;
1513 $$;
1515 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1516 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1517 FOR EACH ROW EXECUTE PROCEDURE
1518 "initiative_requires_first_draft_trigger"();
1520 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1521 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1524 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1525 RETURNS TRIGGER
1526 LANGUAGE 'plpgsql' VOLATILE AS $$
1527 DECLARE
1528 "reference_lost" BOOLEAN;
1529 BEGIN
1530 IF TG_OP = 'DELETE' THEN
1531 "reference_lost" := TRUE;
1532 ELSE
1533 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1534 END IF;
1535 IF
1536 "reference_lost" AND NOT EXISTS (
1537 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1539 THEN
1540 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1541 END IF;
1542 RETURN NULL;
1543 END;
1544 $$;
1546 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1547 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1548 FOR EACH ROW EXECUTE PROCEDURE
1549 "last_draft_deletes_initiative_trigger"();
1551 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1552 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1555 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1556 RETURNS TRIGGER
1557 LANGUAGE 'plpgsql' VOLATILE AS $$
1558 BEGIN
1559 IF NOT EXISTS (
1560 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1561 ) THEN
1562 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1563 END IF;
1564 RETURN NULL;
1565 END;
1566 $$;
1568 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1569 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1570 FOR EACH ROW EXECUTE PROCEDURE
1571 "suggestion_requires_first_opinion_trigger"();
1573 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1574 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1577 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1578 RETURNS TRIGGER
1579 LANGUAGE 'plpgsql' VOLATILE AS $$
1580 DECLARE
1581 "reference_lost" BOOLEAN;
1582 BEGIN
1583 IF TG_OP = 'DELETE' THEN
1584 "reference_lost" := TRUE;
1585 ELSE
1586 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1587 END IF;
1588 IF
1589 "reference_lost" AND NOT EXISTS (
1590 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1592 THEN
1593 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1594 END IF;
1595 RETURN NULL;
1596 END;
1597 $$;
1599 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1600 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1601 FOR EACH ROW EXECUTE PROCEDURE
1602 "last_opinion_deletes_suggestion_trigger"();
1604 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1605 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1609 ---------------------------------------------------------------
1610 -- Ensure that votes are not modified when issues are frozen --
1611 ---------------------------------------------------------------
1613 -- NOTE: Frontends should ensure this anyway, but in case of programming
1614 -- errors the following triggers ensure data integrity.
1617 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1618 RETURNS TRIGGER
1619 LANGUAGE 'plpgsql' VOLATILE AS $$
1620 DECLARE
1621 "issue_id_v" "issue"."id"%TYPE;
1622 "issue_row" "issue"%ROWTYPE;
1623 BEGIN
1624 IF TG_OP = 'DELETE' THEN
1625 "issue_id_v" := OLD."issue_id";
1626 ELSE
1627 "issue_id_v" := NEW."issue_id";
1628 END IF;
1629 SELECT INTO "issue_row" * FROM "issue"
1630 WHERE "id" = "issue_id_v" FOR SHARE;
1631 IF "issue_row"."closed" NOTNULL THEN
1632 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1633 END IF;
1634 RETURN NULL;
1635 END;
1636 $$;
1638 CREATE TRIGGER "forbid_changes_on_closed_issue"
1639 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1640 FOR EACH ROW EXECUTE PROCEDURE
1641 "forbid_changes_on_closed_issue_trigger"();
1643 CREATE TRIGGER "forbid_changes_on_closed_issue"
1644 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1645 FOR EACH ROW EXECUTE PROCEDURE
1646 "forbid_changes_on_closed_issue_trigger"();
1648 CREATE TRIGGER "forbid_changes_on_closed_issue"
1649 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1650 FOR EACH ROW EXECUTE PROCEDURE
1651 "forbid_changes_on_closed_issue_trigger"();
1653 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"';
1654 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';
1655 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';
1656 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';
1660 --------------------------------------------------------------------
1661 -- Auto-retrieval of fields only needed for referential integrity --
1662 --------------------------------------------------------------------
1665 CREATE FUNCTION "autofill_issue_id_trigger"()
1666 RETURNS TRIGGER
1667 LANGUAGE 'plpgsql' VOLATILE AS $$
1668 BEGIN
1669 IF NEW."issue_id" ISNULL THEN
1670 SELECT "issue_id" INTO NEW."issue_id"
1671 FROM "initiative" WHERE "id" = NEW."initiative_id";
1672 END IF;
1673 RETURN NEW;
1674 END;
1675 $$;
1677 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1678 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1680 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1681 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1683 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1684 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1685 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1688 CREATE FUNCTION "autofill_initiative_id_trigger"()
1689 RETURNS TRIGGER
1690 LANGUAGE 'plpgsql' VOLATILE AS $$
1691 BEGIN
1692 IF NEW."initiative_id" ISNULL THEN
1693 SELECT "initiative_id" INTO NEW."initiative_id"
1694 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1695 END IF;
1696 RETURN NEW;
1697 END;
1698 $$;
1700 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1701 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1703 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1704 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1708 -----------------------------------------------------
1709 -- Automatic calculation of certain default values --
1710 -----------------------------------------------------
1713 CREATE FUNCTION "copy_timings_trigger"()
1714 RETURNS TRIGGER
1715 LANGUAGE 'plpgsql' VOLATILE AS $$
1716 DECLARE
1717 "policy_row" "policy"%ROWTYPE;
1718 BEGIN
1719 SELECT * INTO "policy_row" FROM "policy"
1720 WHERE "id" = NEW."policy_id";
1721 IF NEW."admission_time" ISNULL THEN
1722 NEW."admission_time" := "policy_row"."admission_time";
1723 END IF;
1724 IF NEW."discussion_time" ISNULL THEN
1725 NEW."discussion_time" := "policy_row"."discussion_time";
1726 END IF;
1727 IF NEW."verification_time" ISNULL THEN
1728 NEW."verification_time" := "policy_row"."verification_time";
1729 END IF;
1730 IF NEW."voting_time" ISNULL THEN
1731 NEW."voting_time" := "policy_row"."voting_time";
1732 END IF;
1733 RETURN NEW;
1734 END;
1735 $$;
1737 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1738 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1740 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1741 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1744 CREATE FUNCTION "default_for_draft_id_trigger"()
1745 RETURNS TRIGGER
1746 LANGUAGE 'plpgsql' VOLATILE AS $$
1747 BEGIN
1748 IF NEW."draft_id" ISNULL THEN
1749 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1750 WHERE "initiative_id" = NEW."initiative_id";
1751 END IF;
1752 RETURN NEW;
1753 END;
1754 $$;
1756 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1757 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1758 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1759 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1761 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1762 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';
1763 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';
1767 ----------------------------------------
1768 -- Automatic creation of dependencies --
1769 ----------------------------------------
1772 CREATE FUNCTION "autocreate_interest_trigger"()
1773 RETURNS TRIGGER
1774 LANGUAGE 'plpgsql' VOLATILE AS $$
1775 BEGIN
1776 IF NOT EXISTS (
1777 SELECT NULL FROM "initiative" JOIN "interest"
1778 ON "initiative"."issue_id" = "interest"."issue_id"
1779 WHERE "initiative"."id" = NEW."initiative_id"
1780 AND "interest"."member_id" = NEW."member_id"
1781 ) THEN
1782 BEGIN
1783 INSERT INTO "interest" ("issue_id", "member_id")
1784 SELECT "issue_id", NEW."member_id"
1785 FROM "initiative" WHERE "id" = NEW."initiative_id";
1786 EXCEPTION WHEN unique_violation THEN END;
1787 END IF;
1788 RETURN NEW;
1789 END;
1790 $$;
1792 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1793 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1795 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1796 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';
1799 CREATE FUNCTION "autocreate_supporter_trigger"()
1800 RETURNS TRIGGER
1801 LANGUAGE 'plpgsql' VOLATILE AS $$
1802 BEGIN
1803 IF NOT EXISTS (
1804 SELECT NULL FROM "suggestion" JOIN "supporter"
1805 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1806 WHERE "suggestion"."id" = NEW."suggestion_id"
1807 AND "supporter"."member_id" = NEW."member_id"
1808 ) THEN
1809 BEGIN
1810 INSERT INTO "supporter" ("initiative_id", "member_id")
1811 SELECT "initiative_id", NEW."member_id"
1812 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1813 EXCEPTION WHEN unique_violation THEN END;
1814 END IF;
1815 RETURN NEW;
1816 END;
1817 $$;
1819 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1820 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1822 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1823 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.';
1827 ------------------------------------------
1828 -- Views and helper functions for views --
1829 ------------------------------------------
1832 CREATE VIEW "unit_delegation" AS
1833 SELECT
1834 "unit"."id" AS "unit_id",
1835 "delegation"."id",
1836 "delegation"."truster_id",
1837 "delegation"."trustee_id",
1838 "delegation"."scope"
1839 FROM "unit"
1840 JOIN "delegation"
1841 ON "delegation"."unit_id" = "unit"."id"
1842 JOIN "member"
1843 ON "delegation"."truster_id" = "member"."id"
1844 JOIN "privilege"
1845 ON "delegation"."unit_id" = "privilege"."unit_id"
1846 AND "delegation"."truster_id" = "privilege"."member_id"
1847 WHERE "member"."active" AND "privilege"."voting_right";
1849 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1852 CREATE VIEW "area_delegation" AS
1853 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1854 "area"."id" AS "area_id",
1855 "delegation"."id",
1856 "delegation"."truster_id",
1857 "delegation"."trustee_id",
1858 "delegation"."scope"
1859 FROM "area"
1860 JOIN "delegation"
1861 ON "delegation"."unit_id" = "area"."unit_id"
1862 OR "delegation"."area_id" = "area"."id"
1863 JOIN "member"
1864 ON "delegation"."truster_id" = "member"."id"
1865 JOIN "privilege"
1866 ON "area"."unit_id" = "privilege"."unit_id"
1867 AND "delegation"."truster_id" = "privilege"."member_id"
1868 WHERE "member"."active" AND "privilege"."voting_right"
1869 ORDER BY
1870 "area"."id",
1871 "delegation"."truster_id",
1872 "delegation"."scope" DESC;
1874 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1877 CREATE VIEW "issue_delegation" AS
1878 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1879 "issue"."id" AS "issue_id",
1880 "delegation"."id",
1881 "delegation"."truster_id",
1882 "delegation"."trustee_id",
1883 "delegation"."scope"
1884 FROM "issue"
1885 JOIN "area"
1886 ON "area"."id" = "issue"."area_id"
1887 JOIN "delegation"
1888 ON "delegation"."unit_id" = "area"."unit_id"
1889 OR "delegation"."area_id" = "area"."id"
1890 OR "delegation"."issue_id" = "issue"."id"
1891 JOIN "member"
1892 ON "delegation"."truster_id" = "member"."id"
1893 JOIN "privilege"
1894 ON "area"."unit_id" = "privilege"."unit_id"
1895 AND "delegation"."truster_id" = "privilege"."member_id"
1896 WHERE "member"."active" AND "privilege"."voting_right"
1897 ORDER BY
1898 "issue"."id",
1899 "delegation"."truster_id",
1900 "delegation"."scope" DESC;
1902 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1905 CREATE FUNCTION "membership_weight_with_skipping"
1906 ( "area_id_p" "area"."id"%TYPE,
1907 "member_id_p" "member"."id"%TYPE,
1908 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1909 RETURNS INT4
1910 LANGUAGE 'plpgsql' STABLE AS $$
1911 DECLARE
1912 "sum_v" INT4;
1913 "delegation_row" "area_delegation"%ROWTYPE;
1914 BEGIN
1915 "sum_v" := 1;
1916 FOR "delegation_row" IN
1917 SELECT "area_delegation".*
1918 FROM "area_delegation" LEFT JOIN "membership"
1919 ON "membership"."area_id" = "area_id_p"
1920 AND "membership"."member_id" = "area_delegation"."truster_id"
1921 WHERE "area_delegation"."area_id" = "area_id_p"
1922 AND "area_delegation"."trustee_id" = "member_id_p"
1923 AND "membership"."member_id" ISNULL
1924 LOOP
1925 IF NOT
1926 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1927 THEN
1928 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1929 "area_id_p",
1930 "delegation_row"."truster_id",
1931 "skip_member_ids_p" || "delegation_row"."truster_id"
1932 );
1933 END IF;
1934 END LOOP;
1935 RETURN "sum_v";
1936 END;
1937 $$;
1939 COMMENT ON FUNCTION "membership_weight_with_skipping"
1940 ( "area"."id"%TYPE,
1941 "member"."id"%TYPE,
1942 INT4[] )
1943 IS 'Helper function for "membership_weight" function';
1946 CREATE FUNCTION "membership_weight"
1947 ( "area_id_p" "area"."id"%TYPE,
1948 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1949 RETURNS INT4
1950 LANGUAGE 'plpgsql' STABLE AS $$
1951 BEGIN
1952 RETURN "membership_weight_with_skipping"(
1953 "area_id_p",
1954 "member_id_p",
1955 ARRAY["member_id_p"]
1956 );
1957 END;
1958 $$;
1960 COMMENT ON FUNCTION "membership_weight"
1961 ( "area"."id"%TYPE,
1962 "member"."id"%TYPE )
1963 IS 'Calculates the potential voting weight of a member in a given area';
1966 CREATE VIEW "member_count_view" AS
1967 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1969 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1972 CREATE VIEW "unit_member_count" AS
1973 SELECT
1974 "unit"."id" AS "unit_id",
1975 count("member"."id") AS "member_count"
1976 FROM "unit"
1977 LEFT JOIN "privilege"
1978 ON "privilege"."unit_id" = "unit"."id"
1979 AND "privilege"."voting_right"
1980 LEFT JOIN "member"
1981 ON "member"."id" = "privilege"."member_id"
1982 AND "member"."active"
1983 GROUP BY "unit"."id";
1985 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1988 CREATE VIEW "area_member_count" AS
1989 SELECT
1990 "area"."id" AS "area_id",
1991 count("member"."id") AS "direct_member_count",
1992 coalesce(
1993 sum(
1994 CASE WHEN "member"."id" NOTNULL THEN
1995 "membership_weight"("area"."id", "member"."id")
1996 ELSE 0 END
1998 ) AS "member_weight"
1999 FROM "area"
2000 LEFT JOIN "membership"
2001 ON "area"."id" = "membership"."area_id"
2002 LEFT JOIN "privilege"
2003 ON "privilege"."unit_id" = "area"."unit_id"
2004 AND "privilege"."member_id" = "membership"."member_id"
2005 AND "privilege"."voting_right"
2006 LEFT JOIN "member"
2007 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
2008 AND "member"."active"
2009 GROUP BY "area"."id";
2011 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
2014 CREATE VIEW "opening_draft" AS
2015 SELECT "draft".* FROM (
2016 SELECT
2017 "initiative"."id" AS "initiative_id",
2018 min("draft"."id") AS "draft_id"
2019 FROM "initiative" JOIN "draft"
2020 ON "initiative"."id" = "draft"."initiative_id"
2021 GROUP BY "initiative"."id"
2022 ) AS "subquery"
2023 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2025 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
2028 CREATE VIEW "current_draft" AS
2029 SELECT "draft".* FROM (
2030 SELECT
2031 "initiative"."id" AS "initiative_id",
2032 max("draft"."id") AS "draft_id"
2033 FROM "initiative" JOIN "draft"
2034 ON "initiative"."id" = "draft"."initiative_id"
2035 GROUP BY "initiative"."id"
2036 ) AS "subquery"
2037 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
2039 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
2042 CREATE VIEW "critical_opinion" AS
2043 SELECT * FROM "opinion"
2044 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
2045 OR ("degree" = -2 AND "fulfilled" = TRUE);
2047 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
2050 CREATE VIEW "battle_participant" AS
2051 SELECT "initiative"."id", "initiative"."issue_id"
2052 FROM "issue" JOIN "initiative"
2053 ON "issue"."id" = "initiative"."issue_id"
2054 WHERE "initiative"."admitted"
2055 UNION ALL
2056 SELECT NULL, "id" AS "issue_id"
2057 FROM "issue";
2059 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
2062 CREATE VIEW "battle_view" AS
2063 SELECT
2064 "issue"."id" AS "issue_id",
2065 "winning_initiative"."id" AS "winning_initiative_id",
2066 "losing_initiative"."id" AS "losing_initiative_id",
2067 sum(
2068 CASE WHEN
2069 coalesce("better_vote"."grade", 0) >
2070 coalesce("worse_vote"."grade", 0)
2071 THEN "direct_voter"."weight" ELSE 0 END
2072 ) AS "count"
2073 FROM "issue"
2074 LEFT JOIN "direct_voter"
2075 ON "issue"."id" = "direct_voter"."issue_id"
2076 JOIN "battle_participant" AS "winning_initiative"
2077 ON "issue"."id" = "winning_initiative"."issue_id"
2078 JOIN "battle_participant" AS "losing_initiative"
2079 ON "issue"."id" = "losing_initiative"."issue_id"
2080 LEFT JOIN "vote" AS "better_vote"
2081 ON "direct_voter"."member_id" = "better_vote"."member_id"
2082 AND "winning_initiative"."id" = "better_vote"."initiative_id"
2083 LEFT JOIN "vote" AS "worse_vote"
2084 ON "direct_voter"."member_id" = "worse_vote"."member_id"
2085 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
2086 WHERE "issue"."closed" NOTNULL
2087 AND "issue"."cleaned" ISNULL
2088 AND (
2089 "winning_initiative"."id" != "losing_initiative"."id" OR
2090 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
2091 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
2092 GROUP BY
2093 "issue"."id",
2094 "winning_initiative"."id",
2095 "losing_initiative"."id";
2097 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';
2100 CREATE VIEW "expired_session" AS
2101 SELECT * FROM "session" WHERE now() > "expiry";
2103 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
2104 DELETE FROM "session" WHERE "ident" = OLD."ident";
2106 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
2107 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
2110 CREATE VIEW "open_issue" AS
2111 SELECT * FROM "issue" WHERE "closed" ISNULL;
2113 COMMENT ON VIEW "open_issue" IS 'All open issues';
2116 CREATE VIEW "issue_with_ranks_missing" AS
2117 SELECT * FROM "issue"
2118 WHERE "fully_frozen" NOTNULL
2119 AND "closed" NOTNULL
2120 AND "ranks_available" = FALSE;
2122 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
2125 CREATE VIEW "member_contingent" AS
2126 SELECT
2127 "member"."id" AS "member_id",
2128 "contingent"."time_frame",
2129 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2131 SELECT count(1) FROM "draft"
2132 WHERE "draft"."author_id" = "member"."id"
2133 AND "draft"."created" > now() - "contingent"."time_frame"
2134 ) + (
2135 SELECT count(1) FROM "suggestion"
2136 WHERE "suggestion"."author_id" = "member"."id"
2137 AND "suggestion"."created" > now() - "contingent"."time_frame"
2139 ELSE NULL END AS "text_entry_count",
2140 "contingent"."text_entry_limit",
2141 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2142 SELECT count(1) FROM "opening_draft"
2143 WHERE "opening_draft"."author_id" = "member"."id"
2144 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2145 ) ELSE NULL END AS "initiative_count",
2146 "contingent"."initiative_limit"
2147 FROM "member" CROSS JOIN "contingent";
2149 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2151 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2152 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2155 CREATE VIEW "member_contingent_left" AS
2156 SELECT
2157 "member_id",
2158 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2159 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2160 FROM "member_contingent" GROUP BY "member_id";
2162 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.';
2165 CREATE VIEW "event_seen_by_member" AS
2166 SELECT
2167 "member"."id" AS "seen_by_member_id",
2168 CASE WHEN "event"."state" IN (
2169 'voting',
2170 'finished_without_winner',
2171 'finished_with_winner'
2172 ) THEN
2173 'voting'::"notify_level"
2174 ELSE
2175 CASE WHEN "event"."state" IN (
2176 'verification',
2177 'canceled_after_revocation_during_verification',
2178 'canceled_no_initiative_admitted'
2179 ) THEN
2180 'verification'::"notify_level"
2181 ELSE
2182 CASE WHEN "event"."state" IN (
2183 'discussion',
2184 'canceled_after_revocation_during_discussion'
2185 ) THEN
2186 'discussion'::"notify_level"
2187 ELSE
2188 'all'::"notify_level"
2189 END
2190 END
2191 END AS "notify_level",
2192 "event".*
2193 FROM "member" CROSS JOIN "event"
2194 LEFT JOIN "issue"
2195 ON "event"."issue_id" = "issue"."id"
2196 LEFT JOIN "membership"
2197 ON "member"."id" = "membership"."member_id"
2198 AND "issue"."area_id" = "membership"."area_id"
2199 LEFT JOIN "interest"
2200 ON "member"."id" = "interest"."member_id"
2201 AND "event"."issue_id" = "interest"."issue_id"
2202 LEFT JOIN "supporter"
2203 ON "member"."id" = "supporter"."member_id"
2204 AND "event"."initiative_id" = "supporter"."initiative_id"
2205 LEFT JOIN "ignored_member"
2206 ON "member"."id" = "ignored_member"."member_id"
2207 AND "event"."member_id" = "ignored_member"."other_member_id"
2208 LEFT JOIN "ignored_initiative"
2209 ON "member"."id" = "ignored_initiative"."member_id"
2210 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2211 WHERE (
2212 "supporter"."member_id" NOTNULL OR
2213 "interest"."member_id" NOTNULL OR
2214 ( "membership"."member_id" NOTNULL AND
2215 "event"."event" IN (
2216 'issue_state_changed',
2217 'initiative_created_in_new_issue',
2218 'initiative_created_in_existing_issue',
2219 'initiative_revoked' ) ) )
2220 AND "ignored_member"."member_id" ISNULL
2221 AND "ignored_initiative"."member_id" ISNULL;
2223 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"';
2226 CREATE VIEW "selected_event_seen_by_member" AS
2227 SELECT
2228 "member"."id" AS "seen_by_member_id",
2229 CASE WHEN "event"."state" IN (
2230 'voting',
2231 'finished_without_winner',
2232 'finished_with_winner'
2233 ) THEN
2234 'voting'::"notify_level"
2235 ELSE
2236 CASE WHEN "event"."state" IN (
2237 'verification',
2238 'canceled_after_revocation_during_verification',
2239 'canceled_no_initiative_admitted'
2240 ) THEN
2241 'verification'::"notify_level"
2242 ELSE
2243 CASE WHEN "event"."state" IN (
2244 'discussion',
2245 'canceled_after_revocation_during_discussion'
2246 ) THEN
2247 'discussion'::"notify_level"
2248 ELSE
2249 'all'::"notify_level"
2250 END
2251 END
2252 END AS "notify_level",
2253 "event".*
2254 FROM "member" CROSS JOIN "event"
2255 LEFT JOIN "issue"
2256 ON "event"."issue_id" = "issue"."id"
2257 LEFT JOIN "membership"
2258 ON "member"."id" = "membership"."member_id"
2259 AND "issue"."area_id" = "membership"."area_id"
2260 LEFT JOIN "interest"
2261 ON "member"."id" = "interest"."member_id"
2262 AND "event"."issue_id" = "interest"."issue_id"
2263 LEFT JOIN "supporter"
2264 ON "member"."id" = "supporter"."member_id"
2265 AND "event"."initiative_id" = "supporter"."initiative_id"
2266 LEFT JOIN "ignored_member"
2267 ON "member"."id" = "ignored_member"."member_id"
2268 AND "event"."member_id" = "ignored_member"."other_member_id"
2269 LEFT JOIN "ignored_initiative"
2270 ON "member"."id" = "ignored_initiative"."member_id"
2271 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2272 WHERE (
2273 ( "member"."notify_level" >= 'all' ) OR
2274 ( "member"."notify_level" >= 'voting' AND
2275 "event"."state" IN (
2276 'voting',
2277 'finished_without_winner',
2278 'finished_with_winner' ) ) OR
2279 ( "member"."notify_level" >= 'verification' AND
2280 "event"."state" IN (
2281 'verification',
2282 'canceled_after_revocation_during_verification',
2283 'canceled_no_initiative_admitted' ) ) OR
2284 ( "member"."notify_level" >= 'discussion' AND
2285 "event"."state" IN (
2286 'discussion',
2287 'canceled_after_revocation_during_discussion' ) ) )
2288 AND (
2289 "supporter"."member_id" NOTNULL OR
2290 "interest"."member_id" NOTNULL OR
2291 ( "membership"."member_id" NOTNULL AND
2292 "event"."event" IN (
2293 'issue_state_changed',
2294 'initiative_created_in_new_issue',
2295 'initiative_created_in_existing_issue',
2296 'initiative_revoked' ) ) )
2297 AND "ignored_member"."member_id" ISNULL
2298 AND "ignored_initiative"."member_id" ISNULL;
2300 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"';
2303 CREATE TYPE "timeline_event" AS ENUM (
2304 'issue_created',
2305 'issue_canceled',
2306 'issue_accepted',
2307 'issue_half_frozen',
2308 'issue_finished_without_voting',
2309 'issue_voting_started',
2310 'issue_finished_after_voting',
2311 'initiative_created',
2312 'initiative_revoked',
2313 'draft_created',
2314 'suggestion_created');
2316 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2319 CREATE VIEW "timeline_issue" AS
2320 SELECT
2321 "created" AS "occurrence",
2322 'issue_created'::"timeline_event" AS "event",
2323 "id" AS "issue_id"
2324 FROM "issue"
2325 UNION ALL
2326 SELECT
2327 "closed" AS "occurrence",
2328 'issue_canceled'::"timeline_event" AS "event",
2329 "id" AS "issue_id"
2330 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2331 UNION ALL
2332 SELECT
2333 "accepted" AS "occurrence",
2334 'issue_accepted'::"timeline_event" AS "event",
2335 "id" AS "issue_id"
2336 FROM "issue" WHERE "accepted" NOTNULL
2337 UNION ALL
2338 SELECT
2339 "half_frozen" AS "occurrence",
2340 'issue_half_frozen'::"timeline_event" AS "event",
2341 "id" AS "issue_id"
2342 FROM "issue" WHERE "half_frozen" NOTNULL
2343 UNION ALL
2344 SELECT
2345 "fully_frozen" AS "occurrence",
2346 'issue_voting_started'::"timeline_event" AS "event",
2347 "id" AS "issue_id"
2348 FROM "issue"
2349 WHERE "fully_frozen" NOTNULL
2350 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2351 UNION ALL
2352 SELECT
2353 "closed" AS "occurrence",
2354 CASE WHEN "fully_frozen" = "closed" THEN
2355 'issue_finished_without_voting'::"timeline_event"
2356 ELSE
2357 'issue_finished_after_voting'::"timeline_event"
2358 END AS "event",
2359 "id" AS "issue_id"
2360 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2362 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2365 CREATE VIEW "timeline_initiative" AS
2366 SELECT
2367 "created" AS "occurrence",
2368 'initiative_created'::"timeline_event" AS "event",
2369 "id" AS "initiative_id"
2370 FROM "initiative"
2371 UNION ALL
2372 SELECT
2373 "revoked" AS "occurrence",
2374 'initiative_revoked'::"timeline_event" AS "event",
2375 "id" AS "initiative_id"
2376 FROM "initiative" WHERE "revoked" NOTNULL;
2378 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2381 CREATE VIEW "timeline_draft" AS
2382 SELECT
2383 "created" AS "occurrence",
2384 'draft_created'::"timeline_event" AS "event",
2385 "id" AS "draft_id"
2386 FROM "draft";
2388 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2391 CREATE VIEW "timeline_suggestion" AS
2392 SELECT
2393 "created" AS "occurrence",
2394 'suggestion_created'::"timeline_event" AS "event",
2395 "id" AS "suggestion_id"
2396 FROM "suggestion";
2398 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2401 CREATE VIEW "timeline" AS
2402 SELECT
2403 "occurrence",
2404 "event",
2405 "issue_id",
2406 NULL AS "initiative_id",
2407 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2408 NULL::INT8 AS "suggestion_id"
2409 FROM "timeline_issue"
2410 UNION ALL
2411 SELECT
2412 "occurrence",
2413 "event",
2414 NULL AS "issue_id",
2415 "initiative_id",
2416 NULL AS "draft_id",
2417 NULL AS "suggestion_id"
2418 FROM "timeline_initiative"
2419 UNION ALL
2420 SELECT
2421 "occurrence",
2422 "event",
2423 NULL AS "issue_id",
2424 NULL AS "initiative_id",
2425 "draft_id",
2426 NULL AS "suggestion_id"
2427 FROM "timeline_draft"
2428 UNION ALL
2429 SELECT
2430 "occurrence",
2431 "event",
2432 NULL AS "issue_id",
2433 NULL AS "initiative_id",
2434 NULL AS "draft_id",
2435 "suggestion_id"
2436 FROM "timeline_suggestion";
2438 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2442 ------------------------------------------------------
2443 -- Row set returning function for delegation chains --
2444 ------------------------------------------------------
2447 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2448 ('first', 'intermediate', 'last', 'repetition');
2450 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2453 CREATE TYPE "delegation_chain_row" AS (
2454 "index" INT4,
2455 "member_id" INT4,
2456 "member_valid" BOOLEAN,
2457 "participation" BOOLEAN,
2458 "overridden" BOOLEAN,
2459 "scope_in" "delegation_scope",
2460 "scope_out" "delegation_scope",
2461 "disabled_out" BOOLEAN,
2462 "loop" "delegation_chain_loop_tag" );
2464 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
2466 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2467 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';
2468 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2469 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2470 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2471 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2472 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2475 CREATE FUNCTION "delegation_chain_for_closed_issue"
2476 ( "member_id_p" "member"."id"%TYPE,
2477 "issue_id_p" "issue"."id"%TYPE )
2478 RETURNS SETOF "delegation_chain_row"
2479 LANGUAGE 'plpgsql' STABLE AS $$
2480 DECLARE
2481 "output_row" "delegation_chain_row";
2482 "direct_voter_row" "direct_voter"%ROWTYPE;
2483 "delegating_voter_row" "delegating_voter"%ROWTYPE;
2484 BEGIN
2485 "output_row"."index" := 0;
2486 "output_row"."member_id" := "member_id_p";
2487 "output_row"."member_valid" := TRUE;
2488 "output_row"."participation" := FALSE;
2489 "output_row"."overridden" := FALSE;
2490 "output_row"."disabled_out" := FALSE;
2491 LOOP
2492 SELECT INTO "direct_voter_row" * FROM "direct_voter"
2493 WHERE "issue_id" = "issue_id_p"
2494 AND "member_id" = "output_row"."member_id";
2495 IF "direct_voter_row"."member_id" NOTNULL THEN
2496 "output_row"."participation" := TRUE;
2497 "output_row"."scope_out" := NULL;
2498 "output_row"."disabled_out" := NULL;
2499 RETURN NEXT "output_row";
2500 RETURN;
2501 END IF;
2502 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
2503 WHERE "issue_id" = "issue_id_p"
2504 AND "member_id" = "output_row"."member_id";
2505 IF "delegating_voter_row"."member_id" ISNULL THEN
2506 RETURN;
2507 END IF;
2508 "output_row"."scope_out" := "delegating_voter_row"."scope";
2509 RETURN NEXT "output_row";
2510 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
2511 "output_row"."scope_in" := "output_row"."scope_out";
2512 END LOOP;
2513 END;
2514 $$;
2516 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
2517 ( "member"."id"%TYPE,
2518 "member"."id"%TYPE )
2519 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
2522 CREATE FUNCTION "delegation_chain"
2523 ( "member_id_p" "member"."id"%TYPE,
2524 "unit_id_p" "unit"."id"%TYPE,
2525 "area_id_p" "area"."id"%TYPE,
2526 "issue_id_p" "issue"."id"%TYPE,
2527 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2528 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2529 RETURNS SETOF "delegation_chain_row"
2530 LANGUAGE 'plpgsql' STABLE AS $$
2531 DECLARE
2532 "scope_v" "delegation_scope";
2533 "unit_id_v" "unit"."id"%TYPE;
2534 "area_id_v" "area"."id"%TYPE;
2535 "issue_row" "issue"%ROWTYPE;
2536 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2537 "loop_member_id_v" "member"."id"%TYPE;
2538 "output_row" "delegation_chain_row";
2539 "output_rows" "delegation_chain_row"[];
2540 "simulate_v" BOOLEAN;
2541 "simulate_here_v" BOOLEAN;
2542 "delegation_row" "delegation"%ROWTYPE;
2543 "row_count" INT4;
2544 "i" INT4;
2545 "loop_v" BOOLEAN;
2546 BEGIN
2547 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
2548 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
2549 END IF;
2550 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
2551 "simulate_v" := TRUE;
2552 ELSE
2553 "simulate_v" := FALSE;
2554 END IF;
2555 IF
2556 "unit_id_p" NOTNULL AND
2557 "area_id_p" ISNULL AND
2558 "issue_id_p" ISNULL
2559 THEN
2560 "scope_v" := 'unit';
2561 "unit_id_v" := "unit_id_p";
2562 ELSIF
2563 "unit_id_p" ISNULL AND
2564 "area_id_p" NOTNULL AND
2565 "issue_id_p" ISNULL
2566 THEN
2567 "scope_v" := 'area';
2568 "area_id_v" := "area_id_p";
2569 SELECT "unit_id" INTO "unit_id_v"
2570 FROM "area" WHERE "id" = "area_id_v";
2571 ELSIF
2572 "unit_id_p" ISNULL AND
2573 "area_id_p" ISNULL AND
2574 "issue_id_p" NOTNULL
2575 THEN
2576 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
2577 IF "issue_row"."id" ISNULL THEN
2578 RETURN;
2579 END IF;
2580 IF "issue_row"."closed" NOTNULL THEN
2581 IF "simulate_v" THEN
2582 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
2583 END IF;
2584 FOR "output_row" IN
2585 SELECT * FROM
2586 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
2587 LOOP
2588 RETURN NEXT "output_row";
2589 END LOOP;
2590 RETURN;
2591 END IF;
2592 "scope_v" := 'issue';
2593 SELECT "area_id" INTO "area_id_v"
2594 FROM "issue" WHERE "id" = "issue_id_p";
2595 SELECT "unit_id" INTO "unit_id_v"
2596 FROM "area" WHERE "id" = "area_id_v";
2597 ELSE
2598 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2599 END IF;
2600 "visited_member_ids" := '{}';
2601 "loop_member_id_v" := NULL;
2602 "output_rows" := '{}';
2603 "output_row"."index" := 0;
2604 "output_row"."member_id" := "member_id_p";
2605 "output_row"."member_valid" := TRUE;
2606 "output_row"."participation" := FALSE;
2607 "output_row"."overridden" := FALSE;
2608 "output_row"."disabled_out" := FALSE;
2609 "output_row"."scope_out" := NULL;
2610 LOOP
2611 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2612 "loop_member_id_v" := "output_row"."member_id";
2613 ELSE
2614 "visited_member_ids" :=
2615 "visited_member_ids" || "output_row"."member_id";
2616 END IF;
2617 IF "output_row"."participation" ISNULL THEN
2618 "output_row"."overridden" := NULL;
2619 ELSIF "output_row"."participation" THEN
2620 "output_row"."overridden" := TRUE;
2621 END IF;
2622 "output_row"."scope_in" := "output_row"."scope_out";
2623 "output_row"."member_valid" := EXISTS (
2624 SELECT NULL FROM "member" JOIN "privilege"
2625 ON "privilege"."member_id" = "member"."id"
2626 AND "privilege"."unit_id" = "unit_id_v"
2627 WHERE "id" = "output_row"."member_id"
2628 AND "member"."active" AND "privilege"."voting_right"
2629 );
2630 "simulate_here_v" := (
2631 "simulate_v" AND
2632 "output_row"."member_id" = "member_id_p"
2633 );
2634 "delegation_row" := ROW(NULL);
2635 IF "output_row"."member_valid" OR "simulate_here_v" THEN
2636 IF "scope_v" = 'unit' THEN
2637 IF NOT "simulate_here_v" THEN
2638 SELECT * INTO "delegation_row" FROM "delegation"
2639 WHERE "truster_id" = "output_row"."member_id"
2640 AND "unit_id" = "unit_id_v";
2641 END IF;
2642 ELSIF "scope_v" = 'area' THEN
2643 "output_row"."participation" := EXISTS (
2644 SELECT NULL FROM "membership"
2645 WHERE "area_id" = "area_id_p"
2646 AND "member_id" = "output_row"."member_id"
2647 );
2648 IF "simulate_here_v" THEN
2649 IF "simulate_trustee_id_p" ISNULL THEN
2650 SELECT * INTO "delegation_row" FROM "delegation"
2651 WHERE "truster_id" = "output_row"."member_id"
2652 AND "unit_id" = "unit_id_v";
2653 END IF;
2654 ELSE
2655 SELECT * INTO "delegation_row" FROM "delegation"
2656 WHERE "truster_id" = "output_row"."member_id"
2657 AND (
2658 "unit_id" = "unit_id_v" OR
2659 "area_id" = "area_id_v"
2661 ORDER BY "scope" DESC;
2662 END IF;
2663 ELSIF "scope_v" = 'issue' THEN
2664 IF "issue_row"."fully_frozen" ISNULL THEN
2665 "output_row"."participation" := EXISTS (
2666 SELECT NULL FROM "interest"
2667 WHERE "issue_id" = "issue_id_p"
2668 AND "member_id" = "output_row"."member_id"
2669 );
2670 ELSE
2671 IF "output_row"."member_id" = "member_id_p" THEN
2672 "output_row"."participation" := EXISTS (
2673 SELECT NULL FROM "direct_voter"
2674 WHERE "issue_id" = "issue_id_p"
2675 AND "member_id" = "output_row"."member_id"
2676 );
2677 ELSE
2678 "output_row"."participation" := NULL;
2679 END IF;
2680 END IF;
2681 IF "simulate_here_v" THEN
2682 IF "simulate_trustee_id_p" ISNULL THEN
2683 SELECT * INTO "delegation_row" FROM "delegation"
2684 WHERE "truster_id" = "output_row"."member_id"
2685 AND (
2686 "unit_id" = "unit_id_v" OR
2687 "area_id" = "area_id_v"
2689 ORDER BY "scope" DESC;
2690 END IF;
2691 ELSE
2692 SELECT * INTO "delegation_row" FROM "delegation"
2693 WHERE "truster_id" = "output_row"."member_id"
2694 AND (
2695 "unit_id" = "unit_id_v" OR
2696 "area_id" = "area_id_v" OR
2697 "issue_id" = "issue_id_p"
2699 ORDER BY "scope" DESC;
2700 END IF;
2701 END IF;
2702 ELSE
2703 "output_row"."participation" := FALSE;
2704 END IF;
2705 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
2706 "output_row"."scope_out" := "scope_v";
2707 "output_rows" := "output_rows" || "output_row";
2708 "output_row"."member_id" := "simulate_trustee_id_p";
2709 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2710 "output_row"."scope_out" := "delegation_row"."scope";
2711 "output_rows" := "output_rows" || "output_row";
2712 "output_row"."member_id" := "delegation_row"."trustee_id";
2713 ELSIF "delegation_row"."scope" NOTNULL THEN
2714 "output_row"."scope_out" := "delegation_row"."scope";
2715 "output_row"."disabled_out" := TRUE;
2716 "output_rows" := "output_rows" || "output_row";
2717 EXIT;
2718 ELSE
2719 "output_row"."scope_out" := NULL;
2720 "output_rows" := "output_rows" || "output_row";
2721 EXIT;
2722 END IF;
2723 EXIT WHEN "loop_member_id_v" NOTNULL;
2724 "output_row"."index" := "output_row"."index" + 1;
2725 END LOOP;
2726 "row_count" := array_upper("output_rows", 1);
2727 "i" := 1;
2728 "loop_v" := FALSE;
2729 LOOP
2730 "output_row" := "output_rows"["i"];
2731 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2732 IF "loop_v" THEN
2733 IF "i" + 1 = "row_count" THEN
2734 "output_row"."loop" := 'last';
2735 ELSIF "i" = "row_count" THEN
2736 "output_row"."loop" := 'repetition';
2737 ELSE
2738 "output_row"."loop" := 'intermediate';
2739 END IF;
2740 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2741 "output_row"."loop" := 'first';
2742 "loop_v" := TRUE;
2743 END IF;
2744 IF "scope_v" = 'unit' THEN
2745 "output_row"."participation" := NULL;
2746 END IF;
2747 RETURN NEXT "output_row";
2748 "i" := "i" + 1;
2749 END LOOP;
2750 RETURN;
2751 END;
2752 $$;
2754 COMMENT ON FUNCTION "delegation_chain"
2755 ( "member"."id"%TYPE,
2756 "unit"."id"%TYPE,
2757 "area"."id"%TYPE,
2758 "issue"."id"%TYPE,
2759 "member"."id"%TYPE,
2760 BOOLEAN )
2761 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
2765 ---------------------------------------------------------
2766 -- Single row returning function for delegation chains --
2767 ---------------------------------------------------------
2770 CREATE TYPE "delegation_info_loop_type" AS ENUM
2771 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
2773 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''';
2776 CREATE TYPE "delegation_info_type" AS (
2777 "own_participation" BOOLEAN,
2778 "own_delegation_scope" "delegation_scope",
2779 "first_trustee_id" INT4,
2780 "first_trustee_participation" BOOLEAN,
2781 "first_trustee_ellipsis" BOOLEAN,
2782 "other_trustee_id" INT4,
2783 "other_trustee_participation" BOOLEAN,
2784 "other_trustee_ellipsis" BOOLEAN,
2785 "delegation_loop" "delegation_info_loop_type",
2786 "participating_member_id" INT4 );
2788 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';
2790 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
2791 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
2792 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
2793 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
2794 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
2795 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
2796 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)';
2797 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
2798 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';
2799 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
2802 CREATE FUNCTION "delegation_info"
2803 ( "member_id_p" "member"."id"%TYPE,
2804 "unit_id_p" "unit"."id"%TYPE,
2805 "area_id_p" "area"."id"%TYPE,
2806 "issue_id_p" "issue"."id"%TYPE,
2807 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
2808 "simulate_default_p" BOOLEAN DEFAULT FALSE )
2809 RETURNS "delegation_info_type"
2810 LANGUAGE 'plpgsql' STABLE AS $$
2811 DECLARE
2812 "current_row" "delegation_chain_row";
2813 "result" "delegation_info_type";
2814 BEGIN
2815 "result"."own_participation" := FALSE;
2816 FOR "current_row" IN
2817 SELECT * FROM "delegation_chain"(
2818 "member_id_p",
2819 "unit_id_p", "area_id_p", "issue_id_p",
2820 "simulate_trustee_id_p", "simulate_default_p")
2821 LOOP
2822 IF
2823 "result"."participating_member_id" ISNULL AND
2824 "current_row"."participation"
2825 THEN
2826 "result"."participating_member_id" := "current_row"."member_id";
2827 END IF;
2828 IF "current_row"."member_id" = "member_id_p" THEN
2829 "result"."own_participation" := "current_row"."participation";
2830 "result"."own_delegation_scope" := "current_row"."scope_out";
2831 IF "current_row"."loop" = 'first' THEN
2832 "result"."delegation_loop" := 'own';
2833 END IF;
2834 ELSIF
2835 "current_row"."member_valid" AND
2836 ( "current_row"."loop" ISNULL OR
2837 "current_row"."loop" != 'repetition' )
2838 THEN
2839 IF "result"."first_trustee_id" ISNULL THEN
2840 "result"."first_trustee_id" := "current_row"."member_id";
2841 "result"."first_trustee_participation" := "current_row"."participation";
2842 "result"."first_trustee_ellipsis" := FALSE;
2843 IF "current_row"."loop" = 'first' THEN
2844 "result"."delegation_loop" := 'first';
2845 END IF;
2846 ELSIF "result"."other_trustee_id" ISNULL THEN
2847 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
2848 "result"."other_trustee_id" := "current_row"."member_id";
2849 "result"."other_trustee_participation" := TRUE;
2850 "result"."other_trustee_ellipsis" := FALSE;
2851 IF "current_row"."loop" = 'first' THEN
2852 "result"."delegation_loop" := 'other';
2853 END IF;
2854 ELSE
2855 "result"."first_trustee_ellipsis" := TRUE;
2856 IF "current_row"."loop" = 'first' THEN
2857 "result"."delegation_loop" := 'first_ellipsis';
2858 END IF;
2859 END IF;
2860 ELSE
2861 "result"."other_trustee_ellipsis" := TRUE;
2862 IF "current_row"."loop" = 'first' THEN
2863 "result"."delegation_loop" := 'other_ellipsis';
2864 END IF;
2865 END IF;
2866 END IF;
2867 END LOOP;
2868 RETURN "result";
2869 END;
2870 $$;
2872 COMMENT ON FUNCTION "delegation_info"
2873 ( "member"."id"%TYPE,
2874 "unit"."id"%TYPE,
2875 "area"."id"%TYPE,
2876 "issue"."id"%TYPE,
2877 "member"."id"%TYPE,
2878 BOOLEAN )
2879 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
2883 ------------------------------
2884 -- Comparison by vote count --
2885 ------------------------------
2887 CREATE FUNCTION "vote_ratio"
2888 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2889 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2890 RETURNS FLOAT8
2891 LANGUAGE 'plpgsql' STABLE AS $$
2892 BEGIN
2893 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2894 RETURN
2895 "positive_votes_p"::FLOAT8 /
2896 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2897 ELSIF "positive_votes_p" > 0 THEN
2898 RETURN "positive_votes_p";
2899 ELSIF "negative_votes_p" > 0 THEN
2900 RETURN 1 - "negative_votes_p";
2901 ELSE
2902 RETURN 0.5;
2903 END IF;
2904 END;
2905 $$;
2907 COMMENT ON FUNCTION "vote_ratio"
2908 ( "initiative"."positive_votes"%TYPE,
2909 "initiative"."negative_votes"%TYPE )
2910 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.';
2914 ------------------------------------------------
2915 -- Locking for snapshots and voting procedure --
2916 ------------------------------------------------
2919 CREATE FUNCTION "share_row_lock_issue_trigger"()
2920 RETURNS TRIGGER
2921 LANGUAGE 'plpgsql' VOLATILE AS $$
2922 BEGIN
2923 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2924 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2925 END IF;
2926 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2927 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2928 RETURN NEW;
2929 ELSE
2930 RETURN OLD;
2931 END IF;
2932 END;
2933 $$;
2935 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2938 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2939 RETURNS TRIGGER
2940 LANGUAGE 'plpgsql' VOLATILE AS $$
2941 BEGIN
2942 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2943 PERFORM NULL FROM "issue"
2944 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2945 WHERE "initiative"."id" = OLD."initiative_id"
2946 FOR SHARE OF "issue";
2947 END IF;
2948 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2949 PERFORM NULL FROM "issue"
2950 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2951 WHERE "initiative"."id" = NEW."initiative_id"
2952 FOR SHARE OF "issue";
2953 RETURN NEW;
2954 ELSE
2955 RETURN OLD;
2956 END IF;
2957 END;
2958 $$;
2960 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2963 CREATE TRIGGER "share_row_lock_issue"
2964 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2965 FOR EACH ROW EXECUTE PROCEDURE
2966 "share_row_lock_issue_trigger"();
2968 CREATE TRIGGER "share_row_lock_issue"
2969 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2970 FOR EACH ROW EXECUTE PROCEDURE
2971 "share_row_lock_issue_trigger"();
2973 CREATE TRIGGER "share_row_lock_issue"
2974 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2975 FOR EACH ROW EXECUTE PROCEDURE
2976 "share_row_lock_issue_trigger"();
2978 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2979 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2980 FOR EACH ROW EXECUTE PROCEDURE
2981 "share_row_lock_issue_via_initiative_trigger"();
2983 CREATE TRIGGER "share_row_lock_issue"
2984 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2985 FOR EACH ROW EXECUTE PROCEDURE
2986 "share_row_lock_issue_trigger"();
2988 CREATE TRIGGER "share_row_lock_issue"
2989 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2990 FOR EACH ROW EXECUTE PROCEDURE
2991 "share_row_lock_issue_trigger"();
2993 CREATE TRIGGER "share_row_lock_issue"
2994 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2995 FOR EACH ROW EXECUTE PROCEDURE
2996 "share_row_lock_issue_trigger"();
2998 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2999 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
3000 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
3001 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
3002 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
3003 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
3004 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
3007 CREATE FUNCTION "lock_issue"
3008 ( "issue_id_p" "issue"."id"%TYPE )
3009 RETURNS VOID
3010 LANGUAGE 'plpgsql' VOLATILE AS $$
3011 BEGIN
3012 LOCK TABLE "member" IN SHARE MODE;
3013 LOCK TABLE "privilege" IN SHARE MODE;
3014 LOCK TABLE "membership" IN SHARE MODE;
3015 LOCK TABLE "policy" IN SHARE MODE;
3016 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
3017 -- NOTE: The row-level exclusive lock in combination with the
3018 -- share_row_lock_issue(_via_initiative)_trigger functions (which
3019 -- acquire a row-level share lock on the issue) ensure that no data
3020 -- is changed, which could affect calculation of snapshots or
3021 -- counting of votes. Table "delegation" must be table-level-locked,
3022 -- as it also contains issue- and global-scope delegations.
3023 LOCK TABLE "delegation" IN SHARE MODE;
3024 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
3025 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
3026 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
3027 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
3028 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
3029 RETURN;
3030 END;
3031 $$;
3033 COMMENT ON FUNCTION "lock_issue"
3034 ( "issue"."id"%TYPE )
3035 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
3039 ------------------------------------------------------------------------
3040 -- Regular tasks, except calculcation of snapshots and voting results --
3041 ------------------------------------------------------------------------
3043 CREATE FUNCTION "check_activity"()
3044 RETURNS VOID
3045 LANGUAGE 'plpgsql' VOLATILE AS $$
3046 DECLARE
3047 "system_setting_row" "system_setting"%ROWTYPE;
3048 BEGIN
3049 SELECT * INTO "system_setting_row" FROM "system_setting";
3050 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
3051 IF "system_setting_row"."member_ttl" NOTNULL THEN
3052 UPDATE "member" SET "active" = FALSE
3053 WHERE "active" = TRUE
3054 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
3055 END IF;
3056 RETURN;
3057 END;
3058 $$;
3060 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
3063 CREATE FUNCTION "calculate_member_counts"()
3064 RETURNS VOID
3065 LANGUAGE 'plpgsql' VOLATILE AS $$
3066 BEGIN
3067 LOCK TABLE "member" IN SHARE MODE;
3068 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
3069 LOCK TABLE "unit" IN EXCLUSIVE MODE;
3070 LOCK TABLE "area" IN EXCLUSIVE MODE;
3071 LOCK TABLE "privilege" IN SHARE MODE;
3072 LOCK TABLE "membership" IN SHARE MODE;
3073 DELETE FROM "member_count";
3074 INSERT INTO "member_count" ("total_count")
3075 SELECT "total_count" FROM "member_count_view";
3076 UPDATE "unit" SET "member_count" = "view"."member_count"
3077 FROM "unit_member_count" AS "view"
3078 WHERE "view"."unit_id" = "unit"."id";
3079 UPDATE "area" SET
3080 "direct_member_count" = "view"."direct_member_count",
3081 "member_weight" = "view"."member_weight"
3082 FROM "area_member_count" AS "view"
3083 WHERE "view"."area_id" = "area"."id";
3084 RETURN;
3085 END;
3086 $$;
3088 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"';
3092 ------------------------------
3093 -- Calculation of snapshots --
3094 ------------------------------
3096 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
3097 ( "issue_id_p" "issue"."id"%TYPE,
3098 "member_id_p" "member"."id"%TYPE,
3099 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3100 RETURNS "direct_population_snapshot"."weight"%TYPE
3101 LANGUAGE 'plpgsql' VOLATILE AS $$
3102 DECLARE
3103 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3104 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
3105 "weight_v" INT4;
3106 "sub_weight_v" INT4;
3107 BEGIN
3108 "weight_v" := 0;
3109 FOR "issue_delegation_row" IN
3110 SELECT * FROM "issue_delegation"
3111 WHERE "trustee_id" = "member_id_p"
3112 AND "issue_id" = "issue_id_p"
3113 LOOP
3114 IF NOT EXISTS (
3115 SELECT NULL FROM "direct_population_snapshot"
3116 WHERE "issue_id" = "issue_id_p"
3117 AND "event" = 'periodic'
3118 AND "member_id" = "issue_delegation_row"."truster_id"
3119 ) AND NOT EXISTS (
3120 SELECT NULL FROM "delegating_population_snapshot"
3121 WHERE "issue_id" = "issue_id_p"
3122 AND "event" = 'periodic'
3123 AND "member_id" = "issue_delegation_row"."truster_id"
3124 ) THEN
3125 "delegate_member_ids_v" :=
3126 "member_id_p" || "delegate_member_ids_p";
3127 INSERT INTO "delegating_population_snapshot" (
3128 "issue_id",
3129 "event",
3130 "member_id",
3131 "scope",
3132 "delegate_member_ids"
3133 ) VALUES (
3134 "issue_id_p",
3135 'periodic',
3136 "issue_delegation_row"."truster_id",
3137 "issue_delegation_row"."scope",
3138 "delegate_member_ids_v"
3139 );
3140 "sub_weight_v" := 1 +
3141 "weight_of_added_delegations_for_population_snapshot"(
3142 "issue_id_p",
3143 "issue_delegation_row"."truster_id",
3144 "delegate_member_ids_v"
3145 );
3146 UPDATE "delegating_population_snapshot"
3147 SET "weight" = "sub_weight_v"
3148 WHERE "issue_id" = "issue_id_p"
3149 AND "event" = 'periodic'
3150 AND "member_id" = "issue_delegation_row"."truster_id";
3151 "weight_v" := "weight_v" + "sub_weight_v";
3152 END IF;
3153 END LOOP;
3154 RETURN "weight_v";
3155 END;
3156 $$;
3158 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
3159 ( "issue"."id"%TYPE,
3160 "member"."id"%TYPE,
3161 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
3162 IS 'Helper function for "create_population_snapshot" function';
3165 CREATE FUNCTION "create_population_snapshot"
3166 ( "issue_id_p" "issue"."id"%TYPE )
3167 RETURNS VOID
3168 LANGUAGE 'plpgsql' VOLATILE AS $$
3169 DECLARE
3170 "member_id_v" "member"."id"%TYPE;
3171 BEGIN
3172 DELETE FROM "direct_population_snapshot"
3173 WHERE "issue_id" = "issue_id_p"
3174 AND "event" = 'periodic';
3175 DELETE FROM "delegating_population_snapshot"
3176 WHERE "issue_id" = "issue_id_p"
3177 AND "event" = 'periodic';
3178 INSERT INTO "direct_population_snapshot"
3179 ("issue_id", "event", "member_id")
3180 SELECT
3181 "issue_id_p" AS "issue_id",
3182 'periodic'::"snapshot_event" AS "event",
3183 "member"."id" AS "member_id"
3184 FROM "issue"
3185 JOIN "area" ON "issue"."area_id" = "area"."id"
3186 JOIN "membership" ON "area"."id" = "membership"."area_id"
3187 JOIN "member" ON "membership"."member_id" = "member"."id"
3188 JOIN "privilege"
3189 ON "privilege"."unit_id" = "area"."unit_id"
3190 AND "privilege"."member_id" = "member"."id"
3191 WHERE "issue"."id" = "issue_id_p"
3192 AND "member"."active" AND "privilege"."voting_right"
3193 UNION
3194 SELECT
3195 "issue_id_p" AS "issue_id",
3196 'periodic'::"snapshot_event" AS "event",
3197 "member"."id" AS "member_id"
3198 FROM "issue"
3199 JOIN "area" ON "issue"."area_id" = "area"."id"
3200 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3201 JOIN "member" ON "interest"."member_id" = "member"."id"
3202 JOIN "privilege"
3203 ON "privilege"."unit_id" = "area"."unit_id"
3204 AND "privilege"."member_id" = "member"."id"
3205 WHERE "issue"."id" = "issue_id_p"
3206 AND "member"."active" AND "privilege"."voting_right";
3207 FOR "member_id_v" IN
3208 SELECT "member_id" FROM "direct_population_snapshot"
3209 WHERE "issue_id" = "issue_id_p"
3210 AND "event" = 'periodic'
3211 LOOP
3212 UPDATE "direct_population_snapshot" SET
3213 "weight" = 1 +
3214 "weight_of_added_delegations_for_population_snapshot"(
3215 "issue_id_p",
3216 "member_id_v",
3217 '{}'
3219 WHERE "issue_id" = "issue_id_p"
3220 AND "event" = 'periodic'
3221 AND "member_id" = "member_id_v";
3222 END LOOP;
3223 RETURN;
3224 END;
3225 $$;
3227 COMMENT ON FUNCTION "create_population_snapshot"
3228 ( "issue"."id"%TYPE )
3229 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.';
3232 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3233 ( "issue_id_p" "issue"."id"%TYPE,
3234 "member_id_p" "member"."id"%TYPE,
3235 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3236 RETURNS "direct_interest_snapshot"."weight"%TYPE
3237 LANGUAGE 'plpgsql' VOLATILE AS $$
3238 DECLARE
3239 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3240 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
3241 "weight_v" INT4;
3242 "sub_weight_v" INT4;
3243 BEGIN
3244 "weight_v" := 0;
3245 FOR "issue_delegation_row" IN
3246 SELECT * FROM "issue_delegation"
3247 WHERE "trustee_id" = "member_id_p"
3248 AND "issue_id" = "issue_id_p"
3249 LOOP
3250 IF NOT EXISTS (
3251 SELECT NULL FROM "direct_interest_snapshot"
3252 WHERE "issue_id" = "issue_id_p"
3253 AND "event" = 'periodic'
3254 AND "member_id" = "issue_delegation_row"."truster_id"
3255 ) AND NOT EXISTS (
3256 SELECT NULL FROM "delegating_interest_snapshot"
3257 WHERE "issue_id" = "issue_id_p"
3258 AND "event" = 'periodic'
3259 AND "member_id" = "issue_delegation_row"."truster_id"
3260 ) THEN
3261 "delegate_member_ids_v" :=
3262 "member_id_p" || "delegate_member_ids_p";
3263 INSERT INTO "delegating_interest_snapshot" (
3264 "issue_id",
3265 "event",
3266 "member_id",
3267 "scope",
3268 "delegate_member_ids"
3269 ) VALUES (
3270 "issue_id_p",
3271 'periodic',
3272 "issue_delegation_row"."truster_id",
3273 "issue_delegation_row"."scope",
3274 "delegate_member_ids_v"
3275 );
3276 "sub_weight_v" := 1 +
3277 "weight_of_added_delegations_for_interest_snapshot"(
3278 "issue_id_p",
3279 "issue_delegation_row"."truster_id",
3280 "delegate_member_ids_v"
3281 );
3282 UPDATE "delegating_interest_snapshot"
3283 SET "weight" = "sub_weight_v"
3284 WHERE "issue_id" = "issue_id_p"
3285 AND "event" = 'periodic'
3286 AND "member_id" = "issue_delegation_row"."truster_id";
3287 "weight_v" := "weight_v" + "sub_weight_v";
3288 END IF;
3289 END LOOP;
3290 RETURN "weight_v";
3291 END;
3292 $$;
3294 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
3295 ( "issue"."id"%TYPE,
3296 "member"."id"%TYPE,
3297 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
3298 IS 'Helper function for "create_interest_snapshot" function';
3301 CREATE FUNCTION "create_interest_snapshot"
3302 ( "issue_id_p" "issue"."id"%TYPE )
3303 RETURNS VOID
3304 LANGUAGE 'plpgsql' VOLATILE AS $$
3305 DECLARE
3306 "member_id_v" "member"."id"%TYPE;
3307 BEGIN
3308 DELETE FROM "direct_interest_snapshot"
3309 WHERE "issue_id" = "issue_id_p"
3310 AND "event" = 'periodic';
3311 DELETE FROM "delegating_interest_snapshot"
3312 WHERE "issue_id" = "issue_id_p"
3313 AND "event" = 'periodic';
3314 DELETE FROM "direct_supporter_snapshot"
3315 WHERE "issue_id" = "issue_id_p"
3316 AND "event" = 'periodic';
3317 INSERT INTO "direct_interest_snapshot"
3318 ("issue_id", "event", "member_id")
3319 SELECT
3320 "issue_id_p" AS "issue_id",
3321 'periodic' AS "event",
3322 "member"."id" AS "member_id"
3323 FROM "issue"
3324 JOIN "area" ON "issue"."area_id" = "area"."id"
3325 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
3326 JOIN "member" ON "interest"."member_id" = "member"."id"
3327 JOIN "privilege"
3328 ON "privilege"."unit_id" = "area"."unit_id"
3329 AND "privilege"."member_id" = "member"."id"
3330 WHERE "issue"."id" = "issue_id_p"
3331 AND "member"."active" AND "privilege"."voting_right";
3332 FOR "member_id_v" IN
3333 SELECT "member_id" FROM "direct_interest_snapshot"
3334 WHERE "issue_id" = "issue_id_p"
3335 AND "event" = 'periodic'
3336 LOOP
3337 UPDATE "direct_interest_snapshot" SET
3338 "weight" = 1 +
3339 "weight_of_added_delegations_for_interest_snapshot"(
3340 "issue_id_p",
3341 "member_id_v",
3342 '{}'
3344 WHERE "issue_id" = "issue_id_p"
3345 AND "event" = 'periodic'
3346 AND "member_id" = "member_id_v";
3347 END LOOP;
3348 INSERT INTO "direct_supporter_snapshot"
3349 ( "issue_id", "initiative_id", "event", "member_id",
3350 "draft_id", "informed", "satisfied" )
3351 SELECT
3352 "issue_id_p" AS "issue_id",
3353 "initiative"."id" AS "initiative_id",
3354 'periodic' AS "event",
3355 "supporter"."member_id" AS "member_id",
3356 "supporter"."draft_id" AS "draft_id",
3357 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3358 NOT EXISTS (
3359 SELECT NULL FROM "critical_opinion"
3360 WHERE "initiative_id" = "initiative"."id"
3361 AND "member_id" = "supporter"."member_id"
3362 ) AS "satisfied"
3363 FROM "initiative"
3364 JOIN "supporter"
3365 ON "supporter"."initiative_id" = "initiative"."id"
3366 JOIN "current_draft"
3367 ON "initiative"."id" = "current_draft"."initiative_id"
3368 JOIN "direct_interest_snapshot"
3369 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3370 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3371 AND "event" = 'periodic'
3372 WHERE "initiative"."issue_id" = "issue_id_p";
3373 RETURN;
3374 END;
3375 $$;
3377 COMMENT ON FUNCTION "create_interest_snapshot"
3378 ( "issue"."id"%TYPE )
3379 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.';
3382 CREATE FUNCTION "create_snapshot"
3383 ( "issue_id_p" "issue"."id"%TYPE )
3384 RETURNS VOID
3385 LANGUAGE 'plpgsql' VOLATILE AS $$
3386 DECLARE
3387 "initiative_id_v" "initiative"."id"%TYPE;
3388 "suggestion_id_v" "suggestion"."id"%TYPE;
3389 BEGIN
3390 PERFORM "lock_issue"("issue_id_p");
3391 PERFORM "create_population_snapshot"("issue_id_p");
3392 PERFORM "create_interest_snapshot"("issue_id_p");
3393 UPDATE "issue" SET
3394 "snapshot" = now(),
3395 "latest_snapshot_event" = 'periodic',
3396 "population" = (
3397 SELECT coalesce(sum("weight"), 0)
3398 FROM "direct_population_snapshot"
3399 WHERE "issue_id" = "issue_id_p"
3400 AND "event" = 'periodic'
3402 WHERE "id" = "issue_id_p";
3403 FOR "initiative_id_v" IN
3404 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3405 LOOP
3406 UPDATE "initiative" SET
3407 "supporter_count" = (
3408 SELECT coalesce(sum("di"."weight"), 0)
3409 FROM "direct_interest_snapshot" AS "di"
3410 JOIN "direct_supporter_snapshot" AS "ds"
3411 ON "di"."member_id" = "ds"."member_id"
3412 WHERE "di"."issue_id" = "issue_id_p"
3413 AND "di"."event" = 'periodic'
3414 AND "ds"."initiative_id" = "initiative_id_v"
3415 AND "ds"."event" = 'periodic'
3416 ),
3417 "informed_supporter_count" = (
3418 SELECT coalesce(sum("di"."weight"), 0)
3419 FROM "direct_interest_snapshot" AS "di"
3420 JOIN "direct_supporter_snapshot" AS "ds"
3421 ON "di"."member_id" = "ds"."member_id"
3422 WHERE "di"."issue_id" = "issue_id_p"
3423 AND "di"."event" = 'periodic'
3424 AND "ds"."initiative_id" = "initiative_id_v"
3425 AND "ds"."event" = 'periodic'
3426 AND "ds"."informed"
3427 ),
3428 "satisfied_supporter_count" = (
3429 SELECT coalesce(sum("di"."weight"), 0)
3430 FROM "direct_interest_snapshot" AS "di"
3431 JOIN "direct_supporter_snapshot" AS "ds"
3432 ON "di"."member_id" = "ds"."member_id"
3433 WHERE "di"."issue_id" = "issue_id_p"
3434 AND "di"."event" = 'periodic'
3435 AND "ds"."initiative_id" = "initiative_id_v"
3436 AND "ds"."event" = 'periodic'
3437 AND "ds"."satisfied"
3438 ),
3439 "satisfied_informed_supporter_count" = (
3440 SELECT coalesce(sum("di"."weight"), 0)
3441 FROM "direct_interest_snapshot" AS "di"
3442 JOIN "direct_supporter_snapshot" AS "ds"
3443 ON "di"."member_id" = "ds"."member_id"
3444 WHERE "di"."issue_id" = "issue_id_p"
3445 AND "di"."event" = 'periodic'
3446 AND "ds"."initiative_id" = "initiative_id_v"
3447 AND "ds"."event" = 'periodic'
3448 AND "ds"."informed"
3449 AND "ds"."satisfied"
3451 WHERE "id" = "initiative_id_v";
3452 FOR "suggestion_id_v" IN
3453 SELECT "id" FROM "suggestion"
3454 WHERE "initiative_id" = "initiative_id_v"
3455 LOOP
3456 UPDATE "suggestion" SET
3457 "minus2_unfulfilled_count" = (
3458 SELECT coalesce(sum("snapshot"."weight"), 0)
3459 FROM "issue" CROSS JOIN "opinion"
3460 JOIN "direct_interest_snapshot" AS "snapshot"
3461 ON "snapshot"."issue_id" = "issue"."id"
3462 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3463 AND "snapshot"."member_id" = "opinion"."member_id"
3464 WHERE "issue"."id" = "issue_id_p"
3465 AND "opinion"."suggestion_id" = "suggestion_id_v"
3466 AND "opinion"."degree" = -2
3467 AND "opinion"."fulfilled" = FALSE
3468 ),
3469 "minus2_fulfilled_count" = (
3470 SELECT coalesce(sum("snapshot"."weight"), 0)
3471 FROM "issue" CROSS JOIN "opinion"
3472 JOIN "direct_interest_snapshot" AS "snapshot"
3473 ON "snapshot"."issue_id" = "issue"."id"
3474 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3475 AND "snapshot"."member_id" = "opinion"."member_id"
3476 WHERE "issue"."id" = "issue_id_p"
3477 AND "opinion"."suggestion_id" = "suggestion_id_v"
3478 AND "opinion"."degree" = -2
3479 AND "opinion"."fulfilled" = TRUE
3480 ),
3481 "minus1_unfulfilled_count" = (
3482 SELECT coalesce(sum("snapshot"."weight"), 0)
3483 FROM "issue" CROSS JOIN "opinion"
3484 JOIN "direct_interest_snapshot" AS "snapshot"
3485 ON "snapshot"."issue_id" = "issue"."id"
3486 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3487 AND "snapshot"."member_id" = "opinion"."member_id"
3488 WHERE "issue"."id" = "issue_id_p"
3489 AND "opinion"."suggestion_id" = "suggestion_id_v"
3490 AND "opinion"."degree" = -1
3491 AND "opinion"."fulfilled" = FALSE
3492 ),
3493 "minus1_fulfilled_count" = (
3494 SELECT coalesce(sum("snapshot"."weight"), 0)
3495 FROM "issue" CROSS JOIN "opinion"
3496 JOIN "direct_interest_snapshot" AS "snapshot"
3497 ON "snapshot"."issue_id" = "issue"."id"
3498 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3499 AND "snapshot"."member_id" = "opinion"."member_id"
3500 WHERE "issue"."id" = "issue_id_p"
3501 AND "opinion"."suggestion_id" = "suggestion_id_v"
3502 AND "opinion"."degree" = -1
3503 AND "opinion"."fulfilled" = TRUE
3504 ),
3505 "plus1_unfulfilled_count" = (
3506 SELECT coalesce(sum("snapshot"."weight"), 0)
3507 FROM "issue" CROSS JOIN "opinion"
3508 JOIN "direct_interest_snapshot" AS "snapshot"
3509 ON "snapshot"."issue_id" = "issue"."id"
3510 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3511 AND "snapshot"."member_id" = "opinion"."member_id"
3512 WHERE "issue"."id" = "issue_id_p"
3513 AND "opinion"."suggestion_id" = "suggestion_id_v"
3514 AND "opinion"."degree" = 1
3515 AND "opinion"."fulfilled" = FALSE
3516 ),
3517 "plus1_fulfilled_count" = (
3518 SELECT coalesce(sum("snapshot"."weight"), 0)
3519 FROM "issue" CROSS JOIN "opinion"
3520 JOIN "direct_interest_snapshot" AS "snapshot"
3521 ON "snapshot"."issue_id" = "issue"."id"
3522 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3523 AND "snapshot"."member_id" = "opinion"."member_id"
3524 WHERE "issue"."id" = "issue_id_p"
3525 AND "opinion"."suggestion_id" = "suggestion_id_v"
3526 AND "opinion"."degree" = 1
3527 AND "opinion"."fulfilled" = TRUE
3528 ),
3529 "plus2_unfulfilled_count" = (
3530 SELECT coalesce(sum("snapshot"."weight"), 0)
3531 FROM "issue" CROSS JOIN "opinion"
3532 JOIN "direct_interest_snapshot" AS "snapshot"
3533 ON "snapshot"."issue_id" = "issue"."id"
3534 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3535 AND "snapshot"."member_id" = "opinion"."member_id"
3536 WHERE "issue"."id" = "issue_id_p"
3537 AND "opinion"."suggestion_id" = "suggestion_id_v"
3538 AND "opinion"."degree" = 2
3539 AND "opinion"."fulfilled" = FALSE
3540 ),
3541 "plus2_fulfilled_count" = (
3542 SELECT coalesce(sum("snapshot"."weight"), 0)
3543 FROM "issue" CROSS JOIN "opinion"
3544 JOIN "direct_interest_snapshot" AS "snapshot"
3545 ON "snapshot"."issue_id" = "issue"."id"
3546 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3547 AND "snapshot"."member_id" = "opinion"."member_id"
3548 WHERE "issue"."id" = "issue_id_p"
3549 AND "opinion"."suggestion_id" = "suggestion_id_v"
3550 AND "opinion"."degree" = 2
3551 AND "opinion"."fulfilled" = TRUE
3553 WHERE "suggestion"."id" = "suggestion_id_v";
3554 END LOOP;
3555 END LOOP;
3556 RETURN;
3557 END;
3558 $$;
3560 COMMENT ON FUNCTION "create_snapshot"
3561 ( "issue"."id"%TYPE )
3562 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.';
3565 CREATE FUNCTION "set_snapshot_event"
3566 ( "issue_id_p" "issue"."id"%TYPE,
3567 "event_p" "snapshot_event" )
3568 RETURNS VOID
3569 LANGUAGE 'plpgsql' VOLATILE AS $$
3570 DECLARE
3571 "event_v" "issue"."latest_snapshot_event"%TYPE;
3572 BEGIN
3573 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3574 WHERE "id" = "issue_id_p" FOR UPDATE;
3575 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3576 WHERE "id" = "issue_id_p";
3577 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3578 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3579 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3580 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3581 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3582 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3583 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3584 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3585 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3586 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3587 RETURN;
3588 END;
3589 $$;
3591 COMMENT ON FUNCTION "set_snapshot_event"
3592 ( "issue"."id"%TYPE,
3593 "snapshot_event" )
3594 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3598 ---------------------
3599 -- Freezing issues --
3600 ---------------------
3602 CREATE FUNCTION "freeze_after_snapshot"
3603 ( "issue_id_p" "issue"."id"%TYPE )
3604 RETURNS VOID
3605 LANGUAGE 'plpgsql' VOLATILE AS $$
3606 DECLARE
3607 "issue_row" "issue"%ROWTYPE;
3608 "policy_row" "policy"%ROWTYPE;
3609 "initiative_row" "initiative"%ROWTYPE;
3610 BEGIN
3611 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3612 SELECT * INTO "policy_row"
3613 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3614 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3615 FOR "initiative_row" IN
3616 SELECT * FROM "initiative"
3617 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3618 LOOP
3619 IF
3620 "initiative_row"."polling" OR (
3621 "initiative_row"."satisfied_supporter_count" > 0 AND
3622 "initiative_row"."satisfied_supporter_count" *
3623 "policy_row"."initiative_quorum_den" >=
3624 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3626 THEN
3627 UPDATE "initiative" SET "admitted" = TRUE
3628 WHERE "id" = "initiative_row"."id";
3629 ELSE
3630 UPDATE "initiative" SET "admitted" = FALSE
3631 WHERE "id" = "initiative_row"."id";
3632 END IF;
3633 END LOOP;
3634 IF EXISTS (
3635 SELECT NULL FROM "initiative"
3636 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3637 ) THEN
3638 UPDATE "issue" SET
3639 "state" = 'voting',
3640 "accepted" = coalesce("accepted", now()),
3641 "half_frozen" = coalesce("half_frozen", now()),
3642 "fully_frozen" = now()
3643 WHERE "id" = "issue_id_p";
3644 ELSE
3645 UPDATE "issue" SET
3646 "state" = 'canceled_no_initiative_admitted',
3647 "accepted" = coalesce("accepted", now()),
3648 "half_frozen" = coalesce("half_frozen", now()),
3649 "fully_frozen" = now(),
3650 "closed" = now(),
3651 "ranks_available" = TRUE
3652 WHERE "id" = "issue_id_p";
3653 -- NOTE: The following DELETE statements have effect only when
3654 -- issue state has been manipulated
3655 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3656 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3657 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3658 END IF;
3659 RETURN;
3660 END;
3661 $$;
3663 COMMENT ON FUNCTION "freeze_after_snapshot"
3664 ( "issue"."id"%TYPE )
3665 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3668 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3669 RETURNS VOID
3670 LANGUAGE 'plpgsql' VOLATILE AS $$
3671 DECLARE
3672 "issue_row" "issue"%ROWTYPE;
3673 BEGIN
3674 PERFORM "create_snapshot"("issue_id_p");
3675 PERFORM "freeze_after_snapshot"("issue_id_p");
3676 RETURN;
3677 END;
3678 $$;
3680 COMMENT ON FUNCTION "manual_freeze"
3681 ( "issue"."id"%TYPE )
3682 IS 'Freeze an issue manually (fully) and start voting';
3686 -----------------------
3687 -- Counting of votes --
3688 -----------------------
3691 CREATE FUNCTION "weight_of_added_vote_delegations"
3692 ( "issue_id_p" "issue"."id"%TYPE,
3693 "member_id_p" "member"."id"%TYPE,
3694 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3695 RETURNS "direct_voter"."weight"%TYPE
3696 LANGUAGE 'plpgsql' VOLATILE AS $$
3697 DECLARE
3698 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3699 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3700 "weight_v" INT4;
3701 "sub_weight_v" INT4;
3702 BEGIN
3703 "weight_v" := 0;
3704 FOR "issue_delegation_row" IN
3705 SELECT * FROM "issue_delegation"
3706 WHERE "trustee_id" = "member_id_p"
3707 AND "issue_id" = "issue_id_p"
3708 LOOP
3709 IF NOT EXISTS (
3710 SELECT NULL FROM "direct_voter"
3711 WHERE "member_id" = "issue_delegation_row"."truster_id"
3712 AND "issue_id" = "issue_id_p"
3713 ) AND NOT EXISTS (
3714 SELECT NULL FROM "delegating_voter"
3715 WHERE "member_id" = "issue_delegation_row"."truster_id"
3716 AND "issue_id" = "issue_id_p"
3717 ) THEN
3718 "delegate_member_ids_v" :=
3719 "member_id_p" || "delegate_member_ids_p";
3720 INSERT INTO "delegating_voter" (
3721 "issue_id",
3722 "member_id",
3723 "scope",
3724 "delegate_member_ids"
3725 ) VALUES (
3726 "issue_id_p",
3727 "issue_delegation_row"."truster_id",
3728 "issue_delegation_row"."scope",
3729 "delegate_member_ids_v"
3730 );
3731 "sub_weight_v" := 1 +
3732 "weight_of_added_vote_delegations"(
3733 "issue_id_p",
3734 "issue_delegation_row"."truster_id",
3735 "delegate_member_ids_v"
3736 );
3737 UPDATE "delegating_voter"
3738 SET "weight" = "sub_weight_v"
3739 WHERE "issue_id" = "issue_id_p"
3740 AND "member_id" = "issue_delegation_row"."truster_id";
3741 "weight_v" := "weight_v" + "sub_weight_v";
3742 END IF;
3743 END LOOP;
3744 RETURN "weight_v";
3745 END;
3746 $$;
3748 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3749 ( "issue"."id"%TYPE,
3750 "member"."id"%TYPE,
3751 "delegating_voter"."delegate_member_ids"%TYPE )
3752 IS 'Helper function for "add_vote_delegations" function';
3755 CREATE FUNCTION "add_vote_delegations"
3756 ( "issue_id_p" "issue"."id"%TYPE )
3757 RETURNS VOID
3758 LANGUAGE 'plpgsql' VOLATILE AS $$
3759 DECLARE
3760 "member_id_v" "member"."id"%TYPE;
3761 BEGIN
3762 FOR "member_id_v" IN
3763 SELECT "member_id" FROM "direct_voter"
3764 WHERE "issue_id" = "issue_id_p"
3765 LOOP
3766 UPDATE "direct_voter" SET
3767 "weight" = "weight" + "weight_of_added_vote_delegations"(
3768 "issue_id_p",
3769 "member_id_v",
3770 '{}'
3772 WHERE "member_id" = "member_id_v"
3773 AND "issue_id" = "issue_id_p";
3774 END LOOP;
3775 RETURN;
3776 END;
3777 $$;
3779 COMMENT ON FUNCTION "add_vote_delegations"
3780 ( "issue_id_p" "issue"."id"%TYPE )
3781 IS 'Helper function for "close_voting" function';
3784 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3785 RETURNS VOID
3786 LANGUAGE 'plpgsql' VOLATILE AS $$
3787 DECLARE
3788 "area_id_v" "area"."id"%TYPE;
3789 "unit_id_v" "unit"."id"%TYPE;
3790 "member_id_v" "member"."id"%TYPE;
3791 BEGIN
3792 PERFORM "lock_issue"("issue_id_p");
3793 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3794 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3795 -- delete delegating votes (in cases of manual reset of issue state):
3796 DELETE FROM "delegating_voter"
3797 WHERE "issue_id" = "issue_id_p";
3798 -- delete votes from non-privileged voters:
3799 DELETE FROM "direct_voter"
3800 USING (
3801 SELECT
3802 "direct_voter"."member_id"
3803 FROM "direct_voter"
3804 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3805 LEFT JOIN "privilege"
3806 ON "privilege"."unit_id" = "unit_id_v"
3807 AND "privilege"."member_id" = "direct_voter"."member_id"
3808 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3809 "member"."active" = FALSE OR
3810 "privilege"."voting_right" ISNULL OR
3811 "privilege"."voting_right" = FALSE
3813 ) AS "subquery"
3814 WHERE "direct_voter"."issue_id" = "issue_id_p"
3815 AND "direct_voter"."member_id" = "subquery"."member_id";
3816 -- consider delegations:
3817 UPDATE "direct_voter" SET "weight" = 1
3818 WHERE "issue_id" = "issue_id_p";
3819 PERFORM "add_vote_delegations"("issue_id_p");
3820 -- set voter count and mark issue as being calculated:
3821 UPDATE "issue" SET
3822 "state" = 'calculation',
3823 "closed" = now(),
3824 "voter_count" = (
3825 SELECT coalesce(sum("weight"), 0)
3826 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3828 WHERE "id" = "issue_id_p";
3829 -- materialize battle_view:
3830 -- NOTE: "closed" column of issue must be set at this point
3831 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3832 INSERT INTO "battle" (
3833 "issue_id",
3834 "winning_initiative_id", "losing_initiative_id",
3835 "count"
3836 ) SELECT
3837 "issue_id",
3838 "winning_initiative_id", "losing_initiative_id",
3839 "count"
3840 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3841 -- copy "positive_votes" and "negative_votes" from "battle" table:
3842 UPDATE "initiative" SET
3843 "positive_votes" = "battle_win"."count",
3844 "negative_votes" = "battle_lose"."count"
3845 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3846 WHERE
3847 "battle_win"."issue_id" = "issue_id_p" AND
3848 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3849 "battle_win"."losing_initiative_id" ISNULL AND
3850 "battle_lose"."issue_id" = "issue_id_p" AND
3851 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3852 "battle_lose"."winning_initiative_id" ISNULL;
3853 END;
3854 $$;
3856 COMMENT ON FUNCTION "close_voting"
3857 ( "issue"."id"%TYPE )
3858 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.';
3861 CREATE FUNCTION "defeat_strength"
3862 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3863 RETURNS INT8
3864 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3865 BEGIN
3866 IF "positive_votes_p" > "negative_votes_p" THEN
3867 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3868 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3869 RETURN 0;
3870 ELSE
3871 RETURN -1;
3872 END IF;
3873 END;
3874 $$;
3876 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';
3879 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3880 RETURNS VOID
3881 LANGUAGE 'plpgsql' VOLATILE AS $$
3882 DECLARE
3883 "issue_row" "issue"%ROWTYPE;
3884 "policy_row" "policy"%ROWTYPE;
3885 "dimension_v" INTEGER;
3886 "vote_matrix" INT4[][]; -- absolute votes
3887 "matrix" INT8[][]; -- defeat strength / best paths
3888 "i" INTEGER;
3889 "j" INTEGER;
3890 "k" INTEGER;
3891 "battle_row" "battle"%ROWTYPE;
3892 "rank_ary" INT4[];
3893 "rank_v" INT4;
3894 "done_v" INTEGER;
3895 "winners_ary" INTEGER[];
3896 "initiative_id_v" "initiative"."id"%TYPE;
3897 BEGIN
3898 SELECT * INTO "issue_row"
3899 FROM "issue" WHERE "id" = "issue_id_p"
3900 FOR UPDATE;
3901 SELECT * INTO "policy_row"
3902 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3903 SELECT count(1) INTO "dimension_v"
3904 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3905 -- Create "vote_matrix" with absolute number of votes in pairwise
3906 -- comparison:
3907 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3908 "i" := 1;
3909 "j" := 2;
3910 FOR "battle_row" IN
3911 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3912 ORDER BY
3913 "winning_initiative_id" NULLS LAST,
3914 "losing_initiative_id" NULLS LAST
3915 LOOP
3916 "vote_matrix"["i"]["j"] := "battle_row"."count";
3917 IF "j" = "dimension_v" THEN
3918 "i" := "i" + 1;
3919 "j" := 1;
3920 ELSE
3921 "j" := "j" + 1;
3922 IF "j" = "i" THEN
3923 "j" := "j" + 1;
3924 END IF;
3925 END IF;
3926 END LOOP;
3927 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3928 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3929 END IF;
3930 -- Store defeat strengths in "matrix" using "defeat_strength"
3931 -- function:
3932 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3933 "i" := 1;
3934 LOOP
3935 "j" := 1;
3936 LOOP
3937 IF "i" != "j" THEN
3938 "matrix"["i"]["j"] := "defeat_strength"(
3939 "vote_matrix"["i"]["j"],
3940 "vote_matrix"["j"]["i"]
3941 );
3942 END IF;
3943 EXIT WHEN "j" = "dimension_v";
3944 "j" := "j" + 1;
3945 END LOOP;
3946 EXIT WHEN "i" = "dimension_v";
3947 "i" := "i" + 1;
3948 END LOOP;
3949 -- Find best paths:
3950 "i" := 1;
3951 LOOP
3952 "j" := 1;
3953 LOOP
3954 IF "i" != "j" THEN
3955 "k" := 1;
3956 LOOP
3957 IF "i" != "k" AND "j" != "k" THEN
3958 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3959 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3960 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3961 END IF;
3962 ELSE
3963 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3964 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3965 END IF;
3966 END IF;
3967 END IF;
3968 EXIT WHEN "k" = "dimension_v";
3969 "k" := "k" + 1;
3970 END LOOP;
3971 END IF;
3972 EXIT WHEN "j" = "dimension_v";
3973 "j" := "j" + 1;
3974 END LOOP;
3975 EXIT WHEN "i" = "dimension_v";
3976 "i" := "i" + 1;
3977 END LOOP;
3978 -- Determine order of winners:
3979 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3980 "rank_v" := 1;
3981 "done_v" := 0;
3982 LOOP
3983 "winners_ary" := '{}';
3984 "i" := 1;
3985 LOOP
3986 IF "rank_ary"["i"] ISNULL THEN
3987 "j" := 1;
3988 LOOP
3989 IF
3990 "i" != "j" AND
3991 "rank_ary"["j"] ISNULL AND
3992 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3993 THEN
3994 -- someone else is better
3995 EXIT;
3996 END IF;
3997 IF "j" = "dimension_v" THEN
3998 -- noone is better
3999 "winners_ary" := "winners_ary" || "i";
4000 EXIT;
4001 END IF;
4002 "j" := "j" + 1;
4003 END LOOP;
4004 END IF;
4005 EXIT WHEN "i" = "dimension_v";
4006 "i" := "i" + 1;
4007 END LOOP;
4008 "i" := 1;
4009 LOOP
4010 "rank_ary"["winners_ary"["i"]] := "rank_v";
4011 "done_v" := "done_v" + 1;
4012 EXIT WHEN "i" = array_upper("winners_ary", 1);
4013 "i" := "i" + 1;
4014 END LOOP;
4015 EXIT WHEN "done_v" = "dimension_v";
4016 "rank_v" := "rank_v" + 1;
4017 END LOOP;
4018 -- write preliminary results:
4019 "i" := 1;
4020 FOR "initiative_id_v" IN
4021 SELECT "id" FROM "initiative"
4022 WHERE "issue_id" = "issue_id_p" AND "admitted"
4023 ORDER BY "id"
4024 LOOP
4025 UPDATE "initiative" SET
4026 "direct_majority" =
4027 CASE WHEN "policy_row"."direct_majority_strict" THEN
4028 "positive_votes" * "policy_row"."direct_majority_den" >
4029 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4030 ELSE
4031 "positive_votes" * "policy_row"."direct_majority_den" >=
4032 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
4033 END
4034 AND "positive_votes" >= "policy_row"."direct_majority_positive"
4035 AND "issue_row"."voter_count"-"negative_votes" >=
4036 "policy_row"."direct_majority_non_negative",
4037 "indirect_majority" =
4038 CASE WHEN "policy_row"."indirect_majority_strict" THEN
4039 "positive_votes" * "policy_row"."indirect_majority_den" >
4040 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4041 ELSE
4042 "positive_votes" * "policy_row"."indirect_majority_den" >=
4043 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
4044 END
4045 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
4046 AND "issue_row"."voter_count"-"negative_votes" >=
4047 "policy_row"."indirect_majority_non_negative",
4048 "schulze_rank" = "rank_ary"["i"],
4049 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
4050 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
4051 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
4052 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
4053 "eligible" = FALSE,
4054 "winner" = FALSE,
4055 "rank" = NULL -- NOTE: in cases of manual reset of issue state
4056 WHERE "id" = "initiative_id_v";
4057 "i" := "i" + 1;
4058 END LOOP;
4059 IF "i" != "dimension_v" THEN
4060 RAISE EXCEPTION 'Wrong winner count (should not happen)';
4061 END IF;
4062 -- take indirect majorities into account:
4063 LOOP
4064 UPDATE "initiative" SET "indirect_majority" = TRUE
4065 FROM (
4066 SELECT "new_initiative"."id" AS "initiative_id"
4067 FROM "initiative" "old_initiative"
4068 JOIN "initiative" "new_initiative"
4069 ON "new_initiative"."issue_id" = "issue_id_p"
4070 AND "new_initiative"."indirect_majority" = FALSE
4071 JOIN "battle" "battle_win"
4072 ON "battle_win"."issue_id" = "issue_id_p"
4073 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
4074 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
4075 JOIN "battle" "battle_lose"
4076 ON "battle_lose"."issue_id" = "issue_id_p"
4077 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
4078 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
4079 WHERE "old_initiative"."issue_id" = "issue_id_p"
4080 AND "old_initiative"."indirect_majority" = TRUE
4081 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
4082 "battle_win"."count" * "policy_row"."indirect_majority_den" >
4083 "policy_row"."indirect_majority_num" *
4084 ("battle_win"."count"+"battle_lose"."count")
4085 ELSE
4086 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
4087 "policy_row"."indirect_majority_num" *
4088 ("battle_win"."count"+"battle_lose"."count")
4089 END
4090 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
4091 AND "issue_row"."voter_count"-"battle_lose"."count" >=
4092 "policy_row"."indirect_majority_non_negative"
4093 ) AS "subquery"
4094 WHERE "id" = "subquery"."initiative_id";
4095 EXIT WHEN NOT FOUND;
4096 END LOOP;
4097 -- set "multistage_majority" for remaining matching initiatives:
4098 UPDATE "initiative" SET "multistage_majority" = TRUE
4099 FROM (
4100 SELECT "losing_initiative"."id" AS "initiative_id"
4101 FROM "initiative" "losing_initiative"
4102 JOIN "initiative" "winning_initiative"
4103 ON "winning_initiative"."issue_id" = "issue_id_p"
4104 AND "winning_initiative"."admitted"
4105 JOIN "battle" "battle_win"
4106 ON "battle_win"."issue_id" = "issue_id_p"
4107 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
4108 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
4109 JOIN "battle" "battle_lose"
4110 ON "battle_lose"."issue_id" = "issue_id_p"
4111 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
4112 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
4113 WHERE "losing_initiative"."issue_id" = "issue_id_p"
4114 AND "losing_initiative"."admitted"
4115 AND "winning_initiative"."schulze_rank" <
4116 "losing_initiative"."schulze_rank"
4117 AND "battle_win"."count" > "battle_lose"."count"
4118 AND (
4119 "battle_win"."count" > "winning_initiative"."positive_votes" OR
4120 "battle_lose"."count" < "losing_initiative"."negative_votes" )
4121 ) AS "subquery"
4122 WHERE "id" = "subquery"."initiative_id";
4123 -- mark eligible initiatives:
4124 UPDATE "initiative" SET "eligible" = TRUE
4125 WHERE "issue_id" = "issue_id_p"
4126 AND "initiative"."direct_majority"
4127 AND "initiative"."indirect_majority"
4128 AND "initiative"."better_than_status_quo"
4129 AND (
4130 "policy_row"."no_multistage_majority" = FALSE OR
4131 "initiative"."multistage_majority" = FALSE )
4132 AND (
4133 "policy_row"."no_reverse_beat_path" = FALSE OR
4134 "initiative"."reverse_beat_path" = FALSE );
4135 -- mark final winner:
4136 UPDATE "initiative" SET "winner" = TRUE
4137 FROM (
4138 SELECT "id" AS "initiative_id"
4139 FROM "initiative"
4140 WHERE "issue_id" = "issue_id_p" AND "eligible"
4141 ORDER BY
4142 "schulze_rank",
4143 "vote_ratio"("positive_votes", "negative_votes"),
4144 "id"
4145 LIMIT 1
4146 ) AS "subquery"
4147 WHERE "id" = "subquery"."initiative_id";
4148 -- write (final) ranks:
4149 "rank_v" := 1;
4150 FOR "initiative_id_v" IN
4151 SELECT "id"
4152 FROM "initiative"
4153 WHERE "issue_id" = "issue_id_p" AND "admitted"
4154 ORDER BY
4155 "winner" DESC,
4156 "eligible" DESC,
4157 "schulze_rank",
4158 "vote_ratio"("positive_votes", "negative_votes"),
4159 "id"
4160 LOOP
4161 UPDATE "initiative" SET "rank" = "rank_v"
4162 WHERE "id" = "initiative_id_v";
4163 "rank_v" := "rank_v" + 1;
4164 END LOOP;
4165 -- set schulze rank of status quo and mark issue as finished:
4166 UPDATE "issue" SET
4167 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
4168 "state" =
4169 CASE WHEN EXISTS (
4170 SELECT NULL FROM "initiative"
4171 WHERE "issue_id" = "issue_id_p" AND "winner"
4172 ) THEN
4173 'finished_with_winner'::"issue_state"
4174 ELSE
4175 'finished_without_winner'::"issue_state"
4176 END,
4177 "ranks_available" = TRUE
4178 WHERE "id" = "issue_id_p";
4179 RETURN;
4180 END;
4181 $$;
4183 COMMENT ON FUNCTION "calculate_ranks"
4184 ( "issue"."id"%TYPE )
4185 IS 'Determine ranking (Votes have to be counted first)';
4189 -----------------------------
4190 -- Automatic state changes --
4191 -----------------------------
4194 CREATE FUNCTION "check_issue"
4195 ( "issue_id_p" "issue"."id"%TYPE )
4196 RETURNS VOID
4197 LANGUAGE 'plpgsql' VOLATILE AS $$
4198 DECLARE
4199 "issue_row" "issue"%ROWTYPE;
4200 "policy_row" "policy"%ROWTYPE;
4201 BEGIN
4202 PERFORM "lock_issue"("issue_id_p");
4203 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4204 -- only process open issues:
4205 IF "issue_row"."closed" ISNULL THEN
4206 SELECT * INTO "policy_row" FROM "policy"
4207 WHERE "id" = "issue_row"."policy_id";
4208 -- create a snapshot, unless issue is already fully frozen:
4209 IF "issue_row"."fully_frozen" ISNULL THEN
4210 PERFORM "create_snapshot"("issue_id_p");
4211 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4212 END IF;
4213 -- eventually close or accept issues, which have not been accepted:
4214 IF "issue_row"."accepted" ISNULL THEN
4215 IF EXISTS (
4216 SELECT NULL FROM "initiative"
4217 WHERE "issue_id" = "issue_id_p"
4218 AND "supporter_count" > 0
4219 AND "supporter_count" * "policy_row"."issue_quorum_den"
4220 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
4221 ) THEN
4222 -- accept issues, if supporter count is high enough
4223 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4224 -- NOTE: "issue_row" used later
4225 "issue_row"."state" := 'discussion';
4226 "issue_row"."accepted" := now();
4227 UPDATE "issue" SET
4228 "state" = "issue_row"."state",
4229 "accepted" = "issue_row"."accepted"
4230 WHERE "id" = "issue_row"."id";
4231 ELSIF
4232 now() >= "issue_row"."created" + "issue_row"."admission_time"
4233 THEN
4234 -- close issues, if admission time has expired
4235 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
4236 UPDATE "issue" SET
4237 "state" = 'canceled_issue_not_accepted',
4238 "closed" = now()
4239 WHERE "id" = "issue_row"."id";
4240 END IF;
4241 END IF;
4242 -- eventually half freeze issues:
4243 IF
4244 -- NOTE: issue can't be closed at this point, if it has been accepted
4245 "issue_row"."accepted" NOTNULL AND
4246 "issue_row"."half_frozen" ISNULL
4247 THEN
4248 IF
4249 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
4250 THEN
4251 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
4252 -- NOTE: "issue_row" used later
4253 "issue_row"."state" := 'verification';
4254 "issue_row"."half_frozen" := now();
4255 UPDATE "issue" SET
4256 "state" = "issue_row"."state",
4257 "half_frozen" = "issue_row"."half_frozen"
4258 WHERE "id" = "issue_row"."id";
4259 END IF;
4260 END IF;
4261 -- close issues after some time, if all initiatives have been revoked:
4262 IF
4263 "issue_row"."closed" ISNULL AND
4264 NOT EXISTS (
4265 -- all initiatives are revoked
4266 SELECT NULL FROM "initiative"
4267 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
4268 ) AND (
4269 -- and issue has not been accepted yet
4270 "issue_row"."accepted" ISNULL OR
4271 NOT EXISTS (
4272 -- or no initiatives have been revoked lately
4273 SELECT NULL FROM "initiative"
4274 WHERE "issue_id" = "issue_id_p"
4275 AND now() < "revoked" + "issue_row"."verification_time"
4276 ) OR (
4277 -- or verification time has elapsed
4278 "issue_row"."half_frozen" NOTNULL AND
4279 "issue_row"."fully_frozen" ISNULL AND
4280 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4283 THEN
4284 -- NOTE: "issue_row" used later
4285 IF "issue_row"."accepted" ISNULL THEN
4286 "issue_row"."state" := 'canceled_revoked_before_accepted';
4287 ELSIF "issue_row"."half_frozen" ISNULL THEN
4288 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
4289 ELSE
4290 "issue_row"."state" := 'canceled_after_revocation_during_verification';
4291 END IF;
4292 "issue_row"."closed" := now();
4293 UPDATE "issue" SET
4294 "state" = "issue_row"."state",
4295 "closed" = "issue_row"."closed"
4296 WHERE "id" = "issue_row"."id";
4297 END IF;
4298 -- fully freeze issue after verification time:
4299 IF
4300 "issue_row"."half_frozen" NOTNULL AND
4301 "issue_row"."fully_frozen" ISNULL AND
4302 "issue_row"."closed" ISNULL AND
4303 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
4304 THEN
4305 PERFORM "freeze_after_snapshot"("issue_id_p");
4306 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
4307 END IF;
4308 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
4309 -- close issue by calling close_voting(...) after voting time:
4310 IF
4311 "issue_row"."closed" ISNULL AND
4312 "issue_row"."fully_frozen" NOTNULL AND
4313 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
4314 THEN
4315 PERFORM "close_voting"("issue_id_p");
4316 -- calculate ranks will not consume much time and can be done now
4317 PERFORM "calculate_ranks"("issue_id_p");
4318 END IF;
4319 END IF;
4320 RETURN;
4321 END;
4322 $$;
4324 COMMENT ON FUNCTION "check_issue"
4325 ( "issue"."id"%TYPE )
4326 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.';
4329 CREATE FUNCTION "check_everything"()
4330 RETURNS VOID
4331 LANGUAGE 'plpgsql' VOLATILE AS $$
4332 DECLARE
4333 "issue_id_v" "issue"."id"%TYPE;
4334 BEGIN
4335 DELETE FROM "expired_session";
4336 PERFORM "check_activity"();
4337 PERFORM "calculate_member_counts"();
4338 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
4339 PERFORM "check_issue"("issue_id_v");
4340 END LOOP;
4341 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
4342 PERFORM "calculate_ranks"("issue_id_v");
4343 END LOOP;
4344 RETURN;
4345 END;
4346 $$;
4348 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.';
4352 ----------------------
4353 -- Deletion of data --
4354 ----------------------
4357 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4358 RETURNS VOID
4359 LANGUAGE 'plpgsql' VOLATILE AS $$
4360 DECLARE
4361 "issue_row" "issue"%ROWTYPE;
4362 BEGIN
4363 SELECT * INTO "issue_row"
4364 FROM "issue" WHERE "id" = "issue_id_p"
4365 FOR UPDATE;
4366 IF "issue_row"."cleaned" ISNULL THEN
4367 UPDATE "issue" SET
4368 "state" = 'voting',
4369 "closed" = NULL,
4370 "ranks_available" = FALSE
4371 WHERE "id" = "issue_id_p";
4372 DELETE FROM "voting_comment"
4373 WHERE "issue_id" = "issue_id_p";
4374 DELETE FROM "delegating_voter"
4375 WHERE "issue_id" = "issue_id_p";
4376 DELETE FROM "direct_voter"
4377 WHERE "issue_id" = "issue_id_p";
4378 DELETE FROM "delegating_interest_snapshot"
4379 WHERE "issue_id" = "issue_id_p";
4380 DELETE FROM "direct_interest_snapshot"
4381 WHERE "issue_id" = "issue_id_p";
4382 DELETE FROM "delegating_population_snapshot"
4383 WHERE "issue_id" = "issue_id_p";
4384 DELETE FROM "direct_population_snapshot"
4385 WHERE "issue_id" = "issue_id_p";
4386 DELETE FROM "non_voter"
4387 WHERE "issue_id" = "issue_id_p";
4388 DELETE FROM "delegation"
4389 WHERE "issue_id" = "issue_id_p";
4390 DELETE FROM "supporter"
4391 WHERE "issue_id" = "issue_id_p";
4392 UPDATE "issue" SET
4393 "state" = "issue_row"."state",
4394 "closed" = "issue_row"."closed",
4395 "ranks_available" = "issue_row"."ranks_available",
4396 "cleaned" = now()
4397 WHERE "id" = "issue_id_p";
4398 END IF;
4399 RETURN;
4400 END;
4401 $$;
4403 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4406 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4407 RETURNS VOID
4408 LANGUAGE 'plpgsql' VOLATILE AS $$
4409 BEGIN
4410 UPDATE "member" SET
4411 "last_login" = NULL,
4412 "login" = NULL,
4413 "password" = NULL,
4414 "locked" = TRUE,
4415 "active" = FALSE,
4416 "notify_email" = NULL,
4417 "notify_email_unconfirmed" = NULL,
4418 "notify_email_secret" = NULL,
4419 "notify_email_secret_expiry" = NULL,
4420 "notify_email_lock_expiry" = NULL,
4421 "password_reset_secret" = NULL,
4422 "password_reset_secret_expiry" = NULL,
4423 "organizational_unit" = NULL,
4424 "internal_posts" = NULL,
4425 "realname" = NULL,
4426 "birthday" = NULL,
4427 "address" = NULL,
4428 "email" = NULL,
4429 "xmpp_address" = NULL,
4430 "website" = NULL,
4431 "phone" = NULL,
4432 "mobile_phone" = NULL,
4433 "profession" = NULL,
4434 "external_memberships" = NULL,
4435 "external_posts" = NULL,
4436 "statement" = NULL
4437 WHERE "id" = "member_id_p";
4438 -- "text_search_data" is updated by triggers
4439 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4440 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4441 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4442 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4443 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4444 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4445 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4446 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4447 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4448 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4449 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4450 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4451 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4452 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4453 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4454 DELETE FROM "direct_voter" USING "issue"
4455 WHERE "direct_voter"."issue_id" = "issue"."id"
4456 AND "issue"."closed" ISNULL
4457 AND "member_id" = "member_id_p";
4458 RETURN;
4459 END;
4460 $$;
4462 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)';
4465 CREATE FUNCTION "delete_private_data"()
4466 RETURNS VOID
4467 LANGUAGE 'plpgsql' VOLATILE AS $$
4468 BEGIN
4469 DELETE FROM "member" WHERE "activated" ISNULL;
4470 UPDATE "member" SET
4471 "invite_code" = NULL,
4472 "invite_code_expiry" = NULL,
4473 "admin_comment" = NULL,
4474 "last_login" = NULL,
4475 "login" = NULL,
4476 "password" = NULL,
4477 "lang" = NULL,
4478 "notify_email" = NULL,
4479 "notify_email_unconfirmed" = NULL,
4480 "notify_email_secret" = NULL,
4481 "notify_email_secret_expiry" = NULL,
4482 "notify_email_lock_expiry" = NULL,
4483 "notify_level" = NULL,
4484 "password_reset_secret" = NULL,
4485 "password_reset_secret_expiry" = NULL,
4486 "organizational_unit" = NULL,
4487 "internal_posts" = NULL,
4488 "realname" = NULL,
4489 "birthday" = NULL,
4490 "address" = NULL,
4491 "email" = NULL,
4492 "xmpp_address" = NULL,
4493 "website" = NULL,
4494 "phone" = NULL,
4495 "mobile_phone" = NULL,
4496 "profession" = NULL,
4497 "external_memberships" = NULL,
4498 "external_posts" = NULL,
4499 "formatting_engine" = NULL,
4500 "statement" = NULL;
4501 -- "text_search_data" is updated by triggers
4502 DELETE FROM "setting";
4503 DELETE FROM "setting_map";
4504 DELETE FROM "member_relation_setting";
4505 DELETE FROM "member_image";
4506 DELETE FROM "contact";
4507 DELETE FROM "ignored_member";
4508 DELETE FROM "session";
4509 DELETE FROM "area_setting";
4510 DELETE FROM "issue_setting";
4511 DELETE FROM "ignored_initiative";
4512 DELETE FROM "initiative_setting";
4513 DELETE FROM "suggestion_setting";
4514 DELETE FROM "non_voter";
4515 DELETE FROM "direct_voter" USING "issue"
4516 WHERE "direct_voter"."issue_id" = "issue"."id"
4517 AND "issue"."closed" ISNULL;
4518 RETURN;
4519 END;
4520 $$;
4522 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.';
4526 COMMIT;

Impressum / About Us