rev |
line source |
jbe@177
|
1 BEGIN;
|
jbe@177
|
2
|
jbe@177
|
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
|
jbe@177
|
4 SELECT * FROM (VALUES ('1.5.0_devel', 1, 5, -1))
|
jbe@177
|
5 AS "subquery"("string", "major", "minor", "revision");
|
jbe@177
|
6
|
jbe@177
|
7 ALTER TABLE "member" ADD COLUMN "formatting_engine" TEXT;
|
jbe@177
|
8 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
|
jbe@177
|
9
|
jbe@177
|
10 CREATE TABLE "rendered_member_statement" (
|
jbe@177
|
11 PRIMARY KEY ("member_id", "format"),
|
jbe@177
|
12 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@177
|
13 "format" TEXT,
|
jbe@177
|
14 "content" TEXT NOT NULL );
|
jbe@177
|
15
|
jbe@177
|
16 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)';
|
jbe@177
|
17
|
jbe@177
|
18 ALTER TABLE "policy" ADD COLUMN "direct_majority_num" INT4 NOT NULL DEFAULT 1;
|
jbe@177
|
19 ALTER TABLE "policy" ADD COLUMN "direct_majority_den" INT4 NOT NULL DEFAULT 2;
|
jbe@177
|
20 ALTER TABLE "policy" ADD COLUMN "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE;
|
jbe@177
|
21 ALTER TABLE "policy" ADD COLUMN "direct_majority_positive" INT4 NOT NULL DEFAULT 0;
|
jbe@177
|
22 ALTER TABLE "policy" ADD COLUMN "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0;
|
jbe@177
|
23 ALTER TABLE "policy" ADD COLUMN "indirect_majority_num" INT4 NOT NULL DEFAULT 1;
|
jbe@177
|
24 ALTER TABLE "policy" ADD COLUMN "indirect_majority_den" INT4 NOT NULL DEFAULT 2;
|
jbe@177
|
25 ALTER TABLE "policy" ADD COLUMN "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE;
|
jbe@177
|
26 ALTER TABLE "policy" ADD COLUMN "indirect_majority_positive" INT4 NOT NULL DEFAULT 0;
|
jbe@177
|
27 ALTER TABLE "policy" ADD COLUMN "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0;
|
jbe@177
|
28 ALTER TABLE "policy" ADD COLUMN "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE;
|
jbe@177
|
29 ALTER TABLE "policy" ADD COLUMN "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE;
|
jbe@177
|
30
|
jbe@177
|
31 UPDATE "policy" SET
|
jbe@177
|
32 "direct_majority_num" = "majority_num",
|
jbe@177
|
33 "direct_majority_den" = "majority_den",
|
jbe@177
|
34 "direct_majority_strict" = "majority_strict",
|
jbe@177
|
35 "indirect_majority_num" = "majority_num",
|
jbe@177
|
36 "indirect_majority_den" = "majority_den",
|
jbe@177
|
37 "indirect_majority_strict" = "majority_strict";
|
jbe@177
|
38
|
jbe@177
|
39 ALTER TABLE "policy" DROP COLUMN "majority_num";
|
jbe@177
|
40 ALTER TABLE "policy" DROP COLUMN "majority_den";
|
jbe@177
|
41 ALTER TABLE "policy" DROP COLUMN "majority_strict";
|
jbe@177
|
42
|
jbe@177
|
43 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
|
jbe@177
|
44 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
|
jbe@177
|
45 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.';
|
jbe@177
|
46 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
|
jbe@177
|
47 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';
|
jbe@177
|
48 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';
|
jbe@177
|
49 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';
|
jbe@177
|
50 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.';
|
jbe@177
|
51 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';
|
jbe@177
|
52 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';
|
jbe@177
|
53 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.';
|
jbe@177
|
54 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").';
|
jbe@177
|
55
|
jbe@177
|
56 ALTER TABLE "area" DROP COLUMN "autoreject_weight";
|
jbe@177
|
57
|
jbe@177
|
58 DROP VIEW "open_issue";
|
jbe@177
|
59 DROP VIEW "issue_with_ranks_missing";
|
jbe@177
|
60
|
jbe@177
|
61 ALTER TABLE "issue" DROP COLUMN "vote_now";
|
jbe@177
|
62 ALTER TABLE "issue" DROP COLUMN "vote_later";
|
jbe@177
|
63 ALTER TABLE "issue" ADD COLUMN "status_quo_schulze_rank" INT4;
|
jbe@177
|
64
|
jbe@177
|
65 CREATE VIEW "open_issue" AS
|
jbe@177
|
66 SELECT * FROM "issue" WHERE "closed" ISNULL;
|
jbe@177
|
67
|
jbe@177
|
68 COMMENT ON VIEW "open_issue" IS 'All open issues';
|
jbe@177
|
69
|
jbe@177
|
70 CREATE VIEW "issue_with_ranks_missing" AS
|
jbe@177
|
71 SELECT * FROM "issue"
|
jbe@177
|
72 WHERE "fully_frozen" NOTNULL
|
jbe@177
|
73 AND "closed" NOTNULL
|
jbe@177
|
74 AND "ranks_available" = FALSE;
|
jbe@177
|
75
|
jbe@177
|
76 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
|
jbe@177
|
77
|
jbe@177
|
78 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.';
|
jbe@177
|
79 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
|
jbe@177
|
80 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
|
jbe@177
|
81
|
jbe@177
|
82 ALTER TABLE "initiative" ADD COLUMN "direct_majority" BOOLEAN;
|
jbe@177
|
83 ALTER TABLE "initiative" ADD COLUMN "indirect_majority" BOOLEAN;
|
jbe@177
|
84 ALTER TABLE "initiative" ADD COLUMN "schulze_rank" INT4;
|
jbe@177
|
85 ALTER TABLE "initiative" ADD COLUMN "better_than_status_quo" BOOLEAN;
|
jbe@177
|
86 ALTER TABLE "initiative" ADD COLUMN "worse_than_status_quo" BOOLEAN;
|
jbe@177
|
87 ALTER TABLE "initiative" ADD COLUMN "reverse_beat_path" BOOLEAN;
|
jbe@177
|
88 ALTER TABLE "initiative" ADD COLUMN "multistage_majority" BOOLEAN;
|
jbe@177
|
89 ALTER TABLE "initiative" ADD COLUMN "eligible" BOOLEAN;
|
jbe@177
|
90 ALTER TABLE "initiative" ADD COLUMN "winner" BOOLEAN;
|
jbe@177
|
91
|
jbe@177
|
92 ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
|
jbe@177
|
93 ALTER TABLE "initiative" DROP CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null";
|
jbe@177
|
94 ALTER TABLE "initiative" DROP CONSTRAINT "non_agreed_initiatives_cant_get_a_rank";
|
jbe@177
|
95
|
jbe@177
|
96 ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
|
jbe@177
|
97 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
|
jbe@177
|
98 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
|
jbe@177
|
99 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
|
jbe@177
|
100 "schulze_rank" ISNULL AND
|
jbe@177
|
101 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
|
jbe@177
|
102 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
|
jbe@177
|
103 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
|
jbe@177
|
104 ALTER TABLE "initiative" ADD CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo"));
|
jbe@177
|
105 ALTER TABLE "initiative" ADD CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
|
jbe@177
|
106 "eligible" = FALSE OR
|
jbe@177
|
107 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") );
|
jbe@177
|
108 ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE);
|
jbe@177
|
109 ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1);
|
jbe@177
|
110 ALTER TABLE "initiative" ADD CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE);
|
jbe@177
|
111 ALTER TABLE "initiative" ADD CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank");
|
jbe@177
|
112
|
jbe@177
|
113 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"';
|
jbe@177
|
114 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
|
jbe@177
|
115 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
|
jbe@177
|
116 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
|
jbe@177
|
117 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
|
jbe@177
|
118 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';
|
jbe@177
|
119 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';
|
jbe@177
|
120 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
|
jbe@177
|
121 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
|
jbe@177
|
122 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';
|
jbe@177
|
123
|
jbe@177
|
124 ALTER TABLE "battle" DROP CONSTRAINT "battle_pkey";
|
jbe@177
|
125 ALTER TABLE "battle" ALTER COLUMN "issue_id" SET NOT NULL;
|
jbe@177
|
126 ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK (
|
jbe@177
|
127 "winning_initiative_id" != "losing_initiative_id" OR
|
jbe@177
|
128 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
|
jbe@177
|
129 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) );
|
jbe@177
|
130
|
jbe@177
|
131 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
|
jbe@177
|
132 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
|
jbe@177
|
133 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
|
jbe@177
|
134
|
jbe@177
|
135 ALTER TABLE "suggestion" ADD COLUMN "draft_id" INT8;
|
jbe@177
|
136 -- more later
|
jbe@177
|
137
|
jbe@177
|
138 ALTER TABLE "suggestion" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
|
jbe@177
|
139 ALTER TABLE "suggestion" ADD COLUMN "formatting_engine" TEXT;
|
jbe@177
|
140 ALTER TABLE "suggestion" RENAME COLUMN "description" TO "content";
|
jbe@177
|
141
|
jbe@177
|
142 DROP TRIGGER "update_text_search_data" ON "suggestion";
|
jbe@177
|
143
|
jbe@177
|
144 CREATE TRIGGER "update_text_search_data"
|
jbe@177
|
145 BEFORE INSERT OR UPDATE ON "suggestion"
|
jbe@177
|
146 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@177
|
147 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@177
|
148 "name", "content");
|
jbe@177
|
149
|
jbe@177
|
150 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")';
|
jbe@177
|
151
|
jbe@177
|
152 CREATE TABLE "rendered_suggestion" (
|
jbe@177
|
153 PRIMARY KEY ("suggestion_id", "format"),
|
jbe@177
|
154 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@177
|
155 "format" TEXT,
|
jbe@177
|
156 "content" TEXT NOT NULL );
|
jbe@177
|
157
|
jbe@177
|
158 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)';
|
jbe@177
|
159
|
jbe@177
|
160 DROP VIEW "area_member_count";
|
jbe@177
|
161
|
jbe@177
|
162 ALTER TABLE "membership" DROP COLUMN "autoreject";
|
jbe@177
|
163
|
jbe@177
|
164 ALTER TABLE "interest" DROP COLUMN "autoreject";
|
jbe@177
|
165 ALTER TABLE "interest" DROP COLUMN "voting_requested";
|
jbe@177
|
166
|
jbe@177
|
167 ALTER TABLE "supporter" DROP CONSTRAINT "supporter_initiative_id_fkey";
|
jbe@177
|
168 ALTER TABLE "supporter" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
|
jbe@177
|
169
|
jbe@177
|
170 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")';
|
jbe@177
|
171
|
jbe@177
|
172 ALTER TABLE "direct_interest_snapshot" DROP COLUMN "voting_requested";
|
jbe@177
|
173 ALTER TABLE "direct_voter" DROP COLUMN "autoreject";
|
jbe@177
|
174
|
jbe@177
|
175 DROP TRIGGER "default_for_draft_id" ON "supporter";
|
jbe@177
|
176 DROP FUNCTION "supporter_default_for_draft_id_trigger"();
|
jbe@177
|
177
|
jbe@177
|
178 CREATE FUNCTION "default_for_draft_id_trigger"()
|
jbe@177
|
179 RETURNS TRIGGER
|
jbe@177
|
180 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@177
|
181 BEGIN
|
jbe@177
|
182 IF NEW."draft_id" ISNULL THEN
|
jbe@177
|
183 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
|
jbe@177
|
184 WHERE "initiative_id" = NEW."initiative_id";
|
jbe@177
|
185 END IF;
|
jbe@177
|
186 RETURN NEW;
|
jbe@177
|
187 END;
|
jbe@177
|
188 $$;
|
jbe@177
|
189
|
jbe@177
|
190 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
|
jbe@177
|
191 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
|
jbe@177
|
192 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
|
jbe@177
|
193 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
|
jbe@177
|
194
|
jbe@177
|
195 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
|
jbe@177
|
196 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';
|
jbe@177
|
197 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';
|
jbe@177
|
198
|
jbe@177
|
199 CREATE VIEW "area_member_count" AS
|
jbe@177
|
200 SELECT
|
jbe@177
|
201 "area"."id" AS "area_id",
|
jbe@177
|
202 count("member"."id") AS "direct_member_count",
|
jbe@177
|
203 coalesce(
|
jbe@177
|
204 sum(
|
jbe@177
|
205 CASE WHEN "member"."id" NOTNULL THEN
|
jbe@177
|
206 "membership_weight"("area"."id", "member"."id")
|
jbe@177
|
207 ELSE 0 END
|
jbe@177
|
208 )
|
jbe@177
|
209 ) AS "member_weight"
|
jbe@177
|
210 FROM "area"
|
jbe@177
|
211 LEFT JOIN "membership"
|
jbe@177
|
212 ON "area"."id" = "membership"."area_id"
|
jbe@177
|
213 LEFT JOIN "privilege"
|
jbe@177
|
214 ON "privilege"."unit_id" = "area"."unit_id"
|
jbe@177
|
215 AND "privilege"."member_id" = "membership"."member_id"
|
jbe@177
|
216 AND "privilege"."voting_right"
|
jbe@177
|
217 LEFT JOIN "member"
|
jbe@177
|
218 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
|
jbe@177
|
219 AND "member"."active"
|
jbe@177
|
220 GROUP BY "area"."id";
|
jbe@177
|
221
|
jbe@177
|
222 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
|
jbe@177
|
223
|
jbe@177
|
224 CREATE VIEW "battle_participant" AS
|
jbe@177
|
225 SELECT "initiative"."id", "initiative"."issue_id"
|
jbe@177
|
226 FROM "issue" JOIN "initiative"
|
jbe@177
|
227 ON "issue"."id" = "initiative"."issue_id"
|
jbe@177
|
228 WHERE "initiative"."admitted"
|
jbe@177
|
229 UNION ALL
|
jbe@177
|
230 SELECT NULL, "id" AS "issue_id"
|
jbe@177
|
231 FROM "issue";
|
jbe@177
|
232
|
jbe@177
|
233 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
|
jbe@177
|
234
|
jbe@177
|
235 CREATE OR REPLACE VIEW "battle_view" AS
|
jbe@177
|
236 SELECT
|
jbe@177
|
237 "issue"."id" AS "issue_id",
|
jbe@177
|
238 "winning_initiative"."id" AS "winning_initiative_id",
|
jbe@177
|
239 "losing_initiative"."id" AS "losing_initiative_id",
|
jbe@177
|
240 sum(
|
jbe@177
|
241 CASE WHEN
|
jbe@177
|
242 coalesce("better_vote"."grade", 0) >
|
jbe@177
|
243 coalesce("worse_vote"."grade", 0)
|
jbe@177
|
244 THEN "direct_voter"."weight" ELSE 0 END
|
jbe@177
|
245 ) AS "count"
|
jbe@177
|
246 FROM "issue"
|
jbe@177
|
247 LEFT JOIN "direct_voter"
|
jbe@177
|
248 ON "issue"."id" = "direct_voter"."issue_id"
|
jbe@177
|
249 JOIN "battle_participant" AS "winning_initiative"
|
jbe@177
|
250 ON "issue"."id" = "winning_initiative"."issue_id"
|
jbe@177
|
251 JOIN "battle_participant" AS "losing_initiative"
|
jbe@177
|
252 ON "issue"."id" = "losing_initiative"."issue_id"
|
jbe@177
|
253 LEFT JOIN "vote" AS "better_vote"
|
jbe@177
|
254 ON "direct_voter"."member_id" = "better_vote"."member_id"
|
jbe@177
|
255 AND "winning_initiative"."id" = "better_vote"."initiative_id"
|
jbe@177
|
256 LEFT JOIN "vote" AS "worse_vote"
|
jbe@177
|
257 ON "direct_voter"."member_id" = "worse_vote"."member_id"
|
jbe@177
|
258 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
|
jbe@177
|
259 WHERE "issue"."closed" NOTNULL
|
jbe@177
|
260 AND "issue"."cleaned" ISNULL
|
jbe@177
|
261 AND (
|
jbe@177
|
262 "winning_initiative"."id" != "losing_initiative"."id" OR
|
jbe@177
|
263 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
|
jbe@177
|
264 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
|
jbe@177
|
265 GROUP BY
|
jbe@177
|
266 "issue"."id",
|
jbe@177
|
267 "winning_initiative"."id",
|
jbe@177
|
268 "losing_initiative"."id";
|
jbe@177
|
269
|
jbe@177
|
270 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';
|
jbe@177
|
271
|
jbe@177
|
272 CREATE OR REPLACE FUNCTION "create_interest_snapshot"
|
jbe@177
|
273 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@177
|
274 RETURNS VOID
|
jbe@177
|
275 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@177
|
276 DECLARE
|
jbe@177
|
277 "member_id_v" "member"."id"%TYPE;
|
jbe@177
|
278 BEGIN
|
jbe@177
|
279 DELETE FROM "direct_interest_snapshot"
|
jbe@177
|
280 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
281 AND "event" = 'periodic';
|
jbe@177
|
282 DELETE FROM "delegating_interest_snapshot"
|
jbe@177
|
283 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
284 AND "event" = 'periodic';
|
jbe@177
|
285 DELETE FROM "direct_supporter_snapshot"
|
jbe@177
|
286 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
287 AND "event" = 'periodic';
|
jbe@177
|
288 INSERT INTO "direct_interest_snapshot"
|
jbe@177
|
289 ("issue_id", "event", "member_id")
|
jbe@177
|
290 SELECT
|
jbe@177
|
291 "issue_id_p" AS "issue_id",
|
jbe@177
|
292 'periodic' AS "event",
|
jbe@177
|
293 "member"."id" AS "member_id"
|
jbe@177
|
294 FROM "issue"
|
jbe@177
|
295 JOIN "area" ON "issue"."area_id" = "area"."id"
|
jbe@177
|
296 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
|
jbe@177
|
297 JOIN "member" ON "interest"."member_id" = "member"."id"
|
jbe@177
|
298 JOIN "privilege"
|
jbe@177
|
299 ON "privilege"."unit_id" = "area"."unit_id"
|
jbe@177
|
300 AND "privilege"."member_id" = "member"."id"
|
jbe@177
|
301 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
302 AND "member"."active" AND "privilege"."voting_right";
|
jbe@177
|
303 FOR "member_id_v" IN
|
jbe@177
|
304 SELECT "member_id" FROM "direct_interest_snapshot"
|
jbe@177
|
305 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
306 AND "event" = 'periodic'
|
jbe@177
|
307 LOOP
|
jbe@177
|
308 UPDATE "direct_interest_snapshot" SET
|
jbe@177
|
309 "weight" = 1 +
|
jbe@177
|
310 "weight_of_added_delegations_for_interest_snapshot"(
|
jbe@177
|
311 "issue_id_p",
|
jbe@177
|
312 "member_id_v",
|
jbe@177
|
313 '{}'
|
jbe@177
|
314 )
|
jbe@177
|
315 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
316 AND "event" = 'periodic'
|
jbe@177
|
317 AND "member_id" = "member_id_v";
|
jbe@177
|
318 END LOOP;
|
jbe@177
|
319 INSERT INTO "direct_supporter_snapshot"
|
jbe@177
|
320 ( "issue_id", "initiative_id", "event", "member_id",
|
jbe@177
|
321 "informed", "satisfied" )
|
jbe@177
|
322 SELECT
|
jbe@177
|
323 "issue_id_p" AS "issue_id",
|
jbe@177
|
324 "initiative"."id" AS "initiative_id",
|
jbe@177
|
325 'periodic' AS "event",
|
jbe@177
|
326 "supporter"."member_id" AS "member_id",
|
jbe@177
|
327 "supporter"."draft_id" = "current_draft"."id" AS "informed",
|
jbe@177
|
328 NOT EXISTS (
|
jbe@177
|
329 SELECT NULL FROM "critical_opinion"
|
jbe@177
|
330 WHERE "initiative_id" = "initiative"."id"
|
jbe@177
|
331 AND "member_id" = "supporter"."member_id"
|
jbe@177
|
332 ) AS "satisfied"
|
jbe@177
|
333 FROM "initiative"
|
jbe@177
|
334 JOIN "supporter"
|
jbe@177
|
335 ON "supporter"."initiative_id" = "initiative"."id"
|
jbe@177
|
336 JOIN "current_draft"
|
jbe@177
|
337 ON "initiative"."id" = "current_draft"."initiative_id"
|
jbe@177
|
338 JOIN "direct_interest_snapshot"
|
jbe@177
|
339 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
|
jbe@177
|
340 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
|
jbe@177
|
341 AND "event" = 'periodic'
|
jbe@177
|
342 WHERE "initiative"."issue_id" = "issue_id_p";
|
jbe@177
|
343 RETURN;
|
jbe@177
|
344 END;
|
jbe@177
|
345 $$;
|
jbe@177
|
346
|
jbe@177
|
347 CREATE OR REPLACE FUNCTION "create_snapshot"
|
jbe@177
|
348 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@177
|
349 RETURNS VOID
|
jbe@177
|
350 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@177
|
351 DECLARE
|
jbe@177
|
352 "initiative_id_v" "initiative"."id"%TYPE;
|
jbe@177
|
353 "suggestion_id_v" "suggestion"."id"%TYPE;
|
jbe@177
|
354 BEGIN
|
jbe@177
|
355 PERFORM "lock_issue"("issue_id_p");
|
jbe@177
|
356 PERFORM "create_population_snapshot"("issue_id_p");
|
jbe@177
|
357 PERFORM "create_interest_snapshot"("issue_id_p");
|
jbe@177
|
358 UPDATE "issue" SET
|
jbe@177
|
359 "snapshot" = now(),
|
jbe@177
|
360 "latest_snapshot_event" = 'periodic',
|
jbe@177
|
361 "population" = (
|
jbe@177
|
362 SELECT coalesce(sum("weight"), 0)
|
jbe@177
|
363 FROM "direct_population_snapshot"
|
jbe@177
|
364 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
365 AND "event" = 'periodic'
|
jbe@177
|
366 )
|
jbe@177
|
367 WHERE "id" = "issue_id_p";
|
jbe@177
|
368 FOR "initiative_id_v" IN
|
jbe@177
|
369 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
370 LOOP
|
jbe@177
|
371 UPDATE "initiative" SET
|
jbe@177
|
372 "supporter_count" = (
|
jbe@177
|
373 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@177
|
374 FROM "direct_interest_snapshot" AS "di"
|
jbe@177
|
375 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@177
|
376 ON "di"."member_id" = "ds"."member_id"
|
jbe@177
|
377 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@177
|
378 AND "di"."event" = 'periodic'
|
jbe@177
|
379 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@177
|
380 AND "ds"."event" = 'periodic'
|
jbe@177
|
381 ),
|
jbe@177
|
382 "informed_supporter_count" = (
|
jbe@177
|
383 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@177
|
384 FROM "direct_interest_snapshot" AS "di"
|
jbe@177
|
385 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@177
|
386 ON "di"."member_id" = "ds"."member_id"
|
jbe@177
|
387 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@177
|
388 AND "di"."event" = 'periodic'
|
jbe@177
|
389 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@177
|
390 AND "ds"."event" = 'periodic'
|
jbe@177
|
391 AND "ds"."informed"
|
jbe@177
|
392 ),
|
jbe@177
|
393 "satisfied_supporter_count" = (
|
jbe@177
|
394 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@177
|
395 FROM "direct_interest_snapshot" AS "di"
|
jbe@177
|
396 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@177
|
397 ON "di"."member_id" = "ds"."member_id"
|
jbe@177
|
398 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@177
|
399 AND "di"."event" = 'periodic'
|
jbe@177
|
400 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@177
|
401 AND "ds"."event" = 'periodic'
|
jbe@177
|
402 AND "ds"."satisfied"
|
jbe@177
|
403 ),
|
jbe@177
|
404 "satisfied_informed_supporter_count" = (
|
jbe@177
|
405 SELECT coalesce(sum("di"."weight"), 0)
|
jbe@177
|
406 FROM "direct_interest_snapshot" AS "di"
|
jbe@177
|
407 JOIN "direct_supporter_snapshot" AS "ds"
|
jbe@177
|
408 ON "di"."member_id" = "ds"."member_id"
|
jbe@177
|
409 WHERE "di"."issue_id" = "issue_id_p"
|
jbe@177
|
410 AND "di"."event" = 'periodic'
|
jbe@177
|
411 AND "ds"."initiative_id" = "initiative_id_v"
|
jbe@177
|
412 AND "ds"."event" = 'periodic'
|
jbe@177
|
413 AND "ds"."informed"
|
jbe@177
|
414 AND "ds"."satisfied"
|
jbe@177
|
415 )
|
jbe@177
|
416 WHERE "id" = "initiative_id_v";
|
jbe@177
|
417 FOR "suggestion_id_v" IN
|
jbe@177
|
418 SELECT "id" FROM "suggestion"
|
jbe@177
|
419 WHERE "initiative_id" = "initiative_id_v"
|
jbe@177
|
420 LOOP
|
jbe@177
|
421 UPDATE "suggestion" SET
|
jbe@177
|
422 "minus2_unfulfilled_count" = (
|
jbe@177
|
423 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
424 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
425 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
426 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
427 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
428 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
429 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
430 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
431 AND "opinion"."degree" = -2
|
jbe@177
|
432 AND "opinion"."fulfilled" = FALSE
|
jbe@177
|
433 ),
|
jbe@177
|
434 "minus2_fulfilled_count" = (
|
jbe@177
|
435 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
436 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
437 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
438 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
439 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
440 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
441 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
442 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
443 AND "opinion"."degree" = -2
|
jbe@177
|
444 AND "opinion"."fulfilled" = TRUE
|
jbe@177
|
445 ),
|
jbe@177
|
446 "minus1_unfulfilled_count" = (
|
jbe@177
|
447 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
448 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
449 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
450 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
451 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
452 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
453 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
454 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
455 AND "opinion"."degree" = -1
|
jbe@177
|
456 AND "opinion"."fulfilled" = FALSE
|
jbe@177
|
457 ),
|
jbe@177
|
458 "minus1_fulfilled_count" = (
|
jbe@177
|
459 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
460 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
461 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
462 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
463 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
464 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
465 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
466 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
467 AND "opinion"."degree" = -1
|
jbe@177
|
468 AND "opinion"."fulfilled" = TRUE
|
jbe@177
|
469 ),
|
jbe@177
|
470 "plus1_unfulfilled_count" = (
|
jbe@177
|
471 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
472 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
473 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
474 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
475 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
476 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
477 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
478 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
479 AND "opinion"."degree" = 1
|
jbe@177
|
480 AND "opinion"."fulfilled" = FALSE
|
jbe@177
|
481 ),
|
jbe@177
|
482 "plus1_fulfilled_count" = (
|
jbe@177
|
483 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
484 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
485 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
486 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
487 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
488 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
489 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
490 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
491 AND "opinion"."degree" = 1
|
jbe@177
|
492 AND "opinion"."fulfilled" = TRUE
|
jbe@177
|
493 ),
|
jbe@177
|
494 "plus2_unfulfilled_count" = (
|
jbe@177
|
495 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
496 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
497 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
498 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
499 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
500 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
501 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
502 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
503 AND "opinion"."degree" = 2
|
jbe@177
|
504 AND "opinion"."fulfilled" = FALSE
|
jbe@177
|
505 ),
|
jbe@177
|
506 "plus2_fulfilled_count" = (
|
jbe@177
|
507 SELECT coalesce(sum("snapshot"."weight"), 0)
|
jbe@177
|
508 FROM "issue" CROSS JOIN "opinion"
|
jbe@177
|
509 JOIN "direct_interest_snapshot" AS "snapshot"
|
jbe@177
|
510 ON "snapshot"."issue_id" = "issue"."id"
|
jbe@177
|
511 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@177
|
512 AND "snapshot"."member_id" = "opinion"."member_id"
|
jbe@177
|
513 WHERE "issue"."id" = "issue_id_p"
|
jbe@177
|
514 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
jbe@177
|
515 AND "opinion"."degree" = 2
|
jbe@177
|
516 AND "opinion"."fulfilled" = TRUE
|
jbe@177
|
517 )
|
jbe@177
|
518 WHERE "suggestion"."id" = "suggestion_id_v";
|
jbe@177
|
519 END LOOP;
|
jbe@177
|
520 END LOOP;
|
jbe@177
|
521 RETURN;
|
jbe@177
|
522 END;
|
jbe@177
|
523 $$;
|
jbe@177
|
524
|
jbe@177
|
525 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
|
jbe@177
|
526 RETURNS VOID
|
jbe@177
|
527 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@177
|
528 DECLARE
|
jbe@177
|
529 "area_id_v" "area"."id"%TYPE;
|
jbe@177
|
530 "unit_id_v" "unit"."id"%TYPE;
|
jbe@177
|
531 "member_id_v" "member"."id"%TYPE;
|
jbe@177
|
532 BEGIN
|
jbe@177
|
533 PERFORM "lock_issue"("issue_id_p");
|
jbe@177
|
534 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@177
|
535 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
|
jbe@177
|
536 -- delete delegating votes (in cases of manual reset of issue state):
|
jbe@177
|
537 DELETE FROM "delegating_voter"
|
jbe@177
|
538 WHERE "issue_id" = "issue_id_p";
|
jbe@177
|
539 -- delete votes from non-privileged voters:
|
jbe@177
|
540 DELETE FROM "direct_voter"
|
jbe@177
|
541 USING (
|
jbe@177
|
542 SELECT
|
jbe@177
|
543 "direct_voter"."member_id"
|
jbe@177
|
544 FROM "direct_voter"
|
jbe@177
|
545 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
|
jbe@177
|
546 LEFT JOIN "privilege"
|
jbe@177
|
547 ON "privilege"."unit_id" = "unit_id_v"
|
jbe@177
|
548 AND "privilege"."member_id" = "direct_voter"."member_id"
|
jbe@177
|
549 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
|
jbe@177
|
550 "member"."active" = FALSE OR
|
jbe@177
|
551 "privilege"."voting_right" ISNULL OR
|
jbe@177
|
552 "privilege"."voting_right" = FALSE
|
jbe@177
|
553 )
|
jbe@177
|
554 ) AS "subquery"
|
jbe@177
|
555 WHERE "direct_voter"."issue_id" = "issue_id_p"
|
jbe@177
|
556 AND "direct_voter"."member_id" = "subquery"."member_id";
|
jbe@177
|
557 -- consider delegations:
|
jbe@177
|
558 UPDATE "direct_voter" SET "weight" = 1
|
jbe@177
|
559 WHERE "issue_id" = "issue_id_p";
|
jbe@177
|
560 PERFORM "add_vote_delegations"("issue_id_p");
|
jbe@177
|
561 -- set voter count and mark issue as being calculated:
|
jbe@177
|
562 UPDATE "issue" SET
|
jbe@177
|
563 "state" = 'calculation',
|
jbe@177
|
564 "closed" = now(),
|
jbe@177
|
565 "voter_count" = (
|
jbe@177
|
566 SELECT coalesce(sum("weight"), 0)
|
jbe@177
|
567 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
568 )
|
jbe@177
|
569 WHERE "id" = "issue_id_p";
|
jbe@177
|
570 -- materialize battle_view:
|
jbe@177
|
571 -- NOTE: "closed" column of issue must be set at this point
|
jbe@177
|
572 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
|
jbe@177
|
573 INSERT INTO "battle" (
|
jbe@177
|
574 "issue_id",
|
jbe@177
|
575 "winning_initiative_id", "losing_initiative_id",
|
jbe@177
|
576 "count"
|
jbe@177
|
577 ) SELECT
|
jbe@177
|
578 "issue_id",
|
jbe@177
|
579 "winning_initiative_id", "losing_initiative_id",
|
jbe@177
|
580 "count"
|
jbe@177
|
581 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
|
jbe@177
|
582 -- copy "positive_votes" and "negative_votes" from "battle" table:
|
jbe@177
|
583 UPDATE "initiative" SET
|
jbe@177
|
584 "positive_votes" = "battle_win"."count",
|
jbe@177
|
585 "negative_votes" = "battle_lose"."count"
|
jbe@177
|
586 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
|
jbe@177
|
587 WHERE
|
jbe@177
|
588 "battle_win"."issue_id" = "issue_id_p" AND
|
jbe@177
|
589 "battle_win"."winning_initiative_id" = "initiative"."id" AND
|
jbe@177
|
590 "battle_win"."losing_initiative_id" ISNULL AND
|
jbe@177
|
591 "battle_lose"."issue_id" = "issue_id_p" AND
|
jbe@177
|
592 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
|
jbe@177
|
593 "battle_lose"."winning_initiative_id" ISNULL;
|
jbe@177
|
594 END;
|
jbe@177
|
595 $$;
|
jbe@177
|
596
|
jbe@177
|
597 DROP FUNCTION "array_init_string"(INTEGER);
|
jbe@177
|
598 DROP FUNCTION "square_matrix_init_string"(INTEGER);
|
jbe@177
|
599
|
jbe@177
|
600 CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
|
jbe@177
|
601 RETURNS VOID
|
jbe@177
|
602 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@177
|
603 DECLARE
|
jbe@177
|
604 "issue_row" "issue"%ROWTYPE;
|
jbe@177
|
605 "policy_row" "policy"%ROWTYPE;
|
jbe@177
|
606 "dimension_v" INTEGER;
|
jbe@177
|
607 "vote_matrix" INT4[][]; -- absolute votes
|
jbe@177
|
608 "matrix" INT8[][]; -- defeat strength / best paths
|
jbe@177
|
609 "i" INTEGER;
|
jbe@177
|
610 "j" INTEGER;
|
jbe@177
|
611 "k" INTEGER;
|
jbe@177
|
612 "battle_row" "battle"%ROWTYPE;
|
jbe@177
|
613 "rank_ary" INT4[];
|
jbe@177
|
614 "rank_v" INT4;
|
jbe@177
|
615 "done_v" INTEGER;
|
jbe@177
|
616 "winners_ary" INTEGER[];
|
jbe@177
|
617 "initiative_id_v" "initiative"."id"%TYPE;
|
jbe@177
|
618 BEGIN
|
jbe@177
|
619 SELECT * INTO "issue_row"
|
jbe@177
|
620 FROM "issue" WHERE "id" = "issue_id_p"
|
jbe@177
|
621 FOR UPDATE;
|
jbe@177
|
622 SELECT * INTO "policy_row"
|
jbe@177
|
623 FROM "policy" WHERE "id" = "issue_row"."policy_id";
|
jbe@177
|
624 SELECT count(1) INTO "dimension_v"
|
jbe@177
|
625 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
|
jbe@177
|
626 -- Create "vote_matrix" with absolute number of votes in pairwise
|
jbe@177
|
627 -- comparison:
|
jbe@177
|
628 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
|
jbe@177
|
629 "i" := 1;
|
jbe@177
|
630 "j" := 2;
|
jbe@177
|
631 FOR "battle_row" IN
|
jbe@177
|
632 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
633 ORDER BY
|
jbe@177
|
634 "winning_initiative_id" NULLS LAST,
|
jbe@177
|
635 "losing_initiative_id" NULLS LAST
|
jbe@177
|
636 LOOP
|
jbe@177
|
637 "vote_matrix"["i"]["j"] := "battle_row"."count";
|
jbe@177
|
638 IF "j" = "dimension_v" THEN
|
jbe@177
|
639 "i" := "i" + 1;
|
jbe@177
|
640 "j" := 1;
|
jbe@177
|
641 ELSE
|
jbe@177
|
642 "j" := "j" + 1;
|
jbe@177
|
643 IF "j" = "i" THEN
|
jbe@177
|
644 "j" := "j" + 1;
|
jbe@177
|
645 END IF;
|
jbe@177
|
646 END IF;
|
jbe@177
|
647 END LOOP;
|
jbe@177
|
648 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
|
jbe@177
|
649 RAISE EXCEPTION 'Wrong battle count (should not happen)';
|
jbe@177
|
650 END IF;
|
jbe@177
|
651 -- Store defeat strengths in "matrix" using "defeat_strength"
|
jbe@177
|
652 -- function:
|
jbe@177
|
653 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
|
jbe@177
|
654 "i" := 1;
|
jbe@177
|
655 LOOP
|
jbe@177
|
656 "j" := 1;
|
jbe@177
|
657 LOOP
|
jbe@177
|
658 IF "i" != "j" THEN
|
jbe@177
|
659 "matrix"["i"]["j"] := "defeat_strength"(
|
jbe@177
|
660 "vote_matrix"["i"]["j"],
|
jbe@177
|
661 "vote_matrix"["j"]["i"]
|
jbe@177
|
662 );
|
jbe@177
|
663 END IF;
|
jbe@177
|
664 EXIT WHEN "j" = "dimension_v";
|
jbe@177
|
665 "j" := "j" + 1;
|
jbe@177
|
666 END LOOP;
|
jbe@177
|
667 EXIT WHEN "i" = "dimension_v";
|
jbe@177
|
668 "i" := "i" + 1;
|
jbe@177
|
669 END LOOP;
|
jbe@177
|
670 -- Find best paths:
|
jbe@177
|
671 "i" := 1;
|
jbe@177
|
672 LOOP
|
jbe@177
|
673 "j" := 1;
|
jbe@177
|
674 LOOP
|
jbe@177
|
675 IF "i" != "j" THEN
|
jbe@177
|
676 "k" := 1;
|
jbe@177
|
677 LOOP
|
jbe@177
|
678 IF "i" != "k" AND "j" != "k" THEN
|
jbe@177
|
679 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
|
jbe@177
|
680 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
|
jbe@177
|
681 "matrix"["j"]["k"] := "matrix"["j"]["i"];
|
jbe@177
|
682 END IF;
|
jbe@177
|
683 ELSE
|
jbe@177
|
684 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
|
jbe@177
|
685 "matrix"["j"]["k"] := "matrix"["i"]["k"];
|
jbe@177
|
686 END IF;
|
jbe@177
|
687 END IF;
|
jbe@177
|
688 END IF;
|
jbe@177
|
689 EXIT WHEN "k" = "dimension_v";
|
jbe@177
|
690 "k" := "k" + 1;
|
jbe@177
|
691 END LOOP;
|
jbe@177
|
692 END IF;
|
jbe@177
|
693 EXIT WHEN "j" = "dimension_v";
|
jbe@177
|
694 "j" := "j" + 1;
|
jbe@177
|
695 END LOOP;
|
jbe@177
|
696 EXIT WHEN "i" = "dimension_v";
|
jbe@177
|
697 "i" := "i" + 1;
|
jbe@177
|
698 END LOOP;
|
jbe@177
|
699 -- Determine order of winners:
|
jbe@177
|
700 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
|
jbe@177
|
701 "rank_v" := 1;
|
jbe@177
|
702 "done_v" := 0;
|
jbe@177
|
703 LOOP
|
jbe@177
|
704 "winners_ary" := '{}';
|
jbe@177
|
705 "i" := 1;
|
jbe@177
|
706 LOOP
|
jbe@177
|
707 IF "rank_ary"["i"] ISNULL THEN
|
jbe@177
|
708 "j" := 1;
|
jbe@177
|
709 LOOP
|
jbe@177
|
710 IF
|
jbe@177
|
711 "i" != "j" AND
|
jbe@177
|
712 "rank_ary"["j"] ISNULL AND
|
jbe@177
|
713 "matrix"["j"]["i"] > "matrix"["i"]["j"]
|
jbe@177
|
714 THEN
|
jbe@177
|
715 -- someone else is better
|
jbe@177
|
716 EXIT;
|
jbe@177
|
717 END IF;
|
jbe@177
|
718 IF "j" = "dimension_v" THEN
|
jbe@177
|
719 -- noone is better
|
jbe@177
|
720 "winners_ary" := "winners_ary" || "i";
|
jbe@177
|
721 EXIT;
|
jbe@177
|
722 END IF;
|
jbe@177
|
723 "j" := "j" + 1;
|
jbe@177
|
724 END LOOP;
|
jbe@177
|
725 END IF;
|
jbe@177
|
726 EXIT WHEN "i" = "dimension_v";
|
jbe@177
|
727 "i" := "i" + 1;
|
jbe@177
|
728 END LOOP;
|
jbe@177
|
729 "i" := 1;
|
jbe@177
|
730 LOOP
|
jbe@177
|
731 "rank_ary"["winners_ary"["i"]] := "rank_v";
|
jbe@177
|
732 "done_v" := "done_v" + 1;
|
jbe@177
|
733 EXIT WHEN "i" = array_upper("winners_ary", 1);
|
jbe@177
|
734 "i" := "i" + 1;
|
jbe@177
|
735 END LOOP;
|
jbe@177
|
736 EXIT WHEN "done_v" = "dimension_v";
|
jbe@177
|
737 "rank_v" := "rank_v" + 1;
|
jbe@177
|
738 END LOOP;
|
jbe@177
|
739 -- write preliminary results:
|
jbe@177
|
740 "i" := 1;
|
jbe@177
|
741 FOR "initiative_id_v" IN
|
jbe@177
|
742 SELECT "id" FROM "initiative"
|
jbe@177
|
743 WHERE "issue_id" = "issue_id_p" AND "admitted"
|
jbe@177
|
744 ORDER BY "id"
|
jbe@177
|
745 LOOP
|
jbe@177
|
746 UPDATE "initiative" SET
|
jbe@177
|
747 "direct_majority" =
|
jbe@177
|
748 CASE WHEN "policy_row"."direct_majority_strict" THEN
|
jbe@177
|
749 "positive_votes" * "policy_row"."direct_majority_den" >
|
jbe@177
|
750 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
|
jbe@177
|
751 ELSE
|
jbe@177
|
752 "positive_votes" * "policy_row"."direct_majority_den" >=
|
jbe@177
|
753 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
|
jbe@177
|
754 END
|
jbe@177
|
755 AND "positive_votes" >= "policy_row"."direct_majority_positive"
|
jbe@177
|
756 AND "issue_row"."voter_count"-"negative_votes" >=
|
jbe@177
|
757 "policy_row"."direct_majority_non_negative",
|
jbe@177
|
758 "indirect_majority" =
|
jbe@177
|
759 CASE WHEN "policy_row"."indirect_majority_strict" THEN
|
jbe@177
|
760 "positive_votes" * "policy_row"."indirect_majority_den" >
|
jbe@177
|
761 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
|
jbe@177
|
762 ELSE
|
jbe@177
|
763 "positive_votes" * "policy_row"."indirect_majority_den" >=
|
jbe@177
|
764 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
|
jbe@177
|
765 END
|
jbe@177
|
766 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
|
jbe@177
|
767 AND "issue_row"."voter_count"-"negative_votes" >=
|
jbe@177
|
768 "policy_row"."indirect_majority_non_negative",
|
jbe@177
|
769 "schulze_rank" = "rank_ary"["i"],
|
jbe@177
|
770 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
|
jbe@177
|
771 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
|
jbe@177
|
772 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
|
jbe@177
|
773 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
|
jbe@177
|
774 "winner" = FALSE
|
jbe@177
|
775 WHERE "id" = "initiative_id_v";
|
jbe@177
|
776 "i" := "i" + 1;
|
jbe@177
|
777 END LOOP;
|
jbe@177
|
778 IF "i" != "dimension_v" THEN
|
jbe@177
|
779 RAISE EXCEPTION 'Wrong winner count (should not happen)';
|
jbe@177
|
780 END IF;
|
jbe@177
|
781 -- take indirect majorities into account:
|
jbe@177
|
782 LOOP
|
jbe@177
|
783 UPDATE "initiative" SET "indirect_majority" = TRUE
|
jbe@177
|
784 FROM (
|
jbe@177
|
785 SELECT "new_initiative"."id" AS "initiative_id"
|
jbe@177
|
786 FROM "initiative" "old_initiative"
|
jbe@177
|
787 JOIN "initiative" "new_initiative"
|
jbe@177
|
788 ON "new_initiative"."issue_id" = "issue_id_p"
|
jbe@177
|
789 AND "new_initiative"."indirect_majority" = FALSE
|
jbe@177
|
790 JOIN "battle" "battle_win"
|
jbe@177
|
791 ON "battle_win"."issue_id" = "issue_id_p"
|
jbe@177
|
792 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
|
jbe@177
|
793 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
|
jbe@177
|
794 JOIN "battle" "battle_lose"
|
jbe@177
|
795 ON "battle_lose"."issue_id" = "issue_id_p"
|
jbe@177
|
796 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
|
jbe@177
|
797 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
|
jbe@177
|
798 WHERE "old_initiative"."issue_id" = "issue_id_p"
|
jbe@177
|
799 AND "old_initiative"."indirect_majority" = TRUE
|
jbe@177
|
800 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
|
jbe@177
|
801 "battle_win"."count" * "policy_row"."indirect_majority_den" >
|
jbe@177
|
802 "policy_row"."indirect_majority_num" *
|
jbe@177
|
803 ("battle_win"."count"+"battle_lose"."count")
|
jbe@177
|
804 ELSE
|
jbe@177
|
805 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
|
jbe@177
|
806 "policy_row"."indirect_majority_num" *
|
jbe@177
|
807 ("battle_win"."count"+"battle_lose"."count")
|
jbe@177
|
808 END
|
jbe@177
|
809 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
|
jbe@177
|
810 AND "issue_row"."voter_count"-"battle_lose"."count" >=
|
jbe@177
|
811 "policy_row"."indirect_majority_non_negative"
|
jbe@177
|
812 ) AS "subquery"
|
jbe@177
|
813 WHERE "id" = "subquery"."initiative_id";
|
jbe@177
|
814 EXIT WHEN NOT FOUND;
|
jbe@177
|
815 END LOOP;
|
jbe@177
|
816 -- set "multistage_majority" for remaining matching initiatives:
|
jbe@177
|
817 UPDATE "initiative" SET "multistage_majority" = TRUE
|
jbe@177
|
818 FROM (
|
jbe@177
|
819 SELECT "losing_initiative"."id" AS "initiative_id"
|
jbe@177
|
820 FROM "initiative" "losing_initiative"
|
jbe@177
|
821 JOIN "initiative" "winning_initiative"
|
jbe@177
|
822 ON "winning_initiative"."issue_id" = "issue_id_p"
|
jbe@177
|
823 AND "winning_initiative"."admitted"
|
jbe@177
|
824 JOIN "battle" "battle_win"
|
jbe@177
|
825 ON "battle_win"."issue_id" = "issue_id_p"
|
jbe@177
|
826 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
|
jbe@177
|
827 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
|
jbe@177
|
828 JOIN "battle" "battle_lose"
|
jbe@177
|
829 ON "battle_lose"."issue_id" = "issue_id_p"
|
jbe@177
|
830 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
|
jbe@177
|
831 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
|
jbe@177
|
832 WHERE "losing_initiative"."issue_id" = "issue_id_p"
|
jbe@177
|
833 AND "losing_initiative"."admitted"
|
jbe@177
|
834 AND "winning_initiative"."schulze_rank" <
|
jbe@177
|
835 "losing_initiative"."schulze_rank"
|
jbe@177
|
836 AND "battle_win"."count" > "battle_lose"."count"
|
jbe@177
|
837 AND (
|
jbe@177
|
838 "battle_win"."count" > "winning_initiative"."positive_votes" OR
|
jbe@177
|
839 "battle_lose"."count" < "losing_initiative"."negative_votes" )
|
jbe@177
|
840 ) AS "subquery"
|
jbe@177
|
841 WHERE "id" = "subquery"."initiative_id";
|
jbe@177
|
842 -- mark eligible initiatives:
|
jbe@177
|
843 UPDATE "initiative" SET "eligible" = TRUE
|
jbe@177
|
844 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
845 AND "initiative"."direct_majority"
|
jbe@177
|
846 AND "initiative"."indirect_majority"
|
jbe@177
|
847 AND "initiative"."better_than_status_quo"
|
jbe@177
|
848 AND (
|
jbe@177
|
849 "policy_row"."no_multistage_majority" = FALSE OR
|
jbe@177
|
850 "initiative"."multistage_majority" = FALSE )
|
jbe@177
|
851 AND (
|
jbe@177
|
852 "policy_row"."no_reverse_beat_path" = FALSE OR
|
jbe@177
|
853 "initiative"."reverse_beat_path" = FALSE );
|
jbe@177
|
854 -- mark final winner:
|
jbe@177
|
855 UPDATE "initiative" SET "winner" = TRUE
|
jbe@177
|
856 FROM (
|
jbe@177
|
857 SELECT "id" AS "initiative_id"
|
jbe@177
|
858 FROM "initiative"
|
jbe@177
|
859 WHERE "issue_id" = "issue_id_p" AND "eligible"
|
jbe@177
|
860 ORDER BY "schulze_rank", "id"
|
jbe@177
|
861 LIMIT 1
|
jbe@177
|
862 ) AS "subquery"
|
jbe@177
|
863 WHERE "id" = "subquery"."initiative_id";
|
jbe@177
|
864 -- write (final) ranks:
|
jbe@177
|
865 "rank_v" := 1;
|
jbe@177
|
866 FOR "initiative_id_v" IN
|
jbe@177
|
867 SELECT "id"
|
jbe@177
|
868 FROM "initiative"
|
jbe@177
|
869 WHERE "issue_id" = "issue_id_p" AND "admitted"
|
jbe@177
|
870 ORDER BY
|
jbe@177
|
871 "winner" DESC,
|
jbe@177
|
872 ("direct_majority" AND "indirect_majority") DESC,
|
jbe@177
|
873 "schulze_rank",
|
jbe@177
|
874 "id"
|
jbe@177
|
875 LOOP
|
jbe@177
|
876 UPDATE "initiative" SET "rank" = "rank_v"
|
jbe@177
|
877 WHERE "id" = "initiative_id_v";
|
jbe@177
|
878 "rank_v" := "rank_v" + 1;
|
jbe@177
|
879 END LOOP;
|
jbe@177
|
880 -- set schulze rank of status quo and mark issue as finished:
|
jbe@177
|
881 UPDATE "issue" SET
|
jbe@177
|
882 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
|
jbe@177
|
883 "state" =
|
jbe@177
|
884 CASE WHEN EXISTS (
|
jbe@177
|
885 SELECT NULL FROM "initiative"
|
jbe@177
|
886 WHERE "issue_id" = "issue_id_p" AND "winner"
|
jbe@177
|
887 ) THEN
|
jbe@177
|
888 'finished_with_winner'::"issue_state"
|
jbe@177
|
889 ELSE
|
jbe@177
|
890 'finished_without_winner'::"issue_state"
|
jbe@177
|
891 END,
|
jbe@177
|
892 "ranks_available" = TRUE
|
jbe@177
|
893 WHERE "id" = "issue_id_p";
|
jbe@177
|
894 RETURN;
|
jbe@177
|
895 END;
|
jbe@177
|
896 $$;
|
jbe@177
|
897
|
jbe@177
|
898 CREATE OR REPLACE FUNCTION "check_issue"
|
jbe@177
|
899 ( "issue_id_p" "issue"."id"%TYPE )
|
jbe@177
|
900 RETURNS VOID
|
jbe@177
|
901 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@177
|
902 DECLARE
|
jbe@177
|
903 "issue_row" "issue"%ROWTYPE;
|
jbe@177
|
904 "policy_row" "policy"%ROWTYPE;
|
jbe@177
|
905 BEGIN
|
jbe@177
|
906 PERFORM "lock_issue"("issue_id_p");
|
jbe@177
|
907 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@177
|
908 -- only process open issues:
|
jbe@177
|
909 IF "issue_row"."closed" ISNULL THEN
|
jbe@177
|
910 SELECT * INTO "policy_row" FROM "policy"
|
jbe@177
|
911 WHERE "id" = "issue_row"."policy_id";
|
jbe@177
|
912 -- create a snapshot, unless issue is already fully frozen:
|
jbe@177
|
913 IF "issue_row"."fully_frozen" ISNULL THEN
|
jbe@177
|
914 PERFORM "create_snapshot"("issue_id_p");
|
jbe@177
|
915 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@177
|
916 END IF;
|
jbe@177
|
917 -- eventually close or accept issues, which have not been accepted:
|
jbe@177
|
918 IF "issue_row"."accepted" ISNULL THEN
|
jbe@177
|
919 IF EXISTS (
|
jbe@177
|
920 SELECT NULL FROM "initiative"
|
jbe@177
|
921 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
922 AND "supporter_count" > 0
|
jbe@177
|
923 AND "supporter_count" * "policy_row"."issue_quorum_den"
|
jbe@177
|
924 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
|
jbe@177
|
925 ) THEN
|
jbe@177
|
926 -- accept issues, if supporter count is high enough
|
jbe@177
|
927 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
|
jbe@177
|
928 -- NOTE: "issue_row" used later
|
jbe@177
|
929 "issue_row"."state" := 'discussion';
|
jbe@177
|
930 "issue_row"."accepted" := now();
|
jbe@177
|
931 UPDATE "issue" SET
|
jbe@177
|
932 "state" = "issue_row"."state",
|
jbe@177
|
933 "accepted" = "issue_row"."accepted"
|
jbe@177
|
934 WHERE "id" = "issue_row"."id";
|
jbe@177
|
935 ELSIF
|
jbe@177
|
936 now() >= "issue_row"."created" + "issue_row"."admission_time"
|
jbe@177
|
937 THEN
|
jbe@177
|
938 -- close issues, if admission time has expired
|
jbe@177
|
939 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
|
jbe@177
|
940 UPDATE "issue" SET
|
jbe@177
|
941 "state" = 'canceled_issue_not_accepted',
|
jbe@177
|
942 "closed" = now()
|
jbe@177
|
943 WHERE "id" = "issue_row"."id";
|
jbe@177
|
944 END IF;
|
jbe@177
|
945 END IF;
|
jbe@177
|
946 -- eventually half freeze issues:
|
jbe@177
|
947 IF
|
jbe@177
|
948 -- NOTE: issue can't be closed at this point, if it has been accepted
|
jbe@177
|
949 "issue_row"."accepted" NOTNULL AND
|
jbe@177
|
950 "issue_row"."half_frozen" ISNULL
|
jbe@177
|
951 THEN
|
jbe@177
|
952 IF
|
jbe@177
|
953 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
|
jbe@177
|
954 THEN
|
jbe@177
|
955 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
|
jbe@177
|
956 -- NOTE: "issue_row" used later
|
jbe@177
|
957 "issue_row"."state" := 'verification';
|
jbe@177
|
958 "issue_row"."half_frozen" := now();
|
jbe@177
|
959 UPDATE "issue" SET
|
jbe@177
|
960 "state" = "issue_row"."state",
|
jbe@177
|
961 "half_frozen" = "issue_row"."half_frozen"
|
jbe@177
|
962 WHERE "id" = "issue_row"."id";
|
jbe@177
|
963 END IF;
|
jbe@177
|
964 END IF;
|
jbe@177
|
965 -- close issues after some time, if all initiatives have been revoked:
|
jbe@177
|
966 IF
|
jbe@177
|
967 "issue_row"."closed" ISNULL AND
|
jbe@177
|
968 NOT EXISTS (
|
jbe@177
|
969 -- all initiatives are revoked
|
jbe@177
|
970 SELECT NULL FROM "initiative"
|
jbe@177
|
971 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
|
jbe@177
|
972 ) AND (
|
jbe@177
|
973 -- and issue has not been accepted yet
|
jbe@177
|
974 "issue_row"."accepted" ISNULL OR
|
jbe@177
|
975 NOT EXISTS (
|
jbe@177
|
976 -- or no initiatives have been revoked lately
|
jbe@177
|
977 SELECT NULL FROM "initiative"
|
jbe@177
|
978 WHERE "issue_id" = "issue_id_p"
|
jbe@177
|
979 AND now() < "revoked" + "issue_row"."verification_time"
|
jbe@177
|
980 ) OR (
|
jbe@177
|
981 -- or verification time has elapsed
|
jbe@177
|
982 "issue_row"."half_frozen" NOTNULL AND
|
jbe@177
|
983 "issue_row"."fully_frozen" ISNULL AND
|
jbe@177
|
984 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
|
jbe@177
|
985 )
|
jbe@177
|
986 )
|
jbe@177
|
987 THEN
|
jbe@177
|
988 -- NOTE: "issue_row" used later
|
jbe@177
|
989 IF "issue_row"."accepted" ISNULL THEN
|
jbe@177
|
990 "issue_row"."state" := 'canceled_revoked_before_accepted';
|
jbe@177
|
991 ELSIF "issue_row"."half_frozen" ISNULL THEN
|
jbe@177
|
992 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
|
jbe@177
|
993 ELSE
|
jbe@177
|
994 "issue_row"."state" := 'canceled_after_revocation_during_verification';
|
jbe@177
|
995 END IF;
|
jbe@177
|
996 "issue_row"."closed" := now();
|
jbe@177
|
997 UPDATE "issue" SET
|
jbe@177
|
998 "state" = "issue_row"."state",
|
jbe@177
|
999 "closed" = "issue_row"."closed"
|
jbe@177
|
1000 WHERE "id" = "issue_row"."id";
|
jbe@177
|
1001 END IF;
|
jbe@177
|
1002 -- fully freeze issue after verification time:
|
jbe@177
|
1003 IF
|
jbe@177
|
1004 "issue_row"."half_frozen" NOTNULL AND
|
jbe@177
|
1005 "issue_row"."fully_frozen" ISNULL AND
|
jbe@177
|
1006 "issue_row"."closed" ISNULL AND
|
jbe@177
|
1007 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
|
jbe@177
|
1008 THEN
|
jbe@177
|
1009 PERFORM "freeze_after_snapshot"("issue_id_p");
|
jbe@177
|
1010 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
|
jbe@177
|
1011 END IF;
|
jbe@177
|
1012 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@177
|
1013 -- close issue by calling close_voting(...) after voting time:
|
jbe@177
|
1014 IF
|
jbe@177
|
1015 "issue_row"."closed" ISNULL AND
|
jbe@177
|
1016 "issue_row"."fully_frozen" NOTNULL AND
|
jbe@177
|
1017 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
|
jbe@177
|
1018 THEN
|
jbe@177
|
1019 PERFORM "close_voting"("issue_id_p");
|
jbe@177
|
1020 -- calculate ranks will not consume much time and can be done now
|
jbe@177
|
1021 PERFORM "calculate_ranks"("issue_id_p");
|
jbe@177
|
1022 END IF;
|
jbe@177
|
1023 END IF;
|
jbe@177
|
1024 RETURN;
|
jbe@177
|
1025 END;
|
jbe@177
|
1026 $$;
|
jbe@177
|
1027
|
jbe@177
|
1028 -- TODO: recalculate voting results
|
jbe@177
|
1029
|
jbe@177
|
1030 COMMIT;
|
jbe@177
|
1031
|
jbe@177
|
1032 UPDATE "suggestion" SET "draft_id" = "subquery"."draft_id"
|
jbe@177
|
1033 FROM (
|
jbe@177
|
1034 SELECT DISTINCT ON ("suggestion"."id")
|
jbe@177
|
1035 "suggestion"."id" AS "suggestion_id",
|
jbe@177
|
1036 "draft"."id" AS "draft_id"
|
jbe@177
|
1037 FROM "suggestion" JOIN "draft"
|
jbe@177
|
1038 ON "suggestion"."initiative_id" = "draft"."initiative_id"
|
jbe@177
|
1039 WHERE "draft"."created" <= "suggestion"."created"
|
jbe@177
|
1040 ORDER BY "suggestion"."id", "draft"."created" DESC
|
jbe@177
|
1041 ) AS "subquery"
|
jbe@177
|
1042 WHERE "suggestion"."id" = "subquery"."suggestion_id";
|
jbe@177
|
1043
|
jbe@177
|
1044 ALTER TABLE "suggestion" ALTER COLUMN "draft_id" SET NOT NULL;
|