liquid_feedback_core

view core.sql @ 173:d8e11e6cfa1d

Added final "rank" column to table "initiative", which contains a unique order of all admitted initiatives
author jbe
date Tue Jun 07 20:42:50 2011 +0200 (2011-06-07)
parents b8426100fd2d
children 368fe2299d07
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 "rank" INT4,
575 "text_search_data" TSVECTOR,
576 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
577 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL),
578 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
579 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
580 CONSTRAINT "revoked_initiatives_cant_be_admitted"
581 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
582 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
583 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
584 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
585 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
586 "schulze_rank" ISNULL AND
587 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
588 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
589 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
590 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
591 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
592 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
593 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
594 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
595 CREATE TRIGGER "update_text_search_data"
596 BEFORE INSERT OR UPDATE ON "initiative"
597 FOR EACH ROW EXECUTE PROCEDURE
598 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
599 "name", "discussion_url");
601 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.';
603 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
604 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
605 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
606 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
607 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
608 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
609 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
610 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
611 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
612 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
613 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"';
614 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
615 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
616 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
617 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
618 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';
619 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';
620 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
621 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
624 CREATE TABLE "battle" (
625 "issue_id" INT4 NOT NULL,
626 "winning_initiative_id" INT4,
627 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
628 "losing_initiative_id" INT4,
629 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
630 "count" INT4 NOT NULL,
631 CONSTRAINT "initiative_ids_not_equal" CHECK (
632 "winning_initiative_id" != "losing_initiative_id" OR
633 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
634 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
635 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
636 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
637 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
639 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';
642 CREATE TABLE "ignored_initiative" (
643 PRIMARY KEY ("initiative_id", "member_id"),
644 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
645 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
646 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
648 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
651 CREATE TABLE "initiative_setting" (
652 PRIMARY KEY ("member_id", "key", "initiative_id"),
653 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
654 "key" TEXT NOT NULL,
655 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
656 "value" TEXT NOT NULL );
658 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
661 CREATE TABLE "draft" (
662 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
663 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
664 "id" SERIAL8 PRIMARY KEY,
665 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
666 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
667 "formatting_engine" TEXT,
668 "content" TEXT NOT NULL,
669 "text_search_data" TSVECTOR );
670 CREATE INDEX "draft_created_idx" ON "draft" ("created");
671 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
672 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
673 CREATE TRIGGER "update_text_search_data"
674 BEFORE INSERT OR UPDATE ON "draft"
675 FOR EACH ROW EXECUTE PROCEDURE
676 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
678 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.';
680 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
681 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
684 CREATE TABLE "rendered_draft" (
685 PRIMARY KEY ("draft_id", "format"),
686 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
687 "format" TEXT,
688 "content" TEXT NOT NULL );
690 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)';
693 CREATE TABLE "suggestion" (
694 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
695 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
696 "id" SERIAL8 PRIMARY KEY,
697 "draft_id" INT8 NOT NULL,
698 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
699 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
700 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
701 "name" TEXT NOT NULL,
702 "formatting_engine" TEXT,
703 "content" TEXT NOT NULL DEFAULT '',
704 "text_search_data" TSVECTOR,
705 "minus2_unfulfilled_count" INT4,
706 "minus2_fulfilled_count" INT4,
707 "minus1_unfulfilled_count" INT4,
708 "minus1_fulfilled_count" INT4,
709 "plus1_unfulfilled_count" INT4,
710 "plus1_fulfilled_count" INT4,
711 "plus2_unfulfilled_count" INT4,
712 "plus2_fulfilled_count" INT4 );
713 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
714 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
715 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
716 CREATE TRIGGER "update_text_search_data"
717 BEFORE INSERT OR UPDATE ON "suggestion"
718 FOR EACH ROW EXECUTE PROCEDURE
719 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
720 "name", "content");
722 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';
724 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")';
725 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
726 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
727 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
728 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
729 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
730 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
731 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
732 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
735 CREATE TABLE "rendered_suggestion" (
736 PRIMARY KEY ("suggestion_id", "format"),
737 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
738 "format" TEXT,
739 "content" TEXT NOT NULL );
741 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)';
744 CREATE TABLE "suggestion_setting" (
745 PRIMARY KEY ("member_id", "key", "suggestion_id"),
746 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
747 "key" TEXT NOT NULL,
748 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
749 "value" TEXT NOT NULL );
751 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
754 CREATE TABLE "invite_code_unit" (
755 PRIMARY KEY ("invite_code_id", "unit_id"),
756 "invite_code_id" INT8 REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
757 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
759 COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
762 CREATE TABLE "privilege" (
763 PRIMARY KEY ("unit_id", "member_id"),
764 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
765 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
766 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
767 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
768 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
769 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE,
770 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE );
772 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
774 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other users';
775 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create or lock sub units';
776 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create or lock areas and set area parameters';
777 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
778 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote';
781 CREATE TABLE "membership" (
782 PRIMARY KEY ("area_id", "member_id"),
783 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
784 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
785 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
787 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
790 CREATE TABLE "interest" (
791 PRIMARY KEY ("issue_id", "member_id"),
792 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
793 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
794 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
796 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.';
799 CREATE TABLE "initiator" (
800 PRIMARY KEY ("initiative_id", "member_id"),
801 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
802 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
803 "accepted" BOOLEAN );
804 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
806 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.';
808 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.';
811 CREATE TABLE "supporter" (
812 "issue_id" INT4 NOT NULL,
813 PRIMARY KEY ("initiative_id", "member_id"),
814 "initiative_id" INT4,
815 "member_id" INT4,
816 "draft_id" INT8 NOT NULL,
817 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
818 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
819 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
821 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.';
823 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")';
826 CREATE TABLE "opinion" (
827 "initiative_id" INT4 NOT NULL,
828 PRIMARY KEY ("suggestion_id", "member_id"),
829 "suggestion_id" INT8,
830 "member_id" INT4,
831 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
832 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
833 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
834 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
835 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
837 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.';
839 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
842 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
844 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
847 CREATE TABLE "delegation" (
848 "id" SERIAL8 PRIMARY KEY,
849 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
850 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
851 "scope" "delegation_scope" NOT NULL,
852 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
853 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
854 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
855 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
856 CONSTRAINT "no_unit_delegation_to_null"
857 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
858 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
859 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
860 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
861 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
862 UNIQUE ("unit_id", "truster_id"),
863 UNIQUE ("area_id", "truster_id"),
864 UNIQUE ("issue_id", "truster_id") );
865 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
866 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
868 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
870 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
871 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
872 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
875 CREATE TABLE "direct_population_snapshot" (
876 PRIMARY KEY ("issue_id", "event", "member_id"),
877 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
878 "event" "snapshot_event",
879 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
880 "weight" INT4 );
881 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
883 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
885 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
886 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
889 CREATE TABLE "delegating_population_snapshot" (
890 PRIMARY KEY ("issue_id", "event", "member_id"),
891 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
892 "event" "snapshot_event",
893 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
894 "weight" INT4,
895 "scope" "delegation_scope" NOT NULL,
896 "delegate_member_ids" INT4[] NOT NULL );
897 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
899 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
901 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
902 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
903 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
904 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"';
907 CREATE TABLE "direct_interest_snapshot" (
908 PRIMARY KEY ("issue_id", "event", "member_id"),
909 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
910 "event" "snapshot_event",
911 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
912 "weight" INT4 );
913 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
915 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
917 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
918 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
921 CREATE TABLE "delegating_interest_snapshot" (
922 PRIMARY KEY ("issue_id", "event", "member_id"),
923 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
924 "event" "snapshot_event",
925 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
926 "weight" INT4,
927 "scope" "delegation_scope" NOT NULL,
928 "delegate_member_ids" INT4[] NOT NULL );
929 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
931 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
933 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
934 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
935 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
936 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"';
939 CREATE TABLE "direct_supporter_snapshot" (
940 "issue_id" INT4 NOT NULL,
941 PRIMARY KEY ("initiative_id", "event", "member_id"),
942 "initiative_id" INT4,
943 "event" "snapshot_event",
944 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
945 "informed" BOOLEAN NOT NULL,
946 "satisfied" BOOLEAN NOT NULL,
947 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
948 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
949 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
951 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
953 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
954 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
955 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
958 CREATE TABLE "non_voter" (
959 PRIMARY KEY ("issue_id", "member_id"),
960 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
961 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
962 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
964 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
967 CREATE TABLE "direct_voter" (
968 PRIMARY KEY ("issue_id", "member_id"),
969 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
970 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
971 "weight" INT4 );
972 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
974 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.';
976 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
979 CREATE TABLE "delegating_voter" (
980 PRIMARY KEY ("issue_id", "member_id"),
981 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
982 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
983 "weight" INT4,
984 "scope" "delegation_scope" NOT NULL,
985 "delegate_member_ids" INT4[] NOT NULL );
986 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
988 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
990 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
991 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
992 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"';
995 CREATE TABLE "vote" (
996 "issue_id" INT4 NOT NULL,
997 PRIMARY KEY ("initiative_id", "member_id"),
998 "initiative_id" INT4,
999 "member_id" INT4,
1000 "grade" INT4,
1001 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1002 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1003 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1005 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.';
1007 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.';
1010 CREATE TABLE "issue_comment" (
1011 PRIMARY KEY ("issue_id", "member_id"),
1012 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1013 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1014 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(),
1015 "formatting_engine" TEXT,
1016 "content" TEXT NOT NULL,
1017 "text_search_data" TSVECTOR );
1018 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
1019 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
1020 CREATE TRIGGER "update_text_search_data"
1021 BEFORE INSERT OR UPDATE ON "issue_comment"
1022 FOR EACH ROW EXECUTE PROCEDURE
1023 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1025 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
1027 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
1030 CREATE TABLE "rendered_issue_comment" (
1031 PRIMARY KEY ("issue_id", "member_id", "format"),
1032 FOREIGN KEY ("issue_id", "member_id")
1033 REFERENCES "issue_comment" ("issue_id", "member_id")
1034 ON DELETE CASCADE ON UPDATE CASCADE,
1035 "issue_id" INT4,
1036 "member_id" INT4,
1037 "format" TEXT,
1038 "content" TEXT NOT NULL );
1040 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)';
1043 CREATE TABLE "voting_comment" (
1044 PRIMARY KEY ("issue_id", "member_id"),
1045 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1046 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1047 "changed" TIMESTAMPTZ,
1048 "formatting_engine" TEXT,
1049 "content" TEXT NOT NULL,
1050 "text_search_data" TSVECTOR );
1051 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
1052 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
1053 CREATE TRIGGER "update_text_search_data"
1054 BEFORE INSERT OR UPDATE ON "voting_comment"
1055 FOR EACH ROW EXECUTE PROCEDURE
1056 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1058 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
1060 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.';
1063 CREATE TABLE "rendered_voting_comment" (
1064 PRIMARY KEY ("issue_id", "member_id", "format"),
1065 FOREIGN KEY ("issue_id", "member_id")
1066 REFERENCES "voting_comment" ("issue_id", "member_id")
1067 ON DELETE CASCADE ON UPDATE CASCADE,
1068 "issue_id" INT4,
1069 "member_id" INT4,
1070 "format" TEXT,
1071 "content" TEXT NOT NULL );
1073 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)';
1076 CREATE TYPE "event_type" AS ENUM (
1077 'issue_state_changed',
1078 'initiative_created_in_new_issue',
1079 'initiative_created_in_existing_issue',
1080 'initiative_revoked',
1081 'new_draft_created',
1082 'suggestion_created');
1084 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1087 CREATE TABLE "event" (
1088 "id" SERIAL8 PRIMARY KEY,
1089 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1090 "event" "event_type" NOT NULL,
1091 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1092 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1093 "state" "issue_state" CHECK ("state" != 'calculation'),
1094 "initiative_id" INT4,
1095 "draft_id" INT8,
1096 "suggestion_id" INT8,
1097 FOREIGN KEY ("issue_id", "initiative_id")
1098 REFERENCES "initiative" ("issue_id", "id")
1099 ON DELETE CASCADE ON UPDATE CASCADE,
1100 FOREIGN KEY ("initiative_id", "draft_id")
1101 REFERENCES "draft" ("initiative_id", "id")
1102 ON DELETE CASCADE ON UPDATE CASCADE,
1103 FOREIGN KEY ("initiative_id", "suggestion_id")
1104 REFERENCES "suggestion" ("initiative_id", "id")
1105 ON DELETE CASCADE ON UPDATE CASCADE,
1106 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
1107 "event" != 'issue_state_changed' OR (
1108 "member_id" ISNULL AND
1109 "issue_id" NOTNULL AND
1110 "state" NOTNULL AND
1111 "initiative_id" ISNULL AND
1112 "draft_id" ISNULL AND
1113 "suggestion_id" ISNULL )),
1114 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1115 "event" NOT IN (
1116 'initiative_created_in_new_issue',
1117 'initiative_created_in_existing_issue',
1118 'initiative_revoked',
1119 'new_draft_created'
1120 ) OR (
1121 "member_id" NOTNULL AND
1122 "issue_id" NOTNULL AND
1123 "state" NOTNULL AND
1124 "initiative_id" NOTNULL AND
1125 "draft_id" NOTNULL AND
1126 "suggestion_id" ISNULL )),
1127 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
1128 "event" != 'suggestion_created' OR (
1129 "member_id" NOTNULL AND
1130 "issue_id" NOTNULL AND
1131 "state" NOTNULL AND
1132 "initiative_id" NOTNULL AND
1133 "draft_id" ISNULL AND
1134 "suggestion_id" NOTNULL )) );
1136 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1138 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1139 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1140 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1141 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1145 ----------------------------------------------
1146 -- Writing of history entries and event log --
1147 ----------------------------------------------
1149 CREATE FUNCTION "write_member_history_trigger"()
1150 RETURNS TRIGGER
1151 LANGUAGE 'plpgsql' VOLATILE AS $$
1152 BEGIN
1153 IF
1154 NEW."active" != OLD."active" OR
1155 NEW."name" != OLD."name"
1156 THEN
1157 INSERT INTO "member_history"
1158 ("member_id", "active", "name")
1159 VALUES (NEW."id", OLD."active", OLD."name");
1160 END IF;
1161 RETURN NULL;
1162 END;
1163 $$;
1165 CREATE TRIGGER "write_member_history"
1166 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1167 "write_member_history_trigger"();
1169 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1170 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1173 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1174 RETURNS TRIGGER
1175 LANGUAGE 'plpgsql' VOLATILE AS $$
1176 BEGIN
1177 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
1178 INSERT INTO "event" ("event", "issue_id", "state")
1179 VALUES ('issue_state_changed', NEW."id", NEW."state");
1180 END IF;
1181 RETURN NULL;
1182 END;
1183 $$;
1185 CREATE TRIGGER "write_event_issue_state_changed"
1186 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1187 "write_event_issue_state_changed_trigger"();
1189 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1190 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1193 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1194 RETURNS TRIGGER
1195 LANGUAGE 'plpgsql' VOLATILE AS $$
1196 DECLARE
1197 "initiative_row" "initiative"%ROWTYPE;
1198 "issue_row" "issue"%ROWTYPE;
1199 "event_v" "event_type";
1200 BEGIN
1201 SELECT * INTO "initiative_row" FROM "initiative"
1202 WHERE "id" = NEW."initiative_id";
1203 SELECT * INTO "issue_row" FROM "issue"
1204 WHERE "id" = "initiative_row"."issue_id";
1205 IF EXISTS (
1206 SELECT NULL FROM "draft"
1207 WHERE "initiative_id" = NEW."initiative_id"
1208 AND "id" != NEW."id"
1209 ) THEN
1210 "event_v" := 'new_draft_created';
1211 ELSE
1212 IF EXISTS (
1213 SELECT NULL FROM "initiative"
1214 WHERE "issue_id" = "initiative_row"."issue_id"
1215 AND "id" != "initiative_row"."id"
1216 ) THEN
1217 "event_v" := 'initiative_created_in_existing_issue';
1218 ELSE
1219 "event_v" := 'initiative_created_in_new_issue';
1220 END IF;
1221 END IF;
1222 INSERT INTO "event" (
1223 "event", "member_id",
1224 "issue_id", "state", "initiative_id", "draft_id"
1225 ) VALUES (
1226 "event_v",
1227 NEW."author_id",
1228 "initiative_row"."issue_id",
1229 "issue_row"."state",
1230 "initiative_row"."id",
1231 NEW."id" );
1232 RETURN NULL;
1233 END;
1234 $$;
1236 CREATE TRIGGER "write_event_initiative_or_draft_created"
1237 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1238 "write_event_initiative_or_draft_created_trigger"();
1240 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1241 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1244 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1245 RETURNS TRIGGER
1246 LANGUAGE 'plpgsql' VOLATILE AS $$
1247 DECLARE
1248 "issue_row" "issue"%ROWTYPE;
1249 BEGIN
1250 SELECT * INTO "issue_row" FROM "issue"
1251 WHERE "id" = NEW."issue_id";
1252 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1253 INSERT INTO "event" (
1254 "event", "member_id", "issue_id", "state", "initiative_id"
1255 ) VALUES (
1256 'initiative_revoked',
1257 NEW."revoked_by_member_id",
1258 NEW."issue_id",
1259 "issue_row"."state",
1260 NEW."id" );
1261 END IF;
1262 RETURN NULL;
1263 END;
1264 $$;
1266 CREATE TRIGGER "write_event_initiative_revoked"
1267 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1268 "write_event_initiative_revoked_trigger"();
1270 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1271 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1274 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1275 RETURNS TRIGGER
1276 LANGUAGE 'plpgsql' VOLATILE AS $$
1277 DECLARE
1278 "initiative_row" "initiative"%ROWTYPE;
1279 "issue_row" "issue"%ROWTYPE;
1280 BEGIN
1281 SELECT * INTO "initiative_row" FROM "initiative"
1282 WHERE "id" = NEW."initiative_id";
1283 SELECT * INTO "issue_row" FROM "issue"
1284 WHERE "id" = "initiative_row"."issue_id";
1285 INSERT INTO "event" (
1286 "event", "member_id",
1287 "issue_id", "state", "initiative_id", "suggestion_id"
1288 ) VALUES (
1289 'suggestion_created',
1290 NEW."author_id",
1291 "initiative_row"."issue_id",
1292 "issue_row"."state",
1293 "initiative_row"."id",
1294 NEW."id" );
1295 RETURN NULL;
1296 END;
1297 $$;
1299 CREATE TRIGGER "write_event_suggestion_created"
1300 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
1301 "write_event_suggestion_created_trigger"();
1303 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
1304 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
1308 ----------------------------
1309 -- Additional constraints --
1310 ----------------------------
1313 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
1314 RETURNS TRIGGER
1315 LANGUAGE 'plpgsql' VOLATILE AS $$
1316 BEGIN
1317 IF NOT EXISTS (
1318 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
1319 ) THEN
1320 --RAISE 'Cannot create issue without an initial initiative.' USING
1321 -- ERRCODE = 'integrity_constraint_violation',
1322 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
1323 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
1324 END IF;
1325 RETURN NULL;
1326 END;
1327 $$;
1329 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
1330 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
1331 FOR EACH ROW EXECUTE PROCEDURE
1332 "issue_requires_first_initiative_trigger"();
1334 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
1335 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
1338 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
1339 RETURNS TRIGGER
1340 LANGUAGE 'plpgsql' VOLATILE AS $$
1341 DECLARE
1342 "reference_lost" BOOLEAN;
1343 BEGIN
1344 IF TG_OP = 'DELETE' THEN
1345 "reference_lost" := TRUE;
1346 ELSE
1347 "reference_lost" := NEW."issue_id" != OLD."issue_id";
1348 END IF;
1349 IF
1350 "reference_lost" AND NOT EXISTS (
1351 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
1353 THEN
1354 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
1355 END IF;
1356 RETURN NULL;
1357 END;
1358 $$;
1360 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
1361 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1362 FOR EACH ROW EXECUTE PROCEDURE
1363 "last_initiative_deletes_issue_trigger"();
1365 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
1366 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
1369 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
1370 RETURNS TRIGGER
1371 LANGUAGE 'plpgsql' VOLATILE AS $$
1372 BEGIN
1373 IF NOT EXISTS (
1374 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
1375 ) THEN
1376 --RAISE 'Cannot create initiative without an initial draft.' USING
1377 -- ERRCODE = 'integrity_constraint_violation',
1378 -- HINT = 'Create issue, initiative and draft within the same transaction.';
1379 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
1380 END IF;
1381 RETURN NULL;
1382 END;
1383 $$;
1385 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
1386 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
1387 FOR EACH ROW EXECUTE PROCEDURE
1388 "initiative_requires_first_draft_trigger"();
1390 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
1391 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
1394 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
1395 RETURNS TRIGGER
1396 LANGUAGE 'plpgsql' VOLATILE AS $$
1397 DECLARE
1398 "reference_lost" BOOLEAN;
1399 BEGIN
1400 IF TG_OP = 'DELETE' THEN
1401 "reference_lost" := TRUE;
1402 ELSE
1403 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
1404 END IF;
1405 IF
1406 "reference_lost" AND NOT EXISTS (
1407 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
1409 THEN
1410 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
1411 END IF;
1412 RETURN NULL;
1413 END;
1414 $$;
1416 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
1417 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
1418 FOR EACH ROW EXECUTE PROCEDURE
1419 "last_draft_deletes_initiative_trigger"();
1421 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
1422 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
1425 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
1426 RETURNS TRIGGER
1427 LANGUAGE 'plpgsql' VOLATILE AS $$
1428 BEGIN
1429 IF NOT EXISTS (
1430 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
1431 ) THEN
1432 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
1433 END IF;
1434 RETURN NULL;
1435 END;
1436 $$;
1438 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
1439 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
1440 FOR EACH ROW EXECUTE PROCEDURE
1441 "suggestion_requires_first_opinion_trigger"();
1443 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1444 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1447 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1448 RETURNS TRIGGER
1449 LANGUAGE 'plpgsql' VOLATILE AS $$
1450 DECLARE
1451 "reference_lost" BOOLEAN;
1452 BEGIN
1453 IF TG_OP = 'DELETE' THEN
1454 "reference_lost" := TRUE;
1455 ELSE
1456 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1457 END IF;
1458 IF
1459 "reference_lost" AND NOT EXISTS (
1460 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1462 THEN
1463 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1464 END IF;
1465 RETURN NULL;
1466 END;
1467 $$;
1469 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1470 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1471 FOR EACH ROW EXECUTE PROCEDURE
1472 "last_opinion_deletes_suggestion_trigger"();
1474 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1475 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1479 ---------------------------------------------------------------
1480 -- Ensure that votes are not modified when issues are frozen --
1481 ---------------------------------------------------------------
1483 -- NOTE: Frontends should ensure this anyway, but in case of programming
1484 -- errors the following triggers ensure data integrity.
1487 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1488 RETURNS TRIGGER
1489 LANGUAGE 'plpgsql' VOLATILE AS $$
1490 DECLARE
1491 "issue_id_v" "issue"."id"%TYPE;
1492 "issue_row" "issue"%ROWTYPE;
1493 BEGIN
1494 IF TG_OP = 'DELETE' THEN
1495 "issue_id_v" := OLD."issue_id";
1496 ELSE
1497 "issue_id_v" := NEW."issue_id";
1498 END IF;
1499 SELECT INTO "issue_row" * FROM "issue"
1500 WHERE "id" = "issue_id_v" FOR SHARE;
1501 IF "issue_row"."closed" NOTNULL THEN
1502 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1503 END IF;
1504 RETURN NULL;
1505 END;
1506 $$;
1508 CREATE TRIGGER "forbid_changes_on_closed_issue"
1509 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1510 FOR EACH ROW EXECUTE PROCEDURE
1511 "forbid_changes_on_closed_issue_trigger"();
1513 CREATE TRIGGER "forbid_changes_on_closed_issue"
1514 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1515 FOR EACH ROW EXECUTE PROCEDURE
1516 "forbid_changes_on_closed_issue_trigger"();
1518 CREATE TRIGGER "forbid_changes_on_closed_issue"
1519 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1520 FOR EACH ROW EXECUTE PROCEDURE
1521 "forbid_changes_on_closed_issue_trigger"();
1523 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"';
1524 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';
1525 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';
1526 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';
1530 --------------------------------------------------------------------
1531 -- Auto-retrieval of fields only needed for referential integrity --
1532 --------------------------------------------------------------------
1535 CREATE FUNCTION "autofill_issue_id_trigger"()
1536 RETURNS TRIGGER
1537 LANGUAGE 'plpgsql' VOLATILE AS $$
1538 BEGIN
1539 IF NEW."issue_id" ISNULL THEN
1540 SELECT "issue_id" INTO NEW."issue_id"
1541 FROM "initiative" WHERE "id" = NEW."initiative_id";
1542 END IF;
1543 RETURN NEW;
1544 END;
1545 $$;
1547 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1548 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1550 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1551 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1553 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1554 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1555 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1558 CREATE FUNCTION "autofill_initiative_id_trigger"()
1559 RETURNS TRIGGER
1560 LANGUAGE 'plpgsql' VOLATILE AS $$
1561 BEGIN
1562 IF NEW."initiative_id" ISNULL THEN
1563 SELECT "initiative_id" INTO NEW."initiative_id"
1564 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1565 END IF;
1566 RETURN NEW;
1567 END;
1568 $$;
1570 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1571 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1573 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1574 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1578 -----------------------------------------------------
1579 -- Automatic calculation of certain default values --
1580 -----------------------------------------------------
1583 CREATE FUNCTION "copy_timings_trigger"()
1584 RETURNS TRIGGER
1585 LANGUAGE 'plpgsql' VOLATILE AS $$
1586 DECLARE
1587 "policy_row" "policy"%ROWTYPE;
1588 BEGIN
1589 SELECT * INTO "policy_row" FROM "policy"
1590 WHERE "id" = NEW."policy_id";
1591 IF NEW."admission_time" ISNULL THEN
1592 NEW."admission_time" := "policy_row"."admission_time";
1593 END IF;
1594 IF NEW."discussion_time" ISNULL THEN
1595 NEW."discussion_time" := "policy_row"."discussion_time";
1596 END IF;
1597 IF NEW."verification_time" ISNULL THEN
1598 NEW."verification_time" := "policy_row"."verification_time";
1599 END IF;
1600 IF NEW."voting_time" ISNULL THEN
1601 NEW."voting_time" := "policy_row"."voting_time";
1602 END IF;
1603 RETURN NEW;
1604 END;
1605 $$;
1607 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1608 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1610 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1611 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1614 CREATE FUNCTION "default_for_draft_id_trigger"()
1615 RETURNS TRIGGER
1616 LANGUAGE 'plpgsql' VOLATILE AS $$
1617 BEGIN
1618 IF NEW."draft_id" ISNULL THEN
1619 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1620 WHERE "initiative_id" = NEW."initiative_id";
1621 END IF;
1622 RETURN NEW;
1623 END;
1624 $$;
1626 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
1627 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1628 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1629 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
1631 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
1632 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';
1633 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';
1637 ----------------------------------------
1638 -- Automatic creation of dependencies --
1639 ----------------------------------------
1642 CREATE FUNCTION "autocreate_interest_trigger"()
1643 RETURNS TRIGGER
1644 LANGUAGE 'plpgsql' VOLATILE AS $$
1645 BEGIN
1646 IF NOT EXISTS (
1647 SELECT NULL FROM "initiative" JOIN "interest"
1648 ON "initiative"."issue_id" = "interest"."issue_id"
1649 WHERE "initiative"."id" = NEW."initiative_id"
1650 AND "interest"."member_id" = NEW."member_id"
1651 ) THEN
1652 BEGIN
1653 INSERT INTO "interest" ("issue_id", "member_id")
1654 SELECT "issue_id", NEW."member_id"
1655 FROM "initiative" WHERE "id" = NEW."initiative_id";
1656 EXCEPTION WHEN unique_violation THEN END;
1657 END IF;
1658 RETURN NEW;
1659 END;
1660 $$;
1662 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1663 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1665 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1666 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';
1669 CREATE FUNCTION "autocreate_supporter_trigger"()
1670 RETURNS TRIGGER
1671 LANGUAGE 'plpgsql' VOLATILE AS $$
1672 BEGIN
1673 IF NOT EXISTS (
1674 SELECT NULL FROM "suggestion" JOIN "supporter"
1675 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1676 WHERE "suggestion"."id" = NEW."suggestion_id"
1677 AND "supporter"."member_id" = NEW."member_id"
1678 ) THEN
1679 BEGIN
1680 INSERT INTO "supporter" ("initiative_id", "member_id")
1681 SELECT "initiative_id", NEW."member_id"
1682 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1683 EXCEPTION WHEN unique_violation THEN END;
1684 END IF;
1685 RETURN NEW;
1686 END;
1687 $$;
1689 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1690 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1692 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1693 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.';
1697 ------------------------------------------
1698 -- Views and helper functions for views --
1699 ------------------------------------------
1702 CREATE VIEW "unit_delegation" AS
1703 SELECT
1704 "unit"."id" AS "unit_id",
1705 "delegation"."id",
1706 "delegation"."truster_id",
1707 "delegation"."trustee_id",
1708 "delegation"."scope"
1709 FROM "unit"
1710 JOIN "delegation"
1711 ON "delegation"."unit_id" = "unit"."id"
1712 JOIN "member"
1713 ON "delegation"."truster_id" = "member"."id"
1714 JOIN "privilege"
1715 ON "delegation"."unit_id" = "privilege"."unit_id"
1716 AND "delegation"."truster_id" = "privilege"."member_id"
1717 WHERE "member"."active" AND "privilege"."voting_right";
1719 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
1722 CREATE VIEW "area_delegation" AS
1723 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1724 "area"."id" AS "area_id",
1725 "delegation"."id",
1726 "delegation"."truster_id",
1727 "delegation"."trustee_id",
1728 "delegation"."scope"
1729 FROM "area"
1730 JOIN "delegation"
1731 ON "delegation"."unit_id" = "area"."unit_id"
1732 OR "delegation"."area_id" = "area"."id"
1733 JOIN "member"
1734 ON "delegation"."truster_id" = "member"."id"
1735 JOIN "privilege"
1736 ON "area"."unit_id" = "privilege"."unit_id"
1737 AND "delegation"."truster_id" = "privilege"."member_id"
1738 WHERE "member"."active" AND "privilege"."voting_right"
1739 ORDER BY
1740 "area"."id",
1741 "delegation"."truster_id",
1742 "delegation"."scope" DESC;
1744 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
1747 CREATE VIEW "issue_delegation" AS
1748 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1749 "issue"."id" AS "issue_id",
1750 "delegation"."id",
1751 "delegation"."truster_id",
1752 "delegation"."trustee_id",
1753 "delegation"."scope"
1754 FROM "issue"
1755 JOIN "area"
1756 ON "area"."id" = "issue"."area_id"
1757 JOIN "delegation"
1758 ON "delegation"."unit_id" = "area"."unit_id"
1759 OR "delegation"."area_id" = "area"."id"
1760 OR "delegation"."issue_id" = "issue"."id"
1761 JOIN "member"
1762 ON "delegation"."truster_id" = "member"."id"
1763 JOIN "privilege"
1764 ON "area"."unit_id" = "privilege"."unit_id"
1765 AND "delegation"."truster_id" = "privilege"."member_id"
1766 WHERE "member"."active" AND "privilege"."voting_right"
1767 ORDER BY
1768 "issue"."id",
1769 "delegation"."truster_id",
1770 "delegation"."scope" DESC;
1772 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
1775 CREATE FUNCTION "membership_weight_with_skipping"
1776 ( "area_id_p" "area"."id"%TYPE,
1777 "member_id_p" "member"."id"%TYPE,
1778 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1779 RETURNS INT4
1780 LANGUAGE 'plpgsql' STABLE AS $$
1781 DECLARE
1782 "sum_v" INT4;
1783 "delegation_row" "area_delegation"%ROWTYPE;
1784 BEGIN
1785 "sum_v" := 1;
1786 FOR "delegation_row" IN
1787 SELECT "area_delegation".*
1788 FROM "area_delegation" LEFT JOIN "membership"
1789 ON "membership"."area_id" = "area_id_p"
1790 AND "membership"."member_id" = "area_delegation"."truster_id"
1791 WHERE "area_delegation"."area_id" = "area_id_p"
1792 AND "area_delegation"."trustee_id" = "member_id_p"
1793 AND "membership"."member_id" ISNULL
1794 LOOP
1795 IF NOT
1796 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1797 THEN
1798 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1799 "area_id_p",
1800 "delegation_row"."truster_id",
1801 "skip_member_ids_p" || "delegation_row"."truster_id"
1802 );
1803 END IF;
1804 END LOOP;
1805 RETURN "sum_v";
1806 END;
1807 $$;
1809 COMMENT ON FUNCTION "membership_weight_with_skipping"
1810 ( "area"."id"%TYPE,
1811 "member"."id"%TYPE,
1812 INT4[] )
1813 IS 'Helper function for "membership_weight" function';
1816 CREATE FUNCTION "membership_weight"
1817 ( "area_id_p" "area"."id"%TYPE,
1818 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1819 RETURNS INT4
1820 LANGUAGE 'plpgsql' STABLE AS $$
1821 BEGIN
1822 RETURN "membership_weight_with_skipping"(
1823 "area_id_p",
1824 "member_id_p",
1825 ARRAY["member_id_p"]
1826 );
1827 END;
1828 $$;
1830 COMMENT ON FUNCTION "membership_weight"
1831 ( "area"."id"%TYPE,
1832 "member"."id"%TYPE )
1833 IS 'Calculates the potential voting weight of a member in a given area';
1836 CREATE VIEW "member_count_view" AS
1837 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1839 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1842 CREATE VIEW "unit_member_count" AS
1843 SELECT
1844 "unit"."id" AS "unit_id",
1845 sum("member"."id") AS "member_count"
1846 FROM "unit"
1847 LEFT JOIN "privilege"
1848 ON "privilege"."unit_id" = "unit"."id"
1849 AND "privilege"."voting_right"
1850 LEFT JOIN "member"
1851 ON "member"."id" = "privilege"."member_id"
1852 AND "member"."active"
1853 GROUP BY "unit"."id";
1855 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
1858 CREATE VIEW "area_member_count" AS
1859 SELECT
1860 "area"."id" AS "area_id",
1861 count("member"."id") AS "direct_member_count",
1862 coalesce(
1863 sum(
1864 CASE WHEN "member"."id" NOTNULL THEN
1865 "membership_weight"("area"."id", "member"."id")
1866 ELSE 0 END
1868 ) AS "member_weight"
1869 FROM "area"
1870 LEFT JOIN "membership"
1871 ON "area"."id" = "membership"."area_id"
1872 LEFT JOIN "privilege"
1873 ON "privilege"."unit_id" = "area"."unit_id"
1874 AND "privilege"."member_id" = "membership"."member_id"
1875 AND "privilege"."voting_right"
1876 LEFT JOIN "member"
1877 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
1878 AND "member"."active"
1879 GROUP BY "area"."id";
1881 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
1884 CREATE VIEW "opening_draft" AS
1885 SELECT "draft".* FROM (
1886 SELECT
1887 "initiative"."id" AS "initiative_id",
1888 min("draft"."id") AS "draft_id"
1889 FROM "initiative" JOIN "draft"
1890 ON "initiative"."id" = "draft"."initiative_id"
1891 GROUP BY "initiative"."id"
1892 ) AS "subquery"
1893 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1895 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1898 CREATE VIEW "current_draft" AS
1899 SELECT "draft".* FROM (
1900 SELECT
1901 "initiative"."id" AS "initiative_id",
1902 max("draft"."id") AS "draft_id"
1903 FROM "initiative" JOIN "draft"
1904 ON "initiative"."id" = "draft"."initiative_id"
1905 GROUP BY "initiative"."id"
1906 ) AS "subquery"
1907 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1909 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1912 CREATE VIEW "critical_opinion" AS
1913 SELECT * FROM "opinion"
1914 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1915 OR ("degree" = -2 AND "fulfilled" = TRUE);
1917 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1920 CREATE VIEW "battle_participant" AS
1921 SELECT "initiative"."id", "initiative"."issue_id"
1922 FROM "issue" JOIN "initiative"
1923 ON "issue"."id" = "initiative"."issue_id"
1924 WHERE "initiative"."admitted"
1925 UNION ALL
1926 SELECT NULL, "id" AS "issue_id"
1927 FROM "issue";
1929 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
1932 CREATE VIEW "battle_view" AS
1933 SELECT
1934 "issue"."id" AS "issue_id",
1935 "winning_initiative"."id" AS "winning_initiative_id",
1936 "losing_initiative"."id" AS "losing_initiative_id",
1937 sum(
1938 CASE WHEN
1939 coalesce("better_vote"."grade", 0) >
1940 coalesce("worse_vote"."grade", 0)
1941 THEN "direct_voter"."weight" ELSE 0 END
1942 ) AS "count"
1943 FROM "issue"
1944 LEFT JOIN "direct_voter"
1945 ON "issue"."id" = "direct_voter"."issue_id"
1946 JOIN "battle_participant" AS "winning_initiative"
1947 ON "issue"."id" = "winning_initiative"."issue_id"
1948 JOIN "battle_participant" AS "losing_initiative"
1949 ON "issue"."id" = "losing_initiative"."issue_id"
1950 LEFT JOIN "vote" AS "better_vote"
1951 ON "direct_voter"."member_id" = "better_vote"."member_id"
1952 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1953 LEFT JOIN "vote" AS "worse_vote"
1954 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1955 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1956 WHERE "issue"."closed" NOTNULL
1957 AND "issue"."cleaned" ISNULL
1958 AND (
1959 "winning_initiative"."id" != "losing_initiative"."id" OR
1960 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
1961 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
1962 GROUP BY
1963 "issue"."id",
1964 "winning_initiative"."id",
1965 "losing_initiative"."id";
1967 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';
1970 CREATE VIEW "expired_session" AS
1971 SELECT * FROM "session" WHERE now() > "expiry";
1973 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
1974 DELETE FROM "session" WHERE "ident" = OLD."ident";
1976 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
1977 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
1980 CREATE VIEW "open_issue" AS
1981 SELECT * FROM "issue" WHERE "closed" ISNULL;
1983 COMMENT ON VIEW "open_issue" IS 'All open issues';
1986 CREATE VIEW "issue_with_ranks_missing" AS
1987 SELECT * FROM "issue"
1988 WHERE "fully_frozen" NOTNULL
1989 AND "closed" NOTNULL
1990 AND "ranks_available" = FALSE;
1992 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
1995 CREATE VIEW "member_contingent" AS
1996 SELECT
1997 "member"."id" AS "member_id",
1998 "contingent"."time_frame",
1999 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
2001 SELECT count(1) FROM "draft"
2002 WHERE "draft"."author_id" = "member"."id"
2003 AND "draft"."created" > now() - "contingent"."time_frame"
2004 ) + (
2005 SELECT count(1) FROM "suggestion"
2006 WHERE "suggestion"."author_id" = "member"."id"
2007 AND "suggestion"."created" > now() - "contingent"."time_frame"
2009 ELSE NULL END AS "text_entry_count",
2010 "contingent"."text_entry_limit",
2011 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
2012 SELECT count(1) FROM "opening_draft"
2013 WHERE "opening_draft"."author_id" = "member"."id"
2014 AND "opening_draft"."created" > now() - "contingent"."time_frame"
2015 ) ELSE NULL END AS "initiative_count",
2016 "contingent"."initiative_limit"
2017 FROM "member" CROSS JOIN "contingent";
2019 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
2021 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
2022 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
2025 CREATE VIEW "member_contingent_left" AS
2026 SELECT
2027 "member_id",
2028 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
2029 max("initiative_limit" - "initiative_count") AS "initiatives_left"
2030 FROM "member_contingent" GROUP BY "member_id";
2032 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.';
2035 CREATE VIEW "event_seen_by_member" AS
2036 SELECT
2037 "member"."id" AS "seen_by_member_id",
2038 CASE WHEN "event"."state" IN (
2039 'voting',
2040 'finished_without_winner',
2041 'finished_with_winner'
2042 ) THEN
2043 'voting'::"notify_level"
2044 ELSE
2045 CASE WHEN "event"."state" IN (
2046 'verification',
2047 'canceled_after_revocation_during_verification',
2048 'canceled_no_initiative_admitted'
2049 ) THEN
2050 'verification'::"notify_level"
2051 ELSE
2052 CASE WHEN "event"."state" IN (
2053 'discussion',
2054 'canceled_after_revocation_during_discussion'
2055 ) THEN
2056 'discussion'::"notify_level"
2057 ELSE
2058 'all'::"notify_level"
2059 END
2060 END
2061 END AS "notify_level",
2062 "event".*
2063 FROM "member" CROSS JOIN "event"
2064 LEFT JOIN "issue"
2065 ON "event"."issue_id" = "issue"."id"
2066 LEFT JOIN "membership"
2067 ON "member"."id" = "membership"."member_id"
2068 AND "issue"."area_id" = "membership"."area_id"
2069 LEFT JOIN "interest"
2070 ON "member"."id" = "interest"."member_id"
2071 AND "event"."issue_id" = "interest"."issue_id"
2072 LEFT JOIN "supporter"
2073 ON "member"."id" = "supporter"."member_id"
2074 AND "event"."initiative_id" = "supporter"."initiative_id"
2075 LEFT JOIN "ignored_member"
2076 ON "member"."id" = "ignored_member"."member_id"
2077 AND "event"."member_id" = "ignored_member"."other_member_id"
2078 LEFT JOIN "ignored_initiative"
2079 ON "member"."id" = "ignored_initiative"."member_id"
2080 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2081 WHERE (
2082 "supporter"."member_id" NOTNULL OR
2083 "interest"."member_id" NOTNULL OR
2084 ( "membership"."member_id" NOTNULL AND
2085 "event"."event" IN (
2086 'issue_state_changed',
2087 'initiative_created_in_new_issue',
2088 'initiative_created_in_existing_issue',
2089 'initiative_revoked' ) ) )
2090 AND "ignored_member"."member_id" ISNULL
2091 AND "ignored_initiative"."member_id" ISNULL;
2093 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
2096 CREATE VIEW "pending_notification" AS
2097 SELECT
2098 "member"."id" AS "seen_by_member_id",
2099 "event".*
2100 FROM "member" CROSS JOIN "event"
2101 LEFT JOIN "issue"
2102 ON "event"."issue_id" = "issue"."id"
2103 LEFT JOIN "membership"
2104 ON "member"."id" = "membership"."member_id"
2105 AND "issue"."area_id" = "membership"."area_id"
2106 LEFT JOIN "interest"
2107 ON "member"."id" = "interest"."member_id"
2108 AND "event"."issue_id" = "interest"."issue_id"
2109 LEFT JOIN "supporter"
2110 ON "member"."id" = "supporter"."member_id"
2111 AND "event"."initiative_id" = "supporter"."initiative_id"
2112 LEFT JOIN "ignored_member"
2113 ON "member"."id" = "ignored_member"."member_id"
2114 AND "event"."member_id" = "ignored_member"."other_member_id"
2115 LEFT JOIN "ignored_initiative"
2116 ON "member"."id" = "ignored_initiative"."member_id"
2117 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
2118 WHERE (
2119 "member"."notify_event_id" ISNULL OR
2120 ( "member"."notify_event_id" NOTNULL AND
2121 "member"."notify_event_id" < "event"."id" ) )
2122 AND (
2123 ( "member"."notify_level" >= 'all' ) OR
2124 ( "member"."notify_level" >= 'voting' AND
2125 "event"."state" IN (
2126 'voting',
2127 'finished_without_winner',
2128 'finished_with_winner' ) ) OR
2129 ( "member"."notify_level" >= 'verification' AND
2130 "event"."state" IN (
2131 'verification',
2132 'canceled_after_revocation_during_verification',
2133 'canceled_no_initiative_admitted' ) ) OR
2134 ( "member"."notify_level" >= 'discussion' AND
2135 "event"."state" IN (
2136 'discussion',
2137 'canceled_after_revocation_during_discussion' ) ) )
2138 AND (
2139 "supporter"."member_id" NOTNULL OR
2140 "interest"."member_id" NOTNULL OR
2141 ( "membership"."member_id" NOTNULL AND
2142 "event"."event" IN (
2143 'issue_state_changed',
2144 'initiative_created_in_new_issue',
2145 'initiative_created_in_existing_issue',
2146 'initiative_revoked' ) ) )
2147 AND "ignored_member"."member_id" ISNULL
2148 AND "ignored_initiative"."member_id" ISNULL;
2150 COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
2153 CREATE TYPE "timeline_event" AS ENUM (
2154 'issue_created',
2155 'issue_canceled',
2156 'issue_accepted',
2157 'issue_half_frozen',
2158 'issue_finished_without_voting',
2159 'issue_voting_started',
2160 'issue_finished_after_voting',
2161 'initiative_created',
2162 'initiative_revoked',
2163 'draft_created',
2164 'suggestion_created');
2166 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
2169 CREATE VIEW "timeline_issue" AS
2170 SELECT
2171 "created" AS "occurrence",
2172 'issue_created'::"timeline_event" AS "event",
2173 "id" AS "issue_id"
2174 FROM "issue"
2175 UNION ALL
2176 SELECT
2177 "closed" AS "occurrence",
2178 'issue_canceled'::"timeline_event" AS "event",
2179 "id" AS "issue_id"
2180 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
2181 UNION ALL
2182 SELECT
2183 "accepted" AS "occurrence",
2184 'issue_accepted'::"timeline_event" AS "event",
2185 "id" AS "issue_id"
2186 FROM "issue" WHERE "accepted" NOTNULL
2187 UNION ALL
2188 SELECT
2189 "half_frozen" AS "occurrence",
2190 'issue_half_frozen'::"timeline_event" AS "event",
2191 "id" AS "issue_id"
2192 FROM "issue" WHERE "half_frozen" NOTNULL
2193 UNION ALL
2194 SELECT
2195 "fully_frozen" AS "occurrence",
2196 'issue_voting_started'::"timeline_event" AS "event",
2197 "id" AS "issue_id"
2198 FROM "issue"
2199 WHERE "fully_frozen" NOTNULL
2200 AND ("closed" ISNULL OR "closed" != "fully_frozen")
2201 UNION ALL
2202 SELECT
2203 "closed" AS "occurrence",
2204 CASE WHEN "fully_frozen" = "closed" THEN
2205 'issue_finished_without_voting'::"timeline_event"
2206 ELSE
2207 'issue_finished_after_voting'::"timeline_event"
2208 END AS "event",
2209 "id" AS "issue_id"
2210 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
2212 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
2215 CREATE VIEW "timeline_initiative" AS
2216 SELECT
2217 "created" AS "occurrence",
2218 'initiative_created'::"timeline_event" AS "event",
2219 "id" AS "initiative_id"
2220 FROM "initiative"
2221 UNION ALL
2222 SELECT
2223 "revoked" AS "occurrence",
2224 'initiative_revoked'::"timeline_event" AS "event",
2225 "id" AS "initiative_id"
2226 FROM "initiative" WHERE "revoked" NOTNULL;
2228 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
2231 CREATE VIEW "timeline_draft" AS
2232 SELECT
2233 "created" AS "occurrence",
2234 'draft_created'::"timeline_event" AS "event",
2235 "id" AS "draft_id"
2236 FROM "draft";
2238 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
2241 CREATE VIEW "timeline_suggestion" AS
2242 SELECT
2243 "created" AS "occurrence",
2244 'suggestion_created'::"timeline_event" AS "event",
2245 "id" AS "suggestion_id"
2246 FROM "suggestion";
2248 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
2251 CREATE VIEW "timeline" AS
2252 SELECT
2253 "occurrence",
2254 "event",
2255 "issue_id",
2256 NULL AS "initiative_id",
2257 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
2258 NULL::INT8 AS "suggestion_id"
2259 FROM "timeline_issue"
2260 UNION ALL
2261 SELECT
2262 "occurrence",
2263 "event",
2264 NULL AS "issue_id",
2265 "initiative_id",
2266 NULL AS "draft_id",
2267 NULL AS "suggestion_id"
2268 FROM "timeline_initiative"
2269 UNION ALL
2270 SELECT
2271 "occurrence",
2272 "event",
2273 NULL AS "issue_id",
2274 NULL AS "initiative_id",
2275 "draft_id",
2276 NULL AS "suggestion_id"
2277 FROM "timeline_draft"
2278 UNION ALL
2279 SELECT
2280 "occurrence",
2281 "event",
2282 NULL AS "issue_id",
2283 NULL AS "initiative_id",
2284 NULL AS "draft_id",
2285 "suggestion_id"
2286 FROM "timeline_suggestion";
2288 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
2292 --------------------------------------------------
2293 -- Set returning function for delegation chains --
2294 --------------------------------------------------
2297 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
2298 ('first', 'intermediate', 'last', 'repetition');
2300 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
2303 CREATE TYPE "delegation_chain_row" AS (
2304 "index" INT4,
2305 "member_id" INT4,
2306 "member_valid" BOOLEAN,
2307 "participation" BOOLEAN,
2308 "overridden" BOOLEAN,
2309 "scope_in" "delegation_scope",
2310 "scope_out" "delegation_scope",
2311 "disabled_out" BOOLEAN,
2312 "loop" "delegation_chain_loop_tag" );
2314 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
2316 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
2317 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';
2318 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
2319 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
2320 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
2321 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
2322 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
2325 CREATE FUNCTION "delegation_chain"
2326 ( "member_id_p" "member"."id"%TYPE,
2327 "unit_id_p" "unit"."id"%TYPE,
2328 "area_id_p" "area"."id"%TYPE,
2329 "issue_id_p" "issue"."id"%TYPE,
2330 "simulate_trustee_id_p" "member"."id"%TYPE )
2331 RETURNS SETOF "delegation_chain_row"
2332 LANGUAGE 'plpgsql' STABLE AS $$
2333 DECLARE
2334 "scope_v" "delegation_scope";
2335 "unit_id_v" "unit"."id"%TYPE;
2336 "area_id_v" "area"."id"%TYPE;
2337 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
2338 "loop_member_id_v" "member"."id"%TYPE;
2339 "output_row" "delegation_chain_row";
2340 "output_rows" "delegation_chain_row"[];
2341 "delegation_row" "delegation"%ROWTYPE;
2342 "row_count" INT4;
2343 "i" INT4;
2344 "loop_v" BOOLEAN;
2345 BEGIN
2346 IF
2347 "unit_id_p" NOTNULL AND
2348 "area_id_p" ISNULL AND
2349 "issue_id_p" ISNULL
2350 THEN
2351 "scope_v" := 'unit';
2352 "unit_id_v" := "unit_id_p";
2353 ELSIF
2354 "unit_id_p" ISNULL AND
2355 "area_id_p" NOTNULL AND
2356 "issue_id_p" ISNULL
2357 THEN
2358 "scope_v" := 'area';
2359 "area_id_v" := "area_id_p";
2360 SELECT "unit_id" INTO "unit_id_v"
2361 FROM "area" WHERE "id" = "area_id_v";
2362 ELSIF
2363 "unit_id_p" ISNULL AND
2364 "area_id_p" ISNULL AND
2365 "issue_id_p" NOTNULL
2366 THEN
2367 "scope_v" := 'issue';
2368 SELECT "area_id" INTO "area_id_v"
2369 FROM "issue" WHERE "id" = "issue_id_p";
2370 SELECT "unit_id" INTO "unit_id_v"
2371 FROM "area" WHERE "id" = "area_id_v";
2372 ELSE
2373 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
2374 END IF;
2375 "visited_member_ids" := '{}';
2376 "loop_member_id_v" := NULL;
2377 "output_rows" := '{}';
2378 "output_row"."index" := 0;
2379 "output_row"."member_id" := "member_id_p";
2380 "output_row"."member_valid" := TRUE;
2381 "output_row"."participation" := FALSE;
2382 "output_row"."overridden" := FALSE;
2383 "output_row"."disabled_out" := FALSE;
2384 "output_row"."scope_out" := NULL;
2385 LOOP
2386 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
2387 "loop_member_id_v" := "output_row"."member_id";
2388 ELSE
2389 "visited_member_ids" :=
2390 "visited_member_ids" || "output_row"."member_id";
2391 END IF;
2392 IF "output_row"."participation" THEN
2393 "output_row"."overridden" := TRUE;
2394 END IF;
2395 "output_row"."scope_in" := "output_row"."scope_out";
2396 IF EXISTS (
2397 SELECT NULL FROM "member" JOIN "privilege"
2398 ON "privilege"."member_id" = "member"."id"
2399 AND "privilege"."unit_id" = "unit_id_v"
2400 WHERE "id" = "output_row"."member_id"
2401 AND "member"."active" AND "privilege"."voting_right"
2402 ) THEN
2403 IF "scope_v" = 'unit' THEN
2404 SELECT * INTO "delegation_row" FROM "delegation"
2405 WHERE "truster_id" = "output_row"."member_id"
2406 AND "unit_id" = "unit_id_v";
2407 ELSIF "scope_v" = 'area' THEN
2408 "output_row"."participation" := EXISTS (
2409 SELECT NULL FROM "membership"
2410 WHERE "area_id" = "area_id_p"
2411 AND "member_id" = "output_row"."member_id"
2412 );
2413 SELECT * INTO "delegation_row" FROM "delegation"
2414 WHERE "truster_id" = "output_row"."member_id"
2415 AND (
2416 "unit_id" = "unit_id_v" OR
2417 "area_id" = "area_id_v"
2419 ORDER BY "scope" DESC;
2420 ELSIF "scope_v" = 'issue' THEN
2421 "output_row"."participation" := EXISTS (
2422 SELECT NULL FROM "interest"
2423 WHERE "issue_id" = "issue_id_p"
2424 AND "member_id" = "output_row"."member_id"
2425 );
2426 SELECT * INTO "delegation_row" FROM "delegation"
2427 WHERE "truster_id" = "output_row"."member_id"
2428 AND (
2429 "unit_id" = "unit_id_v" OR
2430 "area_id" = "area_id_v" OR
2431 "issue_id" = "issue_id_p"
2433 ORDER BY "scope" DESC;
2434 END IF;
2435 ELSE
2436 "output_row"."member_valid" := FALSE;
2437 "output_row"."participation" := FALSE;
2438 "output_row"."scope_out" := NULL;
2439 "delegation_row" := ROW(NULL);
2440 END IF;
2441 IF
2442 "output_row"."member_id" = "member_id_p" AND
2443 "simulate_trustee_id_p" NOTNULL
2444 THEN
2445 "output_row"."scope_out" := "scope_v";
2446 "output_rows" := "output_rows" || "output_row";
2447 "output_row"."member_id" := "simulate_trustee_id_p";
2448 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
2449 "output_row"."scope_out" := "delegation_row"."scope";
2450 "output_rows" := "output_rows" || "output_row";
2451 "output_row"."member_id" := "delegation_row"."trustee_id";
2452 ELSIF "delegation_row"."scope" NOTNULL THEN
2453 "output_row"."scope_out" := "delegation_row"."scope";
2454 "output_row"."disabled_out" := TRUE;
2455 "output_rows" := "output_rows" || "output_row";
2456 EXIT;
2457 ELSE
2458 "output_row"."scope_out" := NULL;
2459 "output_rows" := "output_rows" || "output_row";
2460 EXIT;
2461 END IF;
2462 EXIT WHEN "loop_member_id_v" NOTNULL;
2463 "output_row"."index" := "output_row"."index" + 1;
2464 END LOOP;
2465 "row_count" := array_upper("output_rows", 1);
2466 "i" := 1;
2467 "loop_v" := FALSE;
2468 LOOP
2469 "output_row" := "output_rows"["i"];
2470 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
2471 IF "loop_v" THEN
2472 IF "i" + 1 = "row_count" THEN
2473 "output_row"."loop" := 'last';
2474 ELSIF "i" = "row_count" THEN
2475 "output_row"."loop" := 'repetition';
2476 ELSE
2477 "output_row"."loop" := 'intermediate';
2478 END IF;
2479 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
2480 "output_row"."loop" := 'first';
2481 "loop_v" := TRUE;
2482 END IF;
2483 IF "scope_v" = 'unit' THEN
2484 "output_row"."participation" := NULL;
2485 END IF;
2486 RETURN NEXT "output_row";
2487 "i" := "i" + 1;
2488 END LOOP;
2489 RETURN;
2490 END;
2491 $$;
2493 COMMENT ON FUNCTION "delegation_chain"
2494 ( "member"."id"%TYPE,
2495 "unit"."id"%TYPE,
2496 "area"."id"%TYPE,
2497 "issue"."id"%TYPE,
2498 "member"."id"%TYPE )
2499 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
2502 CREATE FUNCTION "delegation_chain"
2503 ( "member_id_p" "member"."id"%TYPE,
2504 "unit_id_p" "unit"."id"%TYPE,
2505 "area_id_p" "area"."id"%TYPE,
2506 "issue_id_p" "issue"."id"%TYPE )
2507 RETURNS SETOF "delegation_chain_row"
2508 LANGUAGE 'plpgsql' STABLE AS $$
2509 DECLARE
2510 "result_row" "delegation_chain_row";
2511 BEGIN
2512 FOR "result_row" IN
2513 SELECT * FROM "delegation_chain"(
2514 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
2516 LOOP
2517 RETURN NEXT "result_row";
2518 END LOOP;
2519 RETURN;
2520 END;
2521 $$;
2523 COMMENT ON FUNCTION "delegation_chain"
2524 ( "member"."id"%TYPE,
2525 "unit"."id"%TYPE,
2526 "area"."id"%TYPE,
2527 "issue"."id"%TYPE )
2528 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
2532 ------------------------------
2533 -- Comparison by vote count --
2534 ------------------------------
2536 CREATE FUNCTION "vote_ratio"
2537 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
2538 "negative_votes_p" "initiative"."negative_votes"%TYPE )
2539 RETURNS FLOAT8
2540 LANGUAGE 'plpgsql' STABLE AS $$
2541 BEGIN
2542 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
2543 RETURN
2544 "positive_votes_p"::FLOAT8 /
2545 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
2546 ELSIF "positive_votes_p" > 0 THEN
2547 RETURN "positive_votes_p";
2548 ELSIF "negative_votes_p" > 0 THEN
2549 RETURN 1 - "negative_votes_p";
2550 ELSE
2551 RETURN 0.5;
2552 END IF;
2553 END;
2554 $$;
2556 COMMENT ON FUNCTION "vote_ratio"
2557 ( "initiative"."positive_votes"%TYPE,
2558 "initiative"."negative_votes"%TYPE )
2559 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.';
2563 ------------------------------------------------
2564 -- Locking for snapshots and voting procedure --
2565 ------------------------------------------------
2568 CREATE FUNCTION "share_row_lock_issue_trigger"()
2569 RETURNS TRIGGER
2570 LANGUAGE 'plpgsql' VOLATILE AS $$
2571 BEGIN
2572 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2573 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
2574 END IF;
2575 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2576 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
2577 RETURN NEW;
2578 ELSE
2579 RETURN OLD;
2580 END IF;
2581 END;
2582 $$;
2584 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
2587 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
2588 RETURNS TRIGGER
2589 LANGUAGE 'plpgsql' VOLATILE AS $$
2590 BEGIN
2591 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
2592 PERFORM NULL FROM "issue"
2593 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2594 WHERE "initiative"."id" = OLD."initiative_id"
2595 FOR SHARE OF "issue";
2596 END IF;
2597 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2598 PERFORM NULL FROM "issue"
2599 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
2600 WHERE "initiative"."id" = NEW."initiative_id"
2601 FOR SHARE OF "issue";
2602 RETURN NEW;
2603 ELSE
2604 RETURN OLD;
2605 END IF;
2606 END;
2607 $$;
2609 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
2612 CREATE TRIGGER "share_row_lock_issue"
2613 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
2614 FOR EACH ROW EXECUTE PROCEDURE
2615 "share_row_lock_issue_trigger"();
2617 CREATE TRIGGER "share_row_lock_issue"
2618 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
2619 FOR EACH ROW EXECUTE PROCEDURE
2620 "share_row_lock_issue_trigger"();
2622 CREATE TRIGGER "share_row_lock_issue"
2623 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
2624 FOR EACH ROW EXECUTE PROCEDURE
2625 "share_row_lock_issue_trigger"();
2627 CREATE TRIGGER "share_row_lock_issue_via_initiative"
2628 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
2629 FOR EACH ROW EXECUTE PROCEDURE
2630 "share_row_lock_issue_via_initiative_trigger"();
2632 CREATE TRIGGER "share_row_lock_issue"
2633 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
2634 FOR EACH ROW EXECUTE PROCEDURE
2635 "share_row_lock_issue_trigger"();
2637 CREATE TRIGGER "share_row_lock_issue"
2638 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
2639 FOR EACH ROW EXECUTE PROCEDURE
2640 "share_row_lock_issue_trigger"();
2642 CREATE TRIGGER "share_row_lock_issue"
2643 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
2644 FOR EACH ROW EXECUTE PROCEDURE
2645 "share_row_lock_issue_trigger"();
2647 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2648 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2649 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2650 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2651 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2652 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2653 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2656 CREATE FUNCTION "lock_issue"
2657 ( "issue_id_p" "issue"."id"%TYPE )
2658 RETURNS VOID
2659 LANGUAGE 'plpgsql' VOLATILE AS $$
2660 BEGIN
2661 LOCK TABLE "member" IN SHARE MODE;
2662 LOCK TABLE "privilege" IN SHARE MODE;
2663 LOCK TABLE "membership" IN SHARE MODE;
2664 LOCK TABLE "policy" IN SHARE MODE;
2665 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2666 -- NOTE: The row-level exclusive lock in combination with the
2667 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2668 -- acquire a row-level share lock on the issue) ensure that no data
2669 -- is changed, which could affect calculation of snapshots or
2670 -- counting of votes. Table "delegation" must be table-level-locked,
2671 -- as it also contains issue- and global-scope delegations.
2672 LOCK TABLE "delegation" IN SHARE MODE;
2673 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2674 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2675 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2676 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2677 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2678 RETURN;
2679 END;
2680 $$;
2682 COMMENT ON FUNCTION "lock_issue"
2683 ( "issue"."id"%TYPE )
2684 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2688 ------------------------------------------------------------------------
2689 -- Regular tasks, except calculcation of snapshots and voting results --
2690 ------------------------------------------------------------------------
2692 CREATE FUNCTION "check_last_login"()
2693 RETURNS VOID
2694 LANGUAGE 'plpgsql' VOLATILE AS $$
2695 DECLARE
2696 "system_setting_row" "system_setting"%ROWTYPE;
2697 BEGIN
2698 SELECT * INTO "system_setting_row" FROM "system_setting";
2699 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
2700 UPDATE "member" SET "last_login_public" = "last_login"::date
2701 FROM (
2702 SELECT DISTINCT "member"."id"
2703 FROM "member" LEFT JOIN "member_history"
2704 ON "member"."id" = "member_history"."member_id"
2705 WHERE "member"."last_login"::date < 'today' OR (
2706 "member_history"."until"::date >= 'today' AND
2707 "member_history"."active" = FALSE AND "member"."active" = TRUE
2709 ) AS "subquery"
2710 WHERE "member"."id" = "subquery"."id";
2711 IF "system_setting_row"."member_ttl" NOTNULL THEN
2712 UPDATE "member" SET "active" = FALSE
2713 WHERE "active" = TRUE
2714 AND "last_login"::date < 'today'
2715 AND "last_login_public" <
2716 (now() - "system_setting_row"."member_ttl")::date;
2717 END IF;
2718 RETURN;
2719 END;
2720 $$;
2722 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).';
2725 CREATE FUNCTION "calculate_member_counts"()
2726 RETURNS VOID
2727 LANGUAGE 'plpgsql' VOLATILE AS $$
2728 BEGIN
2729 LOCK TABLE "member" IN SHARE MODE;
2730 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2731 LOCK TABLE "unit" IN EXCLUSIVE MODE;
2732 LOCK TABLE "area" IN EXCLUSIVE MODE;
2733 LOCK TABLE "privilege" IN SHARE MODE;
2734 LOCK TABLE "membership" IN SHARE MODE;
2735 DELETE FROM "member_count";
2736 INSERT INTO "member_count" ("total_count")
2737 SELECT "total_count" FROM "member_count_view";
2738 UPDATE "unit" SET "member_count" = "view"."member_count"
2739 FROM "unit_member_count" AS "view"
2740 WHERE "view"."unit_id" = "unit"."id";
2741 UPDATE "area" SET
2742 "direct_member_count" = "view"."direct_member_count",
2743 "member_weight" = "view"."member_weight"
2744 FROM "area_member_count" AS "view"
2745 WHERE "view"."area_id" = "area"."id";
2746 RETURN;
2747 END;
2748 $$;
2750 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"';
2754 ------------------------------
2755 -- Calculation of snapshots --
2756 ------------------------------
2758 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2759 ( "issue_id_p" "issue"."id"%TYPE,
2760 "member_id_p" "member"."id"%TYPE,
2761 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2762 RETURNS "direct_population_snapshot"."weight"%TYPE
2763 LANGUAGE 'plpgsql' VOLATILE AS $$
2764 DECLARE
2765 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2766 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2767 "weight_v" INT4;
2768 "sub_weight_v" INT4;
2769 BEGIN
2770 "weight_v" := 0;
2771 FOR "issue_delegation_row" IN
2772 SELECT * FROM "issue_delegation"
2773 WHERE "trustee_id" = "member_id_p"
2774 AND "issue_id" = "issue_id_p"
2775 LOOP
2776 IF NOT EXISTS (
2777 SELECT NULL FROM "direct_population_snapshot"
2778 WHERE "issue_id" = "issue_id_p"
2779 AND "event" = 'periodic'
2780 AND "member_id" = "issue_delegation_row"."truster_id"
2781 ) AND NOT EXISTS (
2782 SELECT NULL FROM "delegating_population_snapshot"
2783 WHERE "issue_id" = "issue_id_p"
2784 AND "event" = 'periodic'
2785 AND "member_id" = "issue_delegation_row"."truster_id"
2786 ) THEN
2787 "delegate_member_ids_v" :=
2788 "member_id_p" || "delegate_member_ids_p";
2789 INSERT INTO "delegating_population_snapshot" (
2790 "issue_id",
2791 "event",
2792 "member_id",
2793 "scope",
2794 "delegate_member_ids"
2795 ) VALUES (
2796 "issue_id_p",
2797 'periodic',
2798 "issue_delegation_row"."truster_id",
2799 "issue_delegation_row"."scope",
2800 "delegate_member_ids_v"
2801 );
2802 "sub_weight_v" := 1 +
2803 "weight_of_added_delegations_for_population_snapshot"(
2804 "issue_id_p",
2805 "issue_delegation_row"."truster_id",
2806 "delegate_member_ids_v"
2807 );
2808 UPDATE "delegating_population_snapshot"
2809 SET "weight" = "sub_weight_v"
2810 WHERE "issue_id" = "issue_id_p"
2811 AND "event" = 'periodic'
2812 AND "member_id" = "issue_delegation_row"."truster_id";
2813 "weight_v" := "weight_v" + "sub_weight_v";
2814 END IF;
2815 END LOOP;
2816 RETURN "weight_v";
2817 END;
2818 $$;
2820 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2821 ( "issue"."id"%TYPE,
2822 "member"."id"%TYPE,
2823 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2824 IS 'Helper function for "create_population_snapshot" function';
2827 CREATE FUNCTION "create_population_snapshot"
2828 ( "issue_id_p" "issue"."id"%TYPE )
2829 RETURNS VOID
2830 LANGUAGE 'plpgsql' VOLATILE AS $$
2831 DECLARE
2832 "member_id_v" "member"."id"%TYPE;
2833 BEGIN
2834 DELETE FROM "direct_population_snapshot"
2835 WHERE "issue_id" = "issue_id_p"
2836 AND "event" = 'periodic';
2837 DELETE FROM "delegating_population_snapshot"
2838 WHERE "issue_id" = "issue_id_p"
2839 AND "event" = 'periodic';
2840 INSERT INTO "direct_population_snapshot"
2841 ("issue_id", "event", "member_id")
2842 SELECT
2843 "issue_id_p" AS "issue_id",
2844 'periodic'::"snapshot_event" AS "event",
2845 "member"."id" AS "member_id"
2846 FROM "issue"
2847 JOIN "area" ON "issue"."area_id" = "area"."id"
2848 JOIN "membership" ON "area"."id" = "membership"."area_id"
2849 JOIN "member" ON "membership"."member_id" = "member"."id"
2850 JOIN "privilege"
2851 ON "privilege"."unit_id" = "area"."unit_id"
2852 AND "privilege"."member_id" = "member"."id"
2853 WHERE "issue"."id" = "issue_id_p"
2854 AND "member"."active" AND "privilege"."voting_right"
2855 UNION
2856 SELECT
2857 "issue_id_p" AS "issue_id",
2858 'periodic'::"snapshot_event" AS "event",
2859 "member"."id" AS "member_id"
2860 FROM "issue"
2861 JOIN "area" ON "issue"."area_id" = "area"."id"
2862 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2863 JOIN "member" ON "interest"."member_id" = "member"."id"
2864 JOIN "privilege"
2865 ON "privilege"."unit_id" = "area"."unit_id"
2866 AND "privilege"."member_id" = "member"."id"
2867 WHERE "issue"."id" = "issue_id_p"
2868 AND "member"."active" AND "privilege"."voting_right";
2869 FOR "member_id_v" IN
2870 SELECT "member_id" FROM "direct_population_snapshot"
2871 WHERE "issue_id" = "issue_id_p"
2872 AND "event" = 'periodic'
2873 LOOP
2874 UPDATE "direct_population_snapshot" SET
2875 "weight" = 1 +
2876 "weight_of_added_delegations_for_population_snapshot"(
2877 "issue_id_p",
2878 "member_id_v",
2879 '{}'
2881 WHERE "issue_id" = "issue_id_p"
2882 AND "event" = 'periodic'
2883 AND "member_id" = "member_id_v";
2884 END LOOP;
2885 RETURN;
2886 END;
2887 $$;
2889 COMMENT ON FUNCTION "create_population_snapshot"
2890 ( "issue"."id"%TYPE )
2891 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.';
2894 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2895 ( "issue_id_p" "issue"."id"%TYPE,
2896 "member_id_p" "member"."id"%TYPE,
2897 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2898 RETURNS "direct_interest_snapshot"."weight"%TYPE
2899 LANGUAGE 'plpgsql' VOLATILE AS $$
2900 DECLARE
2901 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2902 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2903 "weight_v" INT4;
2904 "sub_weight_v" INT4;
2905 BEGIN
2906 "weight_v" := 0;
2907 FOR "issue_delegation_row" IN
2908 SELECT * FROM "issue_delegation"
2909 WHERE "trustee_id" = "member_id_p"
2910 AND "issue_id" = "issue_id_p"
2911 LOOP
2912 IF NOT EXISTS (
2913 SELECT NULL FROM "direct_interest_snapshot"
2914 WHERE "issue_id" = "issue_id_p"
2915 AND "event" = 'periodic'
2916 AND "member_id" = "issue_delegation_row"."truster_id"
2917 ) AND NOT EXISTS (
2918 SELECT NULL FROM "delegating_interest_snapshot"
2919 WHERE "issue_id" = "issue_id_p"
2920 AND "event" = 'periodic'
2921 AND "member_id" = "issue_delegation_row"."truster_id"
2922 ) THEN
2923 "delegate_member_ids_v" :=
2924 "member_id_p" || "delegate_member_ids_p";
2925 INSERT INTO "delegating_interest_snapshot" (
2926 "issue_id",
2927 "event",
2928 "member_id",
2929 "scope",
2930 "delegate_member_ids"
2931 ) VALUES (
2932 "issue_id_p",
2933 'periodic',
2934 "issue_delegation_row"."truster_id",
2935 "issue_delegation_row"."scope",
2936 "delegate_member_ids_v"
2937 );
2938 "sub_weight_v" := 1 +
2939 "weight_of_added_delegations_for_interest_snapshot"(
2940 "issue_id_p",
2941 "issue_delegation_row"."truster_id",
2942 "delegate_member_ids_v"
2943 );
2944 UPDATE "delegating_interest_snapshot"
2945 SET "weight" = "sub_weight_v"
2946 WHERE "issue_id" = "issue_id_p"
2947 AND "event" = 'periodic'
2948 AND "member_id" = "issue_delegation_row"."truster_id";
2949 "weight_v" := "weight_v" + "sub_weight_v";
2950 END IF;
2951 END LOOP;
2952 RETURN "weight_v";
2953 END;
2954 $$;
2956 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2957 ( "issue"."id"%TYPE,
2958 "member"."id"%TYPE,
2959 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2960 IS 'Helper function for "create_interest_snapshot" function';
2963 CREATE FUNCTION "create_interest_snapshot"
2964 ( "issue_id_p" "issue"."id"%TYPE )
2965 RETURNS VOID
2966 LANGUAGE 'plpgsql' VOLATILE AS $$
2967 DECLARE
2968 "member_id_v" "member"."id"%TYPE;
2969 BEGIN
2970 DELETE FROM "direct_interest_snapshot"
2971 WHERE "issue_id" = "issue_id_p"
2972 AND "event" = 'periodic';
2973 DELETE FROM "delegating_interest_snapshot"
2974 WHERE "issue_id" = "issue_id_p"
2975 AND "event" = 'periodic';
2976 DELETE FROM "direct_supporter_snapshot"
2977 WHERE "issue_id" = "issue_id_p"
2978 AND "event" = 'periodic';
2979 INSERT INTO "direct_interest_snapshot"
2980 ("issue_id", "event", "member_id")
2981 SELECT
2982 "issue_id_p" AS "issue_id",
2983 'periodic' AS "event",
2984 "member"."id" AS "member_id"
2985 FROM "issue"
2986 JOIN "area" ON "issue"."area_id" = "area"."id"
2987 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
2988 JOIN "member" ON "interest"."member_id" = "member"."id"
2989 JOIN "privilege"
2990 ON "privilege"."unit_id" = "area"."unit_id"
2991 AND "privilege"."member_id" = "member"."id"
2992 WHERE "issue"."id" = "issue_id_p"
2993 AND "member"."active" AND "privilege"."voting_right";
2994 FOR "member_id_v" IN
2995 SELECT "member_id" FROM "direct_interest_snapshot"
2996 WHERE "issue_id" = "issue_id_p"
2997 AND "event" = 'periodic'
2998 LOOP
2999 UPDATE "direct_interest_snapshot" SET
3000 "weight" = 1 +
3001 "weight_of_added_delegations_for_interest_snapshot"(
3002 "issue_id_p",
3003 "member_id_v",
3004 '{}'
3006 WHERE "issue_id" = "issue_id_p"
3007 AND "event" = 'periodic'
3008 AND "member_id" = "member_id_v";
3009 END LOOP;
3010 INSERT INTO "direct_supporter_snapshot"
3011 ( "issue_id", "initiative_id", "event", "member_id",
3012 "informed", "satisfied" )
3013 SELECT
3014 "issue_id_p" AS "issue_id",
3015 "initiative"."id" AS "initiative_id",
3016 'periodic' AS "event",
3017 "supporter"."member_id" AS "member_id",
3018 "supporter"."draft_id" = "current_draft"."id" AS "informed",
3019 NOT EXISTS (
3020 SELECT NULL FROM "critical_opinion"
3021 WHERE "initiative_id" = "initiative"."id"
3022 AND "member_id" = "supporter"."member_id"
3023 ) AS "satisfied"
3024 FROM "initiative"
3025 JOIN "supporter"
3026 ON "supporter"."initiative_id" = "initiative"."id"
3027 JOIN "current_draft"
3028 ON "initiative"."id" = "current_draft"."initiative_id"
3029 JOIN "direct_interest_snapshot"
3030 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
3031 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
3032 AND "event" = 'periodic'
3033 WHERE "initiative"."issue_id" = "issue_id_p";
3034 RETURN;
3035 END;
3036 $$;
3038 COMMENT ON FUNCTION "create_interest_snapshot"
3039 ( "issue"."id"%TYPE )
3040 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.';
3043 CREATE FUNCTION "create_snapshot"
3044 ( "issue_id_p" "issue"."id"%TYPE )
3045 RETURNS VOID
3046 LANGUAGE 'plpgsql' VOLATILE AS $$
3047 DECLARE
3048 "initiative_id_v" "initiative"."id"%TYPE;
3049 "suggestion_id_v" "suggestion"."id"%TYPE;
3050 BEGIN
3051 PERFORM "lock_issue"("issue_id_p");
3052 PERFORM "create_population_snapshot"("issue_id_p");
3053 PERFORM "create_interest_snapshot"("issue_id_p");
3054 UPDATE "issue" SET
3055 "snapshot" = now(),
3056 "latest_snapshot_event" = 'periodic',
3057 "population" = (
3058 SELECT coalesce(sum("weight"), 0)
3059 FROM "direct_population_snapshot"
3060 WHERE "issue_id" = "issue_id_p"
3061 AND "event" = 'periodic'
3063 WHERE "id" = "issue_id_p";
3064 FOR "initiative_id_v" IN
3065 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
3066 LOOP
3067 UPDATE "initiative" SET
3068 "supporter_count" = (
3069 SELECT coalesce(sum("di"."weight"), 0)
3070 FROM "direct_interest_snapshot" AS "di"
3071 JOIN "direct_supporter_snapshot" AS "ds"
3072 ON "di"."member_id" = "ds"."member_id"
3073 WHERE "di"."issue_id" = "issue_id_p"
3074 AND "di"."event" = 'periodic'
3075 AND "ds"."initiative_id" = "initiative_id_v"
3076 AND "ds"."event" = 'periodic'
3077 ),
3078 "informed_supporter_count" = (
3079 SELECT coalesce(sum("di"."weight"), 0)
3080 FROM "direct_interest_snapshot" AS "di"
3081 JOIN "direct_supporter_snapshot" AS "ds"
3082 ON "di"."member_id" = "ds"."member_id"
3083 WHERE "di"."issue_id" = "issue_id_p"
3084 AND "di"."event" = 'periodic'
3085 AND "ds"."initiative_id" = "initiative_id_v"
3086 AND "ds"."event" = 'periodic'
3087 AND "ds"."informed"
3088 ),
3089 "satisfied_supporter_count" = (
3090 SELECT coalesce(sum("di"."weight"), 0)
3091 FROM "direct_interest_snapshot" AS "di"
3092 JOIN "direct_supporter_snapshot" AS "ds"
3093 ON "di"."member_id" = "ds"."member_id"
3094 WHERE "di"."issue_id" = "issue_id_p"
3095 AND "di"."event" = 'periodic'
3096 AND "ds"."initiative_id" = "initiative_id_v"
3097 AND "ds"."event" = 'periodic'
3098 AND "ds"."satisfied"
3099 ),
3100 "satisfied_informed_supporter_count" = (
3101 SELECT coalesce(sum("di"."weight"), 0)
3102 FROM "direct_interest_snapshot" AS "di"
3103 JOIN "direct_supporter_snapshot" AS "ds"
3104 ON "di"."member_id" = "ds"."member_id"
3105 WHERE "di"."issue_id" = "issue_id_p"
3106 AND "di"."event" = 'periodic'
3107 AND "ds"."initiative_id" = "initiative_id_v"
3108 AND "ds"."event" = 'periodic'
3109 AND "ds"."informed"
3110 AND "ds"."satisfied"
3112 WHERE "id" = "initiative_id_v";
3113 FOR "suggestion_id_v" IN
3114 SELECT "id" FROM "suggestion"
3115 WHERE "initiative_id" = "initiative_id_v"
3116 LOOP
3117 UPDATE "suggestion" SET
3118 "minus2_unfulfilled_count" = (
3119 SELECT coalesce(sum("snapshot"."weight"), 0)
3120 FROM "issue" CROSS JOIN "opinion"
3121 JOIN "direct_interest_snapshot" AS "snapshot"
3122 ON "snapshot"."issue_id" = "issue"."id"
3123 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3124 AND "snapshot"."member_id" = "opinion"."member_id"
3125 WHERE "issue"."id" = "issue_id_p"
3126 AND "opinion"."suggestion_id" = "suggestion_id_v"
3127 AND "opinion"."degree" = -2
3128 AND "opinion"."fulfilled" = FALSE
3129 ),
3130 "minus2_fulfilled_count" = (
3131 SELECT coalesce(sum("snapshot"."weight"), 0)
3132 FROM "issue" CROSS JOIN "opinion"
3133 JOIN "direct_interest_snapshot" AS "snapshot"
3134 ON "snapshot"."issue_id" = "issue"."id"
3135 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3136 AND "snapshot"."member_id" = "opinion"."member_id"
3137 WHERE "issue"."id" = "issue_id_p"
3138 AND "opinion"."suggestion_id" = "suggestion_id_v"
3139 AND "opinion"."degree" = -2
3140 AND "opinion"."fulfilled" = TRUE
3141 ),
3142 "minus1_unfulfilled_count" = (
3143 SELECT coalesce(sum("snapshot"."weight"), 0)
3144 FROM "issue" CROSS JOIN "opinion"
3145 JOIN "direct_interest_snapshot" AS "snapshot"
3146 ON "snapshot"."issue_id" = "issue"."id"
3147 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3148 AND "snapshot"."member_id" = "opinion"."member_id"
3149 WHERE "issue"."id" = "issue_id_p"
3150 AND "opinion"."suggestion_id" = "suggestion_id_v"
3151 AND "opinion"."degree" = -1
3152 AND "opinion"."fulfilled" = FALSE
3153 ),
3154 "minus1_fulfilled_count" = (
3155 SELECT coalesce(sum("snapshot"."weight"), 0)
3156 FROM "issue" CROSS JOIN "opinion"
3157 JOIN "direct_interest_snapshot" AS "snapshot"
3158 ON "snapshot"."issue_id" = "issue"."id"
3159 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3160 AND "snapshot"."member_id" = "opinion"."member_id"
3161 WHERE "issue"."id" = "issue_id_p"
3162 AND "opinion"."suggestion_id" = "suggestion_id_v"
3163 AND "opinion"."degree" = -1
3164 AND "opinion"."fulfilled" = TRUE
3165 ),
3166 "plus1_unfulfilled_count" = (
3167 SELECT coalesce(sum("snapshot"."weight"), 0)
3168 FROM "issue" CROSS JOIN "opinion"
3169 JOIN "direct_interest_snapshot" AS "snapshot"
3170 ON "snapshot"."issue_id" = "issue"."id"
3171 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3172 AND "snapshot"."member_id" = "opinion"."member_id"
3173 WHERE "issue"."id" = "issue_id_p"
3174 AND "opinion"."suggestion_id" = "suggestion_id_v"
3175 AND "opinion"."degree" = 1
3176 AND "opinion"."fulfilled" = FALSE
3177 ),
3178 "plus1_fulfilled_count" = (
3179 SELECT coalesce(sum("snapshot"."weight"), 0)
3180 FROM "issue" CROSS JOIN "opinion"
3181 JOIN "direct_interest_snapshot" AS "snapshot"
3182 ON "snapshot"."issue_id" = "issue"."id"
3183 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3184 AND "snapshot"."member_id" = "opinion"."member_id"
3185 WHERE "issue"."id" = "issue_id_p"
3186 AND "opinion"."suggestion_id" = "suggestion_id_v"
3187 AND "opinion"."degree" = 1
3188 AND "opinion"."fulfilled" = TRUE
3189 ),
3190 "plus2_unfulfilled_count" = (
3191 SELECT coalesce(sum("snapshot"."weight"), 0)
3192 FROM "issue" CROSS JOIN "opinion"
3193 JOIN "direct_interest_snapshot" AS "snapshot"
3194 ON "snapshot"."issue_id" = "issue"."id"
3195 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3196 AND "snapshot"."member_id" = "opinion"."member_id"
3197 WHERE "issue"."id" = "issue_id_p"
3198 AND "opinion"."suggestion_id" = "suggestion_id_v"
3199 AND "opinion"."degree" = 2
3200 AND "opinion"."fulfilled" = FALSE
3201 ),
3202 "plus2_fulfilled_count" = (
3203 SELECT coalesce(sum("snapshot"."weight"), 0)
3204 FROM "issue" CROSS JOIN "opinion"
3205 JOIN "direct_interest_snapshot" AS "snapshot"
3206 ON "snapshot"."issue_id" = "issue"."id"
3207 AND "snapshot"."event" = "issue"."latest_snapshot_event"
3208 AND "snapshot"."member_id" = "opinion"."member_id"
3209 WHERE "issue"."id" = "issue_id_p"
3210 AND "opinion"."suggestion_id" = "suggestion_id_v"
3211 AND "opinion"."degree" = 2
3212 AND "opinion"."fulfilled" = TRUE
3214 WHERE "suggestion"."id" = "suggestion_id_v";
3215 END LOOP;
3216 END LOOP;
3217 RETURN;
3218 END;
3219 $$;
3221 COMMENT ON FUNCTION "create_snapshot"
3222 ( "issue"."id"%TYPE )
3223 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.';
3226 CREATE FUNCTION "set_snapshot_event"
3227 ( "issue_id_p" "issue"."id"%TYPE,
3228 "event_p" "snapshot_event" )
3229 RETURNS VOID
3230 LANGUAGE 'plpgsql' VOLATILE AS $$
3231 DECLARE
3232 "event_v" "issue"."latest_snapshot_event"%TYPE;
3233 BEGIN
3234 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
3235 WHERE "id" = "issue_id_p" FOR UPDATE;
3236 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
3237 WHERE "id" = "issue_id_p";
3238 UPDATE "direct_population_snapshot" SET "event" = "event_p"
3239 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3240 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
3241 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3242 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
3243 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3244 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
3245 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3246 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
3247 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
3248 RETURN;
3249 END;
3250 $$;
3252 COMMENT ON FUNCTION "set_snapshot_event"
3253 ( "issue"."id"%TYPE,
3254 "snapshot_event" )
3255 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
3259 ---------------------
3260 -- Freezing issues --
3261 ---------------------
3263 CREATE FUNCTION "freeze_after_snapshot"
3264 ( "issue_id_p" "issue"."id"%TYPE )
3265 RETURNS VOID
3266 LANGUAGE 'plpgsql' VOLATILE AS $$
3267 DECLARE
3268 "issue_row" "issue"%ROWTYPE;
3269 "policy_row" "policy"%ROWTYPE;
3270 "initiative_row" "initiative"%ROWTYPE;
3271 BEGIN
3272 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3273 SELECT * INTO "policy_row"
3274 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3275 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
3276 FOR "initiative_row" IN
3277 SELECT * FROM "initiative"
3278 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3279 LOOP
3280 IF
3281 "initiative_row"."satisfied_supporter_count" > 0 AND
3282 "initiative_row"."satisfied_supporter_count" *
3283 "policy_row"."initiative_quorum_den" >=
3284 "issue_row"."population" * "policy_row"."initiative_quorum_num"
3285 THEN
3286 UPDATE "initiative" SET "admitted" = TRUE
3287 WHERE "id" = "initiative_row"."id";
3288 ELSE
3289 UPDATE "initiative" SET "admitted" = FALSE
3290 WHERE "id" = "initiative_row"."id";
3291 END IF;
3292 END LOOP;
3293 IF EXISTS (
3294 SELECT NULL FROM "initiative"
3295 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
3296 ) THEN
3297 UPDATE "issue" SET
3298 "state" = 'voting',
3299 "accepted" = coalesce("accepted", now()),
3300 "half_frozen" = coalesce("half_frozen", now()),
3301 "fully_frozen" = now()
3302 WHERE "id" = "issue_id_p";
3303 ELSE
3304 UPDATE "issue" SET
3305 "state" = 'canceled_no_initiative_admitted',
3306 "accepted" = coalesce("accepted", now()),
3307 "half_frozen" = coalesce("half_frozen", now()),
3308 "fully_frozen" = now(),
3309 "closed" = now(),
3310 "ranks_available" = TRUE
3311 WHERE "id" = "issue_id_p";
3312 -- NOTE: The following DELETE statements have effect only when
3313 -- issue state has been manipulated
3314 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
3315 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
3316 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3317 END IF;
3318 RETURN;
3319 END;
3320 $$;
3322 COMMENT ON FUNCTION "freeze_after_snapshot"
3323 ( "issue"."id"%TYPE )
3324 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
3327 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
3328 RETURNS VOID
3329 LANGUAGE 'plpgsql' VOLATILE AS $$
3330 DECLARE
3331 "issue_row" "issue"%ROWTYPE;
3332 BEGIN
3333 PERFORM "create_snapshot"("issue_id_p");
3334 PERFORM "freeze_after_snapshot"("issue_id_p");
3335 RETURN;
3336 END;
3337 $$;
3339 COMMENT ON FUNCTION "manual_freeze"
3340 ( "issue"."id"%TYPE )
3341 IS 'Freeze an issue manually (fully) and start voting';
3345 -----------------------
3346 -- Counting of votes --
3347 -----------------------
3350 CREATE FUNCTION "weight_of_added_vote_delegations"
3351 ( "issue_id_p" "issue"."id"%TYPE,
3352 "member_id_p" "member"."id"%TYPE,
3353 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
3354 RETURNS "direct_voter"."weight"%TYPE
3355 LANGUAGE 'plpgsql' VOLATILE AS $$
3356 DECLARE
3357 "issue_delegation_row" "issue_delegation"%ROWTYPE;
3358 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
3359 "weight_v" INT4;
3360 "sub_weight_v" INT4;
3361 BEGIN
3362 "weight_v" := 0;
3363 FOR "issue_delegation_row" IN
3364 SELECT * FROM "issue_delegation"
3365 WHERE "trustee_id" = "member_id_p"
3366 AND "issue_id" = "issue_id_p"
3367 LOOP
3368 IF NOT EXISTS (
3369 SELECT NULL FROM "direct_voter"
3370 WHERE "member_id" = "issue_delegation_row"."truster_id"
3371 AND "issue_id" = "issue_id_p"
3372 ) AND NOT EXISTS (
3373 SELECT NULL FROM "delegating_voter"
3374 WHERE "member_id" = "issue_delegation_row"."truster_id"
3375 AND "issue_id" = "issue_id_p"
3376 ) THEN
3377 "delegate_member_ids_v" :=
3378 "member_id_p" || "delegate_member_ids_p";
3379 INSERT INTO "delegating_voter" (
3380 "issue_id",
3381 "member_id",
3382 "scope",
3383 "delegate_member_ids"
3384 ) VALUES (
3385 "issue_id_p",
3386 "issue_delegation_row"."truster_id",
3387 "issue_delegation_row"."scope",
3388 "delegate_member_ids_v"
3389 );
3390 "sub_weight_v" := 1 +
3391 "weight_of_added_vote_delegations"(
3392 "issue_id_p",
3393 "issue_delegation_row"."truster_id",
3394 "delegate_member_ids_v"
3395 );
3396 UPDATE "delegating_voter"
3397 SET "weight" = "sub_weight_v"
3398 WHERE "issue_id" = "issue_id_p"
3399 AND "member_id" = "issue_delegation_row"."truster_id";
3400 "weight_v" := "weight_v" + "sub_weight_v";
3401 END IF;
3402 END LOOP;
3403 RETURN "weight_v";
3404 END;
3405 $$;
3407 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
3408 ( "issue"."id"%TYPE,
3409 "member"."id"%TYPE,
3410 "delegating_voter"."delegate_member_ids"%TYPE )
3411 IS 'Helper function for "add_vote_delegations" function';
3414 CREATE FUNCTION "add_vote_delegations"
3415 ( "issue_id_p" "issue"."id"%TYPE )
3416 RETURNS VOID
3417 LANGUAGE 'plpgsql' VOLATILE AS $$
3418 DECLARE
3419 "member_id_v" "member"."id"%TYPE;
3420 BEGIN
3421 FOR "member_id_v" IN
3422 SELECT "member_id" FROM "direct_voter"
3423 WHERE "issue_id" = "issue_id_p"
3424 LOOP
3425 UPDATE "direct_voter" SET
3426 "weight" = "weight" + "weight_of_added_vote_delegations"(
3427 "issue_id_p",
3428 "member_id_v",
3429 '{}'
3431 WHERE "member_id" = "member_id_v"
3432 AND "issue_id" = "issue_id_p";
3433 END LOOP;
3434 RETURN;
3435 END;
3436 $$;
3438 COMMENT ON FUNCTION "add_vote_delegations"
3439 ( "issue_id_p" "issue"."id"%TYPE )
3440 IS 'Helper function for "close_voting" function';
3443 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
3444 RETURNS VOID
3445 LANGUAGE 'plpgsql' VOLATILE AS $$
3446 DECLARE
3447 "area_id_v" "area"."id"%TYPE;
3448 "unit_id_v" "unit"."id"%TYPE;
3449 "member_id_v" "member"."id"%TYPE;
3450 BEGIN
3451 PERFORM "lock_issue"("issue_id_p");
3452 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
3453 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
3454 -- delete delegating votes (in cases of manual reset of issue state):
3455 DELETE FROM "delegating_voter"
3456 WHERE "issue_id" = "issue_id_p";
3457 -- delete votes from non-privileged voters:
3458 DELETE FROM "direct_voter"
3459 USING (
3460 SELECT
3461 "direct_voter"."member_id"
3462 FROM "direct_voter"
3463 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
3464 LEFT JOIN "privilege"
3465 ON "privilege"."unit_id" = "unit_id_v"
3466 AND "privilege"."member_id" = "direct_voter"."member_id"
3467 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
3468 "member"."active" = FALSE OR
3469 "privilege"."voting_right" ISNULL OR
3470 "privilege"."voting_right" = FALSE
3472 ) AS "subquery"
3473 WHERE "direct_voter"."issue_id" = "issue_id_p"
3474 AND "direct_voter"."member_id" = "subquery"."member_id";
3475 -- consider delegations:
3476 UPDATE "direct_voter" SET "weight" = 1
3477 WHERE "issue_id" = "issue_id_p";
3478 PERFORM "add_vote_delegations"("issue_id_p");
3479 -- set voter count and mark issue as being calculated:
3480 UPDATE "issue" SET
3481 "state" = 'calculation',
3482 "closed" = now(),
3483 "voter_count" = (
3484 SELECT coalesce(sum("weight"), 0)
3485 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
3487 WHERE "id" = "issue_id_p";
3488 -- materialize battle_view:
3489 -- NOTE: "closed" column of issue must be set at this point
3490 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
3491 INSERT INTO "battle" (
3492 "issue_id",
3493 "winning_initiative_id", "losing_initiative_id",
3494 "count"
3495 ) SELECT
3496 "issue_id",
3497 "winning_initiative_id", "losing_initiative_id",
3498 "count"
3499 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
3500 -- copy "positive_votes" and "negative_votes" from "battle" table:
3501 UPDATE "initiative" SET
3502 "positive_votes" = "battle_win"."count",
3503 "negative_votes" = "battle_lose"."count"
3504 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
3505 WHERE
3506 "battle_win"."issue_id" = "issue_id_p" AND
3507 "battle_win"."winning_initiative_id" = "initiative"."id" AND
3508 "battle_win"."losing_initiative_id" ISNULL AND
3509 "battle_lose"."issue_id" = "issue_id_p" AND
3510 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
3511 "battle_lose"."winning_initiative_id" ISNULL;
3512 END;
3513 $$;
3515 COMMENT ON FUNCTION "close_voting"
3516 ( "issue"."id"%TYPE )
3517 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.';
3520 CREATE FUNCTION "defeat_strength"
3521 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
3522 RETURNS INT8
3523 LANGUAGE 'plpgsql' IMMUTABLE AS $$
3524 BEGIN
3525 IF "positive_votes_p" > "negative_votes_p" THEN
3526 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
3527 ELSIF "positive_votes_p" = "negative_votes_p" THEN
3528 RETURN 0;
3529 ELSE
3530 RETURN -1;
3531 END IF;
3532 END;
3533 $$;
3535 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';
3538 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
3539 RETURNS VOID
3540 LANGUAGE 'plpgsql' VOLATILE AS $$
3541 DECLARE
3542 "issue_row" "issue"%ROWTYPE;
3543 "policy_row" "policy"%ROWTYPE;
3544 "dimension_v" INTEGER;
3545 "vote_matrix" INT4[][]; -- absolute votes
3546 "matrix" INT8[][]; -- defeat strength / best paths
3547 "i" INTEGER;
3548 "j" INTEGER;
3549 "k" INTEGER;
3550 "battle_row" "battle"%ROWTYPE;
3551 "rank_ary" INT4[];
3552 "rank_v" INT4;
3553 "done_v" INTEGER;
3554 "winners_ary" INTEGER[];
3555 "initiative_id_v" "initiative"."id"%TYPE;
3556 BEGIN
3557 SELECT * INTO "issue_row"
3558 FROM "issue" WHERE "id" = "issue_id_p"
3559 FOR UPDATE;
3560 SELECT * INTO "policy_row"
3561 FROM "policy" WHERE "id" = "issue_row"."policy_id";
3562 SELECT count(1) INTO "dimension_v"
3563 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
3564 -- Create "vote_matrix" with absolute number of votes in pairwise
3565 -- comparison:
3566 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
3567 "i" := 1;
3568 "j" := 2;
3569 FOR "battle_row" IN
3570 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3571 ORDER BY
3572 "winning_initiative_id" NULLS LAST,
3573 "losing_initiative_id" NULLS LAST
3574 LOOP
3575 "vote_matrix"["i"]["j"] := "battle_row"."count";
3576 IF "j" = "dimension_v" THEN
3577 "i" := "i" + 1;
3578 "j" := 1;
3579 ELSE
3580 "j" := "j" + 1;
3581 IF "j" = "i" THEN
3582 "j" := "j" + 1;
3583 END IF;
3584 END IF;
3585 END LOOP;
3586 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3587 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3588 END IF;
3589 -- Store defeat strengths in "matrix" using "defeat_strength"
3590 -- function:
3591 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
3592 "i" := 1;
3593 LOOP
3594 "j" := 1;
3595 LOOP
3596 IF "i" != "j" THEN
3597 "matrix"["i"]["j"] := "defeat_strength"(
3598 "vote_matrix"["i"]["j"],
3599 "vote_matrix"["j"]["i"]
3600 );
3601 END IF;
3602 EXIT WHEN "j" = "dimension_v";
3603 "j" := "j" + 1;
3604 END LOOP;
3605 EXIT WHEN "i" = "dimension_v";
3606 "i" := "i" + 1;
3607 END LOOP;
3608 -- Find best paths:
3609 "i" := 1;
3610 LOOP
3611 "j" := 1;
3612 LOOP
3613 IF "i" != "j" THEN
3614 "k" := 1;
3615 LOOP
3616 IF "i" != "k" AND "j" != "k" THEN
3617 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3618 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3619 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3620 END IF;
3621 ELSE
3622 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3623 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3624 END IF;
3625 END IF;
3626 END IF;
3627 EXIT WHEN "k" = "dimension_v";
3628 "k" := "k" + 1;
3629 END LOOP;
3630 END IF;
3631 EXIT WHEN "j" = "dimension_v";
3632 "j" := "j" + 1;
3633 END LOOP;
3634 EXIT WHEN "i" = "dimension_v";
3635 "i" := "i" + 1;
3636 END LOOP;
3637 -- Determine order of winners:
3638 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
3639 "rank_v" := 1;
3640 "done_v" := 0;
3641 LOOP
3642 "winners_ary" := '{}';
3643 "i" := 1;
3644 LOOP
3645 IF "rank_ary"["i"] ISNULL THEN
3646 "j" := 1;
3647 LOOP
3648 IF
3649 "i" != "j" AND
3650 "rank_ary"["j"] ISNULL AND
3651 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3652 THEN
3653 -- someone else is better
3654 EXIT;
3655 END IF;
3656 IF "j" = "dimension_v" THEN
3657 -- noone is better
3658 "winners_ary" := "winners_ary" || "i";
3659 EXIT;
3660 END IF;
3661 "j" := "j" + 1;
3662 END LOOP;
3663 END IF;
3664 EXIT WHEN "i" = "dimension_v";
3665 "i" := "i" + 1;
3666 END LOOP;
3667 "i" := 1;
3668 LOOP
3669 "rank_ary"["winners_ary"["i"]] := "rank_v";
3670 "done_v" := "done_v" + 1;
3671 EXIT WHEN "i" = array_upper("winners_ary", 1);
3672 "i" := "i" + 1;
3673 END LOOP;
3674 EXIT WHEN "done_v" = "dimension_v";
3675 "rank_v" := "rank_v" + 1;
3676 END LOOP;
3677 -- write preliminary results:
3678 "i" := 1;
3679 FOR "initiative_id_v" IN
3680 SELECT "id" FROM "initiative"
3681 WHERE "issue_id" = "issue_id_p" AND "admitted"
3682 ORDER BY "id"
3683 LOOP
3684 UPDATE "initiative" SET
3685 "direct_majority" =
3686 CASE WHEN "policy_row"."direct_majority_strict" THEN
3687 "positive_votes" * "policy_row"."direct_majority_den" >
3688 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3689 ELSE
3690 "positive_votes" * "policy_row"."direct_majority_den" >=
3691 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
3692 END
3693 AND "positive_votes" >= "policy_row"."direct_majority_positive"
3694 AND "issue_row"."voter_count"-"negative_votes" >=
3695 "policy_row"."direct_majority_non_negative",
3696 "indirect_majority" =
3697 CASE WHEN "policy_row"."indirect_majority_strict" THEN
3698 "positive_votes" * "policy_row"."indirect_majority_den" >
3699 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3700 ELSE
3701 "positive_votes" * "policy_row"."indirect_majority_den" >=
3702 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
3703 END
3704 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
3705 AND "issue_row"."voter_count"-"negative_votes" >=
3706 "policy_row"."indirect_majority_non_negative",
3707 "schulze_rank" = "rank_ary"["i"],
3708 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
3709 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
3710 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
3711 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
3712 "winner" = FALSE
3713 WHERE "id" = "initiative_id_v";
3714 "i" := "i" + 1;
3715 END LOOP;
3716 IF "i" != "dimension_v" THEN
3717 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3718 END IF;
3719 -- take indirect majorities into account:
3720 LOOP
3721 UPDATE "initiative" SET "indirect_majority" = TRUE
3722 FROM (
3723 SELECT "new_initiative"."id" AS "initiative_id"
3724 FROM "initiative" "old_initiative"
3725 JOIN "initiative" "new_initiative"
3726 ON "new_initiative"."issue_id" = "issue_id_p"
3727 AND "new_initiative"."indirect_majority" = FALSE
3728 JOIN "battle" "battle_win"
3729 ON "battle_win"."issue_id" = "issue_id_p"
3730 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
3731 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
3732 JOIN "battle" "battle_lose"
3733 ON "battle_lose"."issue_id" = "issue_id_p"
3734 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
3735 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
3736 WHERE "old_initiative"."issue_id" = "issue_id_p"
3737 AND "old_initiative"."indirect_majority" = TRUE
3738 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
3739 "battle_win"."count" * "policy_row"."indirect_majority_den" >
3740 "policy_row"."indirect_majority_num" *
3741 ("battle_win"."count"+"battle_lose"."count")
3742 ELSE
3743 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
3744 "policy_row"."indirect_majority_num" *
3745 ("battle_win"."count"+"battle_lose"."count")
3746 END
3747 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
3748 AND "issue_row"."voter_count"-"battle_lose"."count" >=
3749 "policy_row"."indirect_majority_non_negative"
3750 ) AS "subquery"
3751 WHERE "id" = "subquery"."initiative_id";
3752 EXIT WHEN NOT FOUND;
3753 END LOOP;
3754 -- set "multistage_majority" for remaining matching initiatives:
3755 UPDATE "initiative" SET "multistage_majority" = TRUE
3756 FROM (
3757 SELECT "losing_initiative"."id" AS "initiative_id"
3758 FROM "initiative" "losing_initiative"
3759 JOIN "initiative" "winning_initiative"
3760 ON "winning_initiative"."issue_id" = "issue_id_p"
3761 AND "winning_initiative"."admitted"
3762 JOIN "battle" "battle_win"
3763 ON "battle_win"."issue_id" = "issue_id_p"
3764 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
3765 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
3766 JOIN "battle" "battle_lose"
3767 ON "battle_lose"."issue_id" = "issue_id_p"
3768 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
3769 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
3770 WHERE "losing_initiative"."issue_id" = "issue_id_p"
3771 AND "losing_initiative"."admitted"
3772 AND "winning_initiative"."schulze_rank" <
3773 "losing_initiative"."schulze_rank"
3774 AND "battle_win"."count" > "battle_lose"."count"
3775 AND (
3776 "battle_win"."count" > "winning_initiative"."positive_votes" OR
3777 "battle_lose"."count" < "losing_initiative"."negative_votes" )
3778 ) AS "subquery"
3779 WHERE "id" = "subquery"."initiative_id";
3780 -- mark eligible initiatives:
3781 UPDATE "initiative" SET "eligible" = TRUE
3782 WHERE "issue_id" = "issue_id_p"
3783 AND "initiative"."direct_majority"
3784 AND "initiative"."indirect_majority"
3785 AND "initiative"."better_than_status_quo"
3786 AND (
3787 "policy_row"."no_multistage_majority" = FALSE OR
3788 "initiative"."multistage_majority" = FALSE )
3789 AND (
3790 "policy_row"."no_reverse_beat_path" = FALSE OR
3791 "initiative"."reverse_beat_path" = FALSE );
3792 -- mark final winner:
3793 UPDATE "initiative" SET "winner" = TRUE
3794 FROM (
3795 SELECT "id" AS "initiative_id"
3796 FROM "initiative"
3797 WHERE "issue_id" = "issue_id_p" AND "eligible"
3798 ORDER BY "schulze_rank", "id"
3799 LIMIT 1
3800 ) AS "subquery"
3801 WHERE "id" = "subquery"."initiative_id";
3802 -- write (final) ranks:
3803 "rank_v" := 1;
3804 FOR "initiative_id_v" IN
3805 SELECT "id"
3806 FROM "initiative"
3807 WHERE "issue_id" = "issue_id_p" AND "admitted"
3808 ORDER BY "winner" DESC, "schulze_rank", "id"
3809 LOOP
3810 UPDATE "initiative" SET "rank" = "rank_v"
3811 WHERE "id" = "initiative_id_v";
3812 "rank_v" := "rank_v" + 1;
3813 END LOOP;
3814 -- set schulze rank of status quo and mark issue as finished:
3815 UPDATE "issue" SET
3816 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
3817 "state" =
3818 CASE WHEN EXISTS (
3819 SELECT NULL FROM "initiative"
3820 WHERE "issue_id" = "issue_id_p" AND "winner"
3821 ) THEN
3822 'finished_with_winner'::"issue_state"
3823 ELSE
3824 'finished_without_winner'::"issue_state"
3825 END,
3826 "ranks_available" = TRUE
3827 WHERE "id" = "issue_id_p";
3828 RETURN;
3829 END;
3830 $$;
3832 COMMENT ON FUNCTION "calculate_ranks"
3833 ( "issue"."id"%TYPE )
3834 IS 'Determine ranking (Votes have to be counted first)';
3838 -----------------------------
3839 -- Automatic state changes --
3840 -----------------------------
3843 CREATE FUNCTION "check_issue"
3844 ( "issue_id_p" "issue"."id"%TYPE )
3845 RETURNS VOID
3846 LANGUAGE 'plpgsql' VOLATILE AS $$
3847 DECLARE
3848 "issue_row" "issue"%ROWTYPE;
3849 "policy_row" "policy"%ROWTYPE;
3850 BEGIN
3851 PERFORM "lock_issue"("issue_id_p");
3852 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3853 -- only process open issues:
3854 IF "issue_row"."closed" ISNULL THEN
3855 SELECT * INTO "policy_row" FROM "policy"
3856 WHERE "id" = "issue_row"."policy_id";
3857 -- create a snapshot, unless issue is already fully frozen:
3858 IF "issue_row"."fully_frozen" ISNULL THEN
3859 PERFORM "create_snapshot"("issue_id_p");
3860 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3861 END IF;
3862 -- eventually close or accept issues, which have not been accepted:
3863 IF "issue_row"."accepted" ISNULL THEN
3864 IF EXISTS (
3865 SELECT NULL FROM "initiative"
3866 WHERE "issue_id" = "issue_id_p"
3867 AND "supporter_count" > 0
3868 AND "supporter_count" * "policy_row"."issue_quorum_den"
3869 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3870 ) THEN
3871 -- accept issues, if supporter count is high enough
3872 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3873 -- NOTE: "issue_row" used later
3874 "issue_row"."state" := 'discussion';
3875 "issue_row"."accepted" := now();
3876 UPDATE "issue" SET
3877 "state" = "issue_row"."state",
3878 "accepted" = "issue_row"."accepted"
3879 WHERE "id" = "issue_row"."id";
3880 ELSIF
3881 now() >= "issue_row"."created" + "issue_row"."admission_time"
3882 THEN
3883 -- close issues, if admission time has expired
3884 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3885 UPDATE "issue" SET
3886 "state" = 'canceled_issue_not_accepted',
3887 "closed" = now()
3888 WHERE "id" = "issue_row"."id";
3889 END IF;
3890 END IF;
3891 -- eventually half freeze issues:
3892 IF
3893 -- NOTE: issue can't be closed at this point, if it has been accepted
3894 "issue_row"."accepted" NOTNULL AND
3895 "issue_row"."half_frozen" ISNULL
3896 THEN
3897 IF
3898 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3899 THEN
3900 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3901 -- NOTE: "issue_row" used later
3902 "issue_row"."state" := 'verification';
3903 "issue_row"."half_frozen" := now();
3904 UPDATE "issue" SET
3905 "state" = "issue_row"."state",
3906 "half_frozen" = "issue_row"."half_frozen"
3907 WHERE "id" = "issue_row"."id";
3908 END IF;
3909 END IF;
3910 -- close issues after some time, if all initiatives have been revoked:
3911 IF
3912 "issue_row"."closed" ISNULL AND
3913 NOT EXISTS (
3914 -- all initiatives are revoked
3915 SELECT NULL FROM "initiative"
3916 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3917 ) AND (
3918 -- and issue has not been accepted yet
3919 "issue_row"."accepted" ISNULL OR
3920 NOT EXISTS (
3921 -- or no initiatives have been revoked lately
3922 SELECT NULL FROM "initiative"
3923 WHERE "issue_id" = "issue_id_p"
3924 AND now() < "revoked" + "issue_row"."verification_time"
3925 ) OR (
3926 -- or verification time has elapsed
3927 "issue_row"."half_frozen" NOTNULL AND
3928 "issue_row"."fully_frozen" ISNULL AND
3929 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3932 THEN
3933 -- NOTE: "issue_row" used later
3934 IF "issue_row"."accepted" ISNULL THEN
3935 "issue_row"."state" := 'canceled_revoked_before_accepted';
3936 ELSIF "issue_row"."half_frozen" ISNULL THEN
3937 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
3938 ELSE
3939 "issue_row"."state" := 'canceled_after_revocation_during_verification';
3940 END IF;
3941 "issue_row"."closed" := now();
3942 UPDATE "issue" SET
3943 "state" = "issue_row"."state",
3944 "closed" = "issue_row"."closed"
3945 WHERE "id" = "issue_row"."id";
3946 END IF;
3947 -- fully freeze issue after verification time:
3948 IF
3949 "issue_row"."half_frozen" NOTNULL AND
3950 "issue_row"."fully_frozen" ISNULL AND
3951 "issue_row"."closed" ISNULL AND
3952 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3953 THEN
3954 PERFORM "freeze_after_snapshot"("issue_id_p");
3955 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
3956 END IF;
3957 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3958 -- close issue by calling close_voting(...) after voting time:
3959 IF
3960 "issue_row"."closed" ISNULL AND
3961 "issue_row"."fully_frozen" NOTNULL AND
3962 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
3963 THEN
3964 PERFORM "close_voting"("issue_id_p");
3965 -- calculate ranks will not consume much time and can be done now
3966 PERFORM "calculate_ranks"("issue_id_p");
3967 END IF;
3968 END IF;
3969 RETURN;
3970 END;
3971 $$;
3973 COMMENT ON FUNCTION "check_issue"
3974 ( "issue"."id"%TYPE )
3975 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.';
3978 CREATE FUNCTION "check_everything"()
3979 RETURNS VOID
3980 LANGUAGE 'plpgsql' VOLATILE AS $$
3981 DECLARE
3982 "issue_id_v" "issue"."id"%TYPE;
3983 BEGIN
3984 DELETE FROM "expired_session";
3985 PERFORM "check_last_login"();
3986 PERFORM "calculate_member_counts"();
3987 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
3988 PERFORM "check_issue"("issue_id_v");
3989 END LOOP;
3990 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
3991 PERFORM "calculate_ranks"("issue_id_v");
3992 END LOOP;
3993 RETURN;
3994 END;
3995 $$;
3997 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.';
4001 ----------------------
4002 -- Deletion of data --
4003 ----------------------
4006 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
4007 RETURNS VOID
4008 LANGUAGE 'plpgsql' VOLATILE AS $$
4009 DECLARE
4010 "issue_row" "issue"%ROWTYPE;
4011 BEGIN
4012 SELECT * INTO "issue_row"
4013 FROM "issue" WHERE "id" = "issue_id_p"
4014 FOR UPDATE;
4015 IF "issue_row"."cleaned" ISNULL THEN
4016 UPDATE "issue" SET
4017 "state" = 'voting',
4018 "closed" = NULL,
4019 "ranks_available" = FALSE
4020 WHERE "id" = "issue_id_p";
4021 DELETE FROM "issue_comment"
4022 WHERE "issue_id" = "issue_id_p";
4023 DELETE FROM "voting_comment"
4024 WHERE "issue_id" = "issue_id_p";
4025 DELETE FROM "delegating_voter"
4026 WHERE "issue_id" = "issue_id_p";
4027 DELETE FROM "direct_voter"
4028 WHERE "issue_id" = "issue_id_p";
4029 DELETE FROM "delegating_interest_snapshot"
4030 WHERE "issue_id" = "issue_id_p";
4031 DELETE FROM "direct_interest_snapshot"
4032 WHERE "issue_id" = "issue_id_p";
4033 DELETE FROM "delegating_population_snapshot"
4034 WHERE "issue_id" = "issue_id_p";
4035 DELETE FROM "direct_population_snapshot"
4036 WHERE "issue_id" = "issue_id_p";
4037 DELETE FROM "non_voter"
4038 WHERE "issue_id" = "issue_id_p";
4039 DELETE FROM "delegation"
4040 WHERE "issue_id" = "issue_id_p";
4041 DELETE FROM "supporter"
4042 WHERE "issue_id" = "issue_id_p";
4043 UPDATE "issue" SET
4044 "state" = "issue_row"."state",
4045 "closed" = "issue_row"."closed",
4046 "ranks_available" = "issue_row"."ranks_available",
4047 "cleaned" = now()
4048 WHERE "id" = "issue_id_p";
4049 END IF;
4050 RETURN;
4051 END;
4052 $$;
4054 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
4057 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
4058 RETURNS VOID
4059 LANGUAGE 'plpgsql' VOLATILE AS $$
4060 BEGIN
4061 UPDATE "member" SET
4062 "last_login" = NULL,
4063 "last_login_public" = NULL,
4064 "login" = NULL,
4065 "password" = NULL,
4066 "locked" = TRUE,
4067 "active" = FALSE,
4068 "notify_email" = NULL,
4069 "notify_email_unconfirmed" = NULL,
4070 "notify_email_secret" = NULL,
4071 "notify_email_secret_expiry" = NULL,
4072 "notify_email_lock_expiry" = NULL,
4073 "password_reset_secret" = NULL,
4074 "password_reset_secret_expiry" = NULL,
4075 "organizational_unit" = NULL,
4076 "internal_posts" = NULL,
4077 "realname" = NULL,
4078 "birthday" = NULL,
4079 "address" = NULL,
4080 "email" = NULL,
4081 "xmpp_address" = NULL,
4082 "website" = NULL,
4083 "phone" = NULL,
4084 "mobile_phone" = NULL,
4085 "profession" = NULL,
4086 "external_memberships" = NULL,
4087 "external_posts" = NULL,
4088 "statement" = NULL
4089 WHERE "id" = "member_id_p";
4090 -- "text_search_data" is updated by triggers
4091 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
4092 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
4093 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
4094 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
4095 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
4096 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
4097 DELETE FROM "session" WHERE "member_id" = "member_id_p";
4098 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
4099 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
4100 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
4101 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
4102 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
4103 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
4104 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
4105 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
4106 DELETE FROM "direct_voter" USING "issue"
4107 WHERE "direct_voter"."issue_id" = "issue"."id"
4108 AND "issue"."closed" ISNULL
4109 AND "member_id" = "member_id_p";
4110 RETURN;
4111 END;
4112 $$;
4114 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)';
4117 CREATE FUNCTION "delete_private_data"()
4118 RETURNS VOID
4119 LANGUAGE 'plpgsql' VOLATILE AS $$
4120 BEGIN
4121 UPDATE "member" SET
4122 "last_login" = NULL,
4123 "login" = NULL,
4124 "password" = NULL,
4125 "notify_email" = NULL,
4126 "notify_email_unconfirmed" = NULL,
4127 "notify_email_secret" = NULL,
4128 "notify_email_secret_expiry" = NULL,
4129 "notify_email_lock_expiry" = NULL,
4130 "password_reset_secret" = NULL,
4131 "password_reset_secret_expiry" = NULL,
4132 "organizational_unit" = NULL,
4133 "internal_posts" = NULL,
4134 "realname" = NULL,
4135 "birthday" = NULL,
4136 "address" = NULL,
4137 "email" = NULL,
4138 "xmpp_address" = NULL,
4139 "website" = NULL,
4140 "phone" = NULL,
4141 "mobile_phone" = NULL,
4142 "profession" = NULL,
4143 "external_memberships" = NULL,
4144 "external_posts" = NULL,
4145 "statement" = NULL;
4146 -- "text_search_data" is updated by triggers
4147 DELETE FROM "invite_code";
4148 DELETE FROM "setting";
4149 DELETE FROM "setting_map";
4150 DELETE FROM "member_relation_setting";
4151 DELETE FROM "member_image";
4152 DELETE FROM "contact";
4153 DELETE FROM "ignored_member";
4154 DELETE FROM "session";
4155 DELETE FROM "area_setting";
4156 DELETE FROM "issue_setting";
4157 DELETE FROM "ignored_initiative";
4158 DELETE FROM "initiative_setting";
4159 DELETE FROM "suggestion_setting";
4160 DELETE FROM "non_voter";
4161 DELETE FROM "direct_voter" USING "issue"
4162 WHERE "direct_voter"."issue_id" = "issue"."id"
4163 AND "issue"."closed" ISNULL;
4164 RETURN;
4165 END;
4166 $$;
4168 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.';
4172 COMMIT;

Impressum / About Us