liquid_feedback_core

view core.sql @ 270:b555a544c724

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

Impressum / About Us