liquid_feedback_core
view 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 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 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
    75   RETURNS VOID
    76   LANGUAGE 'plpgsql' VOLATILE AS $$
    77     DECLARE
    78       "area_id_v"   "area"."id"%TYPE;
    79       "unit_id_v"   "unit"."id"%TYPE;
    80       "member_id_v" "member"."id"%TYPE;
    81     BEGIN
    82       PERFORM "require_transaction_isolation"();
    83       SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
    84       SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
    85       -- override protection triggers:
    86       INSERT INTO "temporary_transaction_data" ("key", "value")
    87         VALUES ('override_protection_triggers', TRUE::TEXT);
    88       -- delete timestamp of voting comment:
    89       UPDATE "direct_voter" SET "comment_changed" = NULL
    90         WHERE "issue_id" = "issue_id_p";
    91       -- delete delegating votes (in cases of manual reset of issue state):
    92       DELETE FROM "delegating_voter"
    93         WHERE "issue_id" = "issue_id_p";
    94       -- delete votes from non-privileged voters:
    95       DELETE FROM "direct_voter"
    96         USING (
    97           SELECT
    98             "direct_voter"."member_id"
    99           FROM "direct_voter"
   100           JOIN "member" ON "direct_voter"."member_id" = "member"."id"
   101           LEFT JOIN "privilege"
   102           ON "privilege"."unit_id" = "unit_id_v"
   103           AND "privilege"."member_id" = "direct_voter"."member_id"
   104           WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
   105             "member"."active" = FALSE OR
   106             "privilege"."voting_right" ISNULL OR
   107             "privilege"."voting_right" = FALSE
   108           )
   109         ) AS "subquery"
   110         WHERE "direct_voter"."issue_id" = "issue_id_p"
   111         AND "direct_voter"."member_id" = "subquery"."member_id";
   112       -- consider delegations:
   113       UPDATE "direct_voter" SET "weight" = 1
   114         WHERE "issue_id" = "issue_id_p";
   115       PERFORM "add_vote_delegations"("issue_id_p");
   116       -- mark first preferences:
   117       UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
   118         FROM (
   119           SELECT
   120             "vote"."initiative_id",
   121             "vote"."member_id",
   122             CASE WHEN "vote"."grade" > 0 THEN
   123               CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
   124             ELSE NULL
   125             END AS "first_preference"
   126           FROM "vote"
   127           JOIN "initiative"  -- NOTE: due to missing index on issue_id
   128           ON "vote"."issue_id" = "initiative"."issue_id"
   129           JOIN "vote" AS "agg"
   130           ON "initiative"."id" = "agg"."initiative_id"
   131           AND "vote"."member_id" = "agg"."member_id"
   132           GROUP BY "vote"."initiative_id", "vote"."member_id"
   133         ) AS "subquery"
   134         WHERE "vote"."issue_id" = "issue_id_p"
   135         AND "vote"."initiative_id" = "subquery"."initiative_id"
   136         AND "vote"."member_id" = "subquery"."member_id";
   137       -- finish overriding protection triggers (avoids garbage):
   138       DELETE FROM "temporary_transaction_data"
   139         WHERE "key" = 'override_protection_triggers';
   140       -- materialize battle_view:
   141       -- NOTE: "closed" column of issue must be set at this point
   142       DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
   143       INSERT INTO "battle" (
   144         "issue_id",
   145         "winning_initiative_id", "losing_initiative_id",
   146         "count"
   147       ) SELECT
   148         "issue_id",
   149         "winning_initiative_id", "losing_initiative_id",
   150         "count"
   151         FROM "battle_view" WHERE "issue_id" = "issue_id_p";
   152       -- set voter count:
   153       UPDATE "issue" SET
   154         "voter_count" = (
   155           SELECT coalesce(sum("weight"), 0)
   156           FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
   157         )
   158         WHERE "id" = "issue_id_p";
   159       -- calculate "first_preference_votes":
   160       UPDATE "initiative"
   161         SET "first_preference_votes" = coalesce("subquery"."sum", 0)
   162         FROM (
   163           SELECT "vote"."initiative_id", sum("direct_voter"."weight")
   164           FROM "vote" JOIN "direct_voter"
   165           ON "vote"."issue_id" = "direct_voter"."issue_id"
   166           AND "vote"."member_id" = "direct_voter"."member_id"
   167           WHERE "vote"."first_preference"
   168           GROUP BY "vote"."initiative_id"
   169         ) AS "subquery"
   170         WHERE "initiative"."issue_id" = "issue_id_p"
   171         AND "initiative"."admitted"
   172         AND "initiative"."id" = "subquery"."initiative_id";
   173       -- copy "positive_votes" and "negative_votes" from "battle" table:
   174       UPDATE "initiative" SET
   175         "positive_votes" = "battle_win"."count",
   176         "negative_votes" = "battle_lose"."count"
   177         FROM "battle" AS "battle_win", "battle" AS "battle_lose"
   178         WHERE
   179           "battle_win"."issue_id" = "issue_id_p" AND
   180           "battle_win"."winning_initiative_id" = "initiative"."id" AND
   181           "battle_win"."losing_initiative_id" ISNULL AND
   182           "battle_lose"."issue_id" = "issue_id_p" AND
   183           "battle_lose"."losing_initiative_id" = "initiative"."id" AND
   184           "battle_lose"."winning_initiative_id" ISNULL;
   185     END;
   186   $$;
   188 COMMIT;
