liquid_feedback_core

view core.sql @ 172:b8426100fd2d

Bugfix: Set winner to FALSE for all non-winning admitted initiatives
author jbe
date Tue Jun 07 20:41:14 2011 +0200 (2011-06-07)
parents 60aaf3b11ca3
children d8e11e6cfa1d
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 ('1.5.0_devel', 1, 5, -1))
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 login anymore.';
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 "last_login" TIMESTAMPTZ,
88 "last_login_public" DATE,
89 "login" TEXT UNIQUE,
90 "password" TEXT,
91 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
92 "active" BOOLEAN NOT NULL DEFAULT TRUE,
93 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
94 "notify_email" TEXT,
95 "notify_email_unconfirmed" TEXT,
96 "notify_email_secret" TEXT UNIQUE,
97 "notify_email_secret_expiry" TIMESTAMPTZ,
98 "notify_email_lock_expiry" TIMESTAMPTZ,
99 "notify_level" "notify_level" NOT NULL DEFAULT 'none',
100 "notify_event_id" INT8,
101 "password_reset_secret" TEXT UNIQUE,
102 "password_reset_secret_expiry" TIMESTAMPTZ,
103 "name" TEXT NOT NULL UNIQUE,
104 "identification" TEXT UNIQUE,
105 "organizational_unit" TEXT,
106 "internal_posts" TEXT,
107 "realname" TEXT,
108 "birthday" DATE,
109 "address" TEXT,
110 "email" TEXT,
111 "xmpp_address" TEXT,
112 "website" TEXT,
113 "phone" TEXT,
114 "mobile_phone" TEXT,
115 "profession" TEXT,
116 "external_memberships" TEXT,
117 "external_posts" TEXT,
118 "formatting_engine" TEXT,
119 "statement" TEXT,
120 "text_search_data" TSVECTOR );
121 CREATE INDEX "member_active_idx" ON "member" ("active");
122 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
123 CREATE TRIGGER "update_text_search_data"
124 BEFORE INSERT OR UPDATE ON "member"
125 FOR EACH ROW EXECUTE PROCEDURE
126 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
127 "name", "identification", "organizational_unit", "internal_posts",
128 "realname", "external_memberships", "external_posts", "statement" );
130 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
132 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
133 COMMENT ON COLUMN "member"."last_login_public" IS 'Date of last login (time stripped for privacy reasons, updated only after day change)';
134 COMMENT ON COLUMN "member"."login" IS 'Login name';
135 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
136 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
137 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. When the user does not log in for an extended period of time, this flag may be set to FALSE. If the user is not locked, he/she may reset the active flag by logging in.';
138 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
139 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
140 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
141 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
142 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
143 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
144 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
145 COMMENT ON COLUMN "member"."notify_event_id" IS 'Latest "id" of an "event" the member was notified about';
146 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
147 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
148 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
149 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
150 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
151 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
152 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
153 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
154 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
155 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his homepage within the system';
158 CREATE TABLE "member_history" (
159 "id" SERIAL8 PRIMARY KEY,
160 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
161 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
162 "active" BOOLEAN NOT NULL,
163 "name" TEXT NOT NULL );
164 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
166 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
168 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
169 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
172 CREATE TABLE "rendered_member_statement" (
173 PRIMARY KEY ("member_id", "format"),
174 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
175 "format" TEXT,
176 "content" TEXT NOT NULL );
178 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)';
181 CREATE TABLE "invite_code" (
182 "id" SERIAL8 PRIMARY KEY,
183 "code" TEXT NOT NULL UNIQUE,
184 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
185 "used" TIMESTAMPTZ,
186 "member_id" INT4 UNIQUE REFERENCES "member" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
187 "comment" TEXT,
188 CONSTRAINT "only_used_codes_may_refer_to_member" CHECK ("used" NOTNULL OR "member_id" ISNULL) );
190 COMMENT ON TABLE "invite_code" IS 'Invite codes can be used once to create a new member account.';
192 COMMENT ON COLUMN "invite_code"."code" IS 'Secret code';
193 COMMENT ON COLUMN "invite_code"."created" IS 'Time of creation of the secret code';
194 COMMENT ON COLUMN "invite_code"."used" IS 'NULL, if not used yet, otherwise tells when this code was used to create a member account';
195 COMMENT ON COLUMN "invite_code"."member_id" IS 'References the member whose account was created with this code';
196 COMMENT ON COLUMN "invite_code"."comment" IS 'Comment on the code, which is to be used for administrative reasons only';
199 CREATE TABLE "setting" (
200 PRIMARY KEY ("member_id", "key"),
201 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
202 "key" TEXT NOT NULL,
203 "value" TEXT NOT NULL );
204 CREATE INDEX "setting_key_idx" ON "setting" ("key");
206 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
208 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
211 CREATE TABLE "setting_map" (
212 PRIMARY KEY ("member_id", "key", "subkey"),
213 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
214 "key" TEXT NOT NULL,
215 "subkey" TEXT NOT NULL,
216 "value" TEXT NOT NULL );
217 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
219 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
221 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
222 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
223 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
226 CREATE TABLE "member_relation_setting" (
227 PRIMARY KEY ("member_id", "key", "other_member_id"),
228 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
229 "key" TEXT NOT NULL,
230 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
231 "value" TEXT NOT NULL );
233 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
236 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
238 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
241 CREATE TABLE "member_image" (
242 PRIMARY KEY ("member_id", "image_type", "scaled"),
243 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
244 "image_type" "member_image_type",
245 "scaled" BOOLEAN,
246 "content_type" TEXT,
247 "data" BYTEA NOT NULL );
249 COMMENT ON TABLE "member_image" IS 'Images of members';
251 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
254 CREATE TABLE "member_count" (
255 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
256 "total_count" INT4 NOT NULL );
258 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';
260 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
261 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
264 CREATE TABLE "contact" (
265 PRIMARY KEY ("member_id", "other_member_id"),
266 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
267 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
268 "public" BOOLEAN NOT NULL DEFAULT FALSE,
269 CONSTRAINT "cant_save_yourself_as_contact"
270 CHECK ("member_id" != "other_member_id") );
271 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
273 COMMENT ON TABLE "contact" IS 'Contact lists';
275 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
276 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
277 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
280 CREATE TABLE "ignored_member" (
281 PRIMARY KEY ("member_id", "other_member_id"),
282 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
283 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
284 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
286 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
288 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
289 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
292 CREATE TABLE "session" (
293 "ident" TEXT PRIMARY KEY,
294 "additional_secret" TEXT,
295 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
296 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
297 "lang" TEXT );
298 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
300 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend';
302 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
303 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
304 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
305 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
308 CREATE TABLE "policy" (
309 "id" SERIAL4 PRIMARY KEY,
310 "index" INT4 NOT NULL,
311 "active" BOOLEAN NOT NULL DEFAULT TRUE,
312 "name" TEXT NOT NULL UNIQUE,
313 "description" TEXT NOT NULL DEFAULT '',
314 "admission_time" INTERVAL NOT NULL,
315 "discussion_time" INTERVAL NOT NULL,
316 "verification_time" INTERVAL NOT NULL,
317 "voting_time" INTERVAL NOT NULL,
318 "issue_quorum_num" INT4 NOT NULL,
319 "issue_quorum_den" INT4 NOT NULL,
320 "initiative_quorum_num" INT4 NOT NULL,
321 "initiative_quorum_den" INT4 NOT NULL,
322 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
323 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
324 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
325 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
326 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
327 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
328 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
329 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
330 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
331 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
332 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE,
333 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE );
334 CREATE INDEX "policy_active_idx" ON "policy" ("active");
336 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
338 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
339 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
340 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
341 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
342 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
343 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
344 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"';
345 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"';
346 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
347 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
348 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
349 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
350 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.';
351 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
352 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';
353 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';
354 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';
355 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.';
356 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';
357 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';
358 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.';
359 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").';
362 CREATE TABLE "unit" (
363 "id" SERIAL4 PRIMARY KEY,
364 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
365 "active" BOOLEAN NOT NULL DEFAULT TRUE,
366 "name" TEXT NOT NULL,
367 "description" TEXT NOT NULL DEFAULT '',
368 "member_count" INT4,
369 "text_search_data" TSVECTOR );
370 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
371 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
372 CREATE INDEX "unit_active_idx" ON "unit" ("active");
373 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
374 CREATE TRIGGER "update_text_search_data"
375 BEFORE INSERT OR UPDATE ON "unit"
376 FOR EACH ROW EXECUTE PROCEDURE
377 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
378 "name", "description" );
380 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
382 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
383 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in units of this area';
384 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
387 CREATE TABLE "area" (
388 "id" SERIAL4 PRIMARY KEY,
389 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
390 "active" BOOLEAN NOT NULL DEFAULT TRUE,
391 "name" TEXT NOT NULL,
392 "description" TEXT NOT NULL DEFAULT '',
393 "direct_member_count" INT4,
394 "member_weight" INT4,
395 "text_search_data" TSVECTOR );
396 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
397 CREATE INDEX "area_active_idx" ON "area" ("active");
398 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
399 CREATE TRIGGER "update_text_search_data"
400 BEFORE INSERT OR UPDATE ON "area"
401 FOR EACH ROW EXECUTE PROCEDURE
402 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
403 "name", "description" );
405 COMMENT ON TABLE "area" IS 'Subject areas';
407 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
408 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"';
409 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
412 CREATE TABLE "area_setting" (
413 PRIMARY KEY ("member_id", "key", "area_id"),
414 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
415 "key" TEXT NOT NULL,
416 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
417 "value" TEXT NOT NULL );
419 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
422 CREATE TABLE "allowed_policy" (
423 PRIMARY KEY ("area_id", "policy_id"),
424 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
425 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
426 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
427 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
429 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
431 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
434 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
436 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';
439 CREATE TYPE "issue_state" AS ENUM (
440 'admission', 'discussion', 'verification', 'voting',
441 'canceled_revoked_before_accepted',
442 'canceled_issue_not_accepted',
443 'canceled_after_revocation_during_discussion',
444 'canceled_after_revocation_during_verification',
445 'calculation',
446 'canceled_no_initiative_admitted',
447 'finished_without_winner', 'finished_with_winner');
449 COMMENT ON TYPE "issue_state" IS 'State of issues';
452 CREATE TABLE "issue" (
453 "id" SERIAL4 PRIMARY KEY,
454 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
455 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
456 "state" "issue_state" NOT NULL DEFAULT 'admission',
457 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
458 "accepted" TIMESTAMPTZ,
459 "half_frozen" TIMESTAMPTZ,
460 "fully_frozen" TIMESTAMPTZ,
461 "closed" TIMESTAMPTZ,
462 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
463 "cleaned" TIMESTAMPTZ,
464 "admission_time" INTERVAL NOT NULL,
465 "discussion_time" INTERVAL NOT NULL,
466 "verification_time" INTERVAL NOT NULL,
467 "voting_time" INTERVAL NOT NULL,
468 "snapshot" TIMESTAMPTZ,
469 "latest_snapshot_event" "snapshot_event",
470 "population" INT4,
471 "voter_count" INT4,
472 "status_quo_schulze_rank" INT4,
473 CONSTRAINT "valid_state" CHECK ((
474 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
475 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
476 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
477 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
478 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
479 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
480 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
481 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
482 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND (
483 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
484 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
485 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
486 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
487 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
488 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
489 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
490 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
491 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
492 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
493 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
494 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
495 )),
496 CONSTRAINT "state_change_order" CHECK (
497 "created" <= "accepted" AND
498 "accepted" <= "half_frozen" AND
499 "half_frozen" <= "fully_frozen" AND
500 "fully_frozen" <= "closed" ),
501 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
502 "cleaned" ISNULL OR "closed" NOTNULL ),
503 CONSTRAINT "last_snapshot_on_full_freeze"
504 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
505 CONSTRAINT "freeze_requires_snapshot"
506 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
507 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
508 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
509 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
510 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
511 CREATE INDEX "issue_created_idx" ON "issue" ("created");
512 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
513 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
514 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
515 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
516 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
517 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
519 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
521 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
522 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.';
523 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.';
524 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.';
525 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
526 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
527 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
528 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
529 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
530 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
531 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
532 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';
533 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
534 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';
535 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
538 CREATE TABLE "issue_setting" (
539 PRIMARY KEY ("member_id", "key", "issue_id"),
540 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
541 "key" TEXT NOT NULL,
542 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
543 "value" TEXT NOT NULL );
545 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
548 CREATE TABLE "initiative" (
549 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
550 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
551 "id" SERIAL4 PRIMARY KEY,
552 "name" TEXT NOT NULL,
553 "discussion_url" TEXT,
554 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
555 "revoked" TIMESTAMPTZ,
556 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
557 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
558 "admitted" BOOLEAN,
559 "supporter_count" INT4,
560 "informed_supporter_count" INT4,
561 "satisfied_supporter_count" INT4,
562 "satisfied_informed_supporter_count" INT4,
563 "positive_votes" INT4,
564 "negative_votes" INT4,
565 "direct_majority" BOOLEAN,
566 "indirect_majority" BOOLEAN,
567 "schulze_rank" INT4,
568 "better_than_status_quo" BOOLEAN,
569 "worse_than_status_quo" BOOLEAN,
570 "reverse_beat_path" BOOLEAN,
571 "multistage_majority" BOOLEAN,
572 "eligible" BOOLEAN,
573 "winner" BOOLEAN,
574 "text_search_data" TSVECTOR,
575 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
576 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
577 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
578 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
579 CONSTRAINT "revoked_initiatives_cant_be_admitted"
580 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
581 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
582 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
583 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
584 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
585 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
586 "schulze_rank" ISNULL AND
587 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
588 "eligible" ISNULL AND "winner" ISNULL ) ),
589 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")) );
590 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
591 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
592 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
593 CREATE TRIGGER "update_text_search_data"
594 BEFORE INSERT OR UPDATE ON "initiative"
595 FOR EACH ROW EXECUTE PROCEDURE
596 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
597 "name", "discussion_url");
599 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.';
601 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
602 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
603 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
604 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
605 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
606 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
607 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
608 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
609 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
610 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
611 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"';
612 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
613 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
614 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
615 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
616 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';
617 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';
618 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
619 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
622 CREATE TABLE "battle" (
623 "issue_id" INT4 NOT NULL,
624 "winning_initiative_id" INT4,
625 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
626 "losing_initiative_id" INT4,
627 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
628 "count" INT4 NOT NULL,
629 CONSTRAINT "initiative_ids_not_equal" CHECK (
630 "winning_initiative_id" != "losing_initiative_id" OR
631 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
632 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
633 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
634 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
635 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
637 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';
640 CREATE TABLE "ignored_initiative" (
641 PRIMARY KEY ("initiative_id", "member_id"),
642 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
643 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
644 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
646 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
649 CREATE TABLE "initiative_setting" (
650 PRIMARY KEY ("member_id", "key", "initiative_id"),
651 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
652 "key" TEXT NOT NULL,
653 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
654 "value" TEXT NOT NULL );
656 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
659 CREATE TABLE "draft" (
660 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
661 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
662 "id" SERIAL8 PRIMARY KEY,
663 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
664 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
665 "formatting_engine" TEXT,
666 "content" TEXT NOT NULL,
667 "text_search_data" TSVECTOR );
668 CREATE INDEX "draft_created_idx" ON "draft" ("created");
669 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
670 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
671 CREATE TRIGGER "update_text_search_data"
672 BEFORE INSERT OR UPDATE ON "draft"
673 FOR EACH ROW EXECUTE PROCEDURE
674 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
676 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.';
678 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
679 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
682 CREATE TABLE "rendered_draft" (
683 PRIMARY KEY ("draft_id", "format"),
684 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
685 "format" TEXT,
686 "content" TEXT NOT NULL );
688 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)';
691 CREATE TABLE "suggestion" (
692 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
693 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
694 "id" SERIAL8 PRIMARY KEY,
695 "draft_id" INT8 NOT NULL,
696 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
697 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
698 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
699 "name" TEXT NOT NULL,
700 "formatting_engine" TEXT,
701 "content" TEXT NOT NULL DEFAULT '',
702 "text_search_data" TSVECTOR,
703 "minus2_unfulfilled_count" INT4,
704 "minus2_fulfilled_count" INT4,
705 "minus1_unfulfilled_count" INT4,
706 "minus1_fulfilled_count" INT4,
707 "plus1_unfulfilled_count" INT4,
708 "plus1_fulfilled_count" INT4,
709 "plus2_unfulfilled_count" INT4,
710 "plus2_fulfilled_count" INT4 );
711 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
712 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
713 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
714 CREATE TRIGGER "update_text_search_data"
715 BEFORE INSERT OR UPDATE ON "suggestion"
716 FOR EACH ROW EXECUTE PROCEDURE
717 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
718 "name", "content");
720 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';
722 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")';
723 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
724 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
725 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
726 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
727 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
728 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
729 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
730 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
733 CREATE TABLE "rendered_suggestion" (
734 PRIMARY KEY ("suggestion_id", "format"),
735 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
736 "format" TEXT,
737 "content" TEXT NOT NULL );
739 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)';
742 CREATE TABLE "suggestion_setting" (
743 PRIMARY KEY ("member_id", "key", "suggestion_id"),
744 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
745 "key" TEXT NOT NULL,
746 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
747 "value" TEXT NOT NULL );
749 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
752 CREATE TABLE "invite_code_unit" (
753 PRIMARY KEY ("invite_code_id", "unit_id"),
754 "invite_code_id" INT8 REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
755 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
757 COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
760 CREATE TABLE "privilege" (
761 PRIMARY KEY ("unit_id", "member_id"),
762 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
763 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
764 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
765 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
766 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
767 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
768 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
770 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
772 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
773 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
774 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
775 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
776 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
779 CREATE TABLE "membership" (
780 PRIMARY KEY ("area_id", "member_id"),
781 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
782 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
783 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
785 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
788 CREATE TABLE "interest" (
789 PRIMARY KEY ("issue_id", "member_id"),
790 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
791 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
792 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
794 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.';
797 CREATE TABLE "initiator" (
798 PRIMARY KEY ("initiative_id", "member_id"),
799 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
800 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "accepted" BOOLEAN );
802 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
804 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.';
806 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.';
809 CREATE TABLE "supporter" (
810 "issue_id" INT4 NOT NULL,
811 PRIMARY KEY ("initiative_id", "member_id"),
812 "initiative_id" INT4,
813 "member_id" INT4,
814 "draft_id" INT8 NOT NULL,
815 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
816 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
817 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
819 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.';
821 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")';
824 CREATE TABLE "opinion" (
825 "initiative_id" INT4 NOT NULL,
826 PRIMARY KEY ("suggestion_id", "member_id"),
827 "suggestion_id" INT8,
828 "member_id" INT4,
829 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
830 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
831 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
832 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
833 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
835 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.';
837 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
840 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
842 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
845 CREATE TABLE "delegation" (
846 "id" SERIAL8 PRIMARY KEY,
847 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
848 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
849 "scope" "delegation_scope" NOT NULL,
850 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
851 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
852 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
853 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
854 CONSTRAINT "no_unit_delegation_to_null"
855 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
856 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
857 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
858 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
859 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
860 UNIQUE ("unit_id", "truster_id"),
861 UNIQUE ("area_id", "truster_id"),
862 UNIQUE ("issue_id", "truster_id") );
863 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
864 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
866 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
868 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
869 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
870 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
873 CREATE TABLE "direct_population_snapshot" (
874 PRIMARY KEY ("issue_id", "event", "member_id"),
875 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
876 "event" "snapshot_event",
877 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
878 "weight" INT4 );
879 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
881 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
883 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
884 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
887 CREATE TABLE "delegating_population_snapshot" (
888 PRIMARY KEY ("issue_id", "event", "member_id"),
889 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
890 "event" "snapshot_event",
891 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
892 "weight" INT4,
893 "scope" "delegation_scope" NOT NULL,
894 "delegate_member_ids" INT4[] NOT NULL );
895 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
897 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
899 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
900 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
901 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
902 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"';
905 CREATE TABLE "direct_interest_snapshot" (
906 PRIMARY KEY ("issue_id", "event", "member_id"),
907 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
908 "event" "snapshot_event",
909 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
910 "weight" INT4 );
911 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
913 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
915 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
916 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
919 CREATE TABLE "delegating_interest_snapshot" (
920 PRIMARY KEY ("issue_id", "event", "member_id"),
921 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
922 "event" "snapshot_event",
923 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
924 "weight" INT4,
925 "scope" "delegation_scope" NOT NULL,
926 "delegate_member_ids" INT4[] NOT NULL );
927 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
929 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
931 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
932 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
933 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
934 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"';
937 CREATE TABLE "direct_supporter_snapshot" (
938 "issue_id" INT4 NOT NULL,
939 PRIMARY KEY ("initiative_id", "event", "member_id"),
940 "initiative_id" INT4,
941 "event" "snapshot_event",
942 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
943 "informed" BOOLEAN NOT NULL,
944 "satisfied" BOOLEAN NOT NULL,
945 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
946 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
947 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
949 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
951 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
952 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
953 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
956 CREATE TABLE "non_voter" (
957 PRIMARY KEY ("issue_id", "member_id"),
958 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
959 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
960 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
962 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
965 CREATE TABLE "direct_voter" (
966 PRIMARY KEY ("issue_id", "member_id"),
967 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
968 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
969 "weight" INT4 );
970 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
972 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.';
974 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
977 CREATE TABLE "delegating_voter" (
978 PRIMARY KEY ("issue_id", "member_id"),
979 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
980 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
981 "weight" INT4,
982 "scope" "delegation_scope" NOT NULL,
983 "delegate_member_ids" INT4[] NOT NULL );
984 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
986 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
988 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
989 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
990 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"';
993 CREATE TABLE "vote" (
994 "issue_id" INT4 NOT NULL,
995 PRIMARY KEY ("initiative_id", "member_id"),
996 "initiative_id" INT4,
997 "member_id" INT4,
998 "grade" INT4,
999 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1000 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1001 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1003 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.';
1005 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.';
1008 CREATE TABLE "issue_comment" (
1009 PRIMARY KEY ("issue_id", "member_id"),
1010 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1011 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1012 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
1013 "formatting_engine" TEXT,
1014 "content" TEXT NOT NULL,
1015 "text_search_data" TSVECTOR );
1016 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
1017 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
1018 CREATE TRIGGER "update_text_search_data"
1019 BEFORE INSERT OR UPDATE ON "issue_comment"
1020 FOR EACH ROW EXECUTE PROCEDURE
1021 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1023 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
1025 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
1028 CREATE TABLE "rendered_issue_comment" (
1029 PRIMARY KEY ("issue_id", "member_id", "format"),
1030 FOREIGN KEY ("issue_id", "member_id")
1031 REFERENCES "issue_comment" ("issue_id", "member_id")
1032 ON DELETE CASCADE ON UPDATE CASCADE,
1033 "issue_id" INT4,
1034 "member_id" INT4,
1035 "format" TEXT,
1036 "content" TEXT NOT NULL );
1038 COMMENT ON TABLE "rendered_issue_comment" IS 'This table may be used by frontends to cache "rendered" issue comments (e.g. HTML output generated from wiki text)';
1041 CREATE TABLE "voting_comment" (
1042 PRIMARY KEY ("issue_id", "member_id"),
1043 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1044 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1045 "changed" TIMESTAMPTZ,
1046 "formatting_engine" TEXT,
1047 "content" TEXT NOT NULL,
1048 "text_search_data" TSVECTOR );
1049 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1050 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1051 CREATE TRIGGER "update_text_search_data"
1052 BEFORE INSERT OR UPDATE ON "voting_comment"
1053 FOR EACH ROW EXECUTE PROCEDURE
1054 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1056 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1058 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.';
1061 CREATE TABLE "rendered_voting_comment" (
1062 PRIMARY KEY ("issue_id", "member_id", "format"),
1063 FOREIGN KEY ("issue_id", "member_id")
1064 REFERENCES "voting_comment" ("issue_id", "member_id")
1065 ON DELETE CASCADE ON UPDATE CASCADE,
1066 "issue_id" INT4,
1067 "member_id" INT4,
1068 "format" TEXT,
1069 "content" TEXT NOT NULL );
1071 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)';
1074 CREATE TYPE "event_type" AS ENUM (
1075 'issue_state_changed',
1076 'initiative_created_in_new_issue',
1077 'initiative_created_in_existing_issue',
1078 'initiative_revoked',
1079 'new_draft_created',
1080 'suggestion_created');
1082 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1085 CREATE TABLE "event" (
1086 "id" SERIAL8 PRIMARY KEY,
1087 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1088 "event" "event_type" NOT NULL,
1089 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1090 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1091 "state" "issue_state" CHECK ("state" != 'calculation'),
1092 "initiative_id" INT4,
1093 "draft_id" INT8,
1094 "suggestion_id" INT8,
1095 FOREIGN KEY ("issue_id", "initiative_id")
1096 REFERENCES "initiative" ("issue_id", "id")
1097 ON DELETE CASCADE ON UPDATE CASCADE,
1098 FOREIGN KEY ("initiative_id", "draft_id")
1099 REFERENCES "draft" ("initiative_id", "id")
1100 ON DELETE CASCADE ON UPDATE CASCADE,
1101 FOREIGN KEY ("initiative_id", "suggestion_id")
1102 REFERENCES "suggestion" ("initiative_id", "id")
1103 ON DELETE CASCADE ON UPDATE CASCADE,
1104 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1105 "event" != 'issue_state_changed' OR (
1106 "member_id" ISNULL AND
1107 "issue_id" NOTNULL AND
1108 "state" NOTNULL AND
1109 "initiative_id" ISNULL AND
1110 "draft_id" ISNULL AND
1111 "suggestion_id" ISNULL )),
1112 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1113 "event" NOT IN (
1114 'initiative_created_in_new_issue',
1115 'initiative_created_in_existing_issue',
1116 'initiative_revoked',
1117 'new_draft_created'
1118 ) OR (
1119 "member_id" NOTNULL AND
1120 "issue_id" NOTNULL AND
1121 "state" NOTNULL AND
1122 "initiative_id" NOTNULL AND
1123 "draft_id" NOTNULL AND
1124 "suggestion_id" ISNULL )),
1125 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1126 "event" != 'suggestion_created' OR (
1127 "member_id" NOTNULL AND
1128 "issue_id" NOTNULL AND
1129 "state" NOTNULL AND
1130 "initiative_id" NOTNULL AND
1131 "draft_id" ISNULL AND
1132 "suggestion_id" NOTNULL )) );
1134 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1136 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1137 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1138 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1139 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1143 ----------------------------------------------
1144 -- Writing of history entries and event log --
1145 ----------------------------------------------
1147 CREATE FUNCTION "write_member_history_trigger"()
1148 RETURNS TRIGGER
1149 LANGUAGE 'plpgsql' VOLATILE AS $$
1150 BEGIN
1151 IF
1152 NEW."active" != OLD."active" OR
1153 NEW."name" != OLD."name"
1154 THEN
1155 INSERT INTO "member_history"
1156 ("member_id", "active", "name")
1157 VALUES (NEW."id", OLD."active", OLD."name");
1158 END IF;
1159 RETURN NULL;
1160 END;
1161 $$;
1163 CREATE TRIGGER "write_member_history"
1164 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1165 "write_member_history_trigger"();
1167 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1168 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1171 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1172 RETURNS TRIGGER
1173 LANGUAGE 'plpgsql' VOLATILE AS $$
1174 BEGIN
1175 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1176 INSERT INTO "event" ("event", "issue_id", "state")
1177 VALUES ('issue_state_changed', NEW."id", NEW."state");
1178 END IF;
1179 RETURN NULL;
1180 END;
1181 $$;
1183 CREATE TRIGGER "write_event_issue_state_changed"
1184 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1185 "write_event_issue_state_changed_trigger"();
1187 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1188 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1191 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1192 RETURNS TRIGGER
1193 LANGUAGE 'plpgsql' VOLATILE AS $$
1194 DECLARE
1195 "initiative_row" "initiative"%ROWTYPE;
1196 "issue_row" "issue"%ROWTYPE;
1197 "event_v" "event_type";
1198 BEGIN
1199 SELECT * INTO "initiative_row" FROM "initiative"
1200 WHERE "id" = NEW."initiative_id";
1201 SELECT * INTO "issue_row" FROM "issue"
1202 WHERE "id" = "initiative_row"."issue_id";
1203 IF EXISTS (
1204 SELECT NULL FROM "draft"
1205 WHERE "initiative_id" = NEW."initiative_id"
1206 AND "id" != NEW."id"
1207 ) THEN
1208 "event_v" := 'new_draft_created';
1209 ELSE
1210 IF EXISTS (
1211 SELECT NULL FROM "initiative"
1212 WHERE "issue_id" = "initiative_row"."issue_id"
1213 AND "id" != "initiative_row"."id"
1214 ) THEN
1215 "event_v" := 'initiative_created_in_existing_issue';
1216 ELSE
1217 "event_v" := 'initiative_created_in_new_issue';
1218 END IF;
1219 END IF;
1220 INSERT INTO "event" (
1221 "event", "member_id",
1222 "issue_id", "state", "initiative_id", "draft_id"
1223 ) VALUES (
1224 "event_v",
1225 NEW."author_id",
1226 "initiative_row"."issue_id",
1227 "issue_row"."state",
1228 "initiative_row"."id",
1229 NEW."id" );
1230 RETURN NULL;
1231 END;
1232 $$;
1234 CREATE TRIGGER "write_event_initiative_or_draft_created"
1235 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1236 "write_event_initiative_or_draft_created_trigger"();
1238 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1239 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1242 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1243 RETURNS TRIGGER
1244 LANGUAGE 'plpgsql' VOLATILE AS $$
1245 DECLARE
1246 "issue_row" "issue"%ROWTYPE;
1247 BEGIN
1248 SELECT * INTO "issue_row" FROM "issue"
1249 WHERE "id" = NEW."issue_id";
1250 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1251 INSERT INTO "event" (
1252 "event", "member_id", "issue_id", "state", "initiative_id"
1253 ) VALUES (
1254 'initiative_revoked',
1255 NEW."revoked_by_member_id",
1256 NEW."issue_id",
1257 "issue_row"."state",
1258 NEW."id" );
1259 END IF;
1260 RETURN NULL;
1261 END;
1262 $$;
1264 CREATE TRIGGER "write_event_initiative_revoked"
1265 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1266 "write_event_initiative_revoked_trigger"();
1268 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1269 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1272 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1273 RETURNS TRIGGER
1274 LANGUAGE 'plpgsql' VOLATILE AS $$
1275 DECLARE
1276 "initiative_row" "initiative"%ROWTYPE;
1277 "issue_row" "issue"%ROWTYPE;
1278 BEGIN
1279 SELECT * INTO "initiative_row" FROM "initiative"
1280 WHERE "id" = NEW."initiative_id";
1281 SELECT * INTO "issue_row" FROM "issue"
1282 WHERE "id" = "initiative_row"."issue_id";
1283 INSERT INTO "event" (
1284 "event", "member_id",
1285 "issue_id", "state", "initiative_id", "suggestion_id"
1286 ) VALUES (
1287 'suggestion_created',
1288 NEW."author_id",
1289 "initiative_row"."issue_id",
1290 "issue_row"."state",
1291 "initiative_row"."id",
1292 NEW."id" );
1293 RETURN NULL;
1294 END;
1295 $$;
1297 CREATE TRIGGER "write_event_suggestion_created"
1298 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1299 "write_event_suggestion_created_trigger"();
1301 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1302 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1306 ----------------------------
1307 -- Additional constraints --
1308 ----------------------------
1311 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1312 RETURNS TRIGGER
1313 LANGUAGE 'plpgsql' VOLATILE AS $$
1314 BEGIN
1315 IF NOT EXISTS (
1316 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1317 ) THEN
1318 --RAISE 'Cannot create issue without an initial initiative.' USING
1319 -- ERRCODE = 'integrity_constraint_violation',
1320 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1321 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1322 END IF;
1323 RETURN NULL;
1324 END;
1325 $$;
1327 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1328 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1329 FOR EACH ROW EXECUTE PROCEDURE
1330 "issue_requires_first_initiative_trigger"();
1332 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1333 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1336 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1337 RETURNS TRIGGER
1338 LANGUAGE 'plpgsql' VOLATILE AS $$
1339 DECLARE
1340 "reference_lost" BOOLEAN;
1341 BEGIN
1342 IF TG_OP = 'DELETE' THEN
1343 "reference_lost" := TRUE;
1344 ELSE
1345 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1346 END IF;
1347 IF
1348 "reference_lost" AND NOT EXISTS (
1349 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1351 THEN
1352 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1353 END IF;
1354 RETURN NULL;
1355 END;
1356 $$;
1358 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1359 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1360 FOR EACH ROW EXECUTE PROCEDURE
1361 "last_initiative_deletes_issue_trigger"();
1363 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1364 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1367 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1368 RETURNS TRIGGER
1369 LANGUAGE 'plpgsql' VOLATILE AS $$
1370 BEGIN
1371 IF NOT EXISTS (
1372 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1373 ) THEN
1374 --RAISE 'Cannot create initiative without an initial draft.' USING
1375 -- ERRCODE = 'integrity_constraint_violation',
1376 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1377 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1378 END IF;
1379 RETURN NULL;
1380 END;
1381 $$;
1383 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1384 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1385 FOR EACH ROW EXECUTE PROCEDURE
1386 "initiative_requires_first_draft_trigger"();
1388 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1389 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1392 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1393 RETURNS TRIGGER
1394 LANGUAGE 'plpgsql' VOLATILE AS $$
1395 DECLARE
1396 "reference_lost" BOOLEAN;
1397 BEGIN
1398 IF TG_OP = 'DELETE' THEN
1399 "reference_lost" := TRUE;
1400 ELSE
1401 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1402 END IF;
1403 IF
1404 "reference_lost" AND NOT EXISTS (
1405 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1407 THEN
1408 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1409 END IF;
1410 RETURN NULL;
1411 END;
1412 $$;
1414 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1415 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1416 FOR EACH ROW EXECUTE PROCEDURE
1417 "last_draft_deletes_initiative_trigger"();
1419 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1420 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1423 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1424 RETURNS TRIGGER
1425 LANGUAGE 'plpgsql' VOLATILE AS $$
1426 BEGIN
1427 IF NOT EXISTS (
1428 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1429 ) THEN
1430 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1431 END IF;
1432 RETURN NULL;
1433 END;
1434 $$;
1436 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1437 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1438 FOR EACH ROW EXECUTE PROCEDURE
1439 "suggestion_requires_first_opinion_trigger"();
1441 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1442 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1445 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1446 RETURNS TRIGGER
1447 LANGUAGE 'plpgsql' VOLATILE AS $$
1448 DECLARE
1449 "reference_lost" BOOLEAN;
1450 BEGIN
1451 IF TG_OP = 'DELETE' THEN
1452 "reference_lost" := TRUE;
1453 ELSE
1454 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1455 END IF;
1456 IF
1457 "reference_lost" AND NOT EXISTS (
1458 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1460 THEN
1461 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1462 END IF;
1463 RETURN NULL;
1464 END;
1465 $$;
1467 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1468 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1469 FOR EACH ROW EXECUTE PROCEDURE
1470 "last_opinion_deletes_suggestion_trigger"();
1472 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1473 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1477 ---------------------------------------------------------------
1478 -- Ensure that votes are not modified when issues are frozen --
1479 ---------------------------------------------------------------
1481 -- NOTE: Frontends should ensure this anyway, but in case of programming
1482 -- errors the following triggers ensure data integrity.
1485 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1486 RETURNS TRIGGER
1487 LANGUAGE 'plpgsql' VOLATILE AS $$
1488 DECLARE
1489 "issue_id_v" "issue"."id"%TYPE;
1490 "issue_row" "issue"%ROWTYPE;
1491 BEGIN
1492 IF TG_OP = 'DELETE' THEN
1493 "issue_id_v" := OLD."issue_id";
1494 ELSE
1495 "issue_id_v" := NEW."issue_id";
1496 END IF;
1497 SELECT INTO "issue_row" * FROM "issue"
1498 WHERE "id" = "issue_id_v" FOR SHARE;
1499 IF "issue_row"."closed" NOTNULL THEN
1500 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1501 END IF;
1502 RETURN NULL;
1503 END;
1504 $$;
1506 CREATE TRIGGER "forbid_changes_on_closed_issue"
1507 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1508 FOR EACH ROW EXECUTE PROCEDURE
1509 "forbid_changes_on_closed_issue_trigger"();
1511 CREATE TRIGGER "forbid_changes_on_closed_issue"
1512 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1513 FOR EACH ROW EXECUTE PROCEDURE
1514 "forbid_changes_on_closed_issue_trigger"();
1516 CREATE TRIGGER "forbid_changes_on_closed_issue"
1517 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1518 FOR EACH ROW EXECUTE PROCEDURE
1519 "forbid_changes_on_closed_issue_trigger"();
1521 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"';
1522 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';
1523 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';
1524 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';
1528 --------------------------------------------------------------------
1529 -- Auto-retrieval of fields only needed for referential integrity --
1530 --------------------------------------------------------------------
1533 CREATE FUNCTION "autofill_issue_id_trigger"()
1534 RETURNS TRIGGER
1535 LANGUAGE 'plpgsql' VOLATILE AS $$
1536 BEGIN
1537 IF NEW."issue_id" ISNULL THEN
1538 SELECT "issue_id" INTO NEW."issue_id"
1539 FROM "initiative" WHERE "id" = NEW."initiative_id";
1540 END IF;
1541 RETURN NEW;
1542 END;
1543 $$;
1545 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1546 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1548 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1549 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1551 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1552 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1553 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1556 CREATE FUNCTION "autofill_initiative_id_trigger"()
1557 RETURNS TRIGGER
1558 LANGUAGE 'plpgsql' VOLATILE AS $$
1559 BEGIN
1560 IF NEW."initiative_id" ISNULL THEN
1561 SELECT "initiative_id" INTO NEW."initiative_id"
1562 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1563 END IF;
1564 RETURN NEW;
1565 END;
1566 $$;
1568 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1569 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1571 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1572 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1576 -----------------------------------------------------
1577 -- Automatic calculation of certain default values --
1578 -----------------------------------------------------
1581 CREATE FUNCTION "copy_timings_trigger"()
1582 RETURNS TRIGGER
1583 LANGUAGE 'plpgsql' VOLATILE AS $$
1584 DECLARE
1585 "policy_row" "policy"%ROWTYPE;
1586 BEGIN
1587 SELECT * INTO "policy_row" FROM "policy"
1588 WHERE "id" = NEW."policy_id";
1589 IF NEW."admission_time" ISNULL THEN
1590 NEW."admission_time" := "policy_row"."admission_time";
1591 END IF;
1592 IF NEW."discussion_time" ISNULL THEN
1593 NEW."discussion_time" := "policy_row"."discussion_time";
1594 END IF;
1595 IF NEW."verification_time" ISNULL THEN
1596 NEW."verification_time" := "policy_row"."verification_time";
1597 END IF;
1598 IF NEW."voting_time" ISNULL THEN
1599 NEW."voting_time" := "policy_row"."voting_time";
1600 END IF;
1601 RETURN NEW;
1602 END;
1603 $$;
1605 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1606 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1608 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1609 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1612 CREATE FUNCTION "default_for_draft_id_trigger"()
1613 RETURNS TRIGGER
1614 LANGUAGE 'plpgsql' VOLATILE AS $$
1615 BEGIN
1616 IF NEW."draft_id" ISNULL THEN
1617 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1618 WHERE "initiative_id" = NEW."initiative_id";
1619 END IF;
1620 RETURN NEW;
1621 END;
1622 $$;
1624 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1625 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1626 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1627 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1629 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1630 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';
1631 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';
1635 ----------------------------------------
1636 -- Automatic creation of dependencies --
1637 ----------------------------------------
1640 CREATE FUNCTION "autocreate_interest_trigger"()
1641 RETURNS TRIGGER
1642 LANGUAGE 'plpgsql' VOLATILE AS $$
1643 BEGIN
1644 IF NOT EXISTS (
1645 SELECT NULL FROM "initiative" JOIN "interest"
1646 ON "initiative"."issue_id" = "interest"."issue_id"
1647 WHERE "initiative"."id" = NEW."initiative_id"
1648 AND "interest"."member_id" = NEW."member_id"
1649 ) THEN
1650 BEGIN
1651 INSERT INTO "interest" ("issue_id", "member_id")
1652 SELECT "issue_id", NEW."member_id"
1653 FROM "initiative" WHERE "id" = NEW."initiative_id";
1654 EXCEPTION WHEN unique_violation THEN END;
1655 END IF;
1656 RETURN NEW;
1657 END;
1658 $$;
1660 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1661 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1663 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1664 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';
1667 CREATE FUNCTION "autocreate_supporter_trigger"()
1668 RETURNS TRIGGER
1669 LANGUAGE 'plpgsql' VOLATILE AS $$
1670 BEGIN
1671 IF NOT EXISTS (
1672 SELECT NULL FROM "suggestion" JOIN "supporter"
1673 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1674 WHERE "suggestion"."id" = NEW."suggestion_id"
1675 AND "supporter"."member_id" = NEW."member_id"
1676 ) THEN
1677 BEGIN
1678 INSERT INTO "supporter" ("initiative_id", "member_id")
1679 SELECT "initiative_id", NEW."member_id"
1680 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1681 EXCEPTION WHEN unique_violation THEN END;
1682 END IF;
1683 RETURN NEW;
1684 END;
1685 $$;
1687 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1688 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1690 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1691 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.';
1695 ------------------------------------------
1696 -- Views and helper functions for views --
1697 ------------------------------------------
1700 CREATE VIEW "unit_delegation" AS
1701 SELECT
1702 "unit"."id" AS "unit_id",
1703 "delegation"."id",
1704 "delegation"."truster_id",
1705 "delegation"."trustee_id",
1706 "delegation"."scope"
1707 FROM "unit"
1708 JOIN "delegation"
1709 ON "delegation"."unit_id" = "unit"."id"
1710 JOIN "member"
1711 ON "delegation"."truster_id" = "member"."id"
1712 JOIN "privilege"
1713 ON "delegation"."unit_id" = "privilege"."unit_id"
1714 AND "delegation"."truster_id" = "privilege"."member_id"
1715 WHERE "member"."active" AND "privilege"."voting_right";
1717 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1720 CREATE VIEW "area_delegation" AS
1721 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1722 "area"."id" AS "area_id",
1723 "delegation"."id",
1724 "delegation"."truster_id",
1725 "delegation"."trustee_id",
1726 "delegation"."scope"
1727 FROM "area"
1728 JOIN "delegation"
1729 ON "delegation"."unit_id" = "area"."unit_id"
1730 OR "delegation"."area_id" = "area"."id"
1731 JOIN "member"
1732 ON "delegation"."truster_id" = "member"."id"
1733 JOIN "privilege"
1734 ON "area"."unit_id" = "privilege"."unit_id"
1735 AND "delegation"."truster_id" = "privilege"."member_id"
1736 WHERE "member"."active" AND "privilege"."voting_right"
1737 ORDER BY
1738 "area"."id",
1739 "delegation"."truster_id",
1740 "delegation"."scope" DESC;
1742 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1745 CREATE VIEW "issue_delegation" AS
1746 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1747 "issue"."id" AS "issue_id",
1748 "delegation"."id",
1749 "delegation"."truster_id",
1750 "delegation"."trustee_id",
1751 "delegation"."scope"
1752 FROM "issue"
1753 JOIN "area"
1754 ON "area"."id" = "issue"."area_id"
1755 JOIN "delegation"
1756 ON "delegation"."unit_id" = "area"."unit_id"
1757 OR "delegation"."area_id" = "area"."id"
1758 OR "delegation"."issue_id" = "issue"."id"
1759 JOIN "member"
1760 ON "delegation"."truster_id" = "member"."id"
1761 JOIN "privilege"
1762 ON "area"."unit_id" = "privilege"."unit_id"
1763 AND "delegation"."truster_id" = "privilege"."member_id"
1764 WHERE "member"."active" AND "privilege"."voting_right"
1765 ORDER BY
1766 "issue"."id",
1767 "delegation"."truster_id",
1768 "delegation"."scope" DESC;
1770 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1773 CREATE FUNCTION "membership_weight_with_skipping"
1774 ( "area_id_p" "area"."id"%TYPE,
1775 "member_id_p" "member"."id"%TYPE,
1776 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1777 RETURNS INT4
1778 LANGUAGE 'plpgsql' STABLE AS $$
1779 DECLARE
1780 "sum_v" INT4;
1781 "delegation_row" "area_delegation"%ROWTYPE;
1782 BEGIN
1783 "sum_v" := 1;
1784 FOR "delegation_row" IN
1785 SELECT "area_delegation".*
1786 FROM "area_delegation" LEFT JOIN "membership"
1787 ON "membership"."area_id" = "area_id_p"
1788 AND "membership"."member_id" = "area_delegation"."truster_id"
1789 WHERE "area_delegation"."area_id" = "area_id_p"
1790 AND "area_delegation"."trustee_id" = "member_id_p"
1791 AND "membership"."member_id" ISNULL
1792 LOOP
1793 IF NOT
1794 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1795 THEN
1796 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1797 "area_id_p",
1798 "delegation_row"."truster_id",
1799 "skip_member_ids_p" || "delegation_row"."truster_id"
1800 );
1801 END IF;
1802 END LOOP;
1803 RETURN "sum_v";
1804 END;
1805 $$;
1807 COMMENT ON FUNCTION "membership_weight_with_skipping"
1808 ( "area"."id"%TYPE,
1809 "member"."id"%TYPE,
1810 INT4[] )
1811 IS 'Helper function for "membership_weight" function';
1814 CREATE FUNCTION "membership_weight"
1815 ( "area_id_p" "area"."id"%TYPE,
1816 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1817 RETURNS INT4
1818 LANGUAGE 'plpgsql' STABLE AS $$
1819 BEGIN
1820 RETURN "membership_weight_with_skipping"(
1821 "area_id_p",
1822 "member_id_p",
1823 ARRAY["member_id_p"]
1824 );
1825 END;
1826 $$;
1828 COMMENT ON FUNCTION "membership_weight"
1829 ( "area"."id"%TYPE,
1830 "member"."id"%TYPE )
1831 IS 'Calculates the potential voting weight of a member in a given area';
1834 CREATE VIEW "member_count_view" AS
1835 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1837 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1840 CREATE VIEW "unit_member_count" AS
1841 SELECT
1842 "unit"."id" AS "unit_id",
1843 sum("member"."id") AS "member_count"
1844 FROM "unit"
1845 LEFT JOIN "privilege"
1846 ON "privilege"."unit_id" = "unit"."id"
1847 AND "privilege"."voting_right"
1848 LEFT JOIN "member"
1849 ON "member"."id" = "privilege"."member_id"
1850 AND "member"."active"
1851 GROUP BY "unit"."id";
1853 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1856 CREATE VIEW "area_member_count" AS
1857 SELECT
1858 "area"."id" AS "area_id",
1859 count("member"."id") AS "direct_member_count",
1860 coalesce(
1861 sum(
1862 CASE WHEN "member"."id" NOTNULL THEN
1863 "membership_weight"("area"."id", "member"."id")
1864 ELSE 0 END
1866 ) AS "member_weight"
1867 FROM "area"
1868 LEFT JOIN "membership"
1869 ON "area"."id" = "membership"."area_id"
1870 LEFT JOIN "privilege"
1871 ON "privilege"."unit_id" = "area"."unit_id"
1872 AND "privilege"."member_id" = "membership"."member_id"
1873 AND "privilege"."voting_right"
1874 LEFT JOIN "member"
1875 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1876 AND "member"."active"
1877 GROUP BY "area"."id";
1879 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1882 CREATE VIEW "opening_draft" AS
1883 SELECT "draft".* FROM (
1884 SELECT
1885 "initiative"."id" AS "initiative_id",
1886 min("draft"."id") AS "draft_id"
1887 FROM "initiative" JOIN "draft"
1888 ON "initiative"."id" = "draft"."initiative_id"
1889 GROUP BY "initiative"."id"
1890 ) AS "subquery"
1891 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1893 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1896 CREATE VIEW "current_draft" AS
1897 SELECT "draft".* FROM (
1898 SELECT
1899 "initiative"."id" AS "initiative_id",
1900 max("draft"."id") AS "draft_id"
1901 FROM "initiative" JOIN "draft"
1902 ON "initiative"."id" = "draft"."initiative_id"
1903 GROUP BY "initiative"."id"
1904 ) AS "subquery"
1905 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1907 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1910 CREATE VIEW "critical_opinion" AS
1911 SELECT * FROM "opinion"
1912 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1913 OR ("degree" = -2 AND "fulfilled" = TRUE);
1915 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1918 CREATE VIEW "battle_participant" AS
1919 SELECT "initiative"."id", "initiative"."issue_id"
1920 FROM "issue" JOIN "initiative"
1921 ON "issue"."id" = "initiative"."issue_id"
1922 WHERE "initiative"."admitted"
1923 UNION ALL
1924 SELECT NULL, "id" AS "issue_id"
1925 FROM "issue";
1927 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1930 CREATE VIEW "battle_view" AS
1931 SELECT
1932 "issue"."id" AS "issue_id",
1933 "winning_initiative"."id" AS "winning_initiative_id",
1934 "losing_initiative"."id" AS "losing_initiative_id",
1935 sum(
1936 CASE WHEN
1937 coalesce("better_vote"."grade", 0) >
1938 coalesce("worse_vote"."grade", 0)
1939 THEN "direct_voter"."weight" ELSE 0 END
1940 ) AS "count"
1941 FROM "issue"
1942 LEFT JOIN "direct_voter"
1943 ON "issue"."id" = "direct_voter"."issue_id"
1944 JOIN "battle_participant" AS "winning_initiative"
1945 ON "issue"."id" = "winning_initiative"."issue_id"
1946 JOIN "battle_participant" AS "losing_initiative"
1947 ON "issue"."id" = "losing_initiative"."issue_id"
1948 LEFT JOIN "vote" AS "better_vote"
1949 ON "direct_voter"."member_id" = "better_vote"."member_id"
1950 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1951 LEFT JOIN "vote" AS "worse_vote"
1952 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1953 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1954 WHERE "issue"."closed" NOTNULL
1955 AND "issue"."cleaned" ISNULL
1956 AND (
1957 "winning_initiative"."id" != "losing_initiative"."id" OR
1958 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1959 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1960 GROUP BY
1961 "issue"."id",
1962 "winning_initiative"."id",
1963 "losing_initiative"."id";
1965 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';
1968 CREATE VIEW "expired_session" AS
1969 SELECT * FROM "session" WHERE now() > "expiry";
1971 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
1972 DELETE FROM "session" WHERE "ident" = OLD."ident";
1974 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
1975 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
1978 CREATE VIEW "open_issue" AS
1979 SELECT * FROM "issue" WHERE "closed" ISNULL;
1981 COMMENT ON VIEW "open_issue" IS 'All open issues';
1984 CREATE VIEW "issue_with_ranks_missing" AS
1985 SELECT * FROM "issue"
1986 WHERE "fully_frozen" NOTNULL
1987 AND "closed" NOTNULL
1988 AND "ranks_available" = FALSE;
1990 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
1993 CREATE VIEW "member_contingent" AS
1994 SELECT
1995 "member"."id" AS "member_id",
1996 "contingent"."time_frame",
1997 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
1999 SELECT count(1) FROM "draft"
2000 WHERE "draft"."author_id" = "member"."id"
2001 AND "draft"."created" > now() - "contingent"."time_frame"
2002 ) + (
2003 SELECT count(1) FROM "suggestion"
2004 WHERE "suggestion"."author_id" = "member"."id"
2005 AND "suggestion"."created" > now() - "contingent"."time_frame"
2007 ELSE NULL END AS "text_entry_count",
2008 "contingent"."text_entry_limit",
2009 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2010 SELECT count(1) FROM "opening_draft"
2011 WHERE "opening_draft"."author_id" = "member"."id"
2012 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2013 ) ELSE NULL END AS "initiative_count",
2014 "contingent"."initiative_limit"
2015 FROM "member" CROSS JOIN "contingent";
2017 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2019 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2020 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2023 CREATE VIEW "member_contingent_left" AS
2024 SELECT
2025 "member_id",
2026 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2027 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2028 FROM "member_contingent" GROUP BY "member_id";
2030 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.';
2033 CREATE VIEW "event_seen_by_member" AS
2034 SELECT
2035 "member"."id" AS "seen_by_member_id",
2036 CASE WHEN "event"."state" IN (
2037 'voting',
2038 'finished_without_winner',
2039 'finished_with_winner'
2040 ) THEN
2041 'voting'::"notify_level"
2042 ELSE
2043 CASE WHEN "event"."state" IN (
2044 'verification',
2045 'canceled_after_revocation_during_verification',
2046 'canceled_no_initiative_admitted'
2047 ) THEN
2048 'verification'::"notify_level"
2049 ELSE
2050 CASE WHEN "event"."state" IN (
2051 'discussion',
2052 'canceled_after_revocation_during_discussion'
2053 ) THEN
2054 'discussion'::"notify_level"
2055 ELSE
2056 'all'::"notify_level"
2057 END
2058 END
2059 END AS "notify_level",
2060 "event".*
2061 FROM "member" CROSS JOIN "event"
2062 LEFT JOIN "issue"
2063 ON "event"."issue_id" = "issue"."id"
2064 LEFT JOIN "membership"
2065 ON "member"."id" = "membership"."member_id"
2066 AND "issue"."area_id" = "membership"."area_id"
2067 LEFT JOIN "interest"
2068 ON "member"."id" = "interest"."member_id"
2069 AND "event"."issue_id" = "interest"."issue_id"
2070 LEFT JOIN "supporter"
2071 ON "member"."id" = "supporter"."member_id"
2072 AND "event"."initiative_id" = "supporter"."initiative_id"
2073 LEFT JOIN "ignored_member"
2074 ON "member"."id" = "ignored_member"."member_id"
2075 AND "event"."member_id" = "ignored_member"."other_member_id"
2076 LEFT JOIN "ignored_initiative"
2077 ON "member"."id" = "ignored_initiative"."member_id"
2078 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2079 WHERE (
2080 "supporter"."member_id" NOTNULL OR
2081 "interest"."member_id" NOTNULL OR
2082 ( "membership"."member_id" NOTNULL AND
2083 "event"."event" IN (
2084 'issue_state_changed',
2085 'initiative_created_in_new_issue',
2086 'initiative_created_in_existing_issue',
2087 'initiative_revoked' ) ) )
2088 AND "ignored_member"."member_id" ISNULL
2089 AND "ignored_initiative"."member_id" ISNULL;
2091 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
2094 CREATE VIEW "pending_notification" AS
2095 SELECT
2096 "member"."id" AS "seen_by_member_id",
2097 "event".*
2098 FROM "member" CROSS JOIN "event"
2099 LEFT JOIN "issue"
2100 ON "event"."issue_id" = "issue"."id"
2101 LEFT JOIN "membership"
2102 ON "member"."id" = "membership"."member_id"
2103 AND "issue"."area_id" = "membership"."area_id"
2104 LEFT JOIN "interest"
2105 ON "member"."id" = "interest"."member_id"
2106 AND "event"."issue_id" = "interest"."issue_id"
2107 LEFT JOIN "supporter"
2108 ON "member"."id" = "supporter"."member_id"
2109 AND "event"."initiative_id" = "supporter"."initiative_id"
2110 LEFT JOIN "ignored_member"
2111 ON "member"."id" = "ignored_member"."member_id"
2112 AND "event"."member_id" = "ignored_member"."other_member_id"
2113 LEFT JOIN "ignored_initiative"
2114 ON "member"."id" = "ignored_initiative"."member_id"
2115 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2116 WHERE (
2117 "member"."notify_event_id" ISNULL OR
2118 ( "member"."notify_event_id" NOTNULL AND
2119 "member"."notify_event_id" < "event"."id" ) )
2120 AND (
2121 ( "member"."notify_level" >= 'all' ) OR
2122 ( "member"."notify_level" >= 'voting' AND
2123 "event"."state" IN (
2124 'voting',
2125 'finished_without_winner',
2126 'finished_with_winner' ) ) OR
2127 ( "member"."notify_level" >= 'verification' AND
2128 "event"."state" IN (
2129 'verification',
2130 'canceled_after_revocation_during_verification',
2131 'canceled_no_initiative_admitted' ) ) OR
2132 ( "member"."notify_level" >= 'discussion' AND
2133 "event"."state" IN (
2134 'discussion',
2135 'canceled_after_revocation_during_discussion' ) ) )
2136 AND (
2137 "supporter"."member_id" NOTNULL OR
2138 "interest"."member_id" NOTNULL OR
2139 ( "membership"."member_id" NOTNULL AND
2140 "event"."event" IN (
2141 'issue_state_changed',
2142 'initiative_created_in_new_issue',
2143 'initiative_created_in_existing_issue',
2144 'initiative_revoked' ) ) )
2145 AND "ignored_member"."member_id" ISNULL
2146 AND "ignored_initiative"."member_id" ISNULL;
2148 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
2151 CREATE TYPE "timeline_event" AS ENUM (
2152 'issue_created',
2153 'issue_canceled',
2154 'issue_accepted',
2155 'issue_half_frozen',
2156 'issue_finished_without_voting',
2157 'issue_voting_started',
2158 'issue_finished_after_voting',
2159 'initiative_created',
2160 'initiative_revoked',
2161 'draft_created',
2162 'suggestion_created');
2164 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2167 CREATE VIEW "timeline_issue" AS
2168 SELECT
2169 "created" AS "occurrence",
2170 'issue_created'::"timeline_event" AS "event",
2171 "id" AS "issue_id"
2172 FROM "issue"
2173 UNION ALL
2174 SELECT
2175 "closed" AS "occurrence",
2176 'issue_canceled'::"timeline_event" AS "event",
2177 "id" AS "issue_id"
2178 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2179 UNION ALL
2180 SELECT
2181 "accepted" AS "occurrence",
2182 'issue_accepted'::"timeline_event" AS "event",
2183 "id" AS "issue_id"
2184 FROM "issue" WHERE "accepted" NOTNULL
2185 UNION ALL
2186 SELECT
2187 "half_frozen" AS "occurrence",
2188 'issue_half_frozen'::"timeline_event" AS "event",
2189 "id" AS "issue_id"
2190 FROM "issue" WHERE "half_frozen" NOTNULL
2191 UNION ALL
2192 SELECT
2193 "fully_frozen" AS "occurrence",
2194 'issue_voting_started'::"timeline_event" AS "event",
2195 "id" AS "issue_id"
2196 FROM "issue"
2197 WHERE "fully_frozen" NOTNULL
2198 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2199 UNION ALL
2200 SELECT
2201 "closed" AS "occurrence",
2202 CASE WHEN "fully_frozen" = "closed" THEN
2203 'issue_finished_without_voting'::"timeline_event"
2204 ELSE
2205 'issue_finished_after_voting'::"timeline_event"
2206 END AS "event",
2207 "id" AS "issue_id"
2208 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2210 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2213 CREATE VIEW "timeline_initiative" AS
2214 SELECT
2215 "created" AS "occurrence",
2216 'initiative_created'::"timeline_event" AS "event",
2217 "id" AS "initiative_id"
2218 FROM "initiative"
2219 UNION ALL
2220 SELECT
2221 "revoked" AS "occurrence",
2222 'initiative_revoked'::"timeline_event" AS "event",
2223 "id" AS "initiative_id"
2224 FROM "initiative" WHERE "revoked" NOTNULL;
2226 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2229 CREATE VIEW "timeline_draft" AS
2230 SELECT
2231 "created" AS "occurrence",
2232 'draft_created'::"timeline_event" AS "event",
2233 "id" AS "draft_id"
2234 FROM "draft";
2236 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2239 CREATE VIEW "timeline_suggestion" AS
2240 SELECT
2241 "created" AS "occurrence",
2242 'suggestion_created'::"timeline_event" AS "event",
2243 "id" AS "suggestion_id"
2244 FROM "suggestion";
2246 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2249 CREATE VIEW "timeline" AS
2250 SELECT
2251 "occurrence",
2252 "event",
2253 "issue_id",
2254 NULL AS "initiative_id",
2255 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2256 NULL::INT8 AS "suggestion_id"
2257 FROM "timeline_issue"
2258 UNION ALL
2259 SELECT
2260 "occurrence",
2261 "event",
2262 NULL AS "issue_id",
2263 "initiative_id",
2264 NULL AS "draft_id",
2265 NULL AS "suggestion_id"
2266 FROM "timeline_initiative"
2267 UNION ALL
2268 SELECT
2269 "occurrence",
2270 "event",
2271 NULL AS "issue_id",
2272 NULL AS "initiative_id",
2273 "draft_id",
2274 NULL AS "suggestion_id"
2275 FROM "timeline_draft"
2276 UNION ALL
2277 SELECT
2278 "occurrence",
2279 "event",
2280 NULL AS "issue_id",
2281 NULL AS "initiative_id",
2282 NULL AS "draft_id",
2283 "suggestion_id"
2284 FROM "timeline_suggestion";
2286 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2290 --------------------------------------------------
2291 -- Set returning function for delegation chains --
2292 --------------------------------------------------
2295 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2296 ('first', 'intermediate', 'last', 'repetition');
2298 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2301 CREATE TYPE "delegation_chain_row" AS (
2302 "index" INT4,
2303 "member_id" INT4,
2304 "member_valid" BOOLEAN,
2305 "participation" BOOLEAN,
2306 "overridden" BOOLEAN,
2307 "scope_in" "delegation_scope",
2308 "scope_out" "delegation_scope",
2309 "disabled_out" BOOLEAN,
2310 "loop" "delegation_chain_loop_tag" );
2312 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2314 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2315 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';
2316 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2317 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2318 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2319 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2320 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2323 CREATE FUNCTION "delegation_chain"
2324 ( "member_id_p" "member"."id"%TYPE,
2325 "unit_id_p" "unit"."id"%TYPE,
2326 "area_id_p" "area"."id"%TYPE,
2327 "issue_id_p" "issue"."id"%TYPE,
2328 "simulate_trustee_id_p" "member"."id"%TYPE )
2329 RETURNS SETOF "delegation_chain_row"
2330 LANGUAGE 'plpgsql' STABLE AS $$
2331 DECLARE
2332 "scope_v" "delegation_scope";
2333 "unit_id_v" "unit"."id"%TYPE;
2334 "area_id_v" "area"."id"%TYPE;
2335 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2336 "loop_member_id_v" "member"."id"%TYPE;
2337 "output_row" "delegation_chain_row";
2338 "output_rows" "delegation_chain_row"[];
2339 "delegation_row" "delegation"%ROWTYPE;
2340 "row_count" INT4;
2341 "i" INT4;
2342 "loop_v" BOOLEAN;
2343 BEGIN
2344 IF
2345 "unit_id_p" NOTNULL AND
2346 "area_id_p" ISNULL AND
2347 "issue_id_p" ISNULL
2348 THEN
2349 "scope_v" := 'unit';
2350 "unit_id_v" := "unit_id_p";
2351 ELSIF
2352 "unit_id_p" ISNULL AND
2353 "area_id_p" NOTNULL AND
2354 "issue_id_p" ISNULL
2355 THEN
2356 "scope_v" := 'area';
2357 "area_id_v" := "area_id_p";
2358 SELECT "unit_id" INTO "unit_id_v"
2359 FROM "area" WHERE "id" = "area_id_v";
2360 ELSIF
2361 "unit_id_p" ISNULL AND
2362 "area_id_p" ISNULL AND
2363 "issue_id_p" NOTNULL
2364 THEN
2365 "scope_v" := 'issue';
2366 SELECT "area_id" INTO "area_id_v"
2367 FROM "issue" WHERE "id" = "issue_id_p";
2368 SELECT "unit_id" INTO "unit_id_v"
2369 FROM "area" WHERE "id" = "area_id_v";
2370 ELSE
2371 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2372 END IF;
2373 "visited_member_ids" := '{}';
2374 "loop_member_id_v" := NULL;
2375 "output_rows" := '{}';
2376 "output_row"."index" := 0;
2377 "output_row"."member_id" := "member_id_p";
2378 "output_row"."member_valid" := TRUE;
2379 "output_row"."participation" := FALSE;
2380 "output_row"."overridden" := FALSE;
2381 "output_row"."disabled_out" := FALSE;
2382 "output_row"."scope_out" := NULL;
2383 LOOP
2384 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2385 "loop_member_id_v" := "output_row"."member_id";
2386 ELSE
2387 "visited_member_ids" :=
2388 "visited_member_ids" || "output_row"."member_id";
2389 END IF;
2390 IF "output_row"."participation" THEN
2391 "output_row"."overridden" := TRUE;
2392 END IF;
2393 "output_row"."scope_in" := "output_row"."scope_out";
2394 IF EXISTS (
2395 SELECT NULL FROM "member" JOIN "privilege"
2396 ON "privilege"."member_id" = "member"."id"
2397 AND "privilege"."unit_id" = "unit_id_v"
2398 WHERE "id" = "output_row"."member_id"
2399 AND "member"."active" AND "privilege"."voting_right"
2400 ) THEN
2401 IF "scope_v" = 'unit' THEN
2402 SELECT * INTO "delegation_row" FROM "delegation"
2403 WHERE "truster_id" = "output_row"."member_id"
2404 AND "unit_id" = "unit_id_v";
2405 ELSIF "scope_v" = 'area' THEN
2406 "output_row"."participation" := EXISTS (
2407 SELECT NULL FROM "membership"
2408 WHERE "area_id" = "area_id_p"
2409 AND "member_id" = "output_row"."member_id"
2410 );
2411 SELECT * INTO "delegation_row" FROM "delegation"
2412 WHERE "truster_id" = "output_row"."member_id"
2413 AND (
2414 "unit_id" = "unit_id_v" OR
2415 "area_id" = "area_id_v"
2417 ORDER BY "scope" DESC;
2418 ELSIF "scope_v" = 'issue' THEN
2419 "output_row"."participation" := EXISTS (
2420 SELECT NULL FROM "interest"
2421 WHERE "issue_id" = "issue_id_p"
2422 AND "member_id" = "output_row"."member_id"
2423 );
2424 SELECT * INTO "delegation_row" FROM "delegation"
2425 WHERE "truster_id" = "output_row"."member_id"
2426 AND (
2427 "unit_id" = "unit_id_v" OR
2428 "area_id" = "area_id_v" OR
2429 "issue_id" = "issue_id_p"
2431 ORDER BY "scope" DESC;
2432 END IF;
2433 ELSE
2434 "output_row"."member_valid" := FALSE;
2435 "output_row"."participation" := FALSE;
2436 "output_row"."scope_out" := NULL;
2437 "delegation_row" := ROW(NULL);
2438 END IF;
2439 IF
2440 "output_row"."member_id" = "member_id_p" AND
2441 "simulate_trustee_id_p" NOTNULL
2442 THEN
2443 "output_row"."scope_out" := "scope_v";
2444 "output_rows" := "output_rows" || "output_row";
2445 "output_row"."member_id" := "simulate_trustee_id_p";
2446 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2447 "output_row"."scope_out" := "delegation_row"."scope";
2448 "output_rows" := "output_rows" || "output_row";
2449 "output_row"."member_id" := "delegation_row"."trustee_id";
2450 ELSIF "delegation_row"."scope" NOTNULL THEN
2451 "output_row"."scope_out" := "delegation_row"."scope";
2452 "output_row"."disabled_out" := TRUE;
2453 "output_rows" := "output_rows" || "output_row";
2454 EXIT;
2455 ELSE
2456 "output_row"."scope_out" := NULL;
2457 "output_rows" := "output_rows" || "output_row";
2458 EXIT;
2459 END IF;
2460 EXIT WHEN "loop_member_id_v" NOTNULL;
2461 "output_row"."index" := "output_row"."index" + 1;
2462 END LOOP;
2463 "row_count" := array_upper("output_rows", 1);
2464 "i" := 1;
2465 "loop_v" := FALSE;
2466 LOOP
2467 "output_row" := "output_rows"["i"];
2468 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2469 IF "loop_v" THEN
2470 IF "i" + 1 = "row_count" THEN
2471 "output_row"."loop" := 'last';
2472 ELSIF "i" = "row_count" THEN
2473 "output_row"."loop" := 'repetition';
2474 ELSE
2475 "output_row"."loop" := 'intermediate';
2476 END IF;
2477 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2478 "output_row"."loop" := 'first';
2479 "loop_v" := TRUE;
2480 END IF;
2481 IF "scope_v" = 'unit' THEN
2482 "output_row"."participation" := NULL;
2483 END IF;
2484 RETURN NEXT "output_row";
2485 "i" := "i" + 1;
2486 END LOOP;
2487 RETURN;
2488 END;
2489 $$;
2491 COMMENT ON FUNCTION "delegation_chain"
2492 ( "member"."id"%TYPE,
2493 "unit"."id"%TYPE,
2494 "area"."id"%TYPE,
2495 "issue"."id"%TYPE,
2496 "member"."id"%TYPE )
2497 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2500 CREATE FUNCTION "delegation_chain"
2501 ( "member_id_p" "member"."id"%TYPE,
2502 "unit_id_p" "unit"."id"%TYPE,
2503 "area_id_p" "area"."id"%TYPE,
2504 "issue_id_p" "issue"."id"%TYPE )
2505 RETURNS SETOF "delegation_chain_row"
2506 LANGUAGE 'plpgsql' STABLE AS $$
2507 DECLARE
2508 "result_row" "delegation_chain_row";
2509 BEGIN
2510 FOR "result_row" IN
2511 SELECT * FROM "delegation_chain"(
2512 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2514 LOOP
2515 RETURN NEXT "result_row";
2516 END LOOP;
2517 RETURN;
2518 END;
2519 $$;
2521 COMMENT ON FUNCTION "delegation_chain"
2522 ( "member"."id"%TYPE,
2523 "unit"."id"%TYPE,
2524 "area"."id"%TYPE,
2525 "issue"."id"%TYPE )
2526 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2530 ------------------------------
2531 -- Comparison by vote count --
2532 ------------------------------
2534 CREATE FUNCTION "vote_ratio"
2535 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2536 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2537 RETURNS FLOAT8
2538 LANGUAGE 'plpgsql' STABLE AS $$
2539 BEGIN
2540 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2541 RETURN
2542 "positive_votes_p"::FLOAT8 /
2543 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2544 ELSIF "positive_votes_p" > 0 THEN
2545 RETURN "positive_votes_p";
2546 ELSIF "negative_votes_p" > 0 THEN
2547 RETURN 1 - "negative_votes_p";
2548 ELSE
2549 RETURN 0.5;
2550 END IF;
2551 END;
2552 $$;
2554 COMMENT ON FUNCTION "vote_ratio"
2555 ( "initiative"."positive_votes"%TYPE,
2556 "initiative"."negative_votes"%TYPE )
2557 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.';
2561 ------------------------------------------------
2562 -- Locking for snapshots and voting procedure --
2563 ------------------------------------------------
2566 CREATE FUNCTION "share_row_lock_issue_trigger"()
2567 RETURNS TRIGGER
2568 LANGUAGE 'plpgsql' VOLATILE AS $$
2569 BEGIN
2570 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2571 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2572 END IF;
2573 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2574 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2575 RETURN NEW;
2576 ELSE
2577 RETURN OLD;
2578 END IF;
2579 END;
2580 $$;
2582 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2585 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2586 RETURNS TRIGGER
2587 LANGUAGE 'plpgsql' VOLATILE AS $$
2588 BEGIN
2589 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2590 PERFORM NULL FROM "issue"
2591 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2592 WHERE "initiative"."id" = OLD."initiative_id"
2593 FOR SHARE OF "issue";
2594 END IF;
2595 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2596 PERFORM NULL FROM "issue"
2597 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2598 WHERE "initiative"."id" = NEW."initiative_id"
2599 FOR SHARE OF "issue";
2600 RETURN NEW;
2601 ELSE
2602 RETURN OLD;
2603 END IF;
2604 END;
2605 $$;
2607 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2610 CREATE TRIGGER "share_row_lock_issue"
2611 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2612 FOR EACH ROW EXECUTE PROCEDURE
2613 "share_row_lock_issue_trigger"();
2615 CREATE TRIGGER "share_row_lock_issue"
2616 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2617 FOR EACH ROW EXECUTE PROCEDURE
2618 "share_row_lock_issue_trigger"();
2620 CREATE TRIGGER "share_row_lock_issue"
2621 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2622 FOR EACH ROW EXECUTE PROCEDURE
2623 "share_row_lock_issue_trigger"();
2625 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2626 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2627 FOR EACH ROW EXECUTE PROCEDURE
2628 "share_row_lock_issue_via_initiative_trigger"();
2630 CREATE TRIGGER "share_row_lock_issue"
2631 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2632 FOR EACH ROW EXECUTE PROCEDURE
2633 "share_row_lock_issue_trigger"();
2635 CREATE TRIGGER "share_row_lock_issue"
2636 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2637 FOR EACH ROW EXECUTE PROCEDURE
2638 "share_row_lock_issue_trigger"();
2640 CREATE TRIGGER "share_row_lock_issue"
2641 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2642 FOR EACH ROW EXECUTE PROCEDURE
2643 "share_row_lock_issue_trigger"();
2645 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2646 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2647 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2648 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2649 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2650 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2651 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2654 CREATE FUNCTION "lock_issue"
2655 ( "issue_id_p" "issue"."id"%TYPE )
2656 RETURNS VOID
2657 LANGUAGE 'plpgsql' VOLATILE AS $$
2658 BEGIN
2659 LOCK TABLE "member" IN SHARE MODE;
2660 LOCK TABLE "privilege" IN SHARE MODE;
2661 LOCK TABLE "membership" IN SHARE MODE;
2662 LOCK TABLE "policy" IN SHARE MODE;
2663 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2664 -- NOTE: The row-level exclusive lock in combination with the
2665 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2666 -- acquire a row-level share lock on the issue) ensure that no data
2667 -- is changed, which could affect calculation of snapshots or
2668 -- counting of votes. Table "delegation" must be table-level-locked,
2669 -- as it also contains issue- and global-scope delegations.
2670 LOCK TABLE "delegation" IN SHARE MODE;
2671 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2672 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2673 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2674 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2675 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2676 RETURN;
2677 END;
2678 $$;
2680 COMMENT ON FUNCTION "lock_issue"
2681 ( "issue"."id"%TYPE )
2682 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2686 ------------------------------------------------------------------------
2687 -- Regular tasks, except calculcation of snapshots and voting results --
2688 ------------------------------------------------------------------------
2690 CREATE FUNCTION "check_last_login"()
2691 RETURNS VOID
2692 LANGUAGE 'plpgsql' VOLATILE AS $$
2693 DECLARE
2694 "system_setting_row" "system_setting"%ROWTYPE;
2695 BEGIN
2696 SELECT * INTO "system_setting_row" FROM "system_setting";
2697 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2698 UPDATE "member" SET "last_login_public" = "last_login"::date
2699 FROM (
2700 SELECT DISTINCT "member"."id"
2701 FROM "member" LEFT JOIN "member_history"
2702 ON "member"."id" = "member_history"."member_id"
2703 WHERE "member"."last_login"::date < 'today' OR (
2704 "member_history"."until"::date >= 'today' AND
2705 "member_history"."active" = FALSE AND "member"."active" = TRUE
2707 ) AS "subquery"
2708 WHERE "member"."id" = "subquery"."id";
2709 IF "system_setting_row"."member_ttl" NOTNULL THEN
2710 UPDATE "member" SET "active" = FALSE
2711 WHERE "active" = TRUE
2712 AND "last_login"::date < 'today'
2713 AND "last_login_public" <
2714 (now() - "system_setting_row"."member_ttl")::date;
2715 END IF;
2716 RETURN;
2717 END;
2718 $$;
2720 COMMENT ON FUNCTION "check_last_login"() IS 'Updates "last_login_public" field, which contains the date but not the time of the last login, and deactivates members who do not login for the time specified in "system_setting"."member_ttl". For privacy reasons this function does not update "last_login_public", if the last login of a member has been today (except when member was reactivated today).';
2723 CREATE FUNCTION "calculate_member_counts"()
2724 RETURNS VOID
2725 LANGUAGE 'plpgsql' VOLATILE AS $$
2726 BEGIN
2727 LOCK TABLE "member" IN SHARE MODE;
2728 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2729 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2730 LOCK TABLE "area" IN EXCLUSIVE MODE;
2731 LOCK TABLE "privilege" IN SHARE MODE;
2732 LOCK TABLE "membership" IN SHARE MODE;
2733 DELETE FROM "member_count";
2734 INSERT INTO "member_count" ("total_count")
2735 SELECT "total_count" FROM "member_count_view";
2736 UPDATE "unit" SET "member_count" = "view"."member_count"
2737 FROM "unit_member_count" AS "view"
2738 WHERE "view"."unit_id" = "unit"."id";
2739 UPDATE "area" SET
2740 "direct_member_count" = "view"."direct_member_count",
2741 "member_weight" = "view"."member_weight"
2742 FROM "area_member_count" AS "view"
2743 WHERE "view"."area_id" = "area"."id";
2744 RETURN;
2745 END;
2746 $$;
2748 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"';
2752 ------------------------------
2753 -- Calculation of snapshots --
2754 ------------------------------
2756 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2757 ( "issue_id_p" "issue"."id"%TYPE,
2758 "member_id_p" "member"."id"%TYPE,
2759 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2760 RETURNS "direct_population_snapshot"."weight"%TYPE
2761 LANGUAGE 'plpgsql' VOLATILE AS $$
2762 DECLARE
2763 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2764 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2765 "weight_v" INT4;
2766 "sub_weight_v" INT4;
2767 BEGIN
2768 "weight_v" := 0;
2769 FOR "issue_delegation_row" IN
2770 SELECT * FROM "issue_delegation"
2771 WHERE "trustee_id" = "member_id_p"
2772 AND "issue_id" = "issue_id_p"
2773 LOOP
2774 IF NOT EXISTS (
2775 SELECT NULL FROM "direct_population_snapshot"
2776 WHERE "issue_id" = "issue_id_p"
2777 AND "event" = 'periodic'
2778 AND "member_id" = "issue_delegation_row"."truster_id"
2779 ) AND NOT EXISTS (
2780 SELECT NULL FROM "delegating_population_snapshot"
2781 WHERE "issue_id" = "issue_id_p"
2782 AND "event" = 'periodic'
2783 AND "member_id" = "issue_delegation_row"."truster_id"
2784 ) THEN
2785 "delegate_member_ids_v" :=
2786 "member_id_p" || "delegate_member_ids_p";
2787 INSERT INTO "delegating_population_snapshot" (
2788 "issue_id",
2789 "event",
2790 "member_id",
2791 "scope",
2792 "delegate_member_ids"
2793 ) VALUES (
2794 "issue_id_p",
2795 'periodic',
2796 "issue_delegation_row"."truster_id",
2797 "issue_delegation_row"."scope",
2798 "delegate_member_ids_v"
2799 );
2800 "sub_weight_v" := 1 +
2801 "weight_of_added_delegations_for_population_snapshot"(
2802 "issue_id_p",
2803 "issue_delegation_row"."truster_id",
2804 "delegate_member_ids_v"
2805 );
2806 UPDATE "delegating_population_snapshot"
2807 SET "weight" = "sub_weight_v"
2808 WHERE "issue_id" = "issue_id_p"
2809 AND "event" = 'periodic'
2810 AND "member_id" = "issue_delegation_row"."truster_id";
2811 "weight_v" := "weight_v" + "sub_weight_v";
2812 END IF;
2813 END LOOP;
2814 RETURN "weight_v";
2815 END;
2816 $$;
2818 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2819 ( "issue"."id"%TYPE,
2820 "member"."id"%TYPE,
2821 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2822 IS 'Helper function for "create_population_snapshot" function';
2825 CREATE FUNCTION "create_population_snapshot"
2826 ( "issue_id_p" "issue"."id"%TYPE )
2827 RETURNS VOID
2828 LANGUAGE 'plpgsql' VOLATILE AS $$
2829 DECLARE
2830 "member_id_v" "member"."id"%TYPE;
2831 BEGIN
2832 DELETE FROM "direct_population_snapshot"
2833 WHERE "issue_id" = "issue_id_p"
2834 AND "event" = 'periodic';
2835 DELETE FROM "delegating_population_snapshot"
2836 WHERE "issue_id" = "issue_id_p"
2837 AND "event" = 'periodic';
2838 INSERT INTO "direct_population_snapshot"
2839 ("issue_id", "event", "member_id")
2840 SELECT
2841 "issue_id_p" AS "issue_id",
2842 'periodic'::"snapshot_event" AS "event",
2843 "member"."id" AS "member_id"
2844 FROM "issue"
2845 JOIN "area" ON "issue"."area_id" = "area"."id"
2846 JOIN "membership" ON "area"."id" = "membership"."area_id"
2847 JOIN "member" ON "membership"."member_id" = "member"."id"
2848 JOIN "privilege"
2849 ON "privilege"."unit_id" = "area"."unit_id"
2850 AND "privilege"."member_id" = "member"."id"
2851 WHERE "issue"."id" = "issue_id_p"
2852 AND "member"."active" AND "privilege"."voting_right"
2853 UNION
2854 SELECT
2855 "issue_id_p" AS "issue_id",
2856 'periodic'::"snapshot_event" AS "event",
2857 "member"."id" AS "member_id"
2858 FROM "issue"
2859 JOIN "area" ON "issue"."area_id" = "area"."id"
2860 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2861 JOIN "member" ON "interest"."member_id" = "member"."id"
2862 JOIN "privilege"
2863 ON "privilege"."unit_id" = "area"."unit_id"
2864 AND "privilege"."member_id" = "member"."id"
2865 WHERE "issue"."id" = "issue_id_p"
2866 AND "member"."active" AND "privilege"."voting_right";
2867 FOR "member_id_v" IN
2868 SELECT "member_id" FROM "direct_population_snapshot"
2869 WHERE "issue_id" = "issue_id_p"
2870 AND "event" = 'periodic'
2871 LOOP
2872 UPDATE "direct_population_snapshot" SET
2873 "weight" = 1 +
2874 "weight_of_added_delegations_for_population_snapshot"(
2875 "issue_id_p",
2876 "member_id_v",
2877 '{}'
2879 WHERE "issue_id" = "issue_id_p"
2880 AND "event" = 'periodic'
2881 AND "member_id" = "member_id_v";
2882 END LOOP;
2883 RETURN;
2884 END;
2885 $$;
2887 COMMENT ON FUNCTION "create_population_snapshot"
2888 ( "issue"."id"%TYPE )
2889 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.';
2892 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2893 ( "issue_id_p" "issue"."id"%TYPE,
2894 "member_id_p" "member"."id"%TYPE,
2895 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2896 RETURNS "direct_interest_snapshot"."weight"%TYPE
2897 LANGUAGE 'plpgsql' VOLATILE AS $$
2898 DECLARE
2899 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2900 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2901 "weight_v" INT4;
2902 "sub_weight_v" INT4;
2903 BEGIN
2904 "weight_v" := 0;
2905 FOR "issue_delegation_row" IN
2906 SELECT * FROM "issue_delegation"
2907 WHERE "trustee_id" = "member_id_p"
2908 AND "issue_id" = "issue_id_p"
2909 LOOP
2910 IF NOT EXISTS (
2911 SELECT NULL FROM "direct_interest_snapshot"
2912 WHERE "issue_id" = "issue_id_p"
2913 AND "event" = 'periodic'
2914 AND "member_id" = "issue_delegation_row"."truster_id"
2915 ) AND NOT EXISTS (
2916 SELECT NULL FROM "delegating_interest_snapshot"
2917 WHERE "issue_id" = "issue_id_p"
2918 AND "event" = 'periodic'
2919 AND "member_id" = "issue_delegation_row"."truster_id"
2920 ) THEN
2921 "delegate_member_ids_v" :=
2922 "member_id_p" || "delegate_member_ids_p";
2923 INSERT INTO "delegating_interest_snapshot" (
2924 "issue_id",
2925 "event",
2926 "member_id",
2927 "scope",
2928 "delegate_member_ids"
2929 ) VALUES (
2930 "issue_id_p",
2931 'periodic',
2932 "issue_delegation_row"."truster_id",
2933 "issue_delegation_row"."scope",
2934 "delegate_member_ids_v"
2935 );
2936 "sub_weight_v" := 1 +
2937 "weight_of_added_delegations_for_interest_snapshot"(
2938 "issue_id_p",
2939 "issue_delegation_row"."truster_id",
2940 "delegate_member_ids_v"
2941 );
2942 UPDATE "delegating_interest_snapshot"
2943 SET "weight" = "sub_weight_v"
2944 WHERE "issue_id" = "issue_id_p"
2945 AND "event" = 'periodic'
2946 AND "member_id" = "issue_delegation_row"."truster_id";
2947 "weight_v" := "weight_v" + "sub_weight_v";
2948 END IF;
2949 END LOOP;
2950 RETURN "weight_v";
2951 END;
2952 $$;
2954 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2955 ( "issue"."id"%TYPE,
2956 "member"."id"%TYPE,
2957 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2958 IS 'Helper function for "create_interest_snapshot" function';
2961 CREATE FUNCTION "create_interest_snapshot"
2962 ( "issue_id_p" "issue"."id"%TYPE )
2963 RETURNS VOID
2964 LANGUAGE 'plpgsql' VOLATILE AS $$
2965 DECLARE
2966 "member_id_v" "member"."id"%TYPE;
2967 BEGIN
2968 DELETE FROM "direct_interest_snapshot"
2969 WHERE "issue_id" = "issue_id_p"
2970 AND "event" = 'periodic';
2971 DELETE FROM "delegating_interest_snapshot"
2972 WHERE "issue_id" = "issue_id_p"
2973 AND "event" = 'periodic';
2974 DELETE FROM "direct_supporter_snapshot"
2975 WHERE "issue_id" = "issue_id_p"
2976 AND "event" = 'periodic';
2977 INSERT INTO "direct_interest_snapshot"
2978 ("issue_id", "event", "member_id")
2979 SELECT
2980 "issue_id_p" AS "issue_id",
2981 'periodic' AS "event",
2982 "member"."id" AS "member_id"
2983 FROM "issue"
2984 JOIN "area" ON "issue"."area_id" = "area"."id"
2985 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2986 JOIN "member" ON "interest"."member_id" = "member"."id"
2987 JOIN "privilege"
2988 ON "privilege"."unit_id" = "area"."unit_id"
2989 AND "privilege"."member_id" = "member"."id"
2990 WHERE "issue"."id" = "issue_id_p"
2991 AND "member"."active" AND "privilege"."voting_right";
2992 FOR "member_id_v" IN
2993 SELECT "member_id" FROM "direct_interest_snapshot"
2994 WHERE "issue_id" = "issue_id_p"
2995 AND "event" = 'periodic'
2996 LOOP
2997 UPDATE "direct_interest_snapshot" SET
2998 "weight" = 1 +
2999 "weight_of_added_delegations_for_interest_snapshot"(
3000 "issue_id_p",
3001 "member_id_v",
3002 '{}'
3004 WHERE "issue_id" = "issue_id_p"
3005 AND "event" = 'periodic'
3006 AND "member_id" = "member_id_v";
3007 END LOOP;
3008 INSERT INTO "direct_supporter_snapshot"
3009 ( "issue_id", "initiative_id", "event", "member_id",
3010 "informed", "satisfied" )
3011 SELECT
3012 "issue_id_p" AS "issue_id",
3013 "initiative"."id" AS "initiative_id",
3014 'periodic' AS "event",
3015 "supporter"."member_id" AS "member_id",
3016 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3017 NOT EXISTS (
3018 SELECT NULL FROM "critical_opinion"
3019 WHERE "initiative_id" = "initiative"."id"
3020 AND "member_id" = "supporter"."member_id"
3021 ) AS "satisfied"
3022 FROM "initiative"
3023 JOIN "supporter"
3024 ON "supporter"."initiative_id" = "initiative"."id"
3025 JOIN "current_draft"
3026 ON "initiative"."id" = "current_draft"."initiative_id"
3027 JOIN "direct_interest_snapshot"
3028 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3029 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3030 AND "event" = 'periodic'
3031 WHERE "initiative"."issue_id" = "issue_id_p";
3032 RETURN;
3033 END;
3034 $$;
3036 COMMENT ON FUNCTION "create_interest_snapshot"
3037 ( "issue"."id"%TYPE )
3038 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.';
3041 CREATE FUNCTION "create_snapshot"
3042 ( "issue_id_p" "issue"."id"%TYPE )
3043 RETURNS VOID
3044 LANGUAGE 'plpgsql' VOLATILE AS $$
3045 DECLARE
3046 "initiative_id_v" "initiative"."id"%TYPE;
3047 "suggestion_id_v" "suggestion"."id"%TYPE;
3048 BEGIN
3049 PERFORM "lock_issue"("issue_id_p");
3050 PERFORM "create_population_snapshot"("issue_id_p");
3051 PERFORM "create_interest_snapshot"("issue_id_p");
3052 UPDATE "issue" SET
3053 "snapshot" = now(),
3054 "latest_snapshot_event" = 'periodic',
3055 "population" = (
3056 SELECT coalesce(sum("weight"), 0)
3057 FROM "direct_population_snapshot"
3058 WHERE "issue_id" = "issue_id_p"
3059 AND "event" = 'periodic'
3061 WHERE "id" = "issue_id_p";
3062 FOR "initiative_id_v" IN
3063 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3064 LOOP
3065 UPDATE "initiative" SET
3066 "supporter_count" = (
3067 SELECT coalesce(sum("di"."weight"), 0)
3068 FROM "direct_interest_snapshot" AS "di"
3069 JOIN "direct_supporter_snapshot" AS "ds"
3070 ON "di"."member_id" = "ds"."member_id"
3071 WHERE "di"."issue_id" = "issue_id_p"
3072 AND "di"."event" = 'periodic'
3073 AND "ds"."initiative_id" = "initiative_id_v"
3074 AND "ds"."event" = 'periodic'
3075 ),
3076 "informed_supporter_count" = (
3077 SELECT coalesce(sum("di"."weight"), 0)
3078 FROM "direct_interest_snapshot" AS "di"
3079 JOIN "direct_supporter_snapshot" AS "ds"
3080 ON "di"."member_id" = "ds"."member_id"
3081 WHERE "di"."issue_id" = "issue_id_p"
3082 AND "di"."event" = 'periodic'
3083 AND "ds"."initiative_id" = "initiative_id_v"
3084 AND "ds"."event" = 'periodic'
3085 AND "ds"."informed"
3086 ),
3087 "satisfied_supporter_count" = (
3088 SELECT coalesce(sum("di"."weight"), 0)
3089 FROM "direct_interest_snapshot" AS "di"
3090 JOIN "direct_supporter_snapshot" AS "ds"
3091 ON "di"."member_id" = "ds"."member_id"
3092 WHERE "di"."issue_id" = "issue_id_p"
3093 AND "di"."event" = 'periodic'
3094 AND "ds"."initiative_id" = "initiative_id_v"
3095 AND "ds"."event" = 'periodic'
3096 AND "ds"."satisfied"
3097 ),
3098 "satisfied_informed_supporter_count" = (
3099 SELECT coalesce(sum("di"."weight"), 0)
3100 FROM "direct_interest_snapshot" AS "di"
3101 JOIN "direct_supporter_snapshot" AS "ds"
3102 ON "di"."member_id" = "ds"."member_id"
3103 WHERE "di"."issue_id" = "issue_id_p"
3104 AND "di"."event" = 'periodic'
3105 AND "ds"."initiative_id" = "initiative_id_v"
3106 AND "ds"."event" = 'periodic'
3107 AND "ds"."informed"
3108 AND "ds"."satisfied"
3110 WHERE "id" = "initiative_id_v";
3111 FOR "suggestion_id_v" IN
3112 SELECT "id" FROM "suggestion"
3113 WHERE "initiative_id" = "initiative_id_v"
3114 LOOP
3115 UPDATE "suggestion" SET
3116 "minus2_unfulfilled_count" = (
3117 SELECT coalesce(sum("snapshot"."weight"), 0)
3118 FROM "issue" CROSS JOIN "opinion"
3119 JOIN "direct_interest_snapshot" AS "snapshot"
3120 ON "snapshot"."issue_id" = "issue"."id"
3121 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3122 AND "snapshot"."member_id" = "opinion"."member_id"
3123 WHERE "issue"."id" = "issue_id_p"
3124 AND "opinion"."suggestion_id" = "suggestion_id_v"
3125 AND "opinion"."degree" = -2
3126 AND "opinion"."fulfilled" = FALSE
3127 ),
3128 "minus2_fulfilled_count" = (
3129 SELECT coalesce(sum("snapshot"."weight"), 0)
3130 FROM "issue" CROSS JOIN "opinion"
3131 JOIN "direct_interest_snapshot" AS "snapshot"
3132 ON "snapshot"."issue_id" = "issue"."id"
3133 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3134 AND "snapshot"."member_id" = "opinion"."member_id"
3135 WHERE "issue"."id" = "issue_id_p"
3136 AND "opinion"."suggestion_id" = "suggestion_id_v"
3137 AND "opinion"."degree" = -2
3138 AND "opinion"."fulfilled" = TRUE
3139 ),
3140 "minus1_unfulfilled_count" = (
3141 SELECT coalesce(sum("snapshot"."weight"), 0)
3142 FROM "issue" CROSS JOIN "opinion"
3143 JOIN "direct_interest_snapshot" AS "snapshot"
3144 ON "snapshot"."issue_id" = "issue"."id"
3145 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3146 AND "snapshot"."member_id" = "opinion"."member_id"
3147 WHERE "issue"."id" = "issue_id_p"
3148 AND "opinion"."suggestion_id" = "suggestion_id_v"
3149 AND "opinion"."degree" = -1
3150 AND "opinion"."fulfilled" = FALSE
3151 ),
3152 "minus1_fulfilled_count" = (
3153 SELECT coalesce(sum("snapshot"."weight"), 0)
3154 FROM "issue" CROSS JOIN "opinion"
3155 JOIN "direct_interest_snapshot" AS "snapshot"
3156 ON "snapshot"."issue_id" = "issue"."id"
3157 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3158 AND "snapshot"."member_id" = "opinion"."member_id"
3159 WHERE "issue"."id" = "issue_id_p"
3160 AND "opinion"."suggestion_id" = "suggestion_id_v"
3161 AND "opinion"."degree" = -1
3162 AND "opinion"."fulfilled" = TRUE
3163 ),
3164 "plus1_unfulfilled_count" = (
3165 SELECT coalesce(sum("snapshot"."weight"), 0)
3166 FROM "issue" CROSS JOIN "opinion"
3167 JOIN "direct_interest_snapshot" AS "snapshot"
3168 ON "snapshot"."issue_id" = "issue"."id"
3169 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3170 AND "snapshot"."member_id" = "opinion"."member_id"
3171 WHERE "issue"."id" = "issue_id_p"
3172 AND "opinion"."suggestion_id" = "suggestion_id_v"
3173 AND "opinion"."degree" = 1
3174 AND "opinion"."fulfilled" = FALSE
3175 ),
3176 "plus1_fulfilled_count" = (
3177 SELECT coalesce(sum("snapshot"."weight"), 0)
3178 FROM "issue" CROSS JOIN "opinion"
3179 JOIN "direct_interest_snapshot" AS "snapshot"
3180 ON "snapshot"."issue_id" = "issue"."id"
3181 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3182 AND "snapshot"."member_id" = "opinion"."member_id"
3183 WHERE "issue"."id" = "issue_id_p"
3184 AND "opinion"."suggestion_id" = "suggestion_id_v"
3185 AND "opinion"."degree" = 1
3186 AND "opinion"."fulfilled" = TRUE
3187 ),
3188 "plus2_unfulfilled_count" = (
3189 SELECT coalesce(sum("snapshot"."weight"), 0)
3190 FROM "issue" CROSS JOIN "opinion"
3191 JOIN "direct_interest_snapshot" AS "snapshot"
3192 ON "snapshot"."issue_id" = "issue"."id"
3193 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3194 AND "snapshot"."member_id" = "opinion"."member_id"
3195 WHERE "issue"."id" = "issue_id_p"
3196 AND "opinion"."suggestion_id" = "suggestion_id_v"
3197 AND "opinion"."degree" = 2
3198 AND "opinion"."fulfilled" = FALSE
3199 ),
3200 "plus2_fulfilled_count" = (
3201 SELECT coalesce(sum("snapshot"."weight"), 0)
3202 FROM "issue" CROSS JOIN "opinion"
3203 JOIN "direct_interest_snapshot" AS "snapshot"
3204 ON "snapshot"."issue_id" = "issue"."id"
3205 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3206 AND "snapshot"."member_id" = "opinion"."member_id"
3207 WHERE "issue"."id" = "issue_id_p"
3208 AND "opinion"."suggestion_id" = "suggestion_id_v"
3209 AND "opinion"."degree" = 2
3210 AND "opinion"."fulfilled" = TRUE
3212 WHERE "suggestion"."id" = "suggestion_id_v";
3213 END LOOP;
3214 END LOOP;
3215 RETURN;
3216 END;
3217 $$;
3219 COMMENT ON FUNCTION "create_snapshot"
3220 ( "issue"."id"%TYPE )
3221 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.';
3224 CREATE FUNCTION "set_snapshot_event"
3225 ( "issue_id_p" "issue"."id"%TYPE,
3226 "event_p" "snapshot_event" )
3227 RETURNS VOID
3228 LANGUAGE 'plpgsql' VOLATILE AS $$
3229 DECLARE
3230 "event_v" "issue"."latest_snapshot_event"%TYPE;
3231 BEGIN
3232 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3233 WHERE "id" = "issue_id_p" FOR UPDATE;
3234 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3235 WHERE "id" = "issue_id_p";
3236 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3237 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3238 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3239 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3240 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3241 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3242 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3243 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3244 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3245 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3246 RETURN;
3247 END;
3248 $$;
3250 COMMENT ON FUNCTION "set_snapshot_event"
3251 ( "issue"."id"%TYPE,
3252 "snapshot_event" )
3253 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3257 ---------------------
3258 -- Freezing issues --
3259 ---------------------
3261 CREATE FUNCTION "freeze_after_snapshot"
3262 ( "issue_id_p" "issue"."id"%TYPE )
3263 RETURNS VOID
3264 LANGUAGE 'plpgsql' VOLATILE AS $$
3265 DECLARE
3266 "issue_row" "issue"%ROWTYPE;
3267 "policy_row" "policy"%ROWTYPE;
3268 "initiative_row" "initiative"%ROWTYPE;
3269 BEGIN
3270 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3271 SELECT * INTO "policy_row"
3272 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3273 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3274 FOR "initiative_row" IN
3275 SELECT * FROM "initiative"
3276 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3277 LOOP
3278 IF
3279 "initiative_row"."satisfied_supporter_count" > 0 AND
3280 "initiative_row"."satisfied_supporter_count" *
3281 "policy_row"."initiative_quorum_den" >=
3282 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3283 THEN
3284 UPDATE "initiative" SET "admitted" = TRUE
3285 WHERE "id" = "initiative_row"."id";
3286 ELSE
3287 UPDATE "initiative" SET "admitted" = FALSE
3288 WHERE "id" = "initiative_row"."id";
3289 END IF;
3290 END LOOP;
3291 IF EXISTS (
3292 SELECT NULL FROM "initiative"
3293 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3294 ) THEN
3295 UPDATE "issue" SET
3296 "state" = 'voting',
3297 "accepted" = coalesce("accepted", now()),
3298 "half_frozen" = coalesce("half_frozen", now()),
3299 "fully_frozen" = now()
3300 WHERE "id" = "issue_id_p";
3301 ELSE
3302 UPDATE "issue" SET
3303 "state" = 'canceled_no_initiative_admitted',
3304 "accepted" = coalesce("accepted", now()),
3305 "half_frozen" = coalesce("half_frozen", now()),
3306 "fully_frozen" = now(),
3307 "closed" = now(),
3308 "ranks_available" = TRUE
3309 WHERE "id" = "issue_id_p";
3310 -- NOTE: The following DELETE statements have effect only when
3311 -- issue state has been manipulated
3312 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3313 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3314 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3315 END IF;
3316 RETURN;
3317 END;
3318 $$;
3320 COMMENT ON FUNCTION "freeze_after_snapshot"
3321 ( "issue"."id"%TYPE )
3322 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3325 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3326 RETURNS VOID
3327 LANGUAGE 'plpgsql' VOLATILE AS $$
3328 DECLARE
3329 "issue_row" "issue"%ROWTYPE;
3330 BEGIN
3331 PERFORM "create_snapshot"("issue_id_p");
3332 PERFORM "freeze_after_snapshot"("issue_id_p");
3333 RETURN;
3334 END;
3335 $$;
3337 COMMENT ON FUNCTION "manual_freeze"
3338 ( "issue"."id"%TYPE )
3339 IS 'Freeze an issue manually (fully) and start voting';
3343 -----------------------
3344 -- Counting of votes --
3345 -----------------------
3348 CREATE FUNCTION "weight_of_added_vote_delegations"
3349 ( "issue_id_p" "issue"."id"%TYPE,
3350 "member_id_p" "member"."id"%TYPE,
3351 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3352 RETURNS "direct_voter"."weight"%TYPE
3353 LANGUAGE 'plpgsql' VOLATILE AS $$
3354 DECLARE
3355 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3356 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3357 "weight_v" INT4;
3358 "sub_weight_v" INT4;
3359 BEGIN
3360 "weight_v" := 0;
3361 FOR "issue_delegation_row" IN
3362 SELECT * FROM "issue_delegation"
3363 WHERE "trustee_id" = "member_id_p"
3364 AND "issue_id" = "issue_id_p"
3365 LOOP
3366 IF NOT EXISTS (
3367 SELECT NULL FROM "direct_voter"
3368 WHERE "member_id" = "issue_delegation_row"."truster_id"
3369 AND "issue_id" = "issue_id_p"
3370 ) AND NOT EXISTS (
3371 SELECT NULL FROM "delegating_voter"
3372 WHERE "member_id" = "issue_delegation_row"."truster_id"
3373 AND "issue_id" = "issue_id_p"
3374 ) THEN
3375 "delegate_member_ids_v" :=
3376 "member_id_p" || "delegate_member_ids_p";
3377 INSERT INTO "delegating_voter" (
3378 "issue_id",
3379 "member_id",
3380 "scope",
3381 "delegate_member_ids"
3382 ) VALUES (
3383 "issue_id_p",
3384 "issue_delegation_row"."truster_id",
3385 "issue_delegation_row"."scope",
3386 "delegate_member_ids_v"
3387 );
3388 "sub_weight_v" := 1 +
3389 "weight_of_added_vote_delegations"(
3390 "issue_id_p",
3391 "issue_delegation_row"."truster_id",
3392 "delegate_member_ids_v"
3393 );
3394 UPDATE "delegating_voter"
3395 SET "weight" = "sub_weight_v"
3396 WHERE "issue_id" = "issue_id_p"
3397 AND "member_id" = "issue_delegation_row"."truster_id";
3398 "weight_v" := "weight_v" + "sub_weight_v";
3399 END IF;
3400 END LOOP;
3401 RETURN "weight_v";
3402 END;
3403 $$;
3405 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3406 ( "issue"."id"%TYPE,
3407 "member"."id"%TYPE,
3408 "delegating_voter"."delegate_member_ids"%TYPE )
3409 IS 'Helper function for "add_vote_delegations" function';
3412 CREATE FUNCTION "add_vote_delegations"
3413 ( "issue_id_p" "issue"."id"%TYPE )
3414 RETURNS VOID
3415 LANGUAGE 'plpgsql' VOLATILE AS $$
3416 DECLARE
3417 "member_id_v" "member"."id"%TYPE;
3418 BEGIN
3419 FOR "member_id_v" IN
3420 SELECT "member_id" FROM "direct_voter"
3421 WHERE "issue_id" = "issue_id_p"
3422 LOOP
3423 UPDATE "direct_voter" SET
3424 "weight" = "weight" + "weight_of_added_vote_delegations"(
3425 "issue_id_p",
3426 "member_id_v",
3427 '{}'
3429 WHERE "member_id" = "member_id_v"
3430 AND "issue_id" = "issue_id_p";
3431 END LOOP;
3432 RETURN;
3433 END;
3434 $$;
3436 COMMENT ON FUNCTION "add_vote_delegations"
3437 ( "issue_id_p" "issue"."id"%TYPE )
3438 IS 'Helper function for "close_voting" function';
3441 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3442 RETURNS VOID
3443 LANGUAGE 'plpgsql' VOLATILE AS $$
3444 DECLARE
3445 "area_id_v" "area"."id"%TYPE;
3446 "unit_id_v" "unit"."id"%TYPE;
3447 "member_id_v" "member"."id"%TYPE;
3448 BEGIN
3449 PERFORM "lock_issue"("issue_id_p");
3450 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3451 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3452 -- delete delegating votes (in cases of manual reset of issue state):
3453 DELETE FROM "delegating_voter"
3454 WHERE "issue_id" = "issue_id_p";
3455 -- delete votes from non-privileged voters:
3456 DELETE FROM "direct_voter"
3457 USING (
3458 SELECT
3459 "direct_voter"."member_id"
3460 FROM "direct_voter"
3461 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3462 LEFT JOIN "privilege"
3463 ON "privilege"."unit_id" = "unit_id_v"
3464 AND "privilege"."member_id" = "direct_voter"."member_id"
3465 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3466 "member"."active" = FALSE OR
3467 "privilege"."voting_right" ISNULL OR
3468 "privilege"."voting_right" = FALSE
3470 ) AS "subquery"
3471 WHERE "direct_voter"."issue_id" = "issue_id_p"
3472 AND "direct_voter"."member_id" = "subquery"."member_id";
3473 -- consider delegations:
3474 UPDATE "direct_voter" SET "weight" = 1
3475 WHERE "issue_id" = "issue_id_p";
3476 PERFORM "add_vote_delegations"("issue_id_p");
3477 -- set voter count and mark issue as being calculated:
3478 UPDATE "issue" SET
3479 "state" = 'calculation',
3480 "closed" = now(),
3481 "voter_count" = (
3482 SELECT coalesce(sum("weight"), 0)
3483 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3485 WHERE "id" = "issue_id_p";
3486 -- materialize battle_view:
3487 -- NOTE: "closed" column of issue must be set at this point
3488 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3489 INSERT INTO "battle" (
3490 "issue_id",
3491 "winning_initiative_id", "losing_initiative_id",
3492 "count"
3493 ) SELECT
3494 "issue_id",
3495 "winning_initiative_id", "losing_initiative_id",
3496 "count"
3497 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3498 -- copy "positive_votes" and "negative_votes" from "battle" table:
3499 UPDATE "initiative" SET
3500 "positive_votes" = "battle_win"."count",
3501 "negative_votes" = "battle_lose"."count"
3502 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3503 WHERE
3504 "battle_win"."issue_id" = "issue_id_p" AND
3505 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3506 "battle_win"."losing_initiative_id" ISNULL AND
3507 "battle_lose"."issue_id" = "issue_id_p" AND
3508 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3509 "battle_lose"."winning_initiative_id" ISNULL;
3510 END;
3511 $$;
3513 COMMENT ON FUNCTION "close_voting"
3514 ( "issue"."id"%TYPE )
3515 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.';
3518 CREATE FUNCTION "defeat_strength"
3519 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3520 RETURNS INT8
3521 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3522 BEGIN
3523 IF "positive_votes_p" > "negative_votes_p" THEN
3524 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3525 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3526 RETURN 0;
3527 ELSE
3528 RETURN -1;
3529 END IF;
3530 END;
3531 $$;
3533 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';
3536 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3537 RETURNS VOID
3538 LANGUAGE 'plpgsql' VOLATILE AS $$
3539 DECLARE
3540 "issue_row" "issue"%ROWTYPE;
3541 "policy_row" "policy"%ROWTYPE;
3542 "dimension_v" INTEGER;
3543 "vote_matrix" INT4[][]; -- absolute votes
3544 "matrix" INT8[][]; -- defeat strength / best paths
3545 "i" INTEGER;
3546 "j" INTEGER;
3547 "k" INTEGER;
3548 "battle_row" "battle"%ROWTYPE;
3549 "rank_ary" INT4[];
3550 "rank_v" INT4;
3551 "done_v" INTEGER;
3552 "winners_ary" INTEGER[];
3553 "initiative_id_v" "initiative"."id"%TYPE;
3554 BEGIN
3555 SELECT * INTO "issue_row"
3556 FROM "issue" WHERE "id" = "issue_id_p"
3557 FOR UPDATE;
3558 SELECT * INTO "policy_row"
3559 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3560 SELECT count(1) INTO "dimension_v"
3561 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3562 -- Create "vote_matrix" with absolute number of votes in pairwise
3563 -- comparison:
3564 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3565 "i" := 1;
3566 "j" := 2;
3567 FOR "battle_row" IN
3568 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3569 ORDER BY
3570 "winning_initiative_id" NULLS LAST,
3571 "losing_initiative_id" NULLS LAST
3572 LOOP
3573 "vote_matrix"["i"]["j"] := "battle_row"."count";
3574 IF "j" = "dimension_v" THEN
3575 "i" := "i" + 1;
3576 "j" := 1;
3577 ELSE
3578 "j" := "j" + 1;
3579 IF "j" = "i" THEN
3580 "j" := "j" + 1;
3581 END IF;
3582 END IF;
3583 END LOOP;
3584 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3585 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3586 END IF;
3587 -- Store defeat strengths in "matrix" using "defeat_strength"
3588 -- function:
3589 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3590 "i" := 1;
3591 LOOP
3592 "j" := 1;
3593 LOOP
3594 IF "i" != "j" THEN
3595 "matrix"["i"]["j"] := "defeat_strength"(
3596 "vote_matrix"["i"]["j"],
3597 "vote_matrix"["j"]["i"]
3598 );
3599 END IF;
3600 EXIT WHEN "j" = "dimension_v";
3601 "j" := "j" + 1;
3602 END LOOP;
3603 EXIT WHEN "i" = "dimension_v";
3604 "i" := "i" + 1;
3605 END LOOP;
3606 -- Find best paths:
3607 "i" := 1;
3608 LOOP
3609 "j" := 1;
3610 LOOP
3611 IF "i" != "j" THEN
3612 "k" := 1;
3613 LOOP
3614 IF "i" != "k" AND "j" != "k" THEN
3615 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3616 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3617 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3618 END IF;
3619 ELSE
3620 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3621 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3622 END IF;
3623 END IF;
3624 END IF;
3625 EXIT WHEN "k" = "dimension_v";
3626 "k" := "k" + 1;
3627 END LOOP;
3628 END IF;
3629 EXIT WHEN "j" = "dimension_v";
3630 "j" := "j" + 1;
3631 END LOOP;
3632 EXIT WHEN "i" = "dimension_v";
3633 "i" := "i" + 1;
3634 END LOOP;
3635 -- Determine order of winners:
3636 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3637 "rank_v" := 1;
3638 "done_v" := 0;
3639 LOOP
3640 "winners_ary" := '{}';
3641 "i" := 1;
3642 LOOP
3643 IF "rank_ary"["i"] ISNULL THEN
3644 "j" := 1;
3645 LOOP
3646 IF
3647 "i" != "j" AND
3648 "rank_ary"["j"] ISNULL AND
3649 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3650 THEN
3651 -- someone else is better
3652 EXIT;
3653 END IF;
3654 IF "j" = "dimension_v" THEN
3655 -- noone is better
3656 "winners_ary" := "winners_ary" || "i";
3657 EXIT;
3658 END IF;
3659 "j" := "j" + 1;
3660 END LOOP;
3661 END IF;
3662 EXIT WHEN "i" = "dimension_v";
3663 "i" := "i" + 1;
3664 END LOOP;
3665 "i" := 1;
3666 LOOP
3667 "rank_ary"["winners_ary"["i"]] := "rank_v";
3668 "done_v" := "done_v" + 1;
3669 EXIT WHEN "i" = array_upper("winners_ary", 1);
3670 "i" := "i" + 1;
3671 END LOOP;
3672 EXIT WHEN "done_v" = "dimension_v";
3673 "rank_v" := "rank_v" + 1;
3674 END LOOP;
3675 -- write preliminary results:
3676 "i" := 1;
3677 FOR "initiative_id_v" IN
3678 SELECT "id" FROM "initiative"
3679 WHERE "issue_id" = "issue_id_p" AND "admitted"
3680 ORDER BY "id"
3681 LOOP
3682 UPDATE "initiative" SET
3683 "direct_majority" =
3684 CASE WHEN "policy_row"."direct_majority_strict" THEN
3685 "positive_votes" * "policy_row"."direct_majority_den" >
3686 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3687 ELSE
3688 "positive_votes" * "policy_row"."direct_majority_den" >=
3689 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3690 END
3691 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3692 AND "issue_row"."voter_count"-"negative_votes" >=
3693 "policy_row"."direct_majority_non_negative",
3694 "indirect_majority" =
3695 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3696 "positive_votes" * "policy_row"."indirect_majority_den" >
3697 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3698 ELSE
3699 "positive_votes" * "policy_row"."indirect_majority_den" >=
3700 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3701 END
3702 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3703 AND "issue_row"."voter_count"-"negative_votes" >=
3704 "policy_row"."indirect_majority_non_negative",
3705 "schulze_rank" = "rank_ary"["i"],
3706 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3707 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3708 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3709 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3710 "winner" = FALSE
3711 WHERE "id" = "initiative_id_v";
3712 "i" := "i" + 1;
3713 END LOOP;
3714 IF "i" != "dimension_v" THEN
3715 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3716 END IF;
3717 -- take indirect majorities into account:
3718 LOOP
3719 UPDATE "initiative" SET "indirect_majority" = TRUE
3720 FROM (
3721 SELECT "new_initiative"."id" AS "initiative_id"
3722 FROM "initiative" "old_initiative"
3723 JOIN "initiative" "new_initiative"
3724 ON "new_initiative"."issue_id" = "issue_id_p"
3725 AND "new_initiative"."indirect_majority" = FALSE
3726 JOIN "battle" "battle_win"
3727 ON "battle_win"."issue_id" = "issue_id_p"
3728 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3729 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3730 JOIN "battle" "battle_lose"
3731 ON "battle_lose"."issue_id" = "issue_id_p"
3732 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3733 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3734 WHERE "old_initiative"."issue_id" = "issue_id_p"
3735 AND "old_initiative"."indirect_majority" = TRUE
3736 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3737 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3738 "policy_row"."indirect_majority_num" *
3739 ("battle_win"."count"+"battle_lose"."count")
3740 ELSE
3741 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3742 "policy_row"."indirect_majority_num" *
3743 ("battle_win"."count"+"battle_lose"."count")
3744 END
3745 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3746 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3747 "policy_row"."indirect_majority_non_negative"
3748 ) AS "subquery"
3749 WHERE "id" = "subquery"."initiative_id";
3750 EXIT WHEN NOT FOUND;
3751 END LOOP;
3752 -- set "multistage_majority" for remaining matching initiatives:
3753 UPDATE "initiative" SET "multistage_majority" = TRUE
3754 FROM (
3755 SELECT "losing_initiative"."id" AS "initiative_id"
3756 FROM "initiative" "losing_initiative"
3757 JOIN "initiative" "winning_initiative"
3758 ON "winning_initiative"."issue_id" = "issue_id_p"
3759 AND "winning_initiative"."admitted"
3760 JOIN "battle" "battle_win"
3761 ON "battle_win"."issue_id" = "issue_id_p"
3762 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3763 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3764 JOIN "battle" "battle_lose"
3765 ON "battle_lose"."issue_id" = "issue_id_p"
3766 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3767 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3768 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3769 AND "losing_initiative"."admitted"
3770 AND "winning_initiative"."schulze_rank" <
3771 "losing_initiative"."schulze_rank"
3772 AND "battle_win"."count" > "battle_lose"."count"
3773 AND (
3774 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3775 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3776 ) AS "subquery"
3777 WHERE "id" = "subquery"."initiative_id";
3778 -- mark eligible initiatives:
3779 UPDATE "initiative" SET "eligible" = TRUE
3780 WHERE "issue_id" = "issue_id_p"
3781 AND "initiative"."direct_majority"
3782 AND "initiative"."indirect_majority"
3783 AND "initiative"."better_than_status_quo"
3784 AND (
3785 "policy_row"."no_multistage_majority" = FALSE OR
3786 "initiative"."multistage_majority" = FALSE )
3787 AND (
3788 "policy_row"."no_reverse_beat_path" = FALSE OR
3789 "initiative"."reverse_beat_path" = FALSE );
3790 -- mark final winner:
3791 UPDATE "initiative" SET "winner" = TRUE
3792 FROM (
3793 SELECT "id" AS "initiative_id"
3794 FROM "initiative"
3795 WHERE "issue_id" = "issue_id_p" AND "eligible"
3796 ORDER BY "schulze_rank", "id"
3797 LIMIT 1
3798 ) AS "subquery"
3799 WHERE "id" = "subquery"."initiative_id";
3800 -- set schulze rank of status quo and mark issue as finished:
3801 UPDATE "issue" SET
3802 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
3803 "state" =
3804 CASE WHEN EXISTS (
3805 SELECT NULL FROM "initiative"
3806 WHERE "issue_id" = "issue_id_p" AND "winner"
3807 ) THEN
3808 'finished_with_winner'::"issue_state"
3809 ELSE
3810 'finished_without_winner'::"issue_state"
3811 END,
3812 "ranks_available" = TRUE
3813 WHERE "id" = "issue_id_p";
3814 RETURN;
3815 END;
3816 $$;
3818 COMMENT ON FUNCTION "calculate_ranks"
3819 ( "issue"."id"%TYPE )
3820 IS 'Determine ranking (Votes have to be counted first)';
3824 -----------------------------
3825 -- Automatic state changes --
3826 -----------------------------
3829 CREATE FUNCTION "check_issue"
3830 ( "issue_id_p" "issue"."id"%TYPE )
3831 RETURNS VOID
3832 LANGUAGE 'plpgsql' VOLATILE AS $$
3833 DECLARE
3834 "issue_row" "issue"%ROWTYPE;
3835 "policy_row" "policy"%ROWTYPE;
3836 BEGIN
3837 PERFORM "lock_issue"("issue_id_p");
3838 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3839 -- only process open issues:
3840 IF "issue_row"."closed" ISNULL THEN
3841 SELECT * INTO "policy_row" FROM "policy"
3842 WHERE "id" = "issue_row"."policy_id";
3843 -- create a snapshot, unless issue is already fully frozen:
3844 IF "issue_row"."fully_frozen" ISNULL THEN
3845 PERFORM "create_snapshot"("issue_id_p");
3846 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3847 END IF;
3848 -- eventually close or accept issues, which have not been accepted:
3849 IF "issue_row"."accepted" ISNULL THEN
3850 IF EXISTS (
3851 SELECT NULL FROM "initiative"
3852 WHERE "issue_id" = "issue_id_p"
3853 AND "supporter_count" > 0
3854 AND "supporter_count" * "policy_row"."issue_quorum_den"
3855 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3856 ) THEN
3857 -- accept issues, if supporter count is high enough
3858 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3859 -- NOTE: "issue_row" used later
3860 "issue_row"."state" := 'discussion';
3861 "issue_row"."accepted" := now();
3862 UPDATE "issue" SET
3863 "state" = "issue_row"."state",
3864 "accepted" = "issue_row"."accepted"
3865 WHERE "id" = "issue_row"."id";
3866 ELSIF
3867 now() >= "issue_row"."created" + "issue_row"."admission_time"
3868 THEN
3869 -- close issues, if admission time has expired
3870 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3871 UPDATE "issue" SET
3872 "state" = 'canceled_issue_not_accepted',
3873 "closed" = now()
3874 WHERE "id" = "issue_row"."id";
3875 END IF;
3876 END IF;
3877 -- eventually half freeze issues:
3878 IF
3879 -- NOTE: issue can't be closed at this point, if it has been accepted
3880 "issue_row"."accepted" NOTNULL AND
3881 "issue_row"."half_frozen" ISNULL
3882 THEN
3883 IF
3884 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3885 THEN
3886 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3887 -- NOTE: "issue_row" used later
3888 "issue_row"."state" := 'verification';
3889 "issue_row"."half_frozen" := now();
3890 UPDATE "issue" SET
3891 "state" = "issue_row"."state",
3892 "half_frozen" = "issue_row"."half_frozen"
3893 WHERE "id" = "issue_row"."id";
3894 END IF;
3895 END IF;
3896 -- close issues after some time, if all initiatives have been revoked:
3897 IF
3898 "issue_row"."closed" ISNULL AND
3899 NOT EXISTS (
3900 -- all initiatives are revoked
3901 SELECT NULL FROM "initiative"
3902 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3903 ) AND (
3904 -- and issue has not been accepted yet
3905 "issue_row"."accepted" ISNULL OR
3906 NOT EXISTS (
3907 -- or no initiatives have been revoked lately
3908 SELECT NULL FROM "initiative"
3909 WHERE "issue_id" = "issue_id_p"
3910 AND now() < "revoked" + "issue_row"."verification_time"
3911 ) OR (
3912 -- or verification time has elapsed
3913 "issue_row"."half_frozen" NOTNULL AND
3914 "issue_row"."fully_frozen" ISNULL AND
3915 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3918 THEN
3919 -- NOTE: "issue_row" used later
3920 IF "issue_row"."accepted" ISNULL THEN
3921 "issue_row"."state" := 'canceled_revoked_before_accepted';
3922 ELSIF "issue_row"."half_frozen" ISNULL THEN
3923 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
3924 ELSE
3925 "issue_row"."state" := 'canceled_after_revocation_during_verification';
3926 END IF;
3927 "issue_row"."closed" := now();
3928 UPDATE "issue" SET
3929 "state" = "issue_row"."state",
3930 "closed" = "issue_row"."closed"
3931 WHERE "id" = "issue_row"."id";
3932 END IF;
3933 -- fully freeze issue after verification time:
3934 IF
3935 "issue_row"."half_frozen" NOTNULL AND
3936 "issue_row"."fully_frozen" ISNULL AND
3937 "issue_row"."closed" ISNULL AND
3938 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3939 THEN
3940 PERFORM "freeze_after_snapshot"("issue_id_p");
3941 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
3942 END IF;
3943 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3944 -- close issue by calling close_voting(...) after voting time:
3945 IF
3946 "issue_row"."closed" ISNULL AND
3947 "issue_row"."fully_frozen" NOTNULL AND
3948 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
3949 THEN
3950 PERFORM "close_voting"("issue_id_p");
3951 -- calculate ranks will not consume much time and can be done now
3952 PERFORM "calculate_ranks"("issue_id_p");
3953 END IF;
3954 END IF;
3955 RETURN;
3956 END;
3957 $$;
3959 COMMENT ON FUNCTION "check_issue"
3960 ( "issue"."id"%TYPE )
3961 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.';
3964 CREATE FUNCTION "check_everything"()
3965 RETURNS VOID
3966 LANGUAGE 'plpgsql' VOLATILE AS $$
3967 DECLARE
3968 "issue_id_v" "issue"."id"%TYPE;
3969 BEGIN
3970 DELETE FROM "expired_session";
3971 PERFORM "check_last_login"();
3972 PERFORM "calculate_member_counts"();
3973 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
3974 PERFORM "check_issue"("issue_id_v");
3975 END LOOP;
3976 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
3977 PERFORM "calculate_ranks"("issue_id_v");
3978 END LOOP;
3979 RETURN;
3980 END;
3981 $$;
3983 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.';
3987 ----------------------
3988 -- Deletion of data --
3989 ----------------------
3992 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
3993 RETURNS VOID
3994 LANGUAGE 'plpgsql' VOLATILE AS $$
3995 DECLARE
3996 "issue_row" "issue"%ROWTYPE;
3997 BEGIN
3998 SELECT * INTO "issue_row"
3999 FROM "issue" WHERE "id" = "issue_id_p"
4000 FOR UPDATE;
4001 IF "issue_row"."cleaned" ISNULL THEN
4002 UPDATE "issue" SET
4003 "state" = 'voting',
4004 "closed" = NULL,
4005 "ranks_available" = FALSE
4006 WHERE "id" = "issue_id_p";
4007 DELETE FROM "issue_comment"
4008 WHERE "issue_id" = "issue_id_p";
4009 DELETE FROM "voting_comment"
4010 WHERE "issue_id" = "issue_id_p";
4011 DELETE FROM "delegating_voter"
4012 WHERE "issue_id" = "issue_id_p";
4013 DELETE FROM "direct_voter"
4014 WHERE "issue_id" = "issue_id_p";
4015 DELETE FROM "delegating_interest_snapshot"
4016 WHERE "issue_id" = "issue_id_p";
4017 DELETE FROM "direct_interest_snapshot"
4018 WHERE "issue_id" = "issue_id_p";
4019 DELETE FROM "delegating_population_snapshot"
4020 WHERE "issue_id" = "issue_id_p";
4021 DELETE FROM "direct_population_snapshot"
4022 WHERE "issue_id" = "issue_id_p";
4023 DELETE FROM "non_voter"
4024 WHERE "issue_id" = "issue_id_p";
4025 DELETE FROM "delegation"
4026 WHERE "issue_id" = "issue_id_p";
4027 DELETE FROM "supporter"
4028 WHERE "issue_id" = "issue_id_p";
4029 UPDATE "issue" SET
4030 "state" = "issue_row"."state",
4031 "closed" = "issue_row"."closed",
4032 "ranks_available" = "issue_row"."ranks_available",
4033 "cleaned" = now()
4034 WHERE "id" = "issue_id_p";
4035 END IF;
4036 RETURN;
4037 END;
4038 $$;
4040 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4043 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4044 RETURNS VOID
4045 LANGUAGE 'plpgsql' VOLATILE AS $$
4046 BEGIN
4047 UPDATE "member" SET
4048 "last_login" = NULL,
4049 "last_login_public" = NULL,
4050 "login" = NULL,
4051 "password" = NULL,
4052 "locked" = TRUE,
4053 "active" = FALSE,
4054 "notify_email" = NULL,
4055 "notify_email_unconfirmed" = NULL,
4056 "notify_email_secret" = NULL,
4057 "notify_email_secret_expiry" = NULL,
4058 "notify_email_lock_expiry" = NULL,
4059 "password_reset_secret" = NULL,
4060 "password_reset_secret_expiry" = NULL,
4061 "organizational_unit" = NULL,
4062 "internal_posts" = NULL,
4063 "realname" = NULL,
4064 "birthday" = NULL,
4065 "address" = NULL,
4066 "email" = NULL,
4067 "xmpp_address" = NULL,
4068 "website" = NULL,
4069 "phone" = NULL,
4070 "mobile_phone" = NULL,
4071 "profession" = NULL,
4072 "external_memberships" = NULL,
4073 "external_posts" = NULL,
4074 "statement" = NULL
4075 WHERE "id" = "member_id_p";
4076 -- "text_search_data" is updated by triggers
4077 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4078 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4079 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4080 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4081 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4082 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4083 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4084 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4085 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4086 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4087 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4088 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4089 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4090 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4091 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4092 DELETE FROM "direct_voter" USING "issue"
4093 WHERE "direct_voter"."issue_id" = "issue"."id"
4094 AND "issue"."closed" ISNULL
4095 AND "member_id" = "member_id_p";
4096 RETURN;
4097 END;
4098 $$;
4100 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)';
4103 CREATE FUNCTION "delete_private_data"()
4104 RETURNS VOID
4105 LANGUAGE 'plpgsql' VOLATILE AS $$
4106 BEGIN
4107 UPDATE "member" SET
4108 "last_login" = NULL,
4109 "login" = NULL,
4110 "password" = NULL,
4111 "notify_email" = NULL,
4112 "notify_email_unconfirmed" = NULL,
4113 "notify_email_secret" = NULL,
4114 "notify_email_secret_expiry" = NULL,
4115 "notify_email_lock_expiry" = NULL,
4116 "password_reset_secret" = NULL,
4117 "password_reset_secret_expiry" = NULL,
4118 "organizational_unit" = NULL,
4119 "internal_posts" = NULL,
4120 "realname" = NULL,
4121 "birthday" = NULL,
4122 "address" = NULL,
4123 "email" = NULL,
4124 "xmpp_address" = NULL,
4125 "website" = NULL,
4126 "phone" = NULL,
4127 "mobile_phone" = NULL,
4128 "profession" = NULL,
4129 "external_memberships" = NULL,
4130 "external_posts" = NULL,
4131 "statement" = NULL;
4132 -- "text_search_data" is updated by triggers
4133 DELETE FROM "invite_code";
4134 DELETE FROM "setting";
4135 DELETE FROM "setting_map";
4136 DELETE FROM "member_relation_setting";
4137 DELETE FROM "member_image";
4138 DELETE FROM "contact";
4139 DELETE FROM "ignored_member";
4140 DELETE FROM "session";
4141 DELETE FROM "area_setting";
4142 DELETE FROM "issue_setting";
4143 DELETE FROM "ignored_initiative";
4144 DELETE FROM "initiative_setting";
4145 DELETE FROM "suggestion_setting";
4146 DELETE FROM "non_voter";
4147 DELETE FROM "direct_voter" USING "issue"
4148 WHERE "direct_voter"."issue_id" = "issue"."id"
4149 AND "issue"."closed" ISNULL;
4150 RETURN;
4151 END;
4152 $$;
4154 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.';
4158 COMMIT;

Impressum / About Us