liquid_feedback_core

diff update/core-update.v3.0.1-v3.0.2.sql @ 433:603f6e4bbedf

Bugfix in "close_voting" function that only affected PostgreSQL versions prior 9.1
author jbe
date Wed Jun 11 00:34:12 2014 +0200 (2014-06-11)
parents 5676b0d33833
children
line diff
     1.1 --- a/update/core-update.v3.0.1-v3.0.2.sql	Thu May 22 12:40:30 2014 +0200
     1.2 +++ b/update/core-update.v3.0.1-v3.0.2.sql	Wed Jun 11 00:34:12 2014 +0200
     1.3 @@ -28,6 +28,121 @@
     1.4  COMMENT ON COLUMN "initiative"."reverse_beat_path"      IS 'TRUE, if there is a beat path (may include ties) from this initiative to the status quo; set to NULL if "policy"."defeat_strength" is set to ''simple''';
     1.5   
     1.6  
     1.7 +CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
     1.8 +  RETURNS VOID
     1.9 +  LANGUAGE 'plpgsql' VOLATILE AS $$
    1.10 +    DECLARE
    1.11 +      "area_id_v"   "area"."id"%TYPE;
    1.12 +      "unit_id_v"   "unit"."id"%TYPE;
    1.13 +      "member_id_v" "member"."id"%TYPE;
    1.14 +    BEGIN
    1.15 +      PERFORM "require_transaction_isolation"();
    1.16 +      SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
    1.17 +      SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
    1.18 +      -- override protection triggers:
    1.19 +      INSERT INTO "temporary_transaction_data" ("key", "value")
    1.20 +        VALUES ('override_protection_triggers', TRUE::TEXT);
    1.21 +      -- delete timestamp of voting comment:
    1.22 +      UPDATE "direct_voter" SET "comment_changed" = NULL
    1.23 +        WHERE "issue_id" = "issue_id_p";
    1.24 +      -- delete delegating votes (in cases of manual reset of issue state):
    1.25 +      DELETE FROM "delegating_voter"
    1.26 +        WHERE "issue_id" = "issue_id_p";
    1.27 +      -- delete votes from non-privileged voters:
    1.28 +      DELETE FROM "direct_voter"
    1.29 +        USING (
    1.30 +          SELECT
    1.31 +            "direct_voter"."member_id"
    1.32 +          FROM "direct_voter"
    1.33 +          JOIN "member" ON "direct_voter"."member_id" = "member"."id"
    1.34 +          LEFT JOIN "privilege"
    1.35 +          ON "privilege"."unit_id" = "unit_id_v"
    1.36 +          AND "privilege"."member_id" = "direct_voter"."member_id"
    1.37 +          WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
    1.38 +            "member"."active" = FALSE OR
    1.39 +            "privilege"."voting_right" ISNULL OR
    1.40 +            "privilege"."voting_right" = FALSE
    1.41 +          )
    1.42 +        ) AS "subquery"
    1.43 +        WHERE "direct_voter"."issue_id" = "issue_id_p"
    1.44 +        AND "direct_voter"."member_id" = "subquery"."member_id";
    1.45 +      -- consider delegations:
    1.46 +      UPDATE "direct_voter" SET "weight" = 1
    1.47 +        WHERE "issue_id" = "issue_id_p";
    1.48 +      PERFORM "add_vote_delegations"("issue_id_p");
    1.49 +      -- mark first preferences:
    1.50 +      UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
    1.51 +        FROM (
    1.52 +          SELECT
    1.53 +            "vote"."initiative_id",
    1.54 +            "vote"."member_id",
    1.55 +            CASE WHEN "vote"."grade" > 0 THEN
    1.56 +              CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
    1.57 +            ELSE NULL
    1.58 +            END AS "first_preference"
    1.59 +          FROM "vote"
    1.60 +          JOIN "initiative"  -- NOTE: due to missing index on issue_id
    1.61 +          ON "vote"."issue_id" = "initiative"."issue_id"
    1.62 +          JOIN "vote" AS "agg"
    1.63 +          ON "initiative"."id" = "agg"."initiative_id"
    1.64 +          AND "vote"."member_id" = "agg"."member_id"
    1.65 +          GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
    1.66 +        ) AS "subquery"
    1.67 +        WHERE "vote"."issue_id" = "issue_id_p"
    1.68 +        AND "vote"."initiative_id" = "subquery"."initiative_id"
    1.69 +        AND "vote"."member_id" = "subquery"."member_id";
    1.70 +      -- finish overriding protection triggers (avoids garbage):
    1.71 +      DELETE FROM "temporary_transaction_data"
    1.72 +        WHERE "key" = 'override_protection_triggers';
    1.73 +      -- materialize battle_view:
    1.74 +      -- NOTE: "closed" column of issue must be set at this point
    1.75 +      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
    1.76 +      INSERT INTO "battle" (
    1.77 +        "issue_id",
    1.78 +        "winning_initiative_id", "losing_initiative_id",
    1.79 +        "count"
    1.80 +      ) SELECT
    1.81 +        "issue_id",
    1.82 +        "winning_initiative_id", "losing_initiative_id",
    1.83 +        "count"
    1.84 +        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
    1.85 +      -- set voter count:
    1.86 +      UPDATE "issue" SET
    1.87 +        "voter_count" = (
    1.88 +          SELECT coalesce(sum("weight"), 0)
    1.89 +          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
    1.90 +        )
    1.91 +        WHERE "id" = "issue_id_p";
    1.92 +      -- calculate "first_preference_votes":
    1.93 +      UPDATE "initiative"
    1.94 +        SET "first_preference_votes" = coalesce("subquery"."sum", 0)
    1.95 +        FROM (
    1.96 +          SELECT "vote"."initiative_id", sum("direct_voter"."weight")
    1.97 +          FROM "vote" JOIN "direct_voter"
    1.98 +          ON "vote"."issue_id" = "direct_voter"."issue_id"
    1.99 +          AND "vote"."member_id" = "direct_voter"."member_id"
   1.100 +          WHERE "vote"."first_preference"
   1.101 +          GROUP BY "vote"."initiative_id"
   1.102 +        ) AS "subquery"
   1.103 +        WHERE "initiative"."issue_id" = "issue_id_p"
   1.104 +        AND "initiative"."admitted"
   1.105 +        AND "initiative"."id" = "subquery"."initiative_id";
   1.106 +      -- copy "positive_votes" and "negative_votes" from "battle" table:
   1.107 +      UPDATE "initiative" SET
   1.108 +        "positive_votes" = "battle_win"."count",
   1.109 +        "negative_votes" = "battle_lose"."count"
   1.110 +        FROM "battle" AS "battle_win", "battle" AS "battle_lose"
   1.111 +        WHERE
   1.112 +          "battle_win"."issue_id" = "issue_id_p" AND
   1.113 +          "battle_win"."winning_initiative_id" = "initiative"."id" AND
   1.114 +          "battle_win"."losing_initiative_id" ISNULL AND
   1.115 +          "battle_lose"."issue_id" = "issue_id_p" AND
   1.116 +          "battle_lose"."losing_initiative_id" = "initiative"."id" AND
   1.117 +          "battle_lose"."winning_initiative_id" ISNULL;
   1.118 +    END;
   1.119 +  $$;
   1.120 +
   1.121 +
   1.122  DROP FUNCTION "calculate_ranks"("issue"."id"%TYPE);
   1.123  DROP FUNCTION "defeat_strength"(INT4, INT4);
   1.124  

Impressum / About Us