liquid_feedback_core

view core.sql @ 181:e3b0ea7ab2ad

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

Impressum / About Us