liquid_feedback_core
diff update/core-update.v2.0.11-v2.0.12.sql @ 307:847d59f94ceb
Merged fix from v2.0.12: Removed unwanted (and broken) tie-breaking by approval rate
author | jbe |
---|---|
date | Fri Oct 05 13:45:37 2012 +0200 (2012-10-05) |
parents | a839e7efde9f |
children | 5c98265b39a0 |
line diff
1.1 --- /dev/null Thu Jan 01 00:00:00 1970 +0000 1.2 +++ b/update/core-update.v2.0.11-v2.0.12.sql Fri Oct 05 13:45:37 2012 +0200 1.3 @@ -0,0 +1,309 @@ 1.4 +BEGIN; 1.5 + 1.6 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS 1.7 + SELECT * FROM (VALUES ('2.0.12', 2, 0, 12)) 1.8 + AS "subquery"("string", "major", "minor", "revision"); 1.9 + 1.10 +CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE) 1.11 + RETURNS VOID 1.12 + LANGUAGE 'plpgsql' VOLATILE AS $$ 1.13 + DECLARE 1.14 + "issue_row" "issue"%ROWTYPE; 1.15 + "policy_row" "policy"%ROWTYPE; 1.16 + "dimension_v" INTEGER; 1.17 + "vote_matrix" INT4[][]; -- absolute votes 1.18 + "matrix" INT8[][]; -- defeat strength / best paths 1.19 + "i" INTEGER; 1.20 + "j" INTEGER; 1.21 + "k" INTEGER; 1.22 + "battle_row" "battle"%ROWTYPE; 1.23 + "rank_ary" INT4[]; 1.24 + "rank_v" INT4; 1.25 + "done_v" INTEGER; 1.26 + "winners_ary" INTEGER[]; 1.27 + "initiative_id_v" "initiative"."id"%TYPE; 1.28 + BEGIN 1.29 + SELECT * INTO "issue_row" 1.30 + FROM "issue" WHERE "id" = "issue_id_p" 1.31 + FOR UPDATE; 1.32 + SELECT * INTO "policy_row" 1.33 + FROM "policy" WHERE "id" = "issue_row"."policy_id"; 1.34 + SELECT count(1) INTO "dimension_v" 1.35 + FROM "battle_participant" WHERE "issue_id" = "issue_id_p"; 1.36 + -- Create "vote_matrix" with absolute number of votes in pairwise 1.37 + -- comparison: 1.38 + "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]); 1.39 + "i" := 1; 1.40 + "j" := 2; 1.41 + FOR "battle_row" IN 1.42 + SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p" 1.43 + ORDER BY 1.44 + "winning_initiative_id" NULLS LAST, 1.45 + "losing_initiative_id" NULLS LAST 1.46 + LOOP 1.47 + "vote_matrix"["i"]["j"] := "battle_row"."count"; 1.48 + IF "j" = "dimension_v" THEN 1.49 + "i" := "i" + 1; 1.50 + "j" := 1; 1.51 + ELSE 1.52 + "j" := "j" + 1; 1.53 + IF "j" = "i" THEN 1.54 + "j" := "j" + 1; 1.55 + END IF; 1.56 + END IF; 1.57 + END LOOP; 1.58 + IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN 1.59 + RAISE EXCEPTION 'Wrong battle count (should not happen)'; 1.60 + END IF; 1.61 + -- Store defeat strengths in "matrix" using "defeat_strength" 1.62 + -- function: 1.63 + "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]); 1.64 + "i" := 1; 1.65 + LOOP 1.66 + "j" := 1; 1.67 + LOOP 1.68 + IF "i" != "j" THEN 1.69 + "matrix"["i"]["j"] := "defeat_strength"( 1.70 + "vote_matrix"["i"]["j"], 1.71 + "vote_matrix"["j"]["i"] 1.72 + ); 1.73 + END IF; 1.74 + EXIT WHEN "j" = "dimension_v"; 1.75 + "j" := "j" + 1; 1.76 + END LOOP; 1.77 + EXIT WHEN "i" = "dimension_v"; 1.78 + "i" := "i" + 1; 1.79 + END LOOP; 1.80 + -- Find best paths: 1.81 + "i" := 1; 1.82 + LOOP 1.83 + "j" := 1; 1.84 + LOOP 1.85 + IF "i" != "j" THEN 1.86 + "k" := 1; 1.87 + LOOP 1.88 + IF "i" != "k" AND "j" != "k" THEN 1.89 + IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN 1.90 + IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN 1.91 + "matrix"["j"]["k"] := "matrix"["j"]["i"]; 1.92 + END IF; 1.93 + ELSE 1.94 + IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN 1.95 + "matrix"["j"]["k"] := "matrix"["i"]["k"]; 1.96 + END IF; 1.97 + END IF; 1.98 + END IF; 1.99 + EXIT WHEN "k" = "dimension_v"; 1.100 + "k" := "k" + 1; 1.101 + END LOOP; 1.102 + END IF; 1.103 + EXIT WHEN "j" = "dimension_v"; 1.104 + "j" := "j" + 1; 1.105 + END LOOP; 1.106 + EXIT WHEN "i" = "dimension_v"; 1.107 + "i" := "i" + 1; 1.108 + END LOOP; 1.109 + -- Determine order of winners: 1.110 + "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]); 1.111 + "rank_v" := 1; 1.112 + "done_v" := 0; 1.113 + LOOP 1.114 + "winners_ary" := '{}'; 1.115 + "i" := 1; 1.116 + LOOP 1.117 + IF "rank_ary"["i"] ISNULL THEN 1.118 + "j" := 1; 1.119 + LOOP 1.120 + IF 1.121 + "i" != "j" AND 1.122 + "rank_ary"["j"] ISNULL AND 1.123 + "matrix"["j"]["i"] > "matrix"["i"]["j"] 1.124 + THEN 1.125 + -- someone else is better 1.126 + EXIT; 1.127 + END IF; 1.128 + IF "j" = "dimension_v" THEN 1.129 + -- noone is better 1.130 + "winners_ary" := "winners_ary" || "i"; 1.131 + EXIT; 1.132 + END IF; 1.133 + "j" := "j" + 1; 1.134 + END LOOP; 1.135 + END IF; 1.136 + EXIT WHEN "i" = "dimension_v"; 1.137 + "i" := "i" + 1; 1.138 + END LOOP; 1.139 + "i" := 1; 1.140 + LOOP 1.141 + "rank_ary"["winners_ary"["i"]] := "rank_v"; 1.142 + "done_v" := "done_v" + 1; 1.143 + EXIT WHEN "i" = array_upper("winners_ary", 1); 1.144 + "i" := "i" + 1; 1.145 + END LOOP; 1.146 + EXIT WHEN "done_v" = "dimension_v"; 1.147 + "rank_v" := "rank_v" + 1; 1.148 + END LOOP; 1.149 + -- write preliminary results: 1.150 + "i" := 1; 1.151 + FOR "initiative_id_v" IN 1.152 + SELECT "id" FROM "initiative" 1.153 + WHERE "issue_id" = "issue_id_p" AND "admitted" 1.154 + ORDER BY "id" 1.155 + LOOP 1.156 + UPDATE "initiative" SET 1.157 + "direct_majority" = 1.158 + CASE WHEN "policy_row"."direct_majority_strict" THEN 1.159 + "positive_votes" * "policy_row"."direct_majority_den" > 1.160 + "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes") 1.161 + ELSE 1.162 + "positive_votes" * "policy_row"."direct_majority_den" >= 1.163 + "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes") 1.164 + END 1.165 + AND "positive_votes" >= "policy_row"."direct_majority_positive" 1.166 + AND "issue_row"."voter_count"-"negative_votes" >= 1.167 + "policy_row"."direct_majority_non_negative", 1.168 + "indirect_majority" = 1.169 + CASE WHEN "policy_row"."indirect_majority_strict" THEN 1.170 + "positive_votes" * "policy_row"."indirect_majority_den" > 1.171 + "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes") 1.172 + ELSE 1.173 + "positive_votes" * "policy_row"."indirect_majority_den" >= 1.174 + "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes") 1.175 + END 1.176 + AND "positive_votes" >= "policy_row"."indirect_majority_positive" 1.177 + AND "issue_row"."voter_count"-"negative_votes" >= 1.178 + "policy_row"."indirect_majority_non_negative", 1.179 + "schulze_rank" = "rank_ary"["i"], 1.180 + "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"], 1.181 + "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"], 1.182 + "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"], 1.183 + "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0, 1.184 + "eligible" = FALSE, 1.185 + "winner" = FALSE, 1.186 + "rank" = NULL -- NOTE: in cases of manual reset of issue state 1.187 + WHERE "id" = "initiative_id_v"; 1.188 + "i" := "i" + 1; 1.189 + END LOOP; 1.190 + IF "i" != "dimension_v" THEN 1.191 + RAISE EXCEPTION 'Wrong winner count (should not happen)'; 1.192 + END IF; 1.193 + -- take indirect majorities into account: 1.194 + LOOP 1.195 + UPDATE "initiative" SET "indirect_majority" = TRUE 1.196 + FROM ( 1.197 + SELECT "new_initiative"."id" AS "initiative_id" 1.198 + FROM "initiative" "old_initiative" 1.199 + JOIN "initiative" "new_initiative" 1.200 + ON "new_initiative"."issue_id" = "issue_id_p" 1.201 + AND "new_initiative"."indirect_majority" = FALSE 1.202 + JOIN "battle" "battle_win" 1.203 + ON "battle_win"."issue_id" = "issue_id_p" 1.204 + AND "battle_win"."winning_initiative_id" = "new_initiative"."id" 1.205 + AND "battle_win"."losing_initiative_id" = "old_initiative"."id" 1.206 + JOIN "battle" "battle_lose" 1.207 + ON "battle_lose"."issue_id" = "issue_id_p" 1.208 + AND "battle_lose"."losing_initiative_id" = "new_initiative"."id" 1.209 + AND "battle_lose"."winning_initiative_id" = "old_initiative"."id" 1.210 + WHERE "old_initiative"."issue_id" = "issue_id_p" 1.211 + AND "old_initiative"."indirect_majority" = TRUE 1.212 + AND CASE WHEN "policy_row"."indirect_majority_strict" THEN 1.213 + "battle_win"."count" * "policy_row"."indirect_majority_den" > 1.214 + "policy_row"."indirect_majority_num" * 1.215 + ("battle_win"."count"+"battle_lose"."count") 1.216 + ELSE 1.217 + "battle_win"."count" * "policy_row"."indirect_majority_den" >= 1.218 + "policy_row"."indirect_majority_num" * 1.219 + ("battle_win"."count"+"battle_lose"."count") 1.220 + END 1.221 + AND "battle_win"."count" >= "policy_row"."indirect_majority_positive" 1.222 + AND "issue_row"."voter_count"-"battle_lose"."count" >= 1.223 + "policy_row"."indirect_majority_non_negative" 1.224 + ) AS "subquery" 1.225 + WHERE "id" = "subquery"."initiative_id"; 1.226 + EXIT WHEN NOT FOUND; 1.227 + END LOOP; 1.228 + -- set "multistage_majority" for remaining matching initiatives: 1.229 + UPDATE "initiative" SET "multistage_majority" = TRUE 1.230 + FROM ( 1.231 + SELECT "losing_initiative"."id" AS "initiative_id" 1.232 + FROM "initiative" "losing_initiative" 1.233 + JOIN "initiative" "winning_initiative" 1.234 + ON "winning_initiative"."issue_id" = "issue_id_p" 1.235 + AND "winning_initiative"."admitted" 1.236 + JOIN "battle" "battle_win" 1.237 + ON "battle_win"."issue_id" = "issue_id_p" 1.238 + AND "battle_win"."winning_initiative_id" = "winning_initiative"."id" 1.239 + AND "battle_win"."losing_initiative_id" = "losing_initiative"."id" 1.240 + JOIN "battle" "battle_lose" 1.241 + ON "battle_lose"."issue_id" = "issue_id_p" 1.242 + AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id" 1.243 + AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id" 1.244 + WHERE "losing_initiative"."issue_id" = "issue_id_p" 1.245 + AND "losing_initiative"."admitted" 1.246 + AND "winning_initiative"."schulze_rank" < 1.247 + "losing_initiative"."schulze_rank" 1.248 + AND "battle_win"."count" > "battle_lose"."count" 1.249 + AND ( 1.250 + "battle_win"."count" > "winning_initiative"."positive_votes" OR 1.251 + "battle_lose"."count" < "losing_initiative"."negative_votes" ) 1.252 + ) AS "subquery" 1.253 + WHERE "id" = "subquery"."initiative_id"; 1.254 + -- mark eligible initiatives: 1.255 + UPDATE "initiative" SET "eligible" = TRUE 1.256 + WHERE "issue_id" = "issue_id_p" 1.257 + AND "initiative"."direct_majority" 1.258 + AND "initiative"."indirect_majority" 1.259 + AND "initiative"."better_than_status_quo" 1.260 + AND ( 1.261 + "policy_row"."no_multistage_majority" = FALSE OR 1.262 + "initiative"."multistage_majority" = FALSE ) 1.263 + AND ( 1.264 + "policy_row"."no_reverse_beat_path" = FALSE OR 1.265 + "initiative"."reverse_beat_path" = FALSE ); 1.266 + -- mark final winner: 1.267 + UPDATE "initiative" SET "winner" = TRUE 1.268 + FROM ( 1.269 + SELECT "id" AS "initiative_id" 1.270 + FROM "initiative" 1.271 + WHERE "issue_id" = "issue_id_p" AND "eligible" 1.272 + ORDER BY 1.273 + "schulze_rank", 1.274 + "id" 1.275 + LIMIT 1 1.276 + ) AS "subquery" 1.277 + WHERE "id" = "subquery"."initiative_id"; 1.278 + -- write (final) ranks: 1.279 + "rank_v" := 1; 1.280 + FOR "initiative_id_v" IN 1.281 + SELECT "id" 1.282 + FROM "initiative" 1.283 + WHERE "issue_id" = "issue_id_p" AND "admitted" 1.284 + ORDER BY 1.285 + "winner" DESC, 1.286 + "eligible" DESC, 1.287 + "schulze_rank", 1.288 + "id" 1.289 + LOOP 1.290 + UPDATE "initiative" SET "rank" = "rank_v" 1.291 + WHERE "id" = "initiative_id_v"; 1.292 + "rank_v" := "rank_v" + 1; 1.293 + END LOOP; 1.294 + -- set schulze rank of status quo and mark issue as finished: 1.295 + UPDATE "issue" SET 1.296 + "status_quo_schulze_rank" = "rank_ary"["dimension_v"], 1.297 + "state" = 1.298 + CASE WHEN EXISTS ( 1.299 + SELECT NULL FROM "initiative" 1.300 + WHERE "issue_id" = "issue_id_p" AND "winner" 1.301 + ) THEN 1.302 + 'finished_with_winner'::"issue_state" 1.303 + ELSE 1.304 + 'finished_without_winner'::"issue_state" 1.305 + END, 1.306 + "ranks_available" = TRUE 1.307 + WHERE "id" = "issue_id_p"; 1.308 + RETURN; 1.309 + END; 1.310 + $$; 1.311 + 1.312 +COMMIT;