liquid_feedback_core

view core.sql @ 167:de59f6b1daf3

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

Impressum / About Us