liquid_feedback_core

diff update/core-update.v2.0.2-v2.0.3.sql @ 218:2571bb3bdf56

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

Impressum / About Us