liquid_feedback_core

view update/core-update.v3.0.0-v3.0.1.sql @ 417:bc94ea65757b

Reconstruct battle data in update script to avoid future data loss when executing "clean_issue" to delete voting data
author jbe
date Wed Mar 26 17:09:55 2014 +0100 (2014-03-26)
parents db9ccf3c05f4
children 1088d83d92e8
line source
1 BEGIN;
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
4 SELECT * FROM (VALUES ('3.0.1', 3, 0, 1))
5 AS "subquery"("string", "major", "minor", "revision");
7 ALTER TABLE "initiative" ADD COLUMN "first_preference_votes" INT4;
9 ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
10 ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
11 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
12 ( "first_preference_votes" ISNULL AND
13 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
14 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
15 "schulze_rank" ISNULL AND
16 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
17 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
18 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
20 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
21 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
22 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
24 -- UPDATE TABLE "vote" SET "grade" = 0 WHERE "grade" ISNULL; -- should not be necessary
25 ALTER TABLE "vote" ALTER COLUMN "grade" SET NOT NULL;
27 ALTER TABLE "vote" ADD COLUMN "first_preference" BOOLEAN;
29 ALTER TABLE "vote" ADD
30 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
31 CHECK ("grade" > 0 OR "first_preference" ISNULL);
33 COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.';
35 INSERT INTO "temporary_transaction_data" ("key", "value")
36 VALUES ('override_protection_triggers', TRUE::TEXT);
38 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
39 FROM (
40 SELECT
41 "vote"."initiative_id",
42 "vote"."member_id",
43 CASE WHEN "vote"."grade" > 0 THEN
44 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
45 ELSE NULL
46 END AS "first_preference"
47 FROM "vote"
48 JOIN "initiative" -- NOTE: due to missing index on issue_id
49 ON "vote"."issue_id" = "initiative"."issue_id"
50 JOIN "vote" AS "agg"
51 ON "initiative"."id" = "agg"."initiative_id"
52 AND "vote"."member_id" = "agg"."member_id"
53 GROUP BY "vote"."initiative_id", "vote"."member_id"
54 ) AS "subquery"
55 WHERE "vote"."initiative_id" = "subquery"."initiative_id"
56 AND "vote"."member_id" = "subquery"."member_id";
58 DELETE FROM "temporary_transaction_data"
59 WHERE "key" = 'override_protection_triggers';
61 UPDATE "initiative"
62 SET "first_preference_votes" = coalesce("subquery"."sum", 0)
63 FROM (
64 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
65 FROM "vote" JOIN "direct_voter"
66 ON "vote"."issue_id" = "direct_voter"."issue_id"
67 AND "vote"."member_id" = "direct_voter"."member_id"
68 WHERE "vote"."first_preference"
69 GROUP BY "vote"."initiative_id"
70 ) AS "subquery"
71 WHERE "initiative"."admitted"
72 AND "initiative"."id" = "subquery"."initiative_id";
74 -- reconstruct battle data to avoid future data loss when
75 -- executing "clean_issue" to delete voting data:
76 INSERT INTO "battle" (
77 "issue_id",
78 "winning_initiative_id",
79 "losing_initiative_id",
80 "count"
81 ) SELECT
82 "battle_view"."issue_id",
83 "battle_view"."winning_initiative_id",
84 "battle_view"."losing_initiative_id",
85 "battle_view"."count"
86 FROM "battle_view"
87 LEFT JOIN "battle"
88 ON "battle_view"."winning_initiative_id" = "battle"."winning_initiative_id"
89 AND "battle_view"."losing_initiative_id" = "battle"."losing_initiative_id"
90 -- NOTE: comparisons with status-quo are intentionally omitted to mark
91 -- issues that were counted prior LiquidFeedback Core v2.0.0
92 WHERE "battle" ISNULL;
94 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
95 RETURNS VOID
96 LANGUAGE 'plpgsql' VOLATILE AS $$
97 DECLARE
98 "area_id_v" "area"."id"%TYPE;
99 "unit_id_v" "unit"."id"%TYPE;
100 "member_id_v" "member"."id"%TYPE;
101 BEGIN
102 PERFORM "require_transaction_isolation"();
103 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
104 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
105 -- override protection triggers:
106 INSERT INTO "temporary_transaction_data" ("key", "value")
107 VALUES ('override_protection_triggers', TRUE::TEXT);
108 -- delete timestamp of voting comment:
109 UPDATE "direct_voter" SET "comment_changed" = NULL
110 WHERE "issue_id" = "issue_id_p";
111 -- delete delegating votes (in cases of manual reset of issue state):
112 DELETE FROM "delegating_voter"
113 WHERE "issue_id" = "issue_id_p";
114 -- delete votes from non-privileged voters:
115 DELETE FROM "direct_voter"
116 USING (
117 SELECT
118 "direct_voter"."member_id"
119 FROM "direct_voter"
120 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
121 LEFT JOIN "privilege"
122 ON "privilege"."unit_id" = "unit_id_v"
123 AND "privilege"."member_id" = "direct_voter"."member_id"
124 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
125 "member"."active" = FALSE OR
126 "privilege"."voting_right" ISNULL OR
127 "privilege"."voting_right" = FALSE
128 )
129 ) AS "subquery"
130 WHERE "direct_voter"."issue_id" = "issue_id_p"
131 AND "direct_voter"."member_id" = "subquery"."member_id";
132 -- consider delegations:
133 UPDATE "direct_voter" SET "weight" = 1
134 WHERE "issue_id" = "issue_id_p";
135 PERFORM "add_vote_delegations"("issue_id_p");
136 -- mark first preferences:
137 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
138 FROM (
139 SELECT
140 "vote"."initiative_id",
141 "vote"."member_id",
142 CASE WHEN "vote"."grade" > 0 THEN
143 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
144 ELSE NULL
145 END AS "first_preference"
146 FROM "vote"
147 JOIN "initiative" -- NOTE: due to missing index on issue_id
148 ON "vote"."issue_id" = "initiative"."issue_id"
149 JOIN "vote" AS "agg"
150 ON "initiative"."id" = "agg"."initiative_id"
151 AND "vote"."member_id" = "agg"."member_id"
152 GROUP BY "vote"."initiative_id", "vote"."member_id"
153 ) AS "subquery"
154 WHERE "vote"."issue_id" = "issue_id_p"
155 AND "vote"."initiative_id" = "subquery"."initiative_id"
156 AND "vote"."member_id" = "subquery"."member_id";
157 -- finish overriding protection triggers (avoids garbage):
158 DELETE FROM "temporary_transaction_data"
159 WHERE "key" = 'override_protection_triggers';
160 -- materialize battle_view:
161 -- NOTE: "closed" column of issue must be set at this point
162 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
163 INSERT INTO "battle" (
164 "issue_id",
165 "winning_initiative_id", "losing_initiative_id",
166 "count"
167 ) SELECT
168 "issue_id",
169 "winning_initiative_id", "losing_initiative_id",
170 "count"
171 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
172 -- set voter count:
173 UPDATE "issue" SET
174 "voter_count" = (
175 SELECT coalesce(sum("weight"), 0)
176 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
177 )
178 WHERE "id" = "issue_id_p";
179 -- calculate "first_preference_votes":
180 UPDATE "initiative"
181 SET "first_preference_votes" = coalesce("subquery"."sum", 0)
182 FROM (
183 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
184 FROM "vote" JOIN "direct_voter"
185 ON "vote"."issue_id" = "direct_voter"."issue_id"
186 AND "vote"."member_id" = "direct_voter"."member_id"
187 WHERE "vote"."first_preference"
188 GROUP BY "vote"."initiative_id"
189 ) AS "subquery"
190 WHERE "initiative"."issue_id" = "issue_id_p"
191 AND "initiative"."admitted"
192 AND "initiative"."id" = "subquery"."initiative_id";
193 -- copy "positive_votes" and "negative_votes" from "battle" table:
194 UPDATE "initiative" SET
195 "positive_votes" = "battle_win"."count",
196 "negative_votes" = "battle_lose"."count"
197 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
198 WHERE
199 "battle_win"."issue_id" = "issue_id_p" AND
200 "battle_win"."winning_initiative_id" = "initiative"."id" AND
201 "battle_win"."losing_initiative_id" ISNULL AND
202 "battle_lose"."issue_id" = "issue_id_p" AND
203 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
204 "battle_lose"."winning_initiative_id" ISNULL;
205 END;
206 $$;
208 COMMIT;

Impressum / About Us