liquid_feedback_core

view core.sql @ 95:625f88e41125

Added tag v1.3.0 for changeset fb9688f31740
author jbe
date Mon Nov 08 01:46:58 2010 +0100 (2010-11-08)
parents fb9688f31740
children 07e6a4f11b5b
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.3.0', 1, 3, 0))
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 "member" (
58 "id" SERIAL4 PRIMARY KEY,
59 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
60 "last_login" TIMESTAMPTZ,
61 "login" TEXT UNIQUE,
62 "password" TEXT,
63 "active" BOOLEAN NOT NULL DEFAULT TRUE,
64 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
65 "notify_email" TEXT,
66 "notify_email_unconfirmed" TEXT,
67 "notify_email_secret" TEXT UNIQUE,
68 "notify_email_secret_expiry" TIMESTAMPTZ,
69 "notify_email_lock_expiry" TIMESTAMPTZ,
70 "password_reset_secret" TEXT UNIQUE,
71 "password_reset_secret_expiry" TIMESTAMPTZ,
72 "name" TEXT NOT NULL UNIQUE,
73 "identification" TEXT UNIQUE,
74 "organizational_unit" TEXT,
75 "internal_posts" TEXT,
76 "realname" TEXT,
77 "birthday" DATE,
78 "address" TEXT,
79 "email" TEXT,
80 "xmpp_address" TEXT,
81 "website" TEXT,
82 "phone" TEXT,
83 "mobile_phone" TEXT,
84 "profession" TEXT,
85 "external_memberships" TEXT,
86 "external_posts" TEXT,
87 "statement" TEXT,
88 "text_search_data" TSVECTOR );
89 CREATE INDEX "member_active_idx" ON "member" ("active");
90 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
91 CREATE TRIGGER "update_text_search_data"
92 BEFORE INSERT OR UPDATE ON "member"
93 FOR EACH ROW EXECUTE PROCEDURE
94 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
95 "name", "identification", "organizational_unit", "internal_posts",
96 "realname", "external_memberships", "external_posts", "statement" );
98 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
100 COMMENT ON COLUMN "member"."login" IS 'Login name';
101 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
102 COMMENT ON COLUMN "member"."active" IS 'Inactive members can not login and their supports/votes are not counted by the system.';
103 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
104 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
105 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
106 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
107 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
108 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
109 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member';
110 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
111 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
112 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
113 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
114 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
115 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
116 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
117 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his homepage within the system';
120 CREATE TABLE "member_history" (
121 "id" SERIAL8 PRIMARY KEY,
122 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
123 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
124 "active" BOOLEAN NOT NULL,
125 "name" TEXT NOT NULL );
126 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
128 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
130 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
131 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
134 CREATE TABLE "invite_code" (
135 "code" TEXT PRIMARY KEY,
136 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
137 "used" TIMESTAMPTZ,
138 "member_id" INT4 UNIQUE REFERENCES "member" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
139 "comment" TEXT,
140 CONSTRAINT "only_used_codes_may_refer_to_member" CHECK ("used" NOTNULL OR "member_id" ISNULL) );
142 COMMENT ON TABLE "invite_code" IS 'Invite codes can be used once to create a new member account.';
144 COMMENT ON COLUMN "invite_code"."code" IS 'Secret code';
145 COMMENT ON COLUMN "invite_code"."created" IS 'Time of creation of the secret code';
146 COMMENT ON COLUMN "invite_code"."used" IS 'NULL, if not used yet, otherwise tells when this code was used to create a member account';
147 COMMENT ON COLUMN "invite_code"."member_id" IS 'References the member whose account was created with this code';
148 COMMENT ON COLUMN "invite_code"."comment" IS 'Comment on the code, which is to be used for administrative reasons only';
151 CREATE TABLE "setting" (
152 PRIMARY KEY ("member_id", "key"),
153 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
154 "key" TEXT NOT NULL,
155 "value" TEXT NOT NULL );
156 CREATE INDEX "setting_key_idx" ON "setting" ("key");
158 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
160 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
163 CREATE TABLE "setting_map" (
164 PRIMARY KEY ("member_id", "key", "subkey"),
165 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
166 "key" TEXT NOT NULL,
167 "subkey" TEXT NOT NULL,
168 "value" TEXT NOT NULL );
169 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
171 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
173 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
174 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
175 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
178 CREATE TABLE "member_relation_setting" (
179 PRIMARY KEY ("member_id", "key", "other_member_id"),
180 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
181 "key" TEXT NOT NULL,
182 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
183 "value" TEXT NOT NULL );
185 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
188 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
190 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
193 CREATE TABLE "member_image" (
194 PRIMARY KEY ("member_id", "image_type", "scaled"),
195 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
196 "image_type" "member_image_type",
197 "scaled" BOOLEAN,
198 "content_type" TEXT,
199 "data" BYTEA NOT NULL );
201 COMMENT ON TABLE "member_image" IS 'Images of members';
203 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
206 CREATE TABLE "member_count" (
207 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
208 "total_count" INT4 NOT NULL );
210 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';
212 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
213 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
216 CREATE TABLE "contact" (
217 PRIMARY KEY ("member_id", "other_member_id"),
218 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
219 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
220 "public" BOOLEAN NOT NULL DEFAULT FALSE,
221 CONSTRAINT "cant_save_yourself_as_contact"
222 CHECK ("member_id" != "other_member_id") );
224 COMMENT ON TABLE "contact" IS 'Contact lists';
226 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
227 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
228 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
231 CREATE TABLE "session" (
232 "ident" TEXT PRIMARY KEY,
233 "additional_secret" TEXT,
234 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
235 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL,
236 "lang" TEXT );
237 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
239 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend';
241 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
242 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
243 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
244 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
247 CREATE TABLE "policy" (
248 "id" SERIAL4 PRIMARY KEY,
249 "index" INT4 NOT NULL,
250 "active" BOOLEAN NOT NULL DEFAULT TRUE,
251 "name" TEXT NOT NULL UNIQUE,
252 "description" TEXT NOT NULL DEFAULT '',
253 "admission_time" INTERVAL NOT NULL,
254 "discussion_time" INTERVAL NOT NULL,
255 "verification_time" INTERVAL NOT NULL,
256 "voting_time" INTERVAL NOT NULL,
257 "issue_quorum_num" INT4 NOT NULL,
258 "issue_quorum_den" INT4 NOT NULL,
259 "initiative_quorum_num" INT4 NOT NULL,
260 "initiative_quorum_den" INT4 NOT NULL,
261 "majority_num" INT4 NOT NULL DEFAULT 1,
262 "majority_den" INT4 NOT NULL DEFAULT 2,
263 "majority_strict" BOOLEAN NOT NULL DEFAULT TRUE );
264 CREATE INDEX "policy_active_idx" ON "policy" ("active");
266 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
268 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
269 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
270 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum time an issue stays open without being "accepted"';
271 COMMENT ON COLUMN "policy"."discussion_time" IS 'Regular time until an issue is "half_frozen" after being "accepted"';
272 COMMENT ON COLUMN "policy"."verification_time" IS 'Regular time until an issue is "fully_frozen" after being "half_frozen"';
273 COMMENT ON COLUMN "policy"."voting_time" IS 'Time after an issue is "fully_frozen" but not "closed"';
274 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"';
275 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"';
276 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
277 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
278 COMMENT ON COLUMN "policy"."majority_num" IS 'Numerator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
279 COMMENT ON COLUMN "policy"."majority_den" IS 'Denominator of fraction of majority to be reached during voting by an initiative to be aggreed upon';
280 COMMENT ON COLUMN "policy"."majority_strict" IS 'If TRUE, then the majority must be strictly greater than "majority_num"/"majority_den", otherwise it may also be equal.';
283 CREATE TABLE "area" (
284 "id" SERIAL4 PRIMARY KEY,
285 "active" BOOLEAN NOT NULL DEFAULT TRUE,
286 "name" TEXT NOT NULL,
287 "description" TEXT NOT NULL DEFAULT '',
288 "direct_member_count" INT4,
289 "member_weight" INT4,
290 "autoreject_weight" INT4,
291 "text_search_data" TSVECTOR );
292 CREATE INDEX "area_active_idx" ON "area" ("active");
293 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
294 CREATE TRIGGER "update_text_search_data"
295 BEFORE INSERT OR UPDATE ON "area"
296 FOR EACH ROW EXECUTE PROCEDURE
297 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
298 "name", "description" );
300 COMMENT ON TABLE "area" IS 'Subject areas';
302 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
303 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"';
304 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
305 COMMENT ON COLUMN "area"."autoreject_weight" IS 'Sum of weight of members using the autoreject feature';
308 CREATE TABLE "area_setting" (
309 PRIMARY KEY ("member_id", "key", "area_id"),
310 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
311 "key" TEXT NOT NULL,
312 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
313 "value" TEXT NOT NULL );
315 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
318 CREATE TABLE "allowed_policy" (
319 PRIMARY KEY ("area_id", "policy_id"),
320 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
321 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
322 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
323 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
325 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
327 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
330 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
332 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';
335 CREATE TABLE "issue" (
336 "id" SERIAL4 PRIMARY KEY,
337 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
338 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
339 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
340 "accepted" TIMESTAMPTZ,
341 "half_frozen" TIMESTAMPTZ,
342 "fully_frozen" TIMESTAMPTZ,
343 "closed" TIMESTAMPTZ,
344 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE,
345 "cleaned" TIMESTAMPTZ,
346 "admission_time" INTERVAL NOT NULL,
347 "discussion_time" INTERVAL NOT NULL,
348 "verification_time" INTERVAL NOT NULL,
349 "voting_time" INTERVAL NOT NULL,
350 "snapshot" TIMESTAMPTZ,
351 "latest_snapshot_event" "snapshot_event",
352 "population" INT4,
353 "vote_now" INT4,
354 "vote_later" INT4,
355 "voter_count" INT4,
356 CONSTRAINT "valid_state" CHECK (
357 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
358 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
359 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
360 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
361 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
362 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
363 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR
364 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
365 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE) ),
366 CONSTRAINT "state_change_order" CHECK (
367 "created" <= "accepted" AND
368 "accepted" <= "half_frozen" AND
369 "half_frozen" <= "fully_frozen" AND
370 "fully_frozen" <= "closed" ),
371 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
372 "cleaned" ISNULL OR "closed" NOTNULL ),
373 CONSTRAINT "last_snapshot_on_full_freeze"
374 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
375 CONSTRAINT "freeze_requires_snapshot"
376 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
377 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
378 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) );
379 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
380 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
381 CREATE INDEX "issue_created_idx" ON "issue" ("created");
382 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
383 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
384 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
385 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
386 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
387 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
389 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
391 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
392 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.';
393 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.';
394 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.';
395 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated';
396 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
397 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue';
398 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
399 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
400 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
401 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population", "vote_now", "vote_later" and *_count values were precalculated';
402 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';
403 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
404 COMMENT ON COLUMN "issue"."vote_now" IS 'Number of votes in favor of voting now, as calculated from table "direct_interest_snapshot"';
405 COMMENT ON COLUMN "issue"."vote_later" IS 'Number of votes against voting now, as calculated from table "direct_interest_snapshot"';
406 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';
409 CREATE TABLE "issue_setting" (
410 PRIMARY KEY ("member_id", "key", "issue_id"),
411 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
412 "key" TEXT NOT NULL,
413 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
414 "value" TEXT NOT NULL );
416 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
419 CREATE TABLE "initiative" (
420 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
421 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
422 "id" SERIAL4 PRIMARY KEY,
423 "name" TEXT NOT NULL,
424 "discussion_url" TEXT,
425 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
426 "revoked" TIMESTAMPTZ,
427 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
428 "admitted" BOOLEAN,
429 "supporter_count" INT4,
430 "informed_supporter_count" INT4,
431 "satisfied_supporter_count" INT4,
432 "satisfied_informed_supporter_count" INT4,
433 "positive_votes" INT4,
434 "negative_votes" INT4,
435 "agreed" BOOLEAN,
436 "rank" INT4,
437 "text_search_data" TSVECTOR,
438 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
439 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
440 CONSTRAINT "revoked_initiatives_cant_be_admitted"
441 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
442 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results"
443 CHECK (("admitted" NOTNULL AND "admitted" = TRUE) OR ("positive_votes" ISNULL AND "negative_votes" ISNULL AND "agreed" ISNULL)),
444 CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null"
445 CHECK ("positive_votes" NOTNULL = "negative_votes" NOTNULL AND "positive_votes" NOTNULL = "agreed" NOTNULL),
446 CONSTRAINT "non_agreed_initiatives_cant_get_a_rank"
447 CHECK (("agreed" NOTNULL AND "agreed" = TRUE) OR "rank" ISNULL) );
448 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
449 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
450 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
451 CREATE TRIGGER "update_text_search_data"
452 BEFORE INSERT OR UPDATE ON "initiative"
453 FOR EACH ROW EXECUTE PROCEDURE
454 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
455 "name", "discussion_url");
457 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.';
459 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
460 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
461 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
462 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
463 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
464 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
465 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
466 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
467 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
468 COMMENT ON COLUMN "initiative"."agreed" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "majority_num"/"majority_den"';
469 COMMENT ON COLUMN "initiative"."rank" IS 'Rank of approved initiatives (winner is 1), calculated from table "direct_voter"';
472 CREATE TABLE "battle" (
473 PRIMARY KEY ("issue_id", "winning_initiative_id", "losing_initiative_id"),
474 "issue_id" INT4,
475 "winning_initiative_id" INT4,
476 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
477 "losing_initiative_id" INT4,
478 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
479 "count" INT4 NOT NULL);
481 COMMENT ON TABLE "battle" IS 'Number of members preferring one initiative to another; Filled by "battle_view" when closing an issue';
484 CREATE TABLE "initiative_setting" (
485 PRIMARY KEY ("member_id", "key", "initiative_id"),
486 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
487 "key" TEXT NOT NULL,
488 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
489 "value" TEXT NOT NULL );
491 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
494 CREATE TABLE "draft" (
495 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
496 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
497 "id" SERIAL8 PRIMARY KEY,
498 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
499 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
500 "formatting_engine" TEXT,
501 "content" TEXT NOT NULL,
502 "text_search_data" TSVECTOR );
503 CREATE INDEX "draft_created_idx" ON "draft" ("created");
504 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
505 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
506 CREATE TRIGGER "update_text_search_data"
507 BEFORE INSERT OR UPDATE ON "draft"
508 FOR EACH ROW EXECUTE PROCEDURE
509 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
511 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.';
513 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
514 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
517 CREATE TABLE "rendered_draft" (
518 PRIMARY KEY ("draft_id", "format"),
519 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
520 "format" TEXT,
521 "content" TEXT NOT NULL );
523 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)';
526 CREATE TABLE "suggestion" (
527 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
528 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
529 "id" SERIAL8 PRIMARY KEY,
530 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
531 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
532 "name" TEXT NOT NULL,
533 "description" TEXT NOT NULL DEFAULT '',
534 "text_search_data" TSVECTOR,
535 "minus2_unfulfilled_count" INT4,
536 "minus2_fulfilled_count" INT4,
537 "minus1_unfulfilled_count" INT4,
538 "minus1_fulfilled_count" INT4,
539 "plus1_unfulfilled_count" INT4,
540 "plus1_fulfilled_count" INT4,
541 "plus2_unfulfilled_count" INT4,
542 "plus2_fulfilled_count" INT4 );
543 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
544 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
545 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
546 CREATE TRIGGER "update_text_search_data"
547 BEFORE INSERT OR UPDATE ON "suggestion"
548 FOR EACH ROW EXECUTE PROCEDURE
549 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
550 "name", "description");
552 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';
554 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
555 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
556 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
557 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
558 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
559 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
560 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
561 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
564 CREATE TABLE "suggestion_setting" (
565 PRIMARY KEY ("member_id", "key", "suggestion_id"),
566 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
567 "key" TEXT NOT NULL,
568 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
569 "value" TEXT NOT NULL );
571 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
574 CREATE TABLE "membership" (
575 PRIMARY KEY ("area_id", "member_id"),
576 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
577 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
578 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
579 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
581 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
583 COMMENT ON COLUMN "membership"."autoreject" IS 'TRUE = member votes against all initiatives, if he is neither direct_ or delegating_voter; Entries in the "interest" table can override this setting.';
586 CREATE TABLE "interest" (
587 PRIMARY KEY ("issue_id", "member_id"),
588 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
589 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
590 "autoreject" BOOLEAN,
591 "voting_requested" BOOLEAN );
592 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
594 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.';
596 COMMENT ON COLUMN "interest"."autoreject" IS 'TRUE = member votes against all initiatives in case of not explicitly taking part in the voting procedure';
597 COMMENT ON COLUMN "interest"."voting_requested" IS 'TRUE = member wants to vote now, FALSE = member wants to vote later, NULL = policy rules should apply';
600 CREATE TABLE "ignored_issue" (
601 PRIMARY KEY ("issue_id", "member_id"),
602 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
603 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
604 "new" BOOLEAN NOT NULL DEFAULT FALSE,
605 "accepted" BOOLEAN NOT NULL DEFAULT FALSE,
606 "half_frozen" BOOLEAN NOT NULL DEFAULT FALSE,
607 "fully_frozen" BOOLEAN NOT NULL DEFAULT FALSE );
608 CREATE INDEX "ignored_issue_member_id_idx" ON "ignored_issue" ("member_id");
610 COMMENT ON TABLE "ignored_issue" IS 'Table to store member specific options to ignore issues in selected states';
612 COMMENT ON COLUMN "ignored_issue"."new" IS 'Apply when issue is neither closed nor accepted';
613 COMMENT ON COLUMN "ignored_issue"."accepted" IS 'Apply when issue is accepted but not (half_)frozen or closed';
614 COMMENT ON COLUMN "ignored_issue"."half_frozen" IS 'Apply when issue is half_frozen but not fully_frozen or closed';
615 COMMENT ON COLUMN "ignored_issue"."fully_frozen" IS 'Apply when issue is fully_frozen (in voting) and not closed';
618 CREATE TABLE "initiator" (
619 PRIMARY KEY ("initiative_id", "member_id"),
620 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
621 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
622 "accepted" BOOLEAN );
623 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
625 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.';
627 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.';
630 CREATE TABLE "supporter" (
631 "issue_id" INT4 NOT NULL,
632 PRIMARY KEY ("initiative_id", "member_id"),
633 "initiative_id" INT4,
634 "member_id" INT4,
635 "draft_id" INT8 NOT NULL,
636 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
637 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE );
638 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
640 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.';
642 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft, defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
645 CREATE TABLE "opinion" (
646 "initiative_id" INT4 NOT NULL,
647 PRIMARY KEY ("suggestion_id", "member_id"),
648 "suggestion_id" INT8,
649 "member_id" INT4,
650 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
651 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
652 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
653 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
654 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
656 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.';
658 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
661 CREATE TYPE "delegation_scope" AS ENUM ('global', 'area', 'issue');
663 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''global'', ''area'', or ''issue'' (order is relevant)';
666 CREATE TABLE "delegation" (
667 "id" SERIAL8 PRIMARY KEY,
668 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
669 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
670 "scope" "delegation_scope" NOT NULL,
671 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
672 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
673 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
674 CONSTRAINT "no_global_delegation_to_null"
675 CHECK ("trustee_id" NOTNULL OR "scope" != 'global'),
676 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
677 ("scope" = 'global' AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
678 ("scope" = 'area' AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
679 ("scope" = 'issue' AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
680 UNIQUE ("area_id", "truster_id"),
681 UNIQUE ("issue_id", "truster_id") );
682 CREATE UNIQUE INDEX "delegation_global_truster_id_unique_idx"
683 ON "delegation" ("truster_id") WHERE "scope" = 'global';
684 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
685 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
687 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
689 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
690 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
693 CREATE TABLE "direct_population_snapshot" (
694 PRIMARY KEY ("issue_id", "event", "member_id"),
695 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
696 "event" "snapshot_event",
697 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
698 "weight" INT4 );
699 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
701 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"';
703 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
704 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
707 CREATE TABLE "delegating_population_snapshot" (
708 PRIMARY KEY ("issue_id", "event", "member_id"),
709 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
710 "event" "snapshot_event",
711 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
712 "weight" INT4,
713 "scope" "delegation_scope" NOT NULL,
714 "delegate_member_ids" INT4[] NOT NULL );
715 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
717 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table';
719 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
720 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
721 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
722 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"';
725 CREATE TABLE "direct_interest_snapshot" (
726 PRIMARY KEY ("issue_id", "event", "member_id"),
727 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
728 "event" "snapshot_event",
729 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
730 "weight" INT4,
731 "voting_requested" BOOLEAN );
732 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
734 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"';
736 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
737 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
738 COMMENT ON COLUMN "direct_interest_snapshot"."voting_requested" IS 'Copied from column "voting_requested" of table "interest"';
741 CREATE TABLE "delegating_interest_snapshot" (
742 PRIMARY KEY ("issue_id", "event", "member_id"),
743 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
744 "event" "snapshot_event",
745 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
746 "weight" INT4,
747 "scope" "delegation_scope" NOT NULL,
748 "delegate_member_ids" INT4[] NOT NULL );
749 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
751 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table';
753 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
754 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
755 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
756 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"';
759 CREATE TABLE "direct_supporter_snapshot" (
760 "issue_id" INT4 NOT NULL,
761 PRIMARY KEY ("initiative_id", "event", "member_id"),
762 "initiative_id" INT4,
763 "event" "snapshot_event",
764 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
765 "informed" BOOLEAN NOT NULL,
766 "satisfied" BOOLEAN NOT NULL,
767 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
768 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
769 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
771 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")';
773 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
774 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
775 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
778 CREATE TABLE "direct_voter" (
779 PRIMARY KEY ("issue_id", "member_id"),
780 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
781 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
782 "weight" INT4,
783 "autoreject" BOOLEAN NOT NULL DEFAULT FALSE );
784 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
786 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.';
788 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
789 COMMENT ON COLUMN "direct_voter"."autoreject" IS 'Votes were inserted due to "autoreject" feature';
792 CREATE TABLE "delegating_voter" (
793 PRIMARY KEY ("issue_id", "member_id"),
794 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
795 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
796 "weight" INT4,
797 "scope" "delegation_scope" NOT NULL,
798 "delegate_member_ids" INT4[] NOT NULL );
799 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
801 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table';
803 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
804 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
805 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"';
808 CREATE TABLE "vote" (
809 "issue_id" INT4 NOT NULL,
810 PRIMARY KEY ("initiative_id", "member_id"),
811 "initiative_id" INT4,
812 "member_id" INT4,
813 "grade" INT4,
814 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
815 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
816 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
818 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.';
820 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.';
823 CREATE TABLE "contingent" (
824 "time_frame" INTERVAL PRIMARY KEY,
825 "text_entry_limit" INT4,
826 "initiative_limit" INT4 );
828 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.';
830 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';
831 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
835 --------------------------------
836 -- Writing of history entries --
837 --------------------------------
839 CREATE FUNCTION "write_member_history_trigger"()
840 RETURNS TRIGGER
841 LANGUAGE 'plpgsql' VOLATILE AS $$
842 BEGIN
843 IF
844 NEW."active" != OLD."active" OR
845 NEW."name" != OLD."name"
846 THEN
847 INSERT INTO "member_history"
848 ("member_id", "active", "name")
849 VALUES (NEW."id", OLD."active", OLD."name");
850 END IF;
851 RETURN NULL;
852 END;
853 $$;
855 CREATE TRIGGER "write_member_history"
856 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
857 "write_member_history_trigger"();
859 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
860 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
864 ----------------------------
865 -- Additional constraints --
866 ----------------------------
869 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
870 RETURNS TRIGGER
871 LANGUAGE 'plpgsql' VOLATILE AS $$
872 BEGIN
873 IF NOT EXISTS (
874 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
875 ) THEN
876 --RAISE 'Cannot create issue without an initial initiative.' USING
877 -- ERRCODE = 'integrity_constraint_violation',
878 -- HINT = 'Create issue, initiative, and draft within the same transaction.';
879 RAISE EXCEPTION 'Cannot create issue without an initial initiative.';
880 END IF;
881 RETURN NULL;
882 END;
883 $$;
885 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
886 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
887 FOR EACH ROW EXECUTE PROCEDURE
888 "issue_requires_first_initiative_trigger"();
890 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
891 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
894 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
895 RETURNS TRIGGER
896 LANGUAGE 'plpgsql' VOLATILE AS $$
897 DECLARE
898 "reference_lost" BOOLEAN;
899 BEGIN
900 IF TG_OP = 'DELETE' THEN
901 "reference_lost" := TRUE;
902 ELSE
903 "reference_lost" := NEW."issue_id" != OLD."issue_id";
904 END IF;
905 IF
906 "reference_lost" AND NOT EXISTS (
907 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
908 )
909 THEN
910 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
911 END IF;
912 RETURN NULL;
913 END;
914 $$;
916 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
917 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
918 FOR EACH ROW EXECUTE PROCEDURE
919 "last_initiative_deletes_issue_trigger"();
921 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
922 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
925 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
926 RETURNS TRIGGER
927 LANGUAGE 'plpgsql' VOLATILE AS $$
928 BEGIN
929 IF NOT EXISTS (
930 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
931 ) THEN
932 --RAISE 'Cannot create initiative without an initial draft.' USING
933 -- ERRCODE = 'integrity_constraint_violation',
934 -- HINT = 'Create issue, initiative and draft within the same transaction.';
935 RAISE EXCEPTION 'Cannot create initiative without an initial draft.';
936 END IF;
937 RETURN NULL;
938 END;
939 $$;
941 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
942 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
943 FOR EACH ROW EXECUTE PROCEDURE
944 "initiative_requires_first_draft_trigger"();
946 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
947 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
950 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
951 RETURNS TRIGGER
952 LANGUAGE 'plpgsql' VOLATILE AS $$
953 DECLARE
954 "reference_lost" BOOLEAN;
955 BEGIN
956 IF TG_OP = 'DELETE' THEN
957 "reference_lost" := TRUE;
958 ELSE
959 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
960 END IF;
961 IF
962 "reference_lost" AND NOT EXISTS (
963 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
964 )
965 THEN
966 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
967 END IF;
968 RETURN NULL;
969 END;
970 $$;
972 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
973 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
974 FOR EACH ROW EXECUTE PROCEDURE
975 "last_draft_deletes_initiative_trigger"();
977 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
978 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
981 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
982 RETURNS TRIGGER
983 LANGUAGE 'plpgsql' VOLATILE AS $$
984 BEGIN
985 IF NOT EXISTS (
986 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
987 ) THEN
988 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.';
989 END IF;
990 RETURN NULL;
991 END;
992 $$;
994 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
995 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
996 FOR EACH ROW EXECUTE PROCEDURE
997 "suggestion_requires_first_opinion_trigger"();
999 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
1000 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
1003 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
1004 RETURNS TRIGGER
1005 LANGUAGE 'plpgsql' VOLATILE AS $$
1006 DECLARE
1007 "reference_lost" BOOLEAN;
1008 BEGIN
1009 IF TG_OP = 'DELETE' THEN
1010 "reference_lost" := TRUE;
1011 ELSE
1012 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
1013 END IF;
1014 IF
1015 "reference_lost" AND NOT EXISTS (
1016 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
1018 THEN
1019 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
1020 END IF;
1021 RETURN NULL;
1022 END;
1023 $$;
1025 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
1026 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
1027 FOR EACH ROW EXECUTE PROCEDURE
1028 "last_opinion_deletes_suggestion_trigger"();
1030 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
1031 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
1035 ---------------------------------------------------------------
1036 -- Ensure that votes are not modified when issues are frozen --
1037 ---------------------------------------------------------------
1039 -- NOTE: Frontends should ensure this anyway, but in case of programming
1040 -- errors the following triggers ensure data integrity.
1043 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
1044 RETURNS TRIGGER
1045 LANGUAGE 'plpgsql' VOLATILE AS $$
1046 DECLARE
1047 "issue_id_v" "issue"."id"%TYPE;
1048 "issue_row" "issue"%ROWTYPE;
1049 BEGIN
1050 IF TG_OP = 'DELETE' THEN
1051 "issue_id_v" := OLD."issue_id";
1052 ELSE
1053 "issue_id_v" := NEW."issue_id";
1054 END IF;
1055 SELECT INTO "issue_row" * FROM "issue"
1056 WHERE "id" = "issue_id_v" FOR SHARE;
1057 IF "issue_row"."closed" NOTNULL THEN
1058 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
1059 END IF;
1060 RETURN NULL;
1061 END;
1062 $$;
1064 CREATE TRIGGER "forbid_changes_on_closed_issue"
1065 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
1066 FOR EACH ROW EXECUTE PROCEDURE
1067 "forbid_changes_on_closed_issue_trigger"();
1069 CREATE TRIGGER "forbid_changes_on_closed_issue"
1070 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
1071 FOR EACH ROW EXECUTE PROCEDURE
1072 "forbid_changes_on_closed_issue_trigger"();
1074 CREATE TRIGGER "forbid_changes_on_closed_issue"
1075 AFTER INSERT OR UPDATE OR DELETE ON "vote"
1076 FOR EACH ROW EXECUTE PROCEDURE
1077 "forbid_changes_on_closed_issue_trigger"();
1079 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"';
1080 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';
1081 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';
1082 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';
1086 --------------------------------------------------------------------
1087 -- Auto-retrieval of fields only needed for referential integrity --
1088 --------------------------------------------------------------------
1091 CREATE FUNCTION "autofill_issue_id_trigger"()
1092 RETURNS TRIGGER
1093 LANGUAGE 'plpgsql' VOLATILE AS $$
1094 BEGIN
1095 IF NEW."issue_id" ISNULL THEN
1096 SELECT "issue_id" INTO NEW."issue_id"
1097 FROM "initiative" WHERE "id" = NEW."initiative_id";
1098 END IF;
1099 RETURN NEW;
1100 END;
1101 $$;
1103 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
1104 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1106 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
1107 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
1109 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
1110 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
1111 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
1114 CREATE FUNCTION "autofill_initiative_id_trigger"()
1115 RETURNS TRIGGER
1116 LANGUAGE 'plpgsql' VOLATILE AS $$
1117 BEGIN
1118 IF NEW."initiative_id" ISNULL THEN
1119 SELECT "initiative_id" INTO NEW."initiative_id"
1120 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1121 END IF;
1122 RETURN NEW;
1123 END;
1124 $$;
1126 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
1127 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
1129 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
1130 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
1134 -----------------------------------------------------
1135 -- Automatic calculation of certain default values --
1136 -----------------------------------------------------
1139 CREATE FUNCTION "copy_timings_trigger"()
1140 RETURNS TRIGGER
1141 LANGUAGE 'plpgsql' VOLATILE AS $$
1142 DECLARE
1143 "policy_row" "policy"%ROWTYPE;
1144 BEGIN
1145 SELECT * INTO "policy_row" FROM "policy"
1146 WHERE "id" = NEW."policy_id";
1147 IF NEW."admission_time" ISNULL THEN
1148 NEW."admission_time" := "policy_row"."admission_time";
1149 END IF;
1150 IF NEW."discussion_time" ISNULL THEN
1151 NEW."discussion_time" := "policy_row"."discussion_time";
1152 END IF;
1153 IF NEW."verification_time" ISNULL THEN
1154 NEW."verification_time" := "policy_row"."verification_time";
1155 END IF;
1156 IF NEW."voting_time" ISNULL THEN
1157 NEW."voting_time" := "policy_row"."voting_time";
1158 END IF;
1159 RETURN NEW;
1160 END;
1161 $$;
1163 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
1164 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
1166 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
1167 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
1170 CREATE FUNCTION "supporter_default_for_draft_id_trigger"()
1171 RETURNS TRIGGER
1172 LANGUAGE 'plpgsql' VOLATILE AS $$
1173 BEGIN
1174 IF NEW."draft_id" ISNULL THEN
1175 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
1176 WHERE "initiative_id" = NEW."initiative_id";
1177 END IF;
1178 RETURN NEW;
1179 END;
1180 $$;
1182 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
1183 FOR EACH ROW EXECUTE PROCEDURE "supporter_default_for_draft_id_trigger"();
1185 COMMENT ON FUNCTION "supporter_default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on table "supporter"';
1186 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';
1190 ----------------------------------------
1191 -- Automatic creation of dependencies --
1192 ----------------------------------------
1195 CREATE FUNCTION "autocreate_interest_trigger"()
1196 RETURNS TRIGGER
1197 LANGUAGE 'plpgsql' VOLATILE AS $$
1198 BEGIN
1199 IF NOT EXISTS (
1200 SELECT NULL FROM "initiative" JOIN "interest"
1201 ON "initiative"."issue_id" = "interest"."issue_id"
1202 WHERE "initiative"."id" = NEW."initiative_id"
1203 AND "interest"."member_id" = NEW."member_id"
1204 ) THEN
1205 BEGIN
1206 INSERT INTO "interest" ("issue_id", "member_id")
1207 SELECT "issue_id", NEW."member_id"
1208 FROM "initiative" WHERE "id" = NEW."initiative_id";
1209 EXCEPTION WHEN unique_violation THEN END;
1210 END IF;
1211 RETURN NEW;
1212 END;
1213 $$;
1215 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
1216 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
1218 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
1219 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';
1222 CREATE FUNCTION "autocreate_supporter_trigger"()
1223 RETURNS TRIGGER
1224 LANGUAGE 'plpgsql' VOLATILE AS $$
1225 BEGIN
1226 IF NOT EXISTS (
1227 SELECT NULL FROM "suggestion" JOIN "supporter"
1228 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
1229 WHERE "suggestion"."id" = NEW."suggestion_id"
1230 AND "supporter"."member_id" = NEW."member_id"
1231 ) THEN
1232 BEGIN
1233 INSERT INTO "supporter" ("initiative_id", "member_id")
1234 SELECT "initiative_id", NEW."member_id"
1235 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
1236 EXCEPTION WHEN unique_violation THEN END;
1237 END IF;
1238 RETURN NEW;
1239 END;
1240 $$;
1242 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
1243 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
1245 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
1246 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.';
1250 ------------------------------------------
1251 -- Views and helper functions for views --
1252 ------------------------------------------
1255 CREATE VIEW "active_delegation" AS
1256 SELECT "delegation".* FROM "delegation"
1257 JOIN "member" ON "delegation"."truster_id" = "member"."id"
1258 WHERE "member"."active" = TRUE;
1260 COMMENT ON VIEW "active_delegation" IS 'Helper view for views "global_delegation", "area_delegation" and "issue_delegation": Contains delegations where the truster_id refers to an active member and includes those delegations where trustee_id is NULL';
1263 CREATE VIEW "global_delegation" AS
1264 SELECT "id", "truster_id", "trustee_id"
1265 FROM "active_delegation" WHERE "scope" = 'global';
1267 COMMENT ON VIEW "global_delegation" IS 'Global delegations from active members';
1270 CREATE VIEW "area_delegation" AS
1271 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
1272 "area"."id" AS "area_id",
1273 "delegation"."id",
1274 "delegation"."truster_id",
1275 "delegation"."trustee_id",
1276 "delegation"."scope"
1277 FROM "area" JOIN "active_delegation" AS "delegation"
1278 ON "delegation"."scope" = 'global'
1279 OR "delegation"."area_id" = "area"."id"
1280 ORDER BY
1281 "area"."id",
1282 "delegation"."truster_id",
1283 "delegation"."scope" DESC;
1285 COMMENT ON VIEW "area_delegation" IS 'Resulting area delegations from active members; can include rows with trustee_id set to NULL';
1288 CREATE VIEW "issue_delegation" AS
1289 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
1290 "issue"."id" AS "issue_id",
1291 "delegation"."id",
1292 "delegation"."truster_id",
1293 "delegation"."trustee_id",
1294 "delegation"."scope"
1295 FROM "issue" JOIN "active_delegation" AS "delegation"
1296 ON "delegation"."scope" = 'global'
1297 OR "delegation"."area_id" = "issue"."area_id"
1298 OR "delegation"."issue_id" = "issue"."id"
1299 ORDER BY
1300 "issue"."id",
1301 "delegation"."truster_id",
1302 "delegation"."scope" DESC;
1304 COMMENT ON VIEW "issue_delegation" IS 'Resulting issue delegations from active members; can include rows with trustee_id set to NULL';
1307 CREATE FUNCTION "membership_weight_with_skipping"
1308 ( "area_id_p" "area"."id"%TYPE,
1309 "member_id_p" "member"."id"%TYPE,
1310 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
1311 RETURNS INT4
1312 LANGUAGE 'plpgsql' STABLE AS $$
1313 DECLARE
1314 "sum_v" INT4;
1315 "delegation_row" "area_delegation"%ROWTYPE;
1316 BEGIN
1317 "sum_v" := 1;
1318 FOR "delegation_row" IN
1319 SELECT "area_delegation".*
1320 FROM "area_delegation" LEFT JOIN "membership"
1321 ON "membership"."area_id" = "area_id_p"
1322 AND "membership"."member_id" = "area_delegation"."truster_id"
1323 WHERE "area_delegation"."area_id" = "area_id_p"
1324 AND "area_delegation"."trustee_id" = "member_id_p"
1325 AND "membership"."member_id" ISNULL
1326 LOOP
1327 IF NOT
1328 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
1329 THEN
1330 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
1331 "area_id_p",
1332 "delegation_row"."truster_id",
1333 "skip_member_ids_p" || "delegation_row"."truster_id"
1334 );
1335 END IF;
1336 END LOOP;
1337 RETURN "sum_v";
1338 END;
1339 $$;
1341 COMMENT ON FUNCTION "membership_weight_with_skipping"
1342 ( "area"."id"%TYPE,
1343 "member"."id"%TYPE,
1344 INT4[] )
1345 IS 'Helper function for "membership_weight" function';
1348 CREATE FUNCTION "membership_weight"
1349 ( "area_id_p" "area"."id"%TYPE,
1350 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
1351 RETURNS INT4
1352 LANGUAGE 'plpgsql' STABLE AS $$
1353 BEGIN
1354 RETURN "membership_weight_with_skipping"(
1355 "area_id_p",
1356 "member_id_p",
1357 ARRAY["member_id_p"]
1358 );
1359 END;
1360 $$;
1362 COMMENT ON FUNCTION "membership_weight"
1363 ( "area"."id"%TYPE,
1364 "member"."id"%TYPE )
1365 IS 'Calculates the potential voting weight of a member in a given area';
1368 CREATE VIEW "member_count_view" AS
1369 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
1371 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
1374 CREATE VIEW "area_member_count" AS
1375 SELECT
1376 "area"."id" AS "area_id",
1377 count("member"."id") AS "direct_member_count",
1378 coalesce(
1379 sum(
1380 CASE WHEN "member"."id" NOTNULL THEN
1381 "membership_weight"("area"."id", "member"."id")
1382 ELSE 0 END
1384 ) AS "member_weight",
1385 coalesce(
1386 sum(
1387 CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
1388 "membership_weight"("area"."id", "member"."id")
1389 ELSE 0 END
1391 ) AS "autoreject_weight"
1392 FROM "area"
1393 LEFT JOIN "membership"
1394 ON "area"."id" = "membership"."area_id"
1395 LEFT JOIN "member"
1396 ON "membership"."member_id" = "member"."id"
1397 AND "member"."active"
1398 GROUP BY "area"."id";
1400 COMMENT ON VIEW "area_member_count" IS 'View used to update "member_count" column of table "area"';
1403 CREATE VIEW "opening_draft" AS
1404 SELECT "draft".* FROM (
1405 SELECT
1406 "initiative"."id" AS "initiative_id",
1407 min("draft"."id") AS "draft_id"
1408 FROM "initiative" JOIN "draft"
1409 ON "initiative"."id" = "draft"."initiative_id"
1410 GROUP BY "initiative"."id"
1411 ) AS "subquery"
1412 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1414 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1417 CREATE VIEW "current_draft" AS
1418 SELECT "draft".* FROM (
1419 SELECT
1420 "initiative"."id" AS "initiative_id",
1421 max("draft"."id") AS "draft_id"
1422 FROM "initiative" JOIN "draft"
1423 ON "initiative"."id" = "draft"."initiative_id"
1424 GROUP BY "initiative"."id"
1425 ) AS "subquery"
1426 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
1428 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1431 CREATE VIEW "critical_opinion" AS
1432 SELECT * FROM "opinion"
1433 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
1434 OR ("degree" = -2 AND "fulfilled" = TRUE);
1436 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
1439 CREATE VIEW "battle_view" AS
1440 SELECT
1441 "issue"."id" AS "issue_id",
1442 "winning_initiative"."id" AS "winning_initiative_id",
1443 "losing_initiative"."id" AS "losing_initiative_id",
1444 sum(
1445 CASE WHEN
1446 coalesce("better_vote"."grade", 0) >
1447 coalesce("worse_vote"."grade", 0)
1448 THEN "direct_voter"."weight" ELSE 0 END
1449 ) AS "count"
1450 FROM "issue"
1451 LEFT JOIN "direct_voter"
1452 ON "issue"."id" = "direct_voter"."issue_id"
1453 JOIN "initiative" AS "winning_initiative"
1454 ON "issue"."id" = "winning_initiative"."issue_id"
1455 AND "winning_initiative"."agreed"
1456 JOIN "initiative" AS "losing_initiative"
1457 ON "issue"."id" = "losing_initiative"."issue_id"
1458 AND "losing_initiative"."agreed"
1459 LEFT JOIN "vote" AS "better_vote"
1460 ON "direct_voter"."member_id" = "better_vote"."member_id"
1461 AND "winning_initiative"."id" = "better_vote"."initiative_id"
1462 LEFT JOIN "vote" AS "worse_vote"
1463 ON "direct_voter"."member_id" = "worse_vote"."member_id"
1464 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
1465 WHERE "issue"."closed" NOTNULL
1466 AND "issue"."cleaned" ISNULL
1467 AND "winning_initiative"."id" != "losing_initiative"."id"
1468 GROUP BY
1469 "issue"."id",
1470 "winning_initiative"."id",
1471 "losing_initiative"."id";
1473 COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative to another; Used to fill "battle" table';
1476 CREATE VIEW "expired_session" AS
1477 SELECT * FROM "session" WHERE now() > "expiry";
1479 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
1480 DELETE FROM "session" WHERE "ident" = OLD."ident";
1482 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
1483 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
1486 CREATE VIEW "open_issue" AS
1487 SELECT * FROM "issue" WHERE "closed" ISNULL;
1489 COMMENT ON VIEW "open_issue" IS 'All open issues';
1492 CREATE VIEW "issue_with_ranks_missing" AS
1493 SELECT * FROM "issue"
1494 WHERE "fully_frozen" NOTNULL
1495 AND "closed" NOTNULL
1496 AND "ranks_available" = FALSE;
1498 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
1501 CREATE VIEW "member_contingent" AS
1502 SELECT
1503 "member"."id" AS "member_id",
1504 "contingent"."time_frame",
1505 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
1507 SELECT count(1) FROM "draft"
1508 WHERE "draft"."author_id" = "member"."id"
1509 AND "draft"."created" > now() - "contingent"."time_frame"
1510 ) + (
1511 SELECT count(1) FROM "suggestion"
1512 WHERE "suggestion"."author_id" = "member"."id"
1513 AND "suggestion"."created" > now() - "contingent"."time_frame"
1515 ELSE NULL END AS "text_entry_count",
1516 "contingent"."text_entry_limit",
1517 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
1518 SELECT count(1) FROM "opening_draft"
1519 WHERE "opening_draft"."author_id" = "member"."id"
1520 AND "opening_draft"."created" > now() - "contingent"."time_frame"
1521 ) ELSE NULL END AS "initiative_count",
1522 "contingent"."initiative_limit"
1523 FROM "member" CROSS JOIN "contingent";
1525 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
1527 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
1528 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
1531 CREATE VIEW "member_contingent_left" AS
1532 SELECT
1533 "member_id",
1534 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
1535 max("initiative_limit" - "initiative_count") AS "initiatives_left"
1536 FROM "member_contingent" GROUP BY "member_id";
1538 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.';
1541 CREATE TYPE "timeline_event" AS ENUM (
1542 'issue_created',
1543 'issue_canceled',
1544 'issue_accepted',
1545 'issue_half_frozen',
1546 'issue_finished_without_voting',
1547 'issue_voting_started',
1548 'issue_finished_after_voting',
1549 'initiative_created',
1550 'initiative_revoked',
1551 'draft_created',
1552 'suggestion_created');
1554 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables';
1557 CREATE VIEW "timeline_issue" AS
1558 SELECT
1559 "created" AS "occurrence",
1560 'issue_created'::"timeline_event" AS "event",
1561 "id" AS "issue_id"
1562 FROM "issue"
1563 UNION ALL
1564 SELECT
1565 "closed" AS "occurrence",
1566 'issue_canceled'::"timeline_event" AS "event",
1567 "id" AS "issue_id"
1568 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
1569 UNION ALL
1570 SELECT
1571 "accepted" AS "occurrence",
1572 'issue_accepted'::"timeline_event" AS "event",
1573 "id" AS "issue_id"
1574 FROM "issue" WHERE "accepted" NOTNULL
1575 UNION ALL
1576 SELECT
1577 "half_frozen" AS "occurrence",
1578 'issue_half_frozen'::"timeline_event" AS "event",
1579 "id" AS "issue_id"
1580 FROM "issue" WHERE "half_frozen" NOTNULL
1581 UNION ALL
1582 SELECT
1583 "fully_frozen" AS "occurrence",
1584 'issue_voting_started'::"timeline_event" AS "event",
1585 "id" AS "issue_id"
1586 FROM "issue"
1587 WHERE "fully_frozen" NOTNULL
1588 AND ("closed" ISNULL OR "closed" != "fully_frozen")
1589 UNION ALL
1590 SELECT
1591 "closed" AS "occurrence",
1592 CASE WHEN "fully_frozen" = "closed" THEN
1593 'issue_finished_without_voting'::"timeline_event"
1594 ELSE
1595 'issue_finished_after_voting'::"timeline_event"
1596 END AS "event",
1597 "id" AS "issue_id"
1598 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
1600 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view';
1603 CREATE VIEW "timeline_initiative" AS
1604 SELECT
1605 "created" AS "occurrence",
1606 'initiative_created'::"timeline_event" AS "event",
1607 "id" AS "initiative_id"
1608 FROM "initiative"
1609 UNION ALL
1610 SELECT
1611 "revoked" AS "occurrence",
1612 'initiative_revoked'::"timeline_event" AS "event",
1613 "id" AS "initiative_id"
1614 FROM "initiative" WHERE "revoked" NOTNULL;
1616 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view';
1619 CREATE VIEW "timeline_draft" AS
1620 SELECT
1621 "created" AS "occurrence",
1622 'draft_created'::"timeline_event" AS "event",
1623 "id" AS "draft_id"
1624 FROM "draft";
1626 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view';
1629 CREATE VIEW "timeline_suggestion" AS
1630 SELECT
1631 "created" AS "occurrence",
1632 'suggestion_created'::"timeline_event" AS "event",
1633 "id" AS "suggestion_id"
1634 FROM "suggestion";
1636 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view';
1639 CREATE VIEW "timeline" AS
1640 SELECT
1641 "occurrence",
1642 "event",
1643 "issue_id",
1644 NULL AS "initiative_id",
1645 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
1646 NULL::INT8 AS "suggestion_id"
1647 FROM "timeline_issue"
1648 UNION ALL
1649 SELECT
1650 "occurrence",
1651 "event",
1652 NULL AS "issue_id",
1653 "initiative_id",
1654 NULL AS "draft_id",
1655 NULL AS "suggestion_id"
1656 FROM "timeline_initiative"
1657 UNION ALL
1658 SELECT
1659 "occurrence",
1660 "event",
1661 NULL AS "issue_id",
1662 NULL AS "initiative_id",
1663 "draft_id",
1664 NULL AS "suggestion_id"
1665 FROM "timeline_draft"
1666 UNION ALL
1667 SELECT
1668 "occurrence",
1669 "event",
1670 NULL AS "issue_id",
1671 NULL AS "initiative_id",
1672 NULL AS "draft_id",
1673 "suggestion_id"
1674 FROM "timeline_suggestion";
1676 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system';
1680 --------------------------------------------------
1681 -- Set returning function for delegation chains --
1682 --------------------------------------------------
1685 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
1686 ('first', 'intermediate', 'last', 'repetition');
1688 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
1691 CREATE TYPE "delegation_chain_row" AS (
1692 "index" INT4,
1693 "member_id" INT4,
1694 "member_active" BOOLEAN,
1695 "participation" BOOLEAN,
1696 "overridden" BOOLEAN,
1697 "scope_in" "delegation_scope",
1698 "scope_out" "delegation_scope",
1699 "disabled_out" BOOLEAN,
1700 "loop" "delegation_chain_loop_tag" );
1702 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
1704 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
1705 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';
1706 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
1707 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
1708 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
1709 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
1710 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
1713 CREATE FUNCTION "delegation_chain"
1714 ( "member_id_p" "member"."id"%TYPE,
1715 "area_id_p" "area"."id"%TYPE,
1716 "issue_id_p" "issue"."id"%TYPE,
1717 "simulate_trustee_id_p" "member"."id"%TYPE )
1718 RETURNS SETOF "delegation_chain_row"
1719 LANGUAGE 'plpgsql' STABLE AS $$
1720 DECLARE
1721 "issue_row" "issue"%ROWTYPE;
1722 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
1723 "loop_member_id_v" "member"."id"%TYPE;
1724 "output_row" "delegation_chain_row";
1725 "output_rows" "delegation_chain_row"[];
1726 "delegation_row" "delegation"%ROWTYPE;
1727 "row_count" INT4;
1728 "i" INT4;
1729 "loop_v" BOOLEAN;
1730 BEGIN
1731 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
1732 "visited_member_ids" := '{}';
1733 "loop_member_id_v" := NULL;
1734 "output_rows" := '{}';
1735 "output_row"."index" := 0;
1736 "output_row"."member_id" := "member_id_p";
1737 "output_row"."member_active" := TRUE;
1738 "output_row"."participation" := FALSE;
1739 "output_row"."overridden" := FALSE;
1740 "output_row"."disabled_out" := FALSE;
1741 "output_row"."scope_out" := NULL;
1742 LOOP
1743 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
1744 "loop_member_id_v" := "output_row"."member_id";
1745 ELSE
1746 "visited_member_ids" :=
1747 "visited_member_ids" || "output_row"."member_id";
1748 END IF;
1749 IF "output_row"."participation" THEN
1750 "output_row"."overridden" := TRUE;
1751 END IF;
1752 "output_row"."scope_in" := "output_row"."scope_out";
1753 IF EXISTS (
1754 SELECT NULL FROM "member"
1755 WHERE "id" = "output_row"."member_id" AND "active"
1756 ) THEN
1757 IF "area_id_p" ISNULL AND "issue_id_p" ISNULL THEN
1758 SELECT * INTO "delegation_row" FROM "delegation"
1759 WHERE "truster_id" = "output_row"."member_id"
1760 AND "scope" = 'global';
1761 ELSIF "area_id_p" NOTNULL AND "issue_id_p" ISNULL THEN
1762 "output_row"."participation" := EXISTS (
1763 SELECT NULL FROM "membership"
1764 WHERE "area_id" = "area_id_p"
1765 AND "member_id" = "output_row"."member_id"
1766 );
1767 SELECT * INTO "delegation_row" FROM "delegation"
1768 WHERE "truster_id" = "output_row"."member_id"
1769 AND ("scope" = 'global' OR "area_id" = "area_id_p")
1770 ORDER BY "scope" DESC;
1771 ELSIF "area_id_p" ISNULL AND "issue_id_p" NOTNULL THEN
1772 "output_row"."participation" := EXISTS (
1773 SELECT NULL FROM "interest"
1774 WHERE "issue_id" = "issue_id_p"
1775 AND "member_id" = "output_row"."member_id"
1776 );
1777 SELECT * INTO "delegation_row" FROM "delegation"
1778 WHERE "truster_id" = "output_row"."member_id"
1779 AND ("scope" = 'global' OR
1780 "area_id" = "issue_row"."area_id" OR
1781 "issue_id" = "issue_id_p"
1783 ORDER BY "scope" DESC;
1784 ELSE
1785 RAISE EXCEPTION 'Either area_id or issue_id or both must be NULL.';
1786 END IF;
1787 ELSE
1788 "output_row"."member_active" := FALSE;
1789 "output_row"."participation" := FALSE;
1790 "output_row"."scope_out" := NULL;
1791 "delegation_row" := ROW(NULL);
1792 END IF;
1793 IF
1794 "output_row"."member_id" = "member_id_p" AND
1795 "simulate_trustee_id_p" NOTNULL
1796 THEN
1797 "output_row"."scope_out" := CASE
1798 WHEN "area_id_p" ISNULL AND "issue_id_p" ISNULL THEN 'global'
1799 WHEN "area_id_p" NOTNULL AND "issue_id_p" ISNULL THEN 'area'
1800 WHEN "area_id_p" ISNULL AND "issue_id_p" NOTNULL THEN 'issue'
1801 END;
1802 "output_rows" := "output_rows" || "output_row";
1803 "output_row"."member_id" := "simulate_trustee_id_p";
1804 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
1805 "output_row"."scope_out" := "delegation_row"."scope";
1806 "output_rows" := "output_rows" || "output_row";
1807 "output_row"."member_id" := "delegation_row"."trustee_id";
1808 ELSIF "delegation_row"."scope" NOTNULL THEN
1809 "output_row"."scope_out" := "delegation_row"."scope";
1810 "output_row"."disabled_out" := TRUE;
1811 "output_rows" := "output_rows" || "output_row";
1812 EXIT;
1813 ELSE
1814 "output_row"."scope_out" := NULL;
1815 "output_rows" := "output_rows" || "output_row";
1816 EXIT;
1817 END IF;
1818 EXIT WHEN "loop_member_id_v" NOTNULL;
1819 "output_row"."index" := "output_row"."index" + 1;
1820 END LOOP;
1821 "row_count" := array_upper("output_rows", 1);
1822 "i" := 1;
1823 "loop_v" := FALSE;
1824 LOOP
1825 "output_row" := "output_rows"["i"];
1826 EXIT WHEN "output_row" ISNULL;
1827 IF "loop_v" THEN
1828 IF "i" + 1 = "row_count" THEN
1829 "output_row"."loop" := 'last';
1830 ELSIF "i" = "row_count" THEN
1831 "output_row"."loop" := 'repetition';
1832 ELSE
1833 "output_row"."loop" := 'intermediate';
1834 END IF;
1835 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
1836 "output_row"."loop" := 'first';
1837 "loop_v" := TRUE;
1838 END IF;
1839 IF "area_id_p" ISNULL AND "issue_id_p" ISNULL THEN
1840 "output_row"."participation" := NULL;
1841 END IF;
1842 RETURN NEXT "output_row";
1843 "i" := "i" + 1;
1844 END LOOP;
1845 RETURN;
1846 END;
1847 $$;
1849 COMMENT ON FUNCTION "delegation_chain"
1850 ( "member"."id"%TYPE,
1851 "area"."id"%TYPE,
1852 "issue"."id"%TYPE,
1853 "member"."id"%TYPE )
1854 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
1856 CREATE FUNCTION "delegation_chain"
1857 ( "member_id_p" "member"."id"%TYPE,
1858 "area_id_p" "area"."id"%TYPE,
1859 "issue_id_p" "issue"."id"%TYPE )
1860 RETURNS SETOF "delegation_chain_row"
1861 LANGUAGE 'plpgsql' STABLE AS $$
1862 DECLARE
1863 "result_row" "delegation_chain_row";
1864 BEGIN
1865 FOR "result_row" IN
1866 SELECT * FROM "delegation_chain"(
1867 "member_id_p", "area_id_p", "issue_id_p", NULL
1869 LOOP
1870 RETURN NEXT "result_row";
1871 END LOOP;
1872 RETURN;
1873 END;
1874 $$;
1876 COMMENT ON FUNCTION "delegation_chain"
1877 ( "member"."id"%TYPE,
1878 "area"."id"%TYPE,
1879 "issue"."id"%TYPE )
1880 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
1884 ------------------------------
1885 -- Comparison by vote count --
1886 ------------------------------
1888 CREATE FUNCTION "vote_ratio"
1889 ( "positive_votes_p" "initiative"."positive_votes"%TYPE,
1890 "negative_votes_p" "initiative"."negative_votes"%TYPE )
1891 RETURNS FLOAT8
1892 LANGUAGE 'plpgsql' STABLE AS $$
1893 BEGIN
1894 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN
1895 RETURN
1896 "positive_votes_p"::FLOAT8 /
1897 ("positive_votes_p" + "negative_votes_p")::FLOAT8;
1898 ELSIF "positive_votes_p" > 0 THEN
1899 RETURN "positive_votes_p";
1900 ELSIF "negative_votes_p" > 0 THEN
1901 RETURN 1 - "negative_votes_p";
1902 ELSE
1903 RETURN 0.5;
1904 END IF;
1905 END;
1906 $$;
1908 COMMENT ON FUNCTION "vote_ratio"
1909 ( "initiative"."positive_votes"%TYPE,
1910 "initiative"."negative_votes"%TYPE )
1911 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.';
1915 ------------------------------------------------
1916 -- Locking for snapshots and voting procedure --
1917 ------------------------------------------------
1920 CREATE FUNCTION "share_row_lock_issue_trigger"()
1921 RETURNS TRIGGER
1922 LANGUAGE 'plpgsql' VOLATILE AS $$
1923 BEGIN
1924 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
1925 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
1926 END IF;
1927 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
1928 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
1929 RETURN NEW;
1930 ELSE
1931 RETURN OLD;
1932 END IF;
1933 END;
1934 $$;
1936 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
1939 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
1940 RETURNS TRIGGER
1941 LANGUAGE 'plpgsql' VOLATILE AS $$
1942 BEGIN
1943 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
1944 PERFORM NULL FROM "issue"
1945 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
1946 WHERE "initiative"."id" = OLD."initiative_id"
1947 FOR SHARE OF "issue";
1948 END IF;
1949 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
1950 PERFORM NULL FROM "issue"
1951 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
1952 WHERE "initiative"."id" = NEW."initiative_id"
1953 FOR SHARE OF "issue";
1954 RETURN NEW;
1955 ELSE
1956 RETURN OLD;
1957 END IF;
1958 END;
1959 $$;
1961 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
1964 CREATE TRIGGER "share_row_lock_issue"
1965 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
1966 FOR EACH ROW EXECUTE PROCEDURE
1967 "share_row_lock_issue_trigger"();
1969 CREATE TRIGGER "share_row_lock_issue"
1970 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
1971 FOR EACH ROW EXECUTE PROCEDURE
1972 "share_row_lock_issue_trigger"();
1974 CREATE TRIGGER "share_row_lock_issue"
1975 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
1976 FOR EACH ROW EXECUTE PROCEDURE
1977 "share_row_lock_issue_trigger"();
1979 CREATE TRIGGER "share_row_lock_issue_via_initiative"
1980 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
1981 FOR EACH ROW EXECUTE PROCEDURE
1982 "share_row_lock_issue_via_initiative_trigger"();
1984 CREATE TRIGGER "share_row_lock_issue"
1985 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
1986 FOR EACH ROW EXECUTE PROCEDURE
1987 "share_row_lock_issue_trigger"();
1989 CREATE TRIGGER "share_row_lock_issue"
1990 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
1991 FOR EACH ROW EXECUTE PROCEDURE
1992 "share_row_lock_issue_trigger"();
1994 CREATE TRIGGER "share_row_lock_issue"
1995 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
1996 FOR EACH ROW EXECUTE PROCEDURE
1997 "share_row_lock_issue_trigger"();
1999 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
2000 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
2001 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
2002 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
2003 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
2004 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
2005 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
2008 CREATE FUNCTION "lock_issue"
2009 ( "issue_id_p" "issue"."id"%TYPE )
2010 RETURNS VOID
2011 LANGUAGE 'plpgsql' VOLATILE AS $$
2012 BEGIN
2013 LOCK TABLE "member" IN SHARE MODE;
2014 LOCK TABLE "membership" IN SHARE MODE;
2015 LOCK TABLE "policy" IN SHARE MODE;
2016 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2017 -- NOTE: The row-level exclusive lock in combination with the
2018 -- share_row_lock_issue(_via_initiative)_trigger functions (which
2019 -- acquire a row-level share lock on the issue) ensure that no data
2020 -- is changed, which could affect calculation of snapshots or
2021 -- counting of votes. Table "delegation" must be table-level-locked,
2022 -- as it also contains issue- and global-scope delegations.
2023 LOCK TABLE "delegation" IN SHARE MODE;
2024 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
2025 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
2026 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
2027 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
2028 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
2029 RETURN;
2030 END;
2031 $$;
2033 COMMENT ON FUNCTION "lock_issue"
2034 ( "issue"."id"%TYPE )
2035 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
2039 -------------------------------
2040 -- Materialize member counts --
2041 -------------------------------
2043 CREATE FUNCTION "calculate_member_counts"()
2044 RETURNS VOID
2045 LANGUAGE 'plpgsql' VOLATILE AS $$
2046 BEGIN
2047 LOCK TABLE "member" IN SHARE MODE;
2048 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
2049 LOCK TABLE "area" IN EXCLUSIVE MODE;
2050 LOCK TABLE "membership" IN SHARE MODE;
2051 DELETE FROM "member_count";
2052 INSERT INTO "member_count" ("total_count")
2053 SELECT "total_count" FROM "member_count_view";
2054 UPDATE "area" SET
2055 "direct_member_count" = "view"."direct_member_count",
2056 "member_weight" = "view"."member_weight",
2057 "autoreject_weight" = "view"."autoreject_weight"
2058 FROM "area_member_count" AS "view"
2059 WHERE "view"."area_id" = "area"."id";
2060 RETURN;
2061 END;
2062 $$;
2064 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"';
2068 ------------------------------
2069 -- Calculation of snapshots --
2070 ------------------------------
2072 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
2073 ( "issue_id_p" "issue"."id"%TYPE,
2074 "member_id_p" "member"."id"%TYPE,
2075 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2076 RETURNS "direct_population_snapshot"."weight"%TYPE
2077 LANGUAGE 'plpgsql' VOLATILE AS $$
2078 DECLARE
2079 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2080 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
2081 "weight_v" INT4;
2082 "sub_weight_v" INT4;
2083 BEGIN
2084 "weight_v" := 0;
2085 FOR "issue_delegation_row" IN
2086 SELECT * FROM "issue_delegation"
2087 WHERE "trustee_id" = "member_id_p"
2088 AND "issue_id" = "issue_id_p"
2089 LOOP
2090 IF NOT EXISTS (
2091 SELECT NULL FROM "direct_population_snapshot"
2092 WHERE "issue_id" = "issue_id_p"
2093 AND "event" = 'periodic'
2094 AND "member_id" = "issue_delegation_row"."truster_id"
2095 ) AND NOT EXISTS (
2096 SELECT NULL FROM "delegating_population_snapshot"
2097 WHERE "issue_id" = "issue_id_p"
2098 AND "event" = 'periodic'
2099 AND "member_id" = "issue_delegation_row"."truster_id"
2100 ) THEN
2101 "delegate_member_ids_v" :=
2102 "member_id_p" || "delegate_member_ids_p";
2103 INSERT INTO "delegating_population_snapshot" (
2104 "issue_id",
2105 "event",
2106 "member_id",
2107 "scope",
2108 "delegate_member_ids"
2109 ) VALUES (
2110 "issue_id_p",
2111 'periodic',
2112 "issue_delegation_row"."truster_id",
2113 "issue_delegation_row"."scope",
2114 "delegate_member_ids_v"
2115 );
2116 "sub_weight_v" := 1 +
2117 "weight_of_added_delegations_for_population_snapshot"(
2118 "issue_id_p",
2119 "issue_delegation_row"."truster_id",
2120 "delegate_member_ids_v"
2121 );
2122 UPDATE "delegating_population_snapshot"
2123 SET "weight" = "sub_weight_v"
2124 WHERE "issue_id" = "issue_id_p"
2125 AND "event" = 'periodic'
2126 AND "member_id" = "issue_delegation_row"."truster_id";
2127 "weight_v" := "weight_v" + "sub_weight_v";
2128 END IF;
2129 END LOOP;
2130 RETURN "weight_v";
2131 END;
2132 $$;
2134 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
2135 ( "issue"."id"%TYPE,
2136 "member"."id"%TYPE,
2137 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
2138 IS 'Helper function for "create_population_snapshot" function';
2141 CREATE FUNCTION "create_population_snapshot"
2142 ( "issue_id_p" "issue"."id"%TYPE )
2143 RETURNS VOID
2144 LANGUAGE 'plpgsql' VOLATILE AS $$
2145 DECLARE
2146 "member_id_v" "member"."id"%TYPE;
2147 BEGIN
2148 DELETE FROM "direct_population_snapshot"
2149 WHERE "issue_id" = "issue_id_p"
2150 AND "event" = 'periodic';
2151 DELETE FROM "delegating_population_snapshot"
2152 WHERE "issue_id" = "issue_id_p"
2153 AND "event" = 'periodic';
2154 INSERT INTO "direct_population_snapshot"
2155 ("issue_id", "event", "member_id")
2156 SELECT
2157 "issue_id_p" AS "issue_id",
2158 'periodic'::"snapshot_event" AS "event",
2159 "member"."id" AS "member_id"
2160 FROM "issue"
2161 JOIN "area" ON "issue"."area_id" = "area"."id"
2162 JOIN "membership" ON "area"."id" = "membership"."area_id"
2163 JOIN "member" ON "membership"."member_id" = "member"."id"
2164 WHERE "issue"."id" = "issue_id_p"
2165 AND "member"."active"
2166 UNION
2167 SELECT
2168 "issue_id_p" AS "issue_id",
2169 'periodic'::"snapshot_event" AS "event",
2170 "member"."id" AS "member_id"
2171 FROM "interest" JOIN "member"
2172 ON "interest"."member_id" = "member"."id"
2173 WHERE "interest"."issue_id" = "issue_id_p"
2174 AND "member"."active";
2175 FOR "member_id_v" IN
2176 SELECT "member_id" FROM "direct_population_snapshot"
2177 WHERE "issue_id" = "issue_id_p"
2178 AND "event" = 'periodic'
2179 LOOP
2180 UPDATE "direct_population_snapshot" SET
2181 "weight" = 1 +
2182 "weight_of_added_delegations_for_population_snapshot"(
2183 "issue_id_p",
2184 "member_id_v",
2185 '{}'
2187 WHERE "issue_id" = "issue_id_p"
2188 AND "event" = 'periodic'
2189 AND "member_id" = "member_id_v";
2190 END LOOP;
2191 RETURN;
2192 END;
2193 $$;
2195 COMMENT ON FUNCTION "create_population_snapshot"
2196 ( "issue"."id"%TYPE )
2197 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.';
2200 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2201 ( "issue_id_p" "issue"."id"%TYPE,
2202 "member_id_p" "member"."id"%TYPE,
2203 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2204 RETURNS "direct_interest_snapshot"."weight"%TYPE
2205 LANGUAGE 'plpgsql' VOLATILE AS $$
2206 DECLARE
2207 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2208 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
2209 "weight_v" INT4;
2210 "sub_weight_v" INT4;
2211 BEGIN
2212 "weight_v" := 0;
2213 FOR "issue_delegation_row" IN
2214 SELECT * FROM "issue_delegation"
2215 WHERE "trustee_id" = "member_id_p"
2216 AND "issue_id" = "issue_id_p"
2217 LOOP
2218 IF NOT EXISTS (
2219 SELECT NULL FROM "direct_interest_snapshot"
2220 WHERE "issue_id" = "issue_id_p"
2221 AND "event" = 'periodic'
2222 AND "member_id" = "issue_delegation_row"."truster_id"
2223 ) AND NOT EXISTS (
2224 SELECT NULL FROM "delegating_interest_snapshot"
2225 WHERE "issue_id" = "issue_id_p"
2226 AND "event" = 'periodic'
2227 AND "member_id" = "issue_delegation_row"."truster_id"
2228 ) THEN
2229 "delegate_member_ids_v" :=
2230 "member_id_p" || "delegate_member_ids_p";
2231 INSERT INTO "delegating_interest_snapshot" (
2232 "issue_id",
2233 "event",
2234 "member_id",
2235 "scope",
2236 "delegate_member_ids"
2237 ) VALUES (
2238 "issue_id_p",
2239 'periodic',
2240 "issue_delegation_row"."truster_id",
2241 "issue_delegation_row"."scope",
2242 "delegate_member_ids_v"
2243 );
2244 "sub_weight_v" := 1 +
2245 "weight_of_added_delegations_for_interest_snapshot"(
2246 "issue_id_p",
2247 "issue_delegation_row"."truster_id",
2248 "delegate_member_ids_v"
2249 );
2250 UPDATE "delegating_interest_snapshot"
2251 SET "weight" = "sub_weight_v"
2252 WHERE "issue_id" = "issue_id_p"
2253 AND "event" = 'periodic'
2254 AND "member_id" = "issue_delegation_row"."truster_id";
2255 "weight_v" := "weight_v" + "sub_weight_v";
2256 END IF;
2257 END LOOP;
2258 RETURN "weight_v";
2259 END;
2260 $$;
2262 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
2263 ( "issue"."id"%TYPE,
2264 "member"."id"%TYPE,
2265 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
2266 IS 'Helper function for "create_interest_snapshot" function';
2269 CREATE FUNCTION "create_interest_snapshot"
2270 ( "issue_id_p" "issue"."id"%TYPE )
2271 RETURNS VOID
2272 LANGUAGE 'plpgsql' VOLATILE AS $$
2273 DECLARE
2274 "member_id_v" "member"."id"%TYPE;
2275 BEGIN
2276 DELETE FROM "direct_interest_snapshot"
2277 WHERE "issue_id" = "issue_id_p"
2278 AND "event" = 'periodic';
2279 DELETE FROM "delegating_interest_snapshot"
2280 WHERE "issue_id" = "issue_id_p"
2281 AND "event" = 'periodic';
2282 DELETE FROM "direct_supporter_snapshot"
2283 WHERE "issue_id" = "issue_id_p"
2284 AND "event" = 'periodic';
2285 INSERT INTO "direct_interest_snapshot"
2286 ("issue_id", "event", "member_id", "voting_requested")
2287 SELECT
2288 "issue_id_p" AS "issue_id",
2289 'periodic' AS "event",
2290 "member"."id" AS "member_id",
2291 "interest"."voting_requested"
2292 FROM "interest" JOIN "member"
2293 ON "interest"."member_id" = "member"."id"
2294 WHERE "interest"."issue_id" = "issue_id_p"
2295 AND "member"."active";
2296 FOR "member_id_v" IN
2297 SELECT "member_id" FROM "direct_interest_snapshot"
2298 WHERE "issue_id" = "issue_id_p"
2299 AND "event" = 'periodic'
2300 LOOP
2301 UPDATE "direct_interest_snapshot" SET
2302 "weight" = 1 +
2303 "weight_of_added_delegations_for_interest_snapshot"(
2304 "issue_id_p",
2305 "member_id_v",
2306 '{}'
2308 WHERE "issue_id" = "issue_id_p"
2309 AND "event" = 'periodic'
2310 AND "member_id" = "member_id_v";
2311 END LOOP;
2312 INSERT INTO "direct_supporter_snapshot"
2313 ( "issue_id", "initiative_id", "event", "member_id",
2314 "informed", "satisfied" )
2315 SELECT
2316 "issue_id_p" AS "issue_id",
2317 "initiative"."id" AS "initiative_id",
2318 'periodic' AS "event",
2319 "member"."id" AS "member_id",
2320 "supporter"."draft_id" = "current_draft"."id" AS "informed",
2321 NOT EXISTS (
2322 SELECT NULL FROM "critical_opinion"
2323 WHERE "initiative_id" = "initiative"."id"
2324 AND "member_id" = "member"."id"
2325 ) AS "satisfied"
2326 FROM "supporter"
2327 JOIN "member"
2328 ON "supporter"."member_id" = "member"."id"
2329 JOIN "initiative"
2330 ON "supporter"."initiative_id" = "initiative"."id"
2331 JOIN "current_draft"
2332 ON "initiative"."id" = "current_draft"."initiative_id"
2333 JOIN "direct_interest_snapshot"
2334 ON "member"."id" = "direct_interest_snapshot"."member_id"
2335 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
2336 AND "event" = 'periodic'
2337 WHERE "member"."active"
2338 AND "initiative"."issue_id" = "issue_id_p";
2339 RETURN;
2340 END;
2341 $$;
2343 COMMENT ON FUNCTION "create_interest_snapshot"
2344 ( "issue"."id"%TYPE )
2345 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.';
2348 CREATE FUNCTION "create_snapshot"
2349 ( "issue_id_p" "issue"."id"%TYPE )
2350 RETURNS VOID
2351 LANGUAGE 'plpgsql' VOLATILE AS $$
2352 DECLARE
2353 "initiative_id_v" "initiative"."id"%TYPE;
2354 "suggestion_id_v" "suggestion"."id"%TYPE;
2355 BEGIN
2356 PERFORM "lock_issue"("issue_id_p");
2357 PERFORM "create_population_snapshot"("issue_id_p");
2358 PERFORM "create_interest_snapshot"("issue_id_p");
2359 UPDATE "issue" SET
2360 "snapshot" = now(),
2361 "latest_snapshot_event" = 'periodic',
2362 "population" = (
2363 SELECT coalesce(sum("weight"), 0)
2364 FROM "direct_population_snapshot"
2365 WHERE "issue_id" = "issue_id_p"
2366 AND "event" = 'periodic'
2367 ),
2368 "vote_now" = (
2369 SELECT coalesce(sum("weight"), 0)
2370 FROM "direct_interest_snapshot"
2371 WHERE "issue_id" = "issue_id_p"
2372 AND "event" = 'periodic'
2373 AND "voting_requested" = TRUE
2374 ),
2375 "vote_later" = (
2376 SELECT coalesce(sum("weight"), 0)
2377 FROM "direct_interest_snapshot"
2378 WHERE "issue_id" = "issue_id_p"
2379 AND "event" = 'periodic'
2380 AND "voting_requested" = FALSE
2382 WHERE "id" = "issue_id_p";
2383 FOR "initiative_id_v" IN
2384 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
2385 LOOP
2386 UPDATE "initiative" SET
2387 "supporter_count" = (
2388 SELECT coalesce(sum("di"."weight"), 0)
2389 FROM "direct_interest_snapshot" AS "di"
2390 JOIN "direct_supporter_snapshot" AS "ds"
2391 ON "di"."member_id" = "ds"."member_id"
2392 WHERE "di"."issue_id" = "issue_id_p"
2393 AND "di"."event" = 'periodic'
2394 AND "ds"."initiative_id" = "initiative_id_v"
2395 AND "ds"."event" = 'periodic'
2396 ),
2397 "informed_supporter_count" = (
2398 SELECT coalesce(sum("di"."weight"), 0)
2399 FROM "direct_interest_snapshot" AS "di"
2400 JOIN "direct_supporter_snapshot" AS "ds"
2401 ON "di"."member_id" = "ds"."member_id"
2402 WHERE "di"."issue_id" = "issue_id_p"
2403 AND "di"."event" = 'periodic'
2404 AND "ds"."initiative_id" = "initiative_id_v"
2405 AND "ds"."event" = 'periodic'
2406 AND "ds"."informed"
2407 ),
2408 "satisfied_supporter_count" = (
2409 SELECT coalesce(sum("di"."weight"), 0)
2410 FROM "direct_interest_snapshot" AS "di"
2411 JOIN "direct_supporter_snapshot" AS "ds"
2412 ON "di"."member_id" = "ds"."member_id"
2413 WHERE "di"."issue_id" = "issue_id_p"
2414 AND "di"."event" = 'periodic'
2415 AND "ds"."initiative_id" = "initiative_id_v"
2416 AND "ds"."event" = 'periodic'
2417 AND "ds"."satisfied"
2418 ),
2419 "satisfied_informed_supporter_count" = (
2420 SELECT coalesce(sum("di"."weight"), 0)
2421 FROM "direct_interest_snapshot" AS "di"
2422 JOIN "direct_supporter_snapshot" AS "ds"
2423 ON "di"."member_id" = "ds"."member_id"
2424 WHERE "di"."issue_id" = "issue_id_p"
2425 AND "di"."event" = 'periodic'
2426 AND "ds"."initiative_id" = "initiative_id_v"
2427 AND "ds"."event" = 'periodic'
2428 AND "ds"."informed"
2429 AND "ds"."satisfied"
2431 WHERE "id" = "initiative_id_v";
2432 FOR "suggestion_id_v" IN
2433 SELECT "id" FROM "suggestion"
2434 WHERE "initiative_id" = "initiative_id_v"
2435 LOOP
2436 UPDATE "suggestion" SET
2437 "minus2_unfulfilled_count" = (
2438 SELECT coalesce(sum("snapshot"."weight"), 0)
2439 FROM "issue" CROSS JOIN "opinion"
2440 JOIN "direct_interest_snapshot" AS "snapshot"
2441 ON "snapshot"."issue_id" = "issue"."id"
2442 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2443 AND "snapshot"."member_id" = "opinion"."member_id"
2444 WHERE "issue"."id" = "issue_id_p"
2445 AND "opinion"."suggestion_id" = "suggestion_id_v"
2446 AND "opinion"."degree" = -2
2447 AND "opinion"."fulfilled" = FALSE
2448 ),
2449 "minus2_fulfilled_count" = (
2450 SELECT coalesce(sum("snapshot"."weight"), 0)
2451 FROM "issue" CROSS JOIN "opinion"
2452 JOIN "direct_interest_snapshot" AS "snapshot"
2453 ON "snapshot"."issue_id" = "issue"."id"
2454 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2455 AND "snapshot"."member_id" = "opinion"."member_id"
2456 WHERE "issue"."id" = "issue_id_p"
2457 AND "opinion"."suggestion_id" = "suggestion_id_v"
2458 AND "opinion"."degree" = -2
2459 AND "opinion"."fulfilled" = TRUE
2460 ),
2461 "minus1_unfulfilled_count" = (
2462 SELECT coalesce(sum("snapshot"."weight"), 0)
2463 FROM "issue" CROSS JOIN "opinion"
2464 JOIN "direct_interest_snapshot" AS "snapshot"
2465 ON "snapshot"."issue_id" = "issue"."id"
2466 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2467 AND "snapshot"."member_id" = "opinion"."member_id"
2468 WHERE "issue"."id" = "issue_id_p"
2469 AND "opinion"."suggestion_id" = "suggestion_id_v"
2470 AND "opinion"."degree" = -1
2471 AND "opinion"."fulfilled" = FALSE
2472 ),
2473 "minus1_fulfilled_count" = (
2474 SELECT coalesce(sum("snapshot"."weight"), 0)
2475 FROM "issue" CROSS JOIN "opinion"
2476 JOIN "direct_interest_snapshot" AS "snapshot"
2477 ON "snapshot"."issue_id" = "issue"."id"
2478 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2479 AND "snapshot"."member_id" = "opinion"."member_id"
2480 WHERE "issue"."id" = "issue_id_p"
2481 AND "opinion"."suggestion_id" = "suggestion_id_v"
2482 AND "opinion"."degree" = -1
2483 AND "opinion"."fulfilled" = TRUE
2484 ),
2485 "plus1_unfulfilled_count" = (
2486 SELECT coalesce(sum("snapshot"."weight"), 0)
2487 FROM "issue" CROSS JOIN "opinion"
2488 JOIN "direct_interest_snapshot" AS "snapshot"
2489 ON "snapshot"."issue_id" = "issue"."id"
2490 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2491 AND "snapshot"."member_id" = "opinion"."member_id"
2492 WHERE "issue"."id" = "issue_id_p"
2493 AND "opinion"."suggestion_id" = "suggestion_id_v"
2494 AND "opinion"."degree" = 1
2495 AND "opinion"."fulfilled" = FALSE
2496 ),
2497 "plus1_fulfilled_count" = (
2498 SELECT coalesce(sum("snapshot"."weight"), 0)
2499 FROM "issue" CROSS JOIN "opinion"
2500 JOIN "direct_interest_snapshot" AS "snapshot"
2501 ON "snapshot"."issue_id" = "issue"."id"
2502 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2503 AND "snapshot"."member_id" = "opinion"."member_id"
2504 WHERE "issue"."id" = "issue_id_p"
2505 AND "opinion"."suggestion_id" = "suggestion_id_v"
2506 AND "opinion"."degree" = 1
2507 AND "opinion"."fulfilled" = TRUE
2508 ),
2509 "plus2_unfulfilled_count" = (
2510 SELECT coalesce(sum("snapshot"."weight"), 0)
2511 FROM "issue" CROSS JOIN "opinion"
2512 JOIN "direct_interest_snapshot" AS "snapshot"
2513 ON "snapshot"."issue_id" = "issue"."id"
2514 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2515 AND "snapshot"."member_id" = "opinion"."member_id"
2516 WHERE "issue"."id" = "issue_id_p"
2517 AND "opinion"."suggestion_id" = "suggestion_id_v"
2518 AND "opinion"."degree" = 2
2519 AND "opinion"."fulfilled" = FALSE
2520 ),
2521 "plus2_fulfilled_count" = (
2522 SELECT coalesce(sum("snapshot"."weight"), 0)
2523 FROM "issue" CROSS JOIN "opinion"
2524 JOIN "direct_interest_snapshot" AS "snapshot"
2525 ON "snapshot"."issue_id" = "issue"."id"
2526 AND "snapshot"."event" = "issue"."latest_snapshot_event"
2527 AND "snapshot"."member_id" = "opinion"."member_id"
2528 WHERE "issue"."id" = "issue_id_p"
2529 AND "opinion"."suggestion_id" = "suggestion_id_v"
2530 AND "opinion"."degree" = 2
2531 AND "opinion"."fulfilled" = TRUE
2533 WHERE "suggestion"."id" = "suggestion_id_v";
2534 END LOOP;
2535 END LOOP;
2536 RETURN;
2537 END;
2538 $$;
2540 COMMENT ON FUNCTION "create_snapshot"
2541 ( "issue"."id"%TYPE )
2542 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.';
2545 CREATE FUNCTION "set_snapshot_event"
2546 ( "issue_id_p" "issue"."id"%TYPE,
2547 "event_p" "snapshot_event" )
2548 RETURNS VOID
2549 LANGUAGE 'plpgsql' VOLATILE AS $$
2550 DECLARE
2551 "event_v" "issue"."latest_snapshot_event"%TYPE;
2552 BEGIN
2553 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
2554 WHERE "id" = "issue_id_p" FOR UPDATE;
2555 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
2556 WHERE "id" = "issue_id_p";
2557 UPDATE "direct_population_snapshot" SET "event" = "event_p"
2558 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
2559 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
2560 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
2561 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
2562 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
2563 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
2564 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
2565 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
2566 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
2567 RETURN;
2568 END;
2569 $$;
2571 COMMENT ON FUNCTION "set_snapshot_event"
2572 ( "issue"."id"%TYPE,
2573 "snapshot_event" )
2574 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
2578 ---------------------
2579 -- Freezing issues --
2580 ---------------------
2582 CREATE FUNCTION "freeze_after_snapshot"
2583 ( "issue_id_p" "issue"."id"%TYPE )
2584 RETURNS VOID
2585 LANGUAGE 'plpgsql' VOLATILE AS $$
2586 DECLARE
2587 "issue_row" "issue"%ROWTYPE;
2588 "policy_row" "policy"%ROWTYPE;
2589 "initiative_row" "initiative"%ROWTYPE;
2590 BEGIN
2591 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
2592 SELECT * INTO "policy_row"
2593 FROM "policy" WHERE "id" = "issue_row"."policy_id";
2594 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
2595 UPDATE "issue" SET
2596 "accepted" = coalesce("accepted", now()),
2597 "half_frozen" = coalesce("half_frozen", now()),
2598 "fully_frozen" = now()
2599 WHERE "id" = "issue_id_p";
2600 FOR "initiative_row" IN
2601 SELECT * FROM "initiative"
2602 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
2603 LOOP
2604 IF
2605 "initiative_row"."satisfied_supporter_count" > 0 AND
2606 "initiative_row"."satisfied_supporter_count" *
2607 "policy_row"."initiative_quorum_den" >=
2608 "issue_row"."population" * "policy_row"."initiative_quorum_num"
2609 THEN
2610 UPDATE "initiative" SET "admitted" = TRUE
2611 WHERE "id" = "initiative_row"."id";
2612 ELSE
2613 UPDATE "initiative" SET "admitted" = FALSE
2614 WHERE "id" = "initiative_row"."id";
2615 END IF;
2616 END LOOP;
2617 IF NOT EXISTS (
2618 SELECT NULL FROM "initiative"
2619 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
2620 ) THEN
2621 PERFORM "close_voting"("issue_id_p");
2622 END IF;
2623 RETURN;
2624 END;
2625 $$;
2627 COMMENT ON FUNCTION "freeze_after_snapshot"
2628 ( "issue"."id"%TYPE )
2629 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
2632 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
2633 RETURNS VOID
2634 LANGUAGE 'plpgsql' VOLATILE AS $$
2635 DECLARE
2636 "issue_row" "issue"%ROWTYPE;
2637 BEGIN
2638 PERFORM "create_snapshot"("issue_id_p");
2639 PERFORM "freeze_after_snapshot"("issue_id_p");
2640 RETURN;
2641 END;
2642 $$;
2644 COMMENT ON FUNCTION "manual_freeze"
2645 ( "issue"."id"%TYPE )
2646 IS 'Freeze an issue manually (fully) and start voting';
2650 -----------------------
2651 -- Counting of votes --
2652 -----------------------
2655 CREATE FUNCTION "weight_of_added_vote_delegations"
2656 ( "issue_id_p" "issue"."id"%TYPE,
2657 "member_id_p" "member"."id"%TYPE,
2658 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
2659 RETURNS "direct_voter"."weight"%TYPE
2660 LANGUAGE 'plpgsql' VOLATILE AS $$
2661 DECLARE
2662 "issue_delegation_row" "issue_delegation"%ROWTYPE;
2663 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
2664 "weight_v" INT4;
2665 "sub_weight_v" INT4;
2666 BEGIN
2667 "weight_v" := 0;
2668 FOR "issue_delegation_row" IN
2669 SELECT * FROM "issue_delegation"
2670 WHERE "trustee_id" = "member_id_p"
2671 AND "issue_id" = "issue_id_p"
2672 LOOP
2673 IF NOT EXISTS (
2674 SELECT NULL FROM "direct_voter"
2675 WHERE "member_id" = "issue_delegation_row"."truster_id"
2676 AND "issue_id" = "issue_id_p"
2677 ) AND NOT EXISTS (
2678 SELECT NULL FROM "delegating_voter"
2679 WHERE "member_id" = "issue_delegation_row"."truster_id"
2680 AND "issue_id" = "issue_id_p"
2681 ) THEN
2682 "delegate_member_ids_v" :=
2683 "member_id_p" || "delegate_member_ids_p";
2684 INSERT INTO "delegating_voter" (
2685 "issue_id",
2686 "member_id",
2687 "scope",
2688 "delegate_member_ids"
2689 ) VALUES (
2690 "issue_id_p",
2691 "issue_delegation_row"."truster_id",
2692 "issue_delegation_row"."scope",
2693 "delegate_member_ids_v"
2694 );
2695 "sub_weight_v" := 1 +
2696 "weight_of_added_vote_delegations"(
2697 "issue_id_p",
2698 "issue_delegation_row"."truster_id",
2699 "delegate_member_ids_v"
2700 );
2701 UPDATE "delegating_voter"
2702 SET "weight" = "sub_weight_v"
2703 WHERE "issue_id" = "issue_id_p"
2704 AND "member_id" = "issue_delegation_row"."truster_id";
2705 "weight_v" := "weight_v" + "sub_weight_v";
2706 END IF;
2707 END LOOP;
2708 RETURN "weight_v";
2709 END;
2710 $$;
2712 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
2713 ( "issue"."id"%TYPE,
2714 "member"."id"%TYPE,
2715 "delegating_voter"."delegate_member_ids"%TYPE )
2716 IS 'Helper function for "add_vote_delegations" function';
2719 CREATE FUNCTION "add_vote_delegations"
2720 ( "issue_id_p" "issue"."id"%TYPE )
2721 RETURNS VOID
2722 LANGUAGE 'plpgsql' VOLATILE AS $$
2723 DECLARE
2724 "member_id_v" "member"."id"%TYPE;
2725 BEGIN
2726 FOR "member_id_v" IN
2727 SELECT "member_id" FROM "direct_voter"
2728 WHERE "issue_id" = "issue_id_p"
2729 LOOP
2730 UPDATE "direct_voter" SET
2731 "weight" = "weight" + "weight_of_added_vote_delegations"(
2732 "issue_id_p",
2733 "member_id_v",
2734 '{}'
2736 WHERE "member_id" = "member_id_v"
2737 AND "issue_id" = "issue_id_p";
2738 END LOOP;
2739 RETURN;
2740 END;
2741 $$;
2743 COMMENT ON FUNCTION "add_vote_delegations"
2744 ( "issue_id_p" "issue"."id"%TYPE )
2745 IS 'Helper function for "close_voting" function';
2748 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
2749 RETURNS VOID
2750 LANGUAGE 'plpgsql' VOLATILE AS $$
2751 DECLARE
2752 "issue_row" "issue"%ROWTYPE;
2753 "member_id_v" "member"."id"%TYPE;
2754 BEGIN
2755 PERFORM "lock_issue"("issue_id_p");
2756 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
2757 DELETE FROM "delegating_voter"
2758 WHERE "issue_id" = "issue_id_p";
2759 DELETE FROM "direct_voter"
2760 WHERE "issue_id" = "issue_id_p"
2761 AND "autoreject" = TRUE;
2762 DELETE FROM "direct_voter" USING "member"
2763 WHERE "direct_voter"."member_id" = "member"."id"
2764 AND "direct_voter"."issue_id" = "issue_id_p"
2765 AND "member"."active" = FALSE;
2766 UPDATE "direct_voter" SET "weight" = 1
2767 WHERE "issue_id" = "issue_id_p";
2768 PERFORM "add_vote_delegations"("issue_id_p");
2769 FOR "member_id_v" IN
2770 SELECT "interest"."member_id"
2771 FROM "interest"
2772 JOIN "member"
2773 ON "interest"."member_id" = "member"."id"
2774 LEFT JOIN "direct_voter"
2775 ON "interest"."member_id" = "direct_voter"."member_id"
2776 AND "interest"."issue_id" = "direct_voter"."issue_id"
2777 LEFT JOIN "delegating_voter"
2778 ON "interest"."member_id" = "delegating_voter"."member_id"
2779 AND "interest"."issue_id" = "delegating_voter"."issue_id"
2780 WHERE "interest"."issue_id" = "issue_id_p"
2781 AND "interest"."autoreject" = TRUE
2782 AND "member"."active"
2783 AND "direct_voter"."member_id" ISNULL
2784 AND "delegating_voter"."member_id" ISNULL
2785 UNION SELECT "membership"."member_id"
2786 FROM "membership"
2787 JOIN "member"
2788 ON "membership"."member_id" = "member"."id"
2789 LEFT JOIN "interest"
2790 ON "membership"."member_id" = "interest"."member_id"
2791 AND "interest"."issue_id" = "issue_id_p"
2792 LEFT JOIN "direct_voter"
2793 ON "membership"."member_id" = "direct_voter"."member_id"
2794 AND "direct_voter"."issue_id" = "issue_id_p"
2795 LEFT JOIN "delegating_voter"
2796 ON "membership"."member_id" = "delegating_voter"."member_id"
2797 AND "delegating_voter"."issue_id" = "issue_id_p"
2798 WHERE "membership"."area_id" = "issue_row"."area_id"
2799 AND "membership"."autoreject" = TRUE
2800 AND "member"."active"
2801 AND "interest"."autoreject" ISNULL
2802 AND "direct_voter"."member_id" ISNULL
2803 AND "delegating_voter"."member_id" ISNULL
2804 LOOP
2805 INSERT INTO "direct_voter"
2806 ("member_id", "issue_id", "weight", "autoreject") VALUES
2807 ("member_id_v", "issue_id_p", 1, TRUE);
2808 INSERT INTO "vote" (
2809 "member_id",
2810 "issue_id",
2811 "initiative_id",
2812 "grade"
2813 ) SELECT
2814 "member_id_v" AS "member_id",
2815 "issue_id_p" AS "issue_id",
2816 "id" AS "initiative_id",
2817 -1 AS "grade"
2818 FROM "initiative" WHERE "issue_id" = "issue_id_p";
2819 END LOOP;
2820 PERFORM "add_vote_delegations"("issue_id_p");
2821 UPDATE "issue" SET
2822 "closed" = now(),
2823 "voter_count" = (
2824 SELECT coalesce(sum("weight"), 0)
2825 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
2827 WHERE "id" = "issue_id_p";
2828 UPDATE "initiative" SET
2829 "positive_votes" = "vote_counts"."positive_votes",
2830 "negative_votes" = "vote_counts"."negative_votes",
2831 "agreed" = CASE WHEN "majority_strict" THEN
2832 "vote_counts"."positive_votes" * "majority_den" >
2833 "majority_num" *
2834 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
2835 ELSE
2836 "vote_counts"."positive_votes" * "majority_den" >=
2837 "majority_num" *
2838 ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
2839 END
2840 FROM
2841 ( SELECT
2842 "initiative"."id" AS "initiative_id",
2843 coalesce(
2844 sum(
2845 CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
2846 ),
2848 ) AS "positive_votes",
2849 coalesce(
2850 sum(
2851 CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
2852 ),
2854 ) AS "negative_votes"
2855 FROM "initiative"
2856 JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
2857 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
2858 LEFT JOIN "direct_voter"
2859 ON "direct_voter"."issue_id" = "initiative"."issue_id"
2860 LEFT JOIN "vote"
2861 ON "vote"."initiative_id" = "initiative"."id"
2862 AND "vote"."member_id" = "direct_voter"."member_id"
2863 WHERE "initiative"."issue_id" = "issue_id_p"
2864 AND "initiative"."admitted" -- NOTE: NULL case is handled too
2865 GROUP BY "initiative"."id"
2866 ) AS "vote_counts",
2867 "issue",
2868 "policy"
2869 WHERE "vote_counts"."initiative_id" = "initiative"."id"
2870 AND "issue"."id" = "initiative"."issue_id"
2871 AND "policy"."id" = "issue"."policy_id";
2872 -- NOTE: "closed" column of issue must be set at this point
2873 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
2874 INSERT INTO "battle" (
2875 "issue_id",
2876 "winning_initiative_id", "losing_initiative_id",
2877 "count"
2878 ) SELECT
2879 "issue_id",
2880 "winning_initiative_id", "losing_initiative_id",
2881 "count"
2882 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
2883 END;
2884 $$;
2886 COMMENT ON FUNCTION "close_voting"
2887 ( "issue"."id"%TYPE )
2888 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.';
2891 CREATE FUNCTION "defeat_strength"
2892 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
2893 RETURNS INT8
2894 LANGUAGE 'plpgsql' IMMUTABLE AS $$
2895 BEGIN
2896 IF "positive_votes_p" > "negative_votes_p" THEN
2897 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
2898 ELSIF "positive_votes_p" = "negative_votes_p" THEN
2899 RETURN 0;
2900 ELSE
2901 RETURN -1;
2902 END IF;
2903 END;
2904 $$;
2906 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';
2909 CREATE FUNCTION "array_init_string"("dim_p" INTEGER)
2910 RETURNS TEXT
2911 LANGUAGE 'plpgsql' IMMUTABLE AS $$
2912 DECLARE
2913 "i" INTEGER;
2914 "ary_text_v" TEXT;
2915 BEGIN
2916 IF "dim_p" >= 1 THEN
2917 "ary_text_v" := '{NULL';
2918 "i" := "dim_p";
2919 LOOP
2920 "i" := "i" - 1;
2921 EXIT WHEN "i" = 0;
2922 "ary_text_v" := "ary_text_v" || ',NULL';
2923 END LOOP;
2924 "ary_text_v" := "ary_text_v" || '}';
2925 RETURN "ary_text_v";
2926 ELSE
2927 RAISE EXCEPTION 'Dimension needs to be at least 1.';
2928 END IF;
2929 END;
2930 $$;
2932 COMMENT ON FUNCTION "array_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
2935 CREATE FUNCTION "square_matrix_init_string"("dim_p" INTEGER)
2936 RETURNS TEXT
2937 LANGUAGE 'plpgsql' IMMUTABLE AS $$
2938 DECLARE
2939 "i" INTEGER;
2940 "row_text_v" TEXT;
2941 "ary_text_v" TEXT;
2942 BEGIN
2943 IF "dim_p" >= 1 THEN
2944 "row_text_v" := '{NULL';
2945 "i" := "dim_p";
2946 LOOP
2947 "i" := "i" - 1;
2948 EXIT WHEN "i" = 0;
2949 "row_text_v" := "row_text_v" || ',NULL';
2950 END LOOP;
2951 "row_text_v" := "row_text_v" || '}';
2952 "ary_text_v" := '{' || "row_text_v";
2953 "i" := "dim_p";
2954 LOOP
2955 "i" := "i" - 1;
2956 EXIT WHEN "i" = 0;
2957 "ary_text_v" := "ary_text_v" || ',' || "row_text_v";
2958 END LOOP;
2959 "ary_text_v" := "ary_text_v" || '}';
2960 RETURN "ary_text_v";
2961 ELSE
2962 RAISE EXCEPTION 'Dimension needs to be at least 1.';
2963 END IF;
2964 END;
2965 $$;
2967 COMMENT ON FUNCTION "square_matrix_init_string"(INTEGER) IS 'Needed for PostgreSQL < 8.4, due to missing "array_fill" function';
2970 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
2971 RETURNS VOID
2972 LANGUAGE 'plpgsql' VOLATILE AS $$
2973 DECLARE
2974 "dimension_v" INTEGER;
2975 "vote_matrix" INT4[][]; -- absolute votes
2976 "matrix" INT8[][]; -- defeat strength / best paths
2977 "i" INTEGER;
2978 "j" INTEGER;
2979 "k" INTEGER;
2980 "battle_row" "battle"%ROWTYPE;
2981 "rank_ary" INT4[];
2982 "rank_v" INT4;
2983 "done_v" INTEGER;
2984 "winners_ary" INTEGER[];
2985 "initiative_id_v" "initiative"."id"%TYPE;
2986 BEGIN
2987 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
2988 SELECT count(1) INTO "dimension_v" FROM "initiative"
2989 WHERE "issue_id" = "issue_id_p" AND "agreed";
2990 IF "dimension_v" = 1 THEN
2991 UPDATE "initiative" SET "rank" = 1
2992 WHERE "issue_id" = "issue_id_p" AND "agreed";
2993 ELSIF "dimension_v" > 1 THEN
2994 -- Create "vote_matrix" with absolute number of votes in pairwise
2995 -- comparison:
2996 "vote_matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
2997 "i" := 1;
2998 "j" := 2;
2999 FOR "battle_row" IN
3000 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
3001 ORDER BY "winning_initiative_id", "losing_initiative_id"
3002 LOOP
3003 "vote_matrix"["i"]["j"] := "battle_row"."count";
3004 IF "j" = "dimension_v" THEN
3005 "i" := "i" + 1;
3006 "j" := 1;
3007 ELSE
3008 "j" := "j" + 1;
3009 IF "j" = "i" THEN
3010 "j" := "j" + 1;
3011 END IF;
3012 END IF;
3013 END LOOP;
3014 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
3015 RAISE EXCEPTION 'Wrong battle count (should not happen)';
3016 END IF;
3017 -- Store defeat strengths in "matrix" using "defeat_strength"
3018 -- function:
3019 "matrix" := "square_matrix_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3020 "i" := 1;
3021 LOOP
3022 "j" := 1;
3023 LOOP
3024 IF "i" != "j" THEN
3025 "matrix"["i"]["j"] := "defeat_strength"(
3026 "vote_matrix"["i"]["j"],
3027 "vote_matrix"["j"]["i"]
3028 );
3029 END IF;
3030 EXIT WHEN "j" = "dimension_v";
3031 "j" := "j" + 1;
3032 END LOOP;
3033 EXIT WHEN "i" = "dimension_v";
3034 "i" := "i" + 1;
3035 END LOOP;
3036 -- Find best paths:
3037 "i" := 1;
3038 LOOP
3039 "j" := 1;
3040 LOOP
3041 IF "i" != "j" THEN
3042 "k" := 1;
3043 LOOP
3044 IF "i" != "k" AND "j" != "k" THEN
3045 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
3046 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
3047 "matrix"["j"]["k"] := "matrix"["j"]["i"];
3048 END IF;
3049 ELSE
3050 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
3051 "matrix"["j"]["k"] := "matrix"["i"]["k"];
3052 END IF;
3053 END IF;
3054 END IF;
3055 EXIT WHEN "k" = "dimension_v";
3056 "k" := "k" + 1;
3057 END LOOP;
3058 END IF;
3059 EXIT WHEN "j" = "dimension_v";
3060 "j" := "j" + 1;
3061 END LOOP;
3062 EXIT WHEN "i" = "dimension_v";
3063 "i" := "i" + 1;
3064 END LOOP;
3065 -- Determine order of winners:
3066 "rank_ary" := "array_init_string"("dimension_v"); -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
3067 "rank_v" := 1;
3068 "done_v" := 0;
3069 LOOP
3070 "winners_ary" := '{}';
3071 "i" := 1;
3072 LOOP
3073 IF "rank_ary"["i"] ISNULL THEN
3074 "j" := 1;
3075 LOOP
3076 IF
3077 "i" != "j" AND
3078 "rank_ary"["j"] ISNULL AND
3079 "matrix"["j"]["i"] > "matrix"["i"]["j"]
3080 THEN
3081 -- someone else is better
3082 EXIT;
3083 END IF;
3084 IF "j" = "dimension_v" THEN
3085 -- noone is better
3086 "winners_ary" := "winners_ary" || "i";
3087 EXIT;
3088 END IF;
3089 "j" := "j" + 1;
3090 END LOOP;
3091 END IF;
3092 EXIT WHEN "i" = "dimension_v";
3093 "i" := "i" + 1;
3094 END LOOP;
3095 "i" := 1;
3096 LOOP
3097 "rank_ary"["winners_ary"["i"]] := "rank_v";
3098 "done_v" := "done_v" + 1;
3099 EXIT WHEN "i" = array_upper("winners_ary", 1);
3100 "i" := "i" + 1;
3101 END LOOP;
3102 EXIT WHEN "done_v" = "dimension_v";
3103 "rank_v" := "rank_v" + 1;
3104 END LOOP;
3105 -- write preliminary ranks:
3106 "i" := 1;
3107 FOR "initiative_id_v" IN
3108 SELECT "id" FROM "initiative"
3109 WHERE "issue_id" = "issue_id_p" AND "agreed"
3110 ORDER BY "id"
3111 LOOP
3112 UPDATE "initiative" SET "rank" = "rank_ary"["i"]
3113 WHERE "id" = "initiative_id_v";
3114 "i" := "i" + 1;
3115 END LOOP;
3116 IF "i" != "dimension_v" + 1 THEN
3117 RAISE EXCEPTION 'Wrong winner count (should not happen)';
3118 END IF;
3119 -- straighten ranks (start counting with 1, no equal ranks):
3120 "rank_v" := 1;
3121 FOR "initiative_id_v" IN
3122 SELECT "id" FROM "initiative"
3123 WHERE "issue_id" = "issue_id_p" AND "rank" NOTNULL
3124 ORDER BY
3125 "rank",
3126 "vote_ratio"("positive_votes", "negative_votes") DESC,
3127 "id"
3128 LOOP
3129 UPDATE "initiative" SET "rank" = "rank_v"
3130 WHERE "id" = "initiative_id_v";
3131 "rank_v" := "rank_v" + 1;
3132 END LOOP;
3133 END IF;
3134 -- mark issue as finished
3135 UPDATE "issue" SET "ranks_available" = TRUE
3136 WHERE "id" = "issue_id_p";
3137 RETURN;
3138 END;
3139 $$;
3141 COMMENT ON FUNCTION "calculate_ranks"
3142 ( "issue"."id"%TYPE )
3143 IS 'Determine ranking (Votes have to be counted first)';
3147 -----------------------------
3148 -- Automatic state changes --
3149 -----------------------------
3152 CREATE FUNCTION "check_issue"
3153 ( "issue_id_p" "issue"."id"%TYPE )
3154 RETURNS VOID
3155 LANGUAGE 'plpgsql' VOLATILE AS $$
3156 DECLARE
3157 "issue_row" "issue"%ROWTYPE;
3158 "policy_row" "policy"%ROWTYPE;
3159 "voting_requested_v" BOOLEAN;
3160 BEGIN
3161 PERFORM "lock_issue"("issue_id_p");
3162 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3163 -- only process open issues:
3164 IF "issue_row"."closed" ISNULL THEN
3165 SELECT * INTO "policy_row" FROM "policy"
3166 WHERE "id" = "issue_row"."policy_id";
3167 -- create a snapshot, unless issue is already fully frozen:
3168 IF "issue_row"."fully_frozen" ISNULL THEN
3169 PERFORM "create_snapshot"("issue_id_p");
3170 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3171 END IF;
3172 -- eventually close or accept issues, which have not been accepted:
3173 IF "issue_row"."accepted" ISNULL THEN
3174 IF EXISTS (
3175 SELECT NULL FROM "initiative"
3176 WHERE "issue_id" = "issue_id_p"
3177 AND "supporter_count" > 0
3178 AND "supporter_count" * "policy_row"."issue_quorum_den"
3179 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
3180 ) THEN
3181 -- accept issues, if supporter count is high enough
3182 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3183 "issue_row"."accepted" = now(); -- NOTE: "issue_row" used later
3184 UPDATE "issue" SET "accepted" = "issue_row"."accepted"
3185 WHERE "id" = "issue_row"."id";
3186 ELSIF
3187 now() >= "issue_row"."created" + "issue_row"."admission_time"
3188 THEN
3189 -- close issues, if admission time has expired
3190 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
3191 UPDATE "issue" SET "closed" = now()
3192 WHERE "id" = "issue_row"."id";
3193 END IF;
3194 END IF;
3195 -- eventually half freeze issues:
3196 IF
3197 -- NOTE: issue can't be closed at this point, if it has been accepted
3198 "issue_row"."accepted" NOTNULL AND
3199 "issue_row"."half_frozen" ISNULL
3200 THEN
3201 SELECT
3202 CASE
3203 WHEN "vote_now" * 2 > "issue_row"."population" THEN
3204 TRUE
3205 WHEN "vote_later" * 2 > "issue_row"."population" THEN
3206 FALSE
3207 ELSE NULL
3208 END
3209 INTO "voting_requested_v"
3210 FROM "issue" WHERE "id" = "issue_id_p";
3211 IF
3212 "voting_requested_v" OR (
3213 "voting_requested_v" ISNULL AND
3214 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
3216 THEN
3217 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
3218 "issue_row"."half_frozen" = now(); -- NOTE: "issue_row" used later
3219 UPDATE "issue" SET "half_frozen" = "issue_row"."half_frozen"
3220 WHERE "id" = "issue_row"."id";
3221 END IF;
3222 END IF;
3223 -- close issues after some time, if all initiatives have been revoked:
3224 IF
3225 "issue_row"."closed" ISNULL AND
3226 NOT EXISTS (
3227 -- all initiatives are revoked
3228 SELECT NULL FROM "initiative"
3229 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
3230 ) AND (
3231 NOT EXISTS (
3232 -- and no initiatives have been revoked lately
3233 SELECT NULL FROM "initiative"
3234 WHERE "issue_id" = "issue_id_p"
3235 AND now() < "revoked" + "issue_row"."verification_time"
3236 ) OR (
3237 -- or verification time has elapsed
3238 "issue_row"."half_frozen" NOTNULL AND
3239 "issue_row"."fully_frozen" ISNULL AND
3240 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3243 THEN
3244 "issue_row"."closed" = now(); -- NOTE: "issue_row" used later
3245 UPDATE "issue" SET "closed" = "issue_row"."closed"
3246 WHERE "id" = "issue_row"."id";
3247 END IF;
3248 -- fully freeze issue after verification time:
3249 IF
3250 "issue_row"."half_frozen" NOTNULL AND
3251 "issue_row"."fully_frozen" ISNULL AND
3252 "issue_row"."closed" ISNULL AND
3253 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
3254 THEN
3255 PERFORM "freeze_after_snapshot"("issue_id_p");
3256 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
3257 END IF;
3258 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
3259 -- close issue by calling close_voting(...) after voting time:
3260 IF
3261 "issue_row"."closed" ISNULL AND
3262 "issue_row"."fully_frozen" NOTNULL AND
3263 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
3264 THEN
3265 PERFORM "close_voting"("issue_id_p");
3266 END IF;
3267 END IF;
3268 RETURN;
3269 END;
3270 $$;
3272 COMMENT ON FUNCTION "check_issue"
3273 ( "issue"."id"%TYPE )
3274 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.';
3277 CREATE FUNCTION "check_everything"()
3278 RETURNS VOID
3279 LANGUAGE 'plpgsql' VOLATILE AS $$
3280 DECLARE
3281 "issue_id_v" "issue"."id"%TYPE;
3282 BEGIN
3283 DELETE FROM "expired_session";
3284 PERFORM "calculate_member_counts"();
3285 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
3286 PERFORM "check_issue"("issue_id_v");
3287 END LOOP;
3288 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
3289 PERFORM "calculate_ranks"("issue_id_v");
3290 END LOOP;
3291 RETURN;
3292 END;
3293 $$;
3295 COMMENT ON FUNCTION "check_everything"() IS 'Perform "check_issue" for every open issue, and if possible, automatically calculate ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result.';
3299 ----------------------
3300 -- Deletion of data --
3301 ----------------------
3304 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
3305 RETURNS VOID
3306 LANGUAGE 'plpgsql' VOLATILE AS $$
3307 DECLARE
3308 "issue_row" "issue"%ROWTYPE;
3309 BEGIN
3310 SELECT * INTO "issue_row"
3311 FROM "issue" WHERE "id" = "issue_id_p"
3312 FOR UPDATE;
3313 IF "issue_row"."cleaned" ISNULL THEN
3314 UPDATE "issue" SET
3315 "closed" = NULL,
3316 "ranks_available" = FALSE
3317 WHERE "id" = "issue_id_p";
3318 DELETE FROM "delegating_voter"
3319 WHERE "issue_id" = "issue_id_p";
3320 DELETE FROM "direct_voter"
3321 WHERE "issue_id" = "issue_id_p";
3322 DELETE FROM "delegating_interest_snapshot"
3323 WHERE "issue_id" = "issue_id_p";
3324 DELETE FROM "direct_interest_snapshot"
3325 WHERE "issue_id" = "issue_id_p";
3326 DELETE FROM "delegating_population_snapshot"
3327 WHERE "issue_id" = "issue_id_p";
3328 DELETE FROM "direct_population_snapshot"
3329 WHERE "issue_id" = "issue_id_p";
3330 DELETE FROM "ignored_issue"
3331 WHERE "issue_id" = "issue_id_p";
3332 DELETE FROM "delegation"
3333 WHERE "issue_id" = "issue_id_p";
3334 DELETE FROM "supporter"
3335 WHERE "issue_id" = "issue_id_p";
3336 UPDATE "issue" SET
3337 "closed" = "issue_row"."closed",
3338 "ranks_available" = "issue_row"."ranks_available",
3339 "cleaned" = now()
3340 WHERE "id" = "issue_id_p";
3341 END IF;
3342 RETURN;
3343 END;
3344 $$;
3346 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
3349 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
3350 RETURNS VOID
3351 LANGUAGE 'plpgsql' VOLATILE AS $$
3352 BEGIN
3353 UPDATE "member" SET
3354 "last_login" = NULL,
3355 "login" = NULL,
3356 "password" = NULL,
3357 "active" = FALSE,
3358 "notify_email" = NULL,
3359 "notify_email_unconfirmed" = NULL,
3360 "notify_email_secret" = NULL,
3361 "notify_email_secret_expiry" = NULL,
3362 "notify_email_lock_expiry" = NULL,
3363 "password_reset_secret" = NULL,
3364 "password_reset_secret_expiry" = NULL,
3365 "organizational_unit" = NULL,
3366 "internal_posts" = NULL,
3367 "realname" = NULL,
3368 "birthday" = NULL,
3369 "address" = NULL,
3370 "email" = NULL,
3371 "xmpp_address" = NULL,
3372 "website" = NULL,
3373 "phone" = NULL,
3374 "mobile_phone" = NULL,
3375 "profession" = NULL,
3376 "external_memberships" = NULL,
3377 "external_posts" = NULL,
3378 "statement" = NULL
3379 WHERE "id" = "member_id_p";
3380 -- "text_search_data" is updated by triggers
3381 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
3382 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
3383 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
3384 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
3385 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
3386 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
3387 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
3388 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
3389 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
3390 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
3391 DELETE FROM "ignored_issue" WHERE "member_id" = "member_id_p";
3392 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
3393 DELETE FROM "direct_voter" USING "issue"
3394 WHERE "direct_voter"."issue_id" = "issue"."id"
3395 AND "issue"."closed" ISNULL
3396 AND "member_id" = "member_id_p";
3397 RETURN;
3398 END;
3399 $$;
3401 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)';
3404 CREATE FUNCTION "delete_private_data"()
3405 RETURNS VOID
3406 LANGUAGE 'plpgsql' VOLATILE AS $$
3407 BEGIN
3408 UPDATE "member" SET
3409 "last_login" = NULL,
3410 "login" = NULL,
3411 "password" = NULL,
3412 "notify_email" = NULL,
3413 "notify_email_unconfirmed" = NULL,
3414 "notify_email_secret" = NULL,
3415 "notify_email_secret_expiry" = NULL,
3416 "notify_email_lock_expiry" = NULL,
3417 "password_reset_secret" = NULL,
3418 "password_reset_secret_expiry" = NULL,
3419 "organizational_unit" = NULL,
3420 "internal_posts" = NULL,
3421 "realname" = NULL,
3422 "birthday" = NULL,
3423 "address" = NULL,
3424 "email" = NULL,
3425 "xmpp_address" = NULL,
3426 "website" = NULL,
3427 "phone" = NULL,
3428 "mobile_phone" = NULL,
3429 "profession" = NULL,
3430 "external_memberships" = NULL,
3431 "external_posts" = NULL,
3432 "statement" = NULL;
3433 -- "text_search_data" is updated by triggers
3434 DELETE FROM "invite_code";
3435 DELETE FROM "setting";
3436 DELETE FROM "setting_map";
3437 DELETE FROM "member_relation_setting";
3438 DELETE FROM "member_image";
3439 DELETE FROM "contact";
3440 DELETE FROM "session";
3441 DELETE FROM "area_setting";
3442 DELETE FROM "issue_setting";
3443 DELETE FROM "initiative_setting";
3444 DELETE FROM "suggestion_setting";
3445 DELETE FROM "ignored_issue";
3446 DELETE FROM "direct_voter" USING "issue"
3447 WHERE "direct_voter"."issue_id" = "issue"."id"
3448 AND "issue"."closed" ISNULL;
3449 RETURN;
3450 END;
3451 $$;
3453 COMMENT ON FUNCTION "delete_private_data"() IS '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.';
3457 COMMIT;

Impressum / About Us