liquid_feedback_core

view core.sql @ 273:82f0e365f418

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

Impressum / About Us