liquid_feedback_core

view core.sql @ 265:e3c9f737a096

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

Impressum / About Us