liquid_feedback_core

view core.sql @ 175:62ac82e55a57

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

Impressum / About Us