liquid_feedback_core

view core.sql @ 266:d1d5dca15491

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

Impressum / About Us