liquid_feedback_core

view update/core-update.v1.4.0_rc4-v1.5.0_rc1.sql @ 188:8b496fa85a65

Renamed core-update.v1.4.0-v1.5.0.sql to core-update.v1.4.0_rc4-v1.5.0_rc1.sql; Set version info to v1.5.0_rc1
author jbe
date Sat Jul 30 01:57:27 2011 +0200 (2011-07-30)
parents update/core-update.v1.4.0-v1.5.0.sql@969ce2bea98c
children 548152fa67e5
line source
1 SELECT "calculate_ranks"("id") FROM "issue_with_ranks_missing";
3 BEGIN;
5 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
6 SELECT * FROM (VALUES ('1.5.0_rc1', 1, 5, -1))
7 AS "subquery"("string", "major", "minor", "revision");
9 ALTER TABLE "member" ADD COLUMN "invite_code" TEXT UNIQUE;
10 ALTER TABLE "member" ADD COLUMN "admin_comment" TEXT;
11 ALTER TABLE "member" ADD COLUMN "activated" TIMESTAMPTZ;
12 ALTER TABLE "member" ADD COLUMN "last_activity" DATE;
13 ALTER TABLE "member" DROP COLUMN "last_login_public";
14 ALTER TABLE "member" ALTER COLUMN "active" SET DEFAULT FALSE;
15 ALTER TABLE "member" ADD COLUMN "formatting_engine" TEXT;
17 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
18 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
19 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
20 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
21 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
22 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
23 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
25 CREATE TYPE "application_access_level" AS ENUM
26 ('member', 'full', 'pseudonymous', 'anonymous');
28 COMMENT ON TYPE "application_access_level" IS 'Access privileges for applications using the API';
30 CREATE TABLE "member_application" (
31 "id" SERIAL8 PRIMARY KEY,
32 UNIQUE ("member_id", "name"),
33 "member_id" INT4 NOT NULL REFERENCES "member" ("id")
34 ON DELETE CASCADE ON UPDATE CASCADE,
35 "name" TEXT NOT NULL,
36 "comment" TEXT,
37 "access_level" "application_access_level" NOT NULL,
38 "key" TEXT NOT NULL,
39 "last_usage" TIMESTAMPTZ );
41 COMMENT ON TABLE "member_application" IS 'Registered application being allowed to use the API';
43 CREATE TABLE "rendered_member_statement" (
44 PRIMARY KEY ("member_id", "format"),
45 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
46 "format" TEXT,
47 "content" TEXT NOT NULL );
49 COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)';
51 DROP VIEW "expired_session";
52 DROP TABLE "session";
54 ALTER TABLE "policy" ADD COLUMN "direct_majority_num" INT4 NOT NULL DEFAULT 1;
55 ALTER TABLE "policy" ADD COLUMN "direct_majority_den" INT4 NOT NULL DEFAULT 2;
56 ALTER TABLE "policy" ADD COLUMN "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE;
57 ALTER TABLE "policy" ADD COLUMN "direct_majority_positive" INT4 NOT NULL DEFAULT 0;
58 ALTER TABLE "policy" ADD COLUMN "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0;
59 ALTER TABLE "policy" ADD COLUMN "indirect_majority_num" INT4 NOT NULL DEFAULT 1;
60 ALTER TABLE "policy" ADD COLUMN "indirect_majority_den" INT4 NOT NULL DEFAULT 2;
61 ALTER TABLE "policy" ADD COLUMN "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE;
62 ALTER TABLE "policy" ADD COLUMN "indirect_majority_positive" INT4 NOT NULL DEFAULT 0;
63 ALTER TABLE "policy" ADD COLUMN "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0;
64 ALTER TABLE "policy" ADD COLUMN "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE;
65 ALTER TABLE "policy" ADD COLUMN "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE;
67 UPDATE "policy" SET
68 "direct_majority_num" = "majority_num",
69 "direct_majority_den" = "majority_den",
70 "direct_majority_strict" = "majority_strict",
71 "indirect_majority_num" = "majority_num",
72 "indirect_majority_den" = "majority_den",
73 "indirect_majority_strict" = "majority_strict";
75 ALTER TABLE "policy" DROP COLUMN "majority_num";
76 ALTER TABLE "policy" DROP COLUMN "majority_den";
77 ALTER TABLE "policy" DROP COLUMN "majority_strict";
79 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
80 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
81 COMMENT ON COLUMN "policy"."direct_majority_strict" IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.';
82 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
83 COMMENT ON COLUMN "policy"."direct_majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner';
84 COMMENT ON COLUMN "policy"."indirect_majority_num" IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
85 COMMENT ON COLUMN "policy"."indirect_majority_den" IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
86 COMMENT ON COLUMN "policy"."indirect_majority_strict" IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.';
87 COMMENT ON COLUMN "policy"."indirect_majority_positive" IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner';
88 COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner';
89 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
90 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
92 ALTER TABLE "area" DROP COLUMN "autoreject_weight";
94 DROP VIEW "open_issue";
95 DROP VIEW "issue_with_ranks_missing";
97 ALTER TABLE "issue" DROP COLUMN "vote_now";
98 ALTER TABLE "issue" DROP COLUMN "vote_later";
99 ALTER TABLE "issue" ADD COLUMN "status_quo_schulze_rank" INT4;
101 CREATE VIEW "open_issue" AS
102 SELECT * FROM "issue" WHERE "closed" ISNULL;
104 COMMENT ON VIEW "open_issue" IS 'All open issues';
106 CREATE VIEW "issue_with_ranks_missing" AS
107 SELECT * FROM "issue"
108 WHERE "fully_frozen" NOTNULL
109 AND "closed" NOTNULL
110 AND "ranks_available" = FALSE;
112 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
114 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
115 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
116 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
118 DROP VIEW "battle_view";
120 ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
121 ALTER TABLE "initiative" DROP CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null";
122 ALTER TABLE "initiative" DROP CONSTRAINT "non_agreed_initiatives_cant_get_a_rank";
124 ALTER TABLE "initiative" DROP COLUMN "agreed";
125 ALTER TABLE "initiative" ADD COLUMN "direct_majority" BOOLEAN;
126 ALTER TABLE "initiative" ADD COLUMN "indirect_majority" BOOLEAN;
127 ALTER TABLE "initiative" ADD COLUMN "schulze_rank" INT4;
128 ALTER TABLE "initiative" ADD COLUMN "better_than_status_quo" BOOLEAN;
129 ALTER TABLE "initiative" ADD COLUMN "worse_than_status_quo" BOOLEAN;
130 ALTER TABLE "initiative" ADD COLUMN "reverse_beat_path" BOOLEAN;
131 ALTER TABLE "initiative" ADD COLUMN "multistage_majority" BOOLEAN;
132 ALTER TABLE "initiative" ADD COLUMN "eligible" BOOLEAN;
133 ALTER TABLE "initiative" ADD COLUMN "winner" BOOLEAN;
135 ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
136 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
137 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
138 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
139 "schulze_rank" ISNULL AND
140 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
141 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
142 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
143 ALTER TABLE "initiative" ADD CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo"));
144 ALTER TABLE "initiative" ADD CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
145 "eligible" = FALSE OR
146 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") );
147 ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE);
148 ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1);
149 ALTER TABLE "initiative" ADD CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE);
150 ALTER TABLE "initiative" ADD CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank");
152 COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
153 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
154 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
155 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
156 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
157 COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties), from this initiative to the status quo';
158 COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
159 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
160 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
161 COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
163 ALTER TABLE "battle" DROP CONSTRAINT "battle_pkey";
164 ALTER TABLE "battle" ALTER COLUMN "issue_id" SET NOT NULL;
165 ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK (
166 "winning_initiative_id" != "losing_initiative_id" OR
167 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
168 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) );
170 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
171 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
172 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
174 ALTER TABLE "suggestion" ADD COLUMN "draft_id" INT8;
175 ALTER TABLE "suggestion" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
176 ALTER TABLE "suggestion" ADD COLUMN "formatting_engine" TEXT;
177 ALTER TABLE "suggestion" RENAME COLUMN "description" TO "content";
179 DROP TRIGGER "update_text_search_data" ON "suggestion";
181 CREATE TRIGGER "update_text_search_data"
182 BEFORE INSERT OR UPDATE ON "suggestion"
183 FOR EACH ROW EXECUTE PROCEDURE
184 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
185 "name", "content");
187 COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
189 CREATE TABLE "rendered_suggestion" (
190 PRIMARY KEY ("suggestion_id", "format"),
191 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
192 "format" TEXT,
193 "content" TEXT NOT NULL );
195 COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
197 DROP TABLE "invite_code_unit";
199 DROP VIEW "area_member_count";
201 ALTER TABLE "membership" DROP COLUMN "autoreject";
203 ALTER TABLE "interest" DROP COLUMN "autoreject";
204 ALTER TABLE "interest" DROP COLUMN "voting_requested";
206 ALTER TABLE "supporter" DROP CONSTRAINT "supporter_initiative_id_fkey";
207 ALTER TABLE "supporter" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
209 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
211 ALTER TABLE "direct_interest_snapshot" DROP COLUMN "voting_requested";
212 ALTER TABLE "direct_voter" DROP COLUMN "autoreject";
214 DROP TRIGGER "default_for_draft_id" ON "supporter";
215 DROP FUNCTION "supporter_default_for_draft_id_trigger"();
217 CREATE FUNCTION "default_for_draft_id_trigger"()
218 RETURNS TRIGGER
219 LANGUAGE 'plpgsql' VOLATILE AS $$
220 BEGIN
221 IF NEW."draft_id" ISNULL THEN
222 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
223 WHERE "initiative_id" = NEW."initiative_id";
224 END IF;
225 RETURN NEW;
226 END;
227 $$;
229 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
230 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
231 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
232 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
234 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
235 COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
236 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';
238 CREATE VIEW "area_member_count" AS
239 SELECT
240 "area"."id" AS "area_id",
241 count("member"."id") AS "direct_member_count",
242 coalesce(
243 sum(
244 CASE WHEN "member"."id" NOTNULL THEN
245 "membership_weight"("area"."id", "member"."id")
246 ELSE 0 END
247 )
248 ) AS "member_weight"
249 FROM "area"
250 LEFT JOIN "membership"
251 ON "area"."id" = "membership"."area_id"
252 LEFT JOIN "privilege"
253 ON "privilege"."unit_id" = "area"."unit_id"
254 AND "privilege"."member_id" = "membership"."member_id"
255 AND "privilege"."voting_right"
256 LEFT JOIN "member"
257 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
258 AND "member"."active"
259 GROUP BY "area"."id";
261 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
263 CREATE VIEW "battle_participant" AS
264 SELECT "initiative"."id", "initiative"."issue_id"
265 FROM "issue" JOIN "initiative"
266 ON "issue"."id" = "initiative"."issue_id"
267 WHERE "initiative"."admitted"
268 UNION ALL
269 SELECT NULL, "id" AS "issue_id"
270 FROM "issue";
272 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
274 CREATE VIEW "battle_view" AS
275 SELECT
276 "issue"."id" AS "issue_id",
277 "winning_initiative"."id" AS "winning_initiative_id",
278 "losing_initiative"."id" AS "losing_initiative_id",
279 sum(
280 CASE WHEN
281 coalesce("better_vote"."grade", 0) >
282 coalesce("worse_vote"."grade", 0)
283 THEN "direct_voter"."weight" ELSE 0 END
284 ) AS "count"
285 FROM "issue"
286 LEFT JOIN "direct_voter"
287 ON "issue"."id" = "direct_voter"."issue_id"
288 JOIN "battle_participant" AS "winning_initiative"
289 ON "issue"."id" = "winning_initiative"."issue_id"
290 JOIN "battle_participant" AS "losing_initiative"
291 ON "issue"."id" = "losing_initiative"."issue_id"
292 LEFT JOIN "vote" AS "better_vote"
293 ON "direct_voter"."member_id" = "better_vote"."member_id"
294 AND "winning_initiative"."id" = "better_vote"."initiative_id"
295 LEFT JOIN "vote" AS "worse_vote"
296 ON "direct_voter"."member_id" = "worse_vote"."member_id"
297 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
298 WHERE "issue"."closed" NOTNULL
299 AND "issue"."cleaned" ISNULL
300 AND (
301 "winning_initiative"."id" != "losing_initiative"."id" OR
302 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
303 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
304 GROUP BY
305 "issue"."id",
306 "winning_initiative"."id",
307 "losing_initiative"."id";
309 COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative (or status-quo) to another initiative (or status-quo); Used to fill "battle" table';
311 DROP FUNCTION "check_last_login"();
313 CREATE FUNCTION "check_activity"()
314 RETURNS VOID
315 LANGUAGE 'plpgsql' VOLATILE AS $$
316 DECLARE
317 "system_setting_row" "system_setting"%ROWTYPE;
318 BEGIN
319 SELECT * INTO "system_setting_row" FROM "system_setting";
320 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
321 IF "system_setting_row"."member_ttl" NOTNULL THEN
322 UPDATE "member" SET "active" = FALSE
323 WHERE "active" = TRUE
324 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
325 END IF;
326 RETURN;
327 END;
328 $$;
330 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
332 CREATE OR REPLACE FUNCTION "create_interest_snapshot"
333 ( "issue_id_p" "issue"."id"%TYPE )
334 RETURNS VOID
335 LANGUAGE 'plpgsql' VOLATILE AS $$
336 DECLARE
337 "member_id_v" "member"."id"%TYPE;
338 BEGIN
339 DELETE FROM "direct_interest_snapshot"
340 WHERE "issue_id" = "issue_id_p"
341 AND "event" = 'periodic';
342 DELETE FROM "delegating_interest_snapshot"
343 WHERE "issue_id" = "issue_id_p"
344 AND "event" = 'periodic';
345 DELETE FROM "direct_supporter_snapshot"
346 WHERE "issue_id" = "issue_id_p"
347 AND "event" = 'periodic';
348 INSERT INTO "direct_interest_snapshot"
349 ("issue_id", "event", "member_id")
350 SELECT
351 "issue_id_p" AS "issue_id",
352 'periodic' AS "event",
353 "member"."id" AS "member_id"
354 FROM "issue"
355 JOIN "area" ON "issue"."area_id" = "area"."id"
356 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
357 JOIN "member" ON "interest"."member_id" = "member"."id"
358 JOIN "privilege"
359 ON "privilege"."unit_id" = "area"."unit_id"
360 AND "privilege"."member_id" = "member"."id"
361 WHERE "issue"."id" = "issue_id_p"
362 AND "member"."active" AND "privilege"."voting_right";
363 FOR "member_id_v" IN
364 SELECT "member_id" FROM "direct_interest_snapshot"
365 WHERE "issue_id" = "issue_id_p"
366 AND "event" = 'periodic'
367 LOOP
368 UPDATE "direct_interest_snapshot" SET
369 "weight" = 1 +
370 "weight_of_added_delegations_for_interest_snapshot"(
371 "issue_id_p",
372 "member_id_v",
373 '{}'
374 )
375 WHERE "issue_id" = "issue_id_p"
376 AND "event" = 'periodic'
377 AND "member_id" = "member_id_v";
378 END LOOP;
379 INSERT INTO "direct_supporter_snapshot"
380 ( "issue_id", "initiative_id", "event", "member_id",
381 "informed", "satisfied" )
382 SELECT
383 "issue_id_p" AS "issue_id",
384 "initiative"."id" AS "initiative_id",
385 'periodic' AS "event",
386 "supporter"."member_id" AS "member_id",
387 "supporter"."draft_id" = "current_draft"."id" AS "informed",
388 NOT EXISTS (
389 SELECT NULL FROM "critical_opinion"
390 WHERE "initiative_id" = "initiative"."id"
391 AND "member_id" = "supporter"."member_id"
392 ) AS "satisfied"
393 FROM "initiative"
394 JOIN "supporter"
395 ON "supporter"."initiative_id" = "initiative"."id"
396 JOIN "current_draft"
397 ON "initiative"."id" = "current_draft"."initiative_id"
398 JOIN "direct_interest_snapshot"
399 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
400 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
401 AND "event" = 'periodic'
402 WHERE "initiative"."issue_id" = "issue_id_p";
403 RETURN;
404 END;
405 $$;
407 CREATE OR REPLACE FUNCTION "create_snapshot"
408 ( "issue_id_p" "issue"."id"%TYPE )
409 RETURNS VOID
410 LANGUAGE 'plpgsql' VOLATILE AS $$
411 DECLARE
412 "initiative_id_v" "initiative"."id"%TYPE;
413 "suggestion_id_v" "suggestion"."id"%TYPE;
414 BEGIN
415 PERFORM "lock_issue"("issue_id_p");
416 PERFORM "create_population_snapshot"("issue_id_p");
417 PERFORM "create_interest_snapshot"("issue_id_p");
418 UPDATE "issue" SET
419 "snapshot" = now(),
420 "latest_snapshot_event" = 'periodic',
421 "population" = (
422 SELECT coalesce(sum("weight"), 0)
423 FROM "direct_population_snapshot"
424 WHERE "issue_id" = "issue_id_p"
425 AND "event" = 'periodic'
426 )
427 WHERE "id" = "issue_id_p";
428 FOR "initiative_id_v" IN
429 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
430 LOOP
431 UPDATE "initiative" SET
432 "supporter_count" = (
433 SELECT coalesce(sum("di"."weight"), 0)
434 FROM "direct_interest_snapshot" AS "di"
435 JOIN "direct_supporter_snapshot" AS "ds"
436 ON "di"."member_id" = "ds"."member_id"
437 WHERE "di"."issue_id" = "issue_id_p"
438 AND "di"."event" = 'periodic'
439 AND "ds"."initiative_id" = "initiative_id_v"
440 AND "ds"."event" = 'periodic'
441 ),
442 "informed_supporter_count" = (
443 SELECT coalesce(sum("di"."weight"), 0)
444 FROM "direct_interest_snapshot" AS "di"
445 JOIN "direct_supporter_snapshot" AS "ds"
446 ON "di"."member_id" = "ds"."member_id"
447 WHERE "di"."issue_id" = "issue_id_p"
448 AND "di"."event" = 'periodic'
449 AND "ds"."initiative_id" = "initiative_id_v"
450 AND "ds"."event" = 'periodic'
451 AND "ds"."informed"
452 ),
453 "satisfied_supporter_count" = (
454 SELECT coalesce(sum("di"."weight"), 0)
455 FROM "direct_interest_snapshot" AS "di"
456 JOIN "direct_supporter_snapshot" AS "ds"
457 ON "di"."member_id" = "ds"."member_id"
458 WHERE "di"."issue_id" = "issue_id_p"
459 AND "di"."event" = 'periodic'
460 AND "ds"."initiative_id" = "initiative_id_v"
461 AND "ds"."event" = 'periodic'
462 AND "ds"."satisfied"
463 ),
464 "satisfied_informed_supporter_count" = (
465 SELECT coalesce(sum("di"."weight"), 0)
466 FROM "direct_interest_snapshot" AS "di"
467 JOIN "direct_supporter_snapshot" AS "ds"
468 ON "di"."member_id" = "ds"."member_id"
469 WHERE "di"."issue_id" = "issue_id_p"
470 AND "di"."event" = 'periodic'
471 AND "ds"."initiative_id" = "initiative_id_v"
472 AND "ds"."event" = 'periodic'
473 AND "ds"."informed"
474 AND "ds"."satisfied"
475 )
476 WHERE "id" = "initiative_id_v";
477 FOR "suggestion_id_v" IN
478 SELECT "id" FROM "suggestion"
479 WHERE "initiative_id" = "initiative_id_v"
480 LOOP
481 UPDATE "suggestion" SET
482 "minus2_unfulfilled_count" = (
483 SELECT coalesce(sum("snapshot"."weight"), 0)
484 FROM "issue" CROSS JOIN "opinion"
485 JOIN "direct_interest_snapshot" AS "snapshot"
486 ON "snapshot"."issue_id" = "issue"."id"
487 AND "snapshot"."event" = "issue"."latest_snapshot_event"
488 AND "snapshot"."member_id" = "opinion"."member_id"
489 WHERE "issue"."id" = "issue_id_p"
490 AND "opinion"."suggestion_id" = "suggestion_id_v"
491 AND "opinion"."degree" = -2
492 AND "opinion"."fulfilled" = FALSE
493 ),
494 "minus2_fulfilled_count" = (
495 SELECT coalesce(sum("snapshot"."weight"), 0)
496 FROM "issue" CROSS JOIN "opinion"
497 JOIN "direct_interest_snapshot" AS "snapshot"
498 ON "snapshot"."issue_id" = "issue"."id"
499 AND "snapshot"."event" = "issue"."latest_snapshot_event"
500 AND "snapshot"."member_id" = "opinion"."member_id"
501 WHERE "issue"."id" = "issue_id_p"
502 AND "opinion"."suggestion_id" = "suggestion_id_v"
503 AND "opinion"."degree" = -2
504 AND "opinion"."fulfilled" = TRUE
505 ),
506 "minus1_unfulfilled_count" = (
507 SELECT coalesce(sum("snapshot"."weight"), 0)
508 FROM "issue" CROSS JOIN "opinion"
509 JOIN "direct_interest_snapshot" AS "snapshot"
510 ON "snapshot"."issue_id" = "issue"."id"
511 AND "snapshot"."event" = "issue"."latest_snapshot_event"
512 AND "snapshot"."member_id" = "opinion"."member_id"
513 WHERE "issue"."id" = "issue_id_p"
514 AND "opinion"."suggestion_id" = "suggestion_id_v"
515 AND "opinion"."degree" = -1
516 AND "opinion"."fulfilled" = FALSE
517 ),
518 "minus1_fulfilled_count" = (
519 SELECT coalesce(sum("snapshot"."weight"), 0)
520 FROM "issue" CROSS JOIN "opinion"
521 JOIN "direct_interest_snapshot" AS "snapshot"
522 ON "snapshot"."issue_id" = "issue"."id"
523 AND "snapshot"."event" = "issue"."latest_snapshot_event"
524 AND "snapshot"."member_id" = "opinion"."member_id"
525 WHERE "issue"."id" = "issue_id_p"
526 AND "opinion"."suggestion_id" = "suggestion_id_v"
527 AND "opinion"."degree" = -1
528 AND "opinion"."fulfilled" = TRUE
529 ),
530 "plus1_unfulfilled_count" = (
531 SELECT coalesce(sum("snapshot"."weight"), 0)
532 FROM "issue" CROSS JOIN "opinion"
533 JOIN "direct_interest_snapshot" AS "snapshot"
534 ON "snapshot"."issue_id" = "issue"."id"
535 AND "snapshot"."event" = "issue"."latest_snapshot_event"
536 AND "snapshot"."member_id" = "opinion"."member_id"
537 WHERE "issue"."id" = "issue_id_p"
538 AND "opinion"."suggestion_id" = "suggestion_id_v"
539 AND "opinion"."degree" = 1
540 AND "opinion"."fulfilled" = FALSE
541 ),
542 "plus1_fulfilled_count" = (
543 SELECT coalesce(sum("snapshot"."weight"), 0)
544 FROM "issue" CROSS JOIN "opinion"
545 JOIN "direct_interest_snapshot" AS "snapshot"
546 ON "snapshot"."issue_id" = "issue"."id"
547 AND "snapshot"."event" = "issue"."latest_snapshot_event"
548 AND "snapshot"."member_id" = "opinion"."member_id"
549 WHERE "issue"."id" = "issue_id_p"
550 AND "opinion"."suggestion_id" = "suggestion_id_v"
551 AND "opinion"."degree" = 1
552 AND "opinion"."fulfilled" = TRUE
553 ),
554 "plus2_unfulfilled_count" = (
555 SELECT coalesce(sum("snapshot"."weight"), 0)
556 FROM "issue" CROSS JOIN "opinion"
557 JOIN "direct_interest_snapshot" AS "snapshot"
558 ON "snapshot"."issue_id" = "issue"."id"
559 AND "snapshot"."event" = "issue"."latest_snapshot_event"
560 AND "snapshot"."member_id" = "opinion"."member_id"
561 WHERE "issue"."id" = "issue_id_p"
562 AND "opinion"."suggestion_id" = "suggestion_id_v"
563 AND "opinion"."degree" = 2
564 AND "opinion"."fulfilled" = FALSE
565 ),
566 "plus2_fulfilled_count" = (
567 SELECT coalesce(sum("snapshot"."weight"), 0)
568 FROM "issue" CROSS JOIN "opinion"
569 JOIN "direct_interest_snapshot" AS "snapshot"
570 ON "snapshot"."issue_id" = "issue"."id"
571 AND "snapshot"."event" = "issue"."latest_snapshot_event"
572 AND "snapshot"."member_id" = "opinion"."member_id"
573 WHERE "issue"."id" = "issue_id_p"
574 AND "opinion"."suggestion_id" = "suggestion_id_v"
575 AND "opinion"."degree" = 2
576 AND "opinion"."fulfilled" = TRUE
577 )
578 WHERE "suggestion"."id" = "suggestion_id_v";
579 END LOOP;
580 END LOOP;
581 RETURN;
582 END;
583 $$;
585 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
586 RETURNS VOID
587 LANGUAGE 'plpgsql' VOLATILE AS $$
588 DECLARE
589 "area_id_v" "area"."id"%TYPE;
590 "unit_id_v" "unit"."id"%TYPE;
591 "member_id_v" "member"."id"%TYPE;
592 BEGIN
593 PERFORM "lock_issue"("issue_id_p");
594 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
595 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
596 -- delete delegating votes (in cases of manual reset of issue state):
597 DELETE FROM "delegating_voter"
598 WHERE "issue_id" = "issue_id_p";
599 -- delete votes from non-privileged voters:
600 DELETE FROM "direct_voter"
601 USING (
602 SELECT
603 "direct_voter"."member_id"
604 FROM "direct_voter"
605 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
606 LEFT JOIN "privilege"
607 ON "privilege"."unit_id" = "unit_id_v"
608 AND "privilege"."member_id" = "direct_voter"."member_id"
609 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
610 "member"."active" = FALSE OR
611 "privilege"."voting_right" ISNULL OR
612 "privilege"."voting_right" = FALSE
613 )
614 ) AS "subquery"
615 WHERE "direct_voter"."issue_id" = "issue_id_p"
616 AND "direct_voter"."member_id" = "subquery"."member_id";
617 -- consider delegations:
618 UPDATE "direct_voter" SET "weight" = 1
619 WHERE "issue_id" = "issue_id_p";
620 PERFORM "add_vote_delegations"("issue_id_p");
621 -- set voter count and mark issue as being calculated:
622 UPDATE "issue" SET
623 "state" = 'calculation',
624 "closed" = now(),
625 "voter_count" = (
626 SELECT coalesce(sum("weight"), 0)
627 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
628 )
629 WHERE "id" = "issue_id_p";
630 -- materialize battle_view:
631 -- NOTE: "closed" column of issue must be set at this point
632 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
633 INSERT INTO "battle" (
634 "issue_id",
635 "winning_initiative_id", "losing_initiative_id",
636 "count"
637 ) SELECT
638 "issue_id",
639 "winning_initiative_id", "losing_initiative_id",
640 "count"
641 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
642 -- copy "positive_votes" and "negative_votes" from "battle" table:
643 UPDATE "initiative" SET
644 "positive_votes" = "battle_win"."count",
645 "negative_votes" = "battle_lose"."count"
646 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
647 WHERE
648 "battle_win"."issue_id" = "issue_id_p" AND
649 "battle_win"."winning_initiative_id" = "initiative"."id" AND
650 "battle_win"."losing_initiative_id" ISNULL AND
651 "battle_lose"."issue_id" = "issue_id_p" AND
652 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
653 "battle_lose"."winning_initiative_id" ISNULL;
654 END;
655 $$;
657 DROP FUNCTION "array_init_string"(INTEGER);
658 DROP FUNCTION "square_matrix_init_string"(INTEGER);
660 CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
661 RETURNS VOID
662 LANGUAGE 'plpgsql' VOLATILE AS $$
663 DECLARE
664 "issue_row" "issue"%ROWTYPE;
665 "policy_row" "policy"%ROWTYPE;
666 "dimension_v" INTEGER;
667 "vote_matrix" INT4[][]; -- absolute votes
668 "matrix" INT8[][]; -- defeat strength / best paths
669 "i" INTEGER;
670 "j" INTEGER;
671 "k" INTEGER;
672 "battle_row" "battle"%ROWTYPE;
673 "rank_ary" INT4[];
674 "rank_v" INT4;
675 "done_v" INTEGER;
676 "winners_ary" INTEGER[];
677 "initiative_id_v" "initiative"."id"%TYPE;
678 BEGIN
679 SELECT * INTO "issue_row"
680 FROM "issue" WHERE "id" = "issue_id_p"
681 FOR UPDATE;
682 SELECT * INTO "policy_row"
683 FROM "policy" WHERE "id" = "issue_row"."policy_id";
684 SELECT count(1) INTO "dimension_v"
685 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
686 -- Create "vote_matrix" with absolute number of votes in pairwise
687 -- comparison:
688 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
689 "i" := 1;
690 "j" := 2;
691 FOR "battle_row" IN
692 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
693 ORDER BY
694 "winning_initiative_id" NULLS LAST,
695 "losing_initiative_id" NULLS LAST
696 LOOP
697 "vote_matrix"["i"]["j"] := "battle_row"."count";
698 IF "j" = "dimension_v" THEN
699 "i" := "i" + 1;
700 "j" := 1;
701 ELSE
702 "j" := "j" + 1;
703 IF "j" = "i" THEN
704 "j" := "j" + 1;
705 END IF;
706 END IF;
707 END LOOP;
708 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
709 RAISE EXCEPTION 'Wrong battle count (should not happen)';
710 END IF;
711 -- Store defeat strengths in "matrix" using "defeat_strength"
712 -- function:
713 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
714 "i" := 1;
715 LOOP
716 "j" := 1;
717 LOOP
718 IF "i" != "j" THEN
719 "matrix"["i"]["j"] := "defeat_strength"(
720 "vote_matrix"["i"]["j"],
721 "vote_matrix"["j"]["i"]
722 );
723 END IF;
724 EXIT WHEN "j" = "dimension_v";
725 "j" := "j" + 1;
726 END LOOP;
727 EXIT WHEN "i" = "dimension_v";
728 "i" := "i" + 1;
729 END LOOP;
730 -- Find best paths:
731 "i" := 1;
732 LOOP
733 "j" := 1;
734 LOOP
735 IF "i" != "j" THEN
736 "k" := 1;
737 LOOP
738 IF "i" != "k" AND "j" != "k" THEN
739 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
740 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
741 "matrix"["j"]["k"] := "matrix"["j"]["i"];
742 END IF;
743 ELSE
744 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
745 "matrix"["j"]["k"] := "matrix"["i"]["k"];
746 END IF;
747 END IF;
748 END IF;
749 EXIT WHEN "k" = "dimension_v";
750 "k" := "k" + 1;
751 END LOOP;
752 END IF;
753 EXIT WHEN "j" = "dimension_v";
754 "j" := "j" + 1;
755 END LOOP;
756 EXIT WHEN "i" = "dimension_v";
757 "i" := "i" + 1;
758 END LOOP;
759 -- Determine order of winners:
760 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
761 "rank_v" := 1;
762 "done_v" := 0;
763 LOOP
764 "winners_ary" := '{}';
765 "i" := 1;
766 LOOP
767 IF "rank_ary"["i"] ISNULL THEN
768 "j" := 1;
769 LOOP
770 IF
771 "i" != "j" AND
772 "rank_ary"["j"] ISNULL AND
773 "matrix"["j"]["i"] > "matrix"["i"]["j"]
774 THEN
775 -- someone else is better
776 EXIT;
777 END IF;
778 IF "j" = "dimension_v" THEN
779 -- noone is better
780 "winners_ary" := "winners_ary" || "i";
781 EXIT;
782 END IF;
783 "j" := "j" + 1;
784 END LOOP;
785 END IF;
786 EXIT WHEN "i" = "dimension_v";
787 "i" := "i" + 1;
788 END LOOP;
789 "i" := 1;
790 LOOP
791 "rank_ary"["winners_ary"["i"]] := "rank_v";
792 "done_v" := "done_v" + 1;
793 EXIT WHEN "i" = array_upper("winners_ary", 1);
794 "i" := "i" + 1;
795 END LOOP;
796 EXIT WHEN "done_v" = "dimension_v";
797 "rank_v" := "rank_v" + 1;
798 END LOOP;
799 -- write preliminary results:
800 "i" := 1;
801 FOR "initiative_id_v" IN
802 SELECT "id" FROM "initiative"
803 WHERE "issue_id" = "issue_id_p" AND "admitted"
804 ORDER BY "id"
805 LOOP
806 UPDATE "initiative" SET
807 "direct_majority" =
808 CASE WHEN "policy_row"."direct_majority_strict" THEN
809 "positive_votes" * "policy_row"."direct_majority_den" >
810 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
811 ELSE
812 "positive_votes" * "policy_row"."direct_majority_den" >=
813 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
814 END
815 AND "positive_votes" >= "policy_row"."direct_majority_positive"
816 AND "issue_row"."voter_count"-"negative_votes" >=
817 "policy_row"."direct_majority_non_negative",
818 "indirect_majority" =
819 CASE WHEN "policy_row"."indirect_majority_strict" THEN
820 "positive_votes" * "policy_row"."indirect_majority_den" >
821 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
822 ELSE
823 "positive_votes" * "policy_row"."indirect_majority_den" >=
824 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
825 END
826 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
827 AND "issue_row"."voter_count"-"negative_votes" >=
828 "policy_row"."indirect_majority_non_negative",
829 "schulze_rank" = "rank_ary"["i"],
830 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
831 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
832 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
833 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
834 "winner" = FALSE
835 WHERE "id" = "initiative_id_v";
836 "i" := "i" + 1;
837 END LOOP;
838 IF "i" != "dimension_v" THEN
839 RAISE EXCEPTION 'Wrong winner count (should not happen)';
840 END IF;
841 -- take indirect majorities into account:
842 LOOP
843 UPDATE "initiative" SET "indirect_majority" = TRUE
844 FROM (
845 SELECT "new_initiative"."id" AS "initiative_id"
846 FROM "initiative" "old_initiative"
847 JOIN "initiative" "new_initiative"
848 ON "new_initiative"."issue_id" = "issue_id_p"
849 AND "new_initiative"."indirect_majority" = FALSE
850 JOIN "battle" "battle_win"
851 ON "battle_win"."issue_id" = "issue_id_p"
852 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
853 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
854 JOIN "battle" "battle_lose"
855 ON "battle_lose"."issue_id" = "issue_id_p"
856 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
857 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
858 WHERE "old_initiative"."issue_id" = "issue_id_p"
859 AND "old_initiative"."indirect_majority" = TRUE
860 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
861 "battle_win"."count" * "policy_row"."indirect_majority_den" >
862 "policy_row"."indirect_majority_num" *
863 ("battle_win"."count"+"battle_lose"."count")
864 ELSE
865 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
866 "policy_row"."indirect_majority_num" *
867 ("battle_win"."count"+"battle_lose"."count")
868 END
869 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
870 AND "issue_row"."voter_count"-"battle_lose"."count" >=
871 "policy_row"."indirect_majority_non_negative"
872 ) AS "subquery"
873 WHERE "id" = "subquery"."initiative_id";
874 EXIT WHEN NOT FOUND;
875 END LOOP;
876 -- set "multistage_majority" for remaining matching initiatives:
877 UPDATE "initiative" SET "multistage_majority" = TRUE
878 FROM (
879 SELECT "losing_initiative"."id" AS "initiative_id"
880 FROM "initiative" "losing_initiative"
881 JOIN "initiative" "winning_initiative"
882 ON "winning_initiative"."issue_id" = "issue_id_p"
883 AND "winning_initiative"."admitted"
884 JOIN "battle" "battle_win"
885 ON "battle_win"."issue_id" = "issue_id_p"
886 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
887 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
888 JOIN "battle" "battle_lose"
889 ON "battle_lose"."issue_id" = "issue_id_p"
890 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
891 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
892 WHERE "losing_initiative"."issue_id" = "issue_id_p"
893 AND "losing_initiative"."admitted"
894 AND "winning_initiative"."schulze_rank" <
895 "losing_initiative"."schulze_rank"
896 AND "battle_win"."count" > "battle_lose"."count"
897 AND (
898 "battle_win"."count" > "winning_initiative"."positive_votes" OR
899 "battle_lose"."count" < "losing_initiative"."negative_votes" )
900 ) AS "subquery"
901 WHERE "id" = "subquery"."initiative_id";
902 -- mark eligible initiatives:
903 UPDATE "initiative" SET "eligible" = TRUE
904 WHERE "issue_id" = "issue_id_p"
905 AND "initiative"."direct_majority"
906 AND "initiative"."indirect_majority"
907 AND "initiative"."better_than_status_quo"
908 AND (
909 "policy_row"."no_multistage_majority" = FALSE OR
910 "initiative"."multistage_majority" = FALSE )
911 AND (
912 "policy_row"."no_reverse_beat_path" = FALSE OR
913 "initiative"."reverse_beat_path" = FALSE );
914 -- mark final winner:
915 UPDATE "initiative" SET "winner" = TRUE
916 FROM (
917 SELECT "id" AS "initiative_id"
918 FROM "initiative"
919 WHERE "issue_id" = "issue_id_p" AND "eligible"
920 ORDER BY "schulze_rank", "id"
921 LIMIT 1
922 ) AS "subquery"
923 WHERE "id" = "subquery"."initiative_id";
924 -- write (final) ranks:
925 "rank_v" := 1;
926 FOR "initiative_id_v" IN
927 SELECT "id"
928 FROM "initiative"
929 WHERE "issue_id" = "issue_id_p" AND "admitted"
930 ORDER BY
931 "winner" DESC,
932 ("direct_majority" AND "indirect_majority") DESC,
933 "schulze_rank",
934 "id"
935 LOOP
936 UPDATE "initiative" SET "rank" = "rank_v"
937 WHERE "id" = "initiative_id_v";
938 "rank_v" := "rank_v" + 1;
939 END LOOP;
940 -- set schulze rank of status quo and mark issue as finished:
941 UPDATE "issue" SET
942 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
943 "state" =
944 CASE WHEN EXISTS (
945 SELECT NULL FROM "initiative"
946 WHERE "issue_id" = "issue_id_p" AND "winner"
947 ) THEN
948 'finished_with_winner'::"issue_state"
949 ELSE
950 'finished_without_winner'::"issue_state"
951 END,
952 "ranks_available" = TRUE
953 WHERE "id" = "issue_id_p";
954 RETURN;
955 END;
956 $$;
958 CREATE OR REPLACE FUNCTION "check_issue"
959 ( "issue_id_p" "issue"."id"%TYPE )
960 RETURNS VOID
961 LANGUAGE 'plpgsql' VOLATILE AS $$
962 DECLARE
963 "issue_row" "issue"%ROWTYPE;
964 "policy_row" "policy"%ROWTYPE;
965 BEGIN
966 PERFORM "lock_issue"("issue_id_p");
967 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
968 -- only process open issues:
969 IF "issue_row"."closed" ISNULL THEN
970 SELECT * INTO "policy_row" FROM "policy"
971 WHERE "id" = "issue_row"."policy_id";
972 -- create a snapshot, unless issue is already fully frozen:
973 IF "issue_row"."fully_frozen" ISNULL THEN
974 PERFORM "create_snapshot"("issue_id_p");
975 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
976 END IF;
977 -- eventually close or accept issues, which have not been accepted:
978 IF "issue_row"."accepted" ISNULL THEN
979 IF EXISTS (
980 SELECT NULL FROM "initiative"
981 WHERE "issue_id" = "issue_id_p"
982 AND "supporter_count" > 0
983 AND "supporter_count" * "policy_row"."issue_quorum_den"
984 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
985 ) THEN
986 -- accept issues, if supporter count is high enough
987 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
988 -- NOTE: "issue_row" used later
989 "issue_row"."state" := 'discussion';
990 "issue_row"."accepted" := now();
991 UPDATE "issue" SET
992 "state" = "issue_row"."state",
993 "accepted" = "issue_row"."accepted"
994 WHERE "id" = "issue_row"."id";
995 ELSIF
996 now() >= "issue_row"."created" + "issue_row"."admission_time"
997 THEN
998 -- close issues, if admission time has expired
999 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
1000 UPDATE "issue" SET
1001 "state" = 'canceled_issue_not_accepted',
1002 "closed" = now()
1003 WHERE "id" = "issue_row"."id";
1004 END IF;
1005 END IF;
1006 -- eventually half freeze issues:
1007 IF
1008 -- NOTE: issue can't be closed at this point, if it has been accepted
1009 "issue_row"."accepted" NOTNULL AND
1010 "issue_row"."half_frozen" ISNULL
1011 THEN
1012 IF
1013 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
1014 THEN
1015 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
1016 -- NOTE: "issue_row" used later
1017 "issue_row"."state" := 'verification';
1018 "issue_row"."half_frozen" := now();
1019 UPDATE "issue" SET
1020 "state" = "issue_row"."state",
1021 "half_frozen" = "issue_row"."half_frozen"
1022 WHERE "id" = "issue_row"."id";
1023 END IF;
1024 END IF;
1025 -- close issues after some time, if all initiatives have been revoked:
1026 IF
1027 "issue_row"."closed" ISNULL AND
1028 NOT EXISTS (
1029 -- all initiatives are revoked
1030 SELECT NULL FROM "initiative"
1031 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
1032 ) AND (
1033 -- and issue has not been accepted yet
1034 "issue_row"."accepted" ISNULL OR
1035 NOT EXISTS (
1036 -- or no initiatives have been revoked lately
1037 SELECT NULL FROM "initiative"
1038 WHERE "issue_id" = "issue_id_p"
1039 AND now() < "revoked" + "issue_row"."verification_time"
1040 ) OR (
1041 -- or verification time has elapsed
1042 "issue_row"."half_frozen" NOTNULL AND
1043 "issue_row"."fully_frozen" ISNULL AND
1044 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
1047 THEN
1048 -- NOTE: "issue_row" used later
1049 IF "issue_row"."accepted" ISNULL THEN
1050 "issue_row"."state" := 'canceled_revoked_before_accepted';
1051 ELSIF "issue_row"."half_frozen" ISNULL THEN
1052 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
1053 ELSE
1054 "issue_row"."state" := 'canceled_after_revocation_during_verification';
1055 END IF;
1056 "issue_row"."closed" := now();
1057 UPDATE "issue" SET
1058 "state" = "issue_row"."state",
1059 "closed" = "issue_row"."closed"
1060 WHERE "id" = "issue_row"."id";
1061 END IF;
1062 -- fully freeze issue after verification time:
1063 IF
1064 "issue_row"."half_frozen" NOTNULL AND
1065 "issue_row"."fully_frozen" ISNULL AND
1066 "issue_row"."closed" ISNULL AND
1067 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
1068 THEN
1069 PERFORM "freeze_after_snapshot"("issue_id_p");
1070 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
1071 END IF;
1072 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
1073 -- close issue by calling close_voting(...) after voting time:
1074 IF
1075 "issue_row"."closed" ISNULL AND
1076 "issue_row"."fully_frozen" NOTNULL AND
1077 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
1078 THEN
1079 PERFORM "close_voting"("issue_id_p");
1080 -- calculate ranks will not consume much time and can be done now
1081 PERFORM "calculate_ranks"("issue_id_p");
1082 END IF;
1083 END IF;
1084 RETURN;
1085 END;
1086 $$;
1088 CREATE OR REPLACE FUNCTION "check_everything"()
1089 RETURNS VOID
1090 LANGUAGE 'plpgsql' VOLATILE AS $$
1091 DECLARE
1092 "issue_id_v" "issue"."id"%TYPE;
1093 BEGIN
1094 PERFORM "check_activity"();
1095 PERFORM "calculate_member_counts"();
1096 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
1097 PERFORM "check_issue"("issue_id_v");
1098 END LOOP;
1099 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
1100 PERFORM "calculate_ranks"("issue_id_v");
1101 END LOOP;
1102 RETURN;
1103 END;
1104 $$;
1106 CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
1107 RETURNS VOID
1108 LANGUAGE 'plpgsql' VOLATILE AS $$
1109 BEGIN
1110 UPDATE "member" SET
1111 "last_login" = NULL,
1112 "login" = NULL,
1113 "password" = NULL,
1114 "locked" = TRUE,
1115 "active" = FALSE,
1116 "notify_email" = NULL,
1117 "notify_email_unconfirmed" = NULL,
1118 "notify_email_secret" = NULL,
1119 "notify_email_secret_expiry" = NULL,
1120 "notify_email_lock_expiry" = NULL,
1121 "password_reset_secret" = NULL,
1122 "password_reset_secret_expiry" = NULL,
1123 "organizational_unit" = NULL,
1124 "internal_posts" = NULL,
1125 "realname" = NULL,
1126 "birthday" = NULL,
1127 "address" = NULL,
1128 "email" = NULL,
1129 "xmpp_address" = NULL,
1130 "website" = NULL,
1131 "phone" = NULL,
1132 "mobile_phone" = NULL,
1133 "profession" = NULL,
1134 "external_memberships" = NULL,
1135 "external_posts" = NULL,
1136 "statement" = NULL
1137 WHERE "id" = "member_id_p";
1138 -- "text_search_data" is updated by triggers
1139 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
1140 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
1141 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
1142 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
1143 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
1144 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
1145 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
1146 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
1147 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
1148 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
1149 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
1150 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
1151 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
1152 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
1153 DELETE FROM "direct_voter" USING "issue"
1154 WHERE "direct_voter"."issue_id" = "issue"."id"
1155 AND "issue"."closed" ISNULL
1156 AND "member_id" = "member_id_p";
1157 RETURN;
1158 END;
1159 $$;
1161 CREATE OR REPLACE FUNCTION "delete_private_data"()
1162 RETURNS VOID
1163 LANGUAGE 'plpgsql' VOLATILE AS $$
1164 BEGIN
1165 UPDATE "member" SET
1166 "last_login" = NULL,
1167 "login" = NULL,
1168 "password" = NULL,
1169 "notify_email" = NULL,
1170 "notify_email_unconfirmed" = NULL,
1171 "notify_email_secret" = NULL,
1172 "notify_email_secret_expiry" = NULL,
1173 "notify_email_lock_expiry" = NULL,
1174 "password_reset_secret" = NULL,
1175 "password_reset_secret_expiry" = NULL,
1176 "organizational_unit" = NULL,
1177 "internal_posts" = NULL,
1178 "realname" = NULL,
1179 "birthday" = NULL,
1180 "address" = NULL,
1181 "email" = NULL,
1182 "xmpp_address" = NULL,
1183 "website" = NULL,
1184 "phone" = NULL,
1185 "mobile_phone" = NULL,
1186 "profession" = NULL,
1187 "external_memberships" = NULL,
1188 "external_posts" = NULL,
1189 "statement" = NULL;
1190 -- "text_search_data" is updated by triggers
1191 DELETE FROM "invite_code";
1192 DELETE FROM "setting";
1193 DELETE FROM "setting_map";
1194 DELETE FROM "member_relation_setting";
1195 DELETE FROM "member_image";
1196 DELETE FROM "contact";
1197 DELETE FROM "ignored_member";
1198 DELETE FROM "area_setting";
1199 DELETE FROM "issue_setting";
1200 DELETE FROM "ignored_initiative";
1201 DELETE FROM "initiative_setting";
1202 DELETE FROM "suggestion_setting";
1203 DELETE FROM "non_voter";
1204 DELETE FROM "direct_voter" USING "issue"
1205 WHERE "direct_voter"."issue_id" = "issue"."id"
1206 AND "issue"."closed" ISNULL;
1207 RETURN;
1208 END;
1209 $$;
1211 COMMIT;
1213 BEGIN;
1215 UPDATE "member" SET
1216 "activated" = "created",
1217 "last_activity" = CASE WHEN "active" THEN
1218 coalesce("last_login"::DATE, now())
1219 ELSE
1220 "last_login"::DATE
1221 END;
1223 UPDATE "member" SET
1224 "created" = "invite_code"."created",
1225 "invite_code" = "invite_code"."code",
1226 "admin_comment" = "invite_code"."comment"
1227 FROM "invite_code"
1228 WHERE "member"."id" = "invite_code"."member_id";
1230 DROP TABLE "invite_code";
1232 UPDATE "initiative" SET
1233 "direct_majority" = "rank" NOTNULL,
1234 "indirect_majority" = "rank" NOTNULL,
1235 "schulze_rank" = "rank",
1236 "better_than_status_quo" = "rank" NOTNULL,
1237 "worse_than_status_quo" = "rank" ISNULL,
1238 "reverse_beat_path" = "rank" ISNULL,
1239 "multistage_majority" = "rank" ISNULL,
1240 "eligible" = "rank" NOTNULL,
1241 "winner" = ("rank" = 1)
1242 FROM "issue"
1243 WHERE "issue"."id" = "initiative"."issue_id"
1244 AND "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
1245 AND "initiative"."admitted";
1247 UPDATE "issue" SET "status_quo_schulze_rank" = "subquery"."rank"
1248 FROM (
1249 SELECT
1250 "issue"."id" AS "issue_id",
1251 COALESCE(max("initiative"."rank") + 1, 1) AS "rank"
1252 FROM "issue" JOIN "initiative"
1253 ON "issue"."id" = "initiative"."issue_id"
1254 WHERE "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
1255 AND "initiative"."admitted"
1256 GROUP BY "issue"."id"
1257 ) AS "subquery"
1258 WHERE "issue"."id" = "subquery"."issue_id";
1260 CREATE FUNCTION "update__set_remaining_ranks"("issue_id_p" "issue"."id"%TYPE)
1261 RETURNS VOID
1262 LANGUAGE 'plpgsql' AS $$
1263 DECLARE
1264 "rank_v" INT4;
1265 "initiative_id_v" INT4;
1266 BEGIN
1267 SELECT "status_quo_schulze_rank" INTO "rank_v"
1268 FROM "issue" WHERE "id" = "issue_id_p";
1269 FOR "initiative_id_v" IN
1270 SELECT "id" FROM "initiative"
1271 WHERE "issue_id" = "issue_id_p" AND "admitted" AND "rank" ISNULL
1272 ORDER BY "vote_ratio"("positive_votes", "negative_votes") DESC
1273 LOOP
1274 UPDATE "initiative" SET
1275 "schulze_rank" = "rank_v" + 1,
1276 "rank" = "rank_v"
1277 WHERE "id" = "initiative_id_v";
1278 "rank_v" := "rank_v" + 1;
1279 END LOOP;
1280 RETURN;
1281 END;
1282 $$;
1284 SELECT "update__set_remaining_ranks"("id") FROM "issue"
1285 WHERE "state" IN ('finished_without_winner', 'finished_with_winner');
1287 DROP FUNCTION "update__set_remaining_ranks"("issue"."id"%TYPE);
1289 UPDATE "suggestion" SET "draft_id" = "subquery"."draft_id"
1290 FROM (
1291 SELECT DISTINCT ON ("suggestion"."id")
1292 "suggestion"."id" AS "suggestion_id",
1293 "draft"."id" AS "draft_id"
1294 FROM "suggestion" JOIN "draft"
1295 ON "suggestion"."initiative_id" = "draft"."initiative_id"
1296 WHERE "draft"."created" <= "suggestion"."created"
1297 ORDER BY "suggestion"."id", "draft"."created" DESC
1298 ) AS "subquery"
1299 WHERE "suggestion"."id" = "subquery"."suggestion_id";
1301 COMMIT;
1303 ALTER TABLE "member" ADD CONSTRAINT "active_requires_activated_and_last_activity"
1304 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL));
1305 ALTER TABLE "suggestion" ALTER COLUMN "draft_id" SET NOT NULL;

Impressum / About Us