liquid_feedback_core

diff update/core-update.v3.0.0-v3.0.1.sql @ 416:db9ccf3c05f4

Added update script to introduce "first_preference_votes"
author jbe
date Wed Mar 26 14:45:49 2014 +0100 (2014-03-26)
parents
children bc94ea65757b
line diff
     1.1 --- /dev/null	Thu Jan 01 00:00:00 1970 +0000
     1.2 +++ b/update/core-update.v3.0.0-v3.0.1.sql	Wed Mar 26 14:45:49 2014 +0100
     1.3 @@ -0,0 +1,188 @@
     1.4 +BEGIN;
     1.5 +
     1.6 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     1.7 +  SELECT * FROM (VALUES ('3.0.1', 3, 0, 1))
     1.8 +  AS "subquery"("string", "major", "minor", "revision");
     1.9 +
    1.10 +ALTER TABLE "initiative" ADD COLUMN "first_preference_votes" INT4;
    1.11 +
    1.12 +ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
    1.13 +ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
    1.14 +          ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
    1.15 +          ( "first_preference_votes" ISNULL AND
    1.16 +            "positive_votes" ISNULL AND "negative_votes" ISNULL AND
    1.17 +            "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
    1.18 +            "schulze_rank" ISNULL AND
    1.19 +            "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
    1.20 +            "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
    1.21 +            "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
    1.22 +
    1.23 +COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
    1.24 +COMMENT ON COLUMN "initiative"."positive_votes"         IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
    1.25 +COMMENT ON COLUMN "initiative"."negative_votes"         IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
    1.26 +
    1.27 +-- UPDATE TABLE "vote" SET "grade" = 0 WHERE "grade" ISNULL;  -- should not be necessary
    1.28 +ALTER TABLE "vote" ALTER COLUMN "grade" SET NOT NULL;
    1.29 +
    1.30 +ALTER TABLE "vote" ADD COLUMN "first_preference" BOOLEAN;
    1.31 +
    1.32 +ALTER TABLE "vote" ADD
    1.33 +        CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
    1.34 +        CHECK ("grade" > 0 OR "first_preference" ISNULL);
    1.35 +
    1.36 +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.';
    1.37 + 
    1.38 +INSERT INTO "temporary_transaction_data" ("key", "value")
    1.39 +  VALUES ('override_protection_triggers', TRUE::TEXT);
    1.40 +
    1.41 +UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
    1.42 +  FROM (
    1.43 +    SELECT
    1.44 +      "vote"."initiative_id",
    1.45 +      "vote"."member_id",
    1.46 +      CASE WHEN "vote"."grade" > 0 THEN
    1.47 +        CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
    1.48 +      ELSE NULL
    1.49 +      END AS "first_preference"
    1.50 +    FROM "vote"
    1.51 +    JOIN "initiative"  -- NOTE: due to missing index on issue_id
    1.52 +    ON "vote"."issue_id" = "initiative"."issue_id"
    1.53 +    JOIN "vote" AS "agg"
    1.54 +    ON "initiative"."id" = "agg"."initiative_id"
    1.55 +    AND "vote"."member_id" = "agg"."member_id"
    1.56 +    GROUP BY "vote"."initiative_id", "vote"."member_id"
    1.57 +  ) AS "subquery"
    1.58 +  WHERE "vote"."initiative_id" = "subquery"."initiative_id"
    1.59 +  AND "vote"."member_id" = "subquery"."member_id";
    1.60 +
    1.61 +DELETE FROM "temporary_transaction_data"
    1.62 +  WHERE "key" = 'override_protection_triggers';
    1.63 +
    1.64 +UPDATE "initiative"
    1.65 +  SET "first_preference_votes" = coalesce("subquery"."sum", 0)
    1.66 +  FROM (
    1.67 +    SELECT "vote"."initiative_id", sum("direct_voter"."weight")
    1.68 +    FROM "vote" JOIN "direct_voter"
    1.69 +    ON "vote"."issue_id" = "direct_voter"."issue_id"
    1.70 +    AND "vote"."member_id" = "direct_voter"."member_id"
    1.71 +    WHERE "vote"."first_preference"
    1.72 +    GROUP BY "vote"."initiative_id"
    1.73 +  ) AS "subquery"
    1.74 +  WHERE "initiative"."admitted"
    1.75 +  AND "initiative"."id" = "subquery"."initiative_id";
    1.76 +
    1.77 +CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
    1.78 +  RETURNS VOID
    1.79 +  LANGUAGE 'plpgsql' VOLATILE AS $$
    1.80 +    DECLARE
    1.81 +      "area_id_v"   "area"."id"%TYPE;
    1.82 +      "unit_id_v"   "unit"."id"%TYPE;
    1.83 +      "member_id_v" "member"."id"%TYPE;
    1.84 +    BEGIN
    1.85 +      PERFORM "require_transaction_isolation"();
    1.86 +      SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
    1.87 +      SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
    1.88 +      -- override protection triggers:
    1.89 +      INSERT INTO "temporary_transaction_data" ("key", "value")
    1.90 +        VALUES ('override_protection_triggers', TRUE::TEXT);
    1.91 +      -- delete timestamp of voting comment:
    1.92 +      UPDATE "direct_voter" SET "comment_changed" = NULL
    1.93 +        WHERE "issue_id" = "issue_id_p";
    1.94 +      -- delete delegating votes (in cases of manual reset of issue state):
    1.95 +      DELETE FROM "delegating_voter"
    1.96 +        WHERE "issue_id" = "issue_id_p";
    1.97 +      -- delete votes from non-privileged voters:
    1.98 +      DELETE FROM "direct_voter"
    1.99 +        USING (
   1.100 +          SELECT
   1.101 +            "direct_voter"."member_id"
   1.102 +          FROM "direct_voter"
   1.103 +          JOIN "member" ON "direct_voter"."member_id" = "member"."id"
   1.104 +          LEFT JOIN "privilege"
   1.105 +          ON "privilege"."unit_id" = "unit_id_v"
   1.106 +          AND "privilege"."member_id" = "direct_voter"."member_id"
   1.107 +          WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
   1.108 +            "member"."active" = FALSE OR
   1.109 +            "privilege"."voting_right" ISNULL OR
   1.110 +            "privilege"."voting_right" = FALSE
   1.111 +          )
   1.112 +        ) AS "subquery"
   1.113 +        WHERE "direct_voter"."issue_id" = "issue_id_p"
   1.114 +        AND "direct_voter"."member_id" = "subquery"."member_id";
   1.115 +      -- consider delegations:
   1.116 +      UPDATE "direct_voter" SET "weight" = 1
   1.117 +        WHERE "issue_id" = "issue_id_p";
   1.118 +      PERFORM "add_vote_delegations"("issue_id_p");
   1.119 +      -- mark first preferences:
   1.120 +      UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
   1.121 +        FROM (
   1.122 +          SELECT
   1.123 +            "vote"."initiative_id",
   1.124 +            "vote"."member_id",
   1.125 +            CASE WHEN "vote"."grade" > 0 THEN
   1.126 +              CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
   1.127 +            ELSE NULL
   1.128 +            END AS "first_preference"
   1.129 +          FROM "vote"
   1.130 +          JOIN "initiative"  -- NOTE: due to missing index on issue_id
   1.131 +          ON "vote"."issue_id" = "initiative"."issue_id"
   1.132 +          JOIN "vote" AS "agg"
   1.133 +          ON "initiative"."id" = "agg"."initiative_id"
   1.134 +          AND "vote"."member_id" = "agg"."member_id"
   1.135 +          GROUP BY "vote"."initiative_id", "vote"."member_id"
   1.136 +        ) AS "subquery"
   1.137 +        WHERE "vote"."issue_id" = "issue_id_p"
   1.138 +        AND "vote"."initiative_id" = "subquery"."initiative_id"
   1.139 +        AND "vote"."member_id" = "subquery"."member_id";
   1.140 +      -- finish overriding protection triggers (avoids garbage):
   1.141 +      DELETE FROM "temporary_transaction_data"
   1.142 +        WHERE "key" = 'override_protection_triggers';
   1.143 +      -- materialize battle_view:
   1.144 +      -- NOTE: "closed" column of issue must be set at this point
   1.145 +      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
   1.146 +      INSERT INTO "battle" (
   1.147 +        "issue_id",
   1.148 +        "winning_initiative_id", "losing_initiative_id",
   1.149 +        "count"
   1.150 +      ) SELECT
   1.151 +        "issue_id",
   1.152 +        "winning_initiative_id", "losing_initiative_id",
   1.153 +        "count"
   1.154 +        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
   1.155 +      -- set voter count:
   1.156 +      UPDATE "issue" SET
   1.157 +        "voter_count" = (
   1.158 +          SELECT coalesce(sum("weight"), 0)
   1.159 +          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
   1.160 +        )
   1.161 +        WHERE "id" = "issue_id_p";
   1.162 +      -- calculate "first_preference_votes":
   1.163 +      UPDATE "initiative"
   1.164 +        SET "first_preference_votes" = coalesce("subquery"."sum", 0)
   1.165 +        FROM (
   1.166 +          SELECT "vote"."initiative_id", sum("direct_voter"."weight")
   1.167 +          FROM "vote" JOIN "direct_voter"
   1.168 +          ON "vote"."issue_id" = "direct_voter"."issue_id"
   1.169 +          AND "vote"."member_id" = "direct_voter"."member_id"
   1.170 +          WHERE "vote"."first_preference"
   1.171 +          GROUP BY "vote"."initiative_id"
   1.172 +        ) AS "subquery"
   1.173 +        WHERE "initiative"."issue_id" = "issue_id_p"
   1.174 +        AND "initiative"."admitted"
   1.175 +        AND "initiative"."id" = "subquery"."initiative_id";
   1.176 +      -- copy "positive_votes" and "negative_votes" from "battle" table:
   1.177 +      UPDATE "initiative" SET
   1.178 +        "positive_votes" = "battle_win"."count",
   1.179 +        "negative_votes" = "battle_lose"."count"
   1.180 +        FROM "battle" AS "battle_win", "battle" AS "battle_lose"
   1.181 +        WHERE
   1.182 +          "battle_win"."issue_id" = "issue_id_p" AND
   1.183 +          "battle_win"."winning_initiative_id" = "initiative"."id" AND
   1.184 +          "battle_win"."losing_initiative_id" ISNULL AND
   1.185 +          "battle_lose"."issue_id" = "issue_id_p" AND
   1.186 +          "battle_lose"."losing_initiative_id" = "initiative"."id" AND
   1.187 +          "battle_lose"."winning_initiative_id" ISNULL;
   1.188 +    END;
   1.189 +  $$;
   1.190 +
   1.191 +COMMIT;

Impressum / About Us