liquid_feedback_core

diff update/core-update.v1.2.1-v1.2.2.sql @ 61:598af132a6f9

Save battle data from calls of "clean_issue"("issue"."id")

Details:
- Calling "clean_issue" is also allowed before ranks are calculated
- View "battle" was renamed to "battle_view"
- "battle_view" only contains entries for closed issues
- New table "battle", which is filled when an issue is closed
- Version change to v1.2.2
- Update script to v1.2.2 materializes battles of existent (closed) issues
author jbe
date Tue Jul 20 00:53:30 2010 +0200 (2010-07-20)
parents
children
line diff
     1.1 --- /dev/null	Thu Jan 01 00:00:00 1970 +0000
     1.2 +++ b/update/core-update.v1.2.1-v1.2.2.sql	Tue Jul 20 00:53:30 2010 +0200
     1.3 @@ -0,0 +1,204 @@
     1.4 +BEGIN;
     1.5 +
     1.6 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     1.7 +  SELECT * FROM (VALUES ('1.2.2', 1, 2, 2))
     1.8 +  AS "subquery"("string", "major", "minor", "revision");
     1.9 +
    1.10 +ALTER TABLE "issue" DROP CONSTRAINT "clean_restriction";
    1.11 +
    1.12 +ALTER TABLE "issue" ADD CONSTRAINT "only_closed_issues_may_be_cleaned"
    1.13 +  CHECK ("cleaned" ISNULL OR "closed" NOTNULL);
    1.14 +
    1.15 +ALTER VIEW "battle" RENAME TO "battle_view";
    1.16 +
    1.17 +CREATE TABLE "battle" (
    1.18 +        PRIMARY KEY ("issue_id", "winning_initiative_id", "losing_initiative_id"),
    1.19 +        "issue_id"              INT4,
    1.20 +        "winning_initiative_id" INT4,
    1.21 +        FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
    1.22 +        "losing_initiative_id"  INT4,
    1.23 +        FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
    1.24 +        "count"                 INT4            NOT NULL);
    1.25 +
    1.26 +COMMENT ON TABLE "battle" IS 'Number of members preferring one initiative to another; Filled by "battle_view" when closing an issue';
    1.27 +
    1.28 +CREATE OR REPLACE VIEW "battle_view" AS
    1.29 +  SELECT
    1.30 +    "issue"."id" AS "issue_id",
    1.31 +    "winning_initiative"."id" AS "winning_initiative_id",
    1.32 +    "losing_initiative"."id" AS "losing_initiative_id",
    1.33 +    sum(
    1.34 +      CASE WHEN
    1.35 +        coalesce("better_vote"."grade", 0) >
    1.36 +        coalesce("worse_vote"."grade", 0)
    1.37 +      THEN "direct_voter"."weight" ELSE 0 END
    1.38 +    ) AS "count"
    1.39 +  FROM "issue"
    1.40 +  LEFT JOIN "direct_voter"
    1.41 +  ON "issue"."id" = "direct_voter"."issue_id"
    1.42 +  JOIN "initiative" AS "winning_initiative"
    1.43 +    ON "issue"."id" = "winning_initiative"."issue_id"
    1.44 +    AND "winning_initiative"."agreed"
    1.45 +  JOIN "initiative" AS "losing_initiative"
    1.46 +    ON "issue"."id" = "losing_initiative"."issue_id"
    1.47 +    AND "losing_initiative"."agreed"
    1.48 +  LEFT JOIN "vote" AS "better_vote"
    1.49 +    ON "direct_voter"."member_id" = "better_vote"."member_id"
    1.50 +    AND "winning_initiative"."id" = "better_vote"."initiative_id"
    1.51 +  LEFT JOIN "vote" AS "worse_vote"
    1.52 +    ON "direct_voter"."member_id" = "worse_vote"."member_id"
    1.53 +    AND "losing_initiative"."id" = "worse_vote"."initiative_id"
    1.54 +  WHERE "issue"."closed" NOTNULL
    1.55 +  AND "issue"."cleaned" ISNULL
    1.56 +  AND "winning_initiative"."id" != "losing_initiative"."id"
    1.57 +  GROUP BY
    1.58 +    "issue"."id",
    1.59 +    "winning_initiative"."id",
    1.60 +    "losing_initiative"."id";
    1.61 +
    1.62 +COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative to another; Used to fill "battle" table';
    1.63 +
    1.64 +INSERT INTO "battle" (
    1.65 +  "issue_id",
    1.66 +  "winning_initiative_id",
    1.67 +  "losing_initiative_id",
    1.68 +  "count"
    1.69 +) SELECT
    1.70 +  "issue_id",
    1.71 +  "winning_initiative_id", "losing_initiative_id",
    1.72 +  "count"
    1.73 +  FROM "battle_view";
    1.74 +
    1.75 +CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
    1.76 +  RETURNS VOID
    1.77 +  LANGUAGE 'plpgsql' VOLATILE AS $$
    1.78 +    DECLARE
    1.79 +      "issue_row"   "issue"%ROWTYPE;
    1.80 +      "member_id_v" "member"."id"%TYPE;
    1.81 +    BEGIN
    1.82 +      PERFORM "global_lock"();
    1.83 +      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
    1.84 +      DELETE FROM "delegating_voter"
    1.85 +        WHERE "issue_id" = "issue_id_p";
    1.86 +      DELETE FROM "direct_voter"
    1.87 +        WHERE "issue_id" = "issue_id_p"
    1.88 +        AND "autoreject" = TRUE;
    1.89 +      DELETE FROM "direct_voter" USING "member"
    1.90 +        WHERE "direct_voter"."member_id" = "member"."id"
    1.91 +        AND "direct_voter"."issue_id" = "issue_id_p"
    1.92 +        AND "member"."active" = FALSE;
    1.93 +      UPDATE "direct_voter" SET "weight" = 1
    1.94 +        WHERE "issue_id" = "issue_id_p";
    1.95 +      PERFORM "add_vote_delegations"("issue_id_p");
    1.96 +      FOR "member_id_v" IN
    1.97 +        SELECT "interest"."member_id"
    1.98 +          FROM "interest"
    1.99 +          LEFT JOIN "direct_voter"
   1.100 +            ON "interest"."member_id" = "direct_voter"."member_id"
   1.101 +            AND "interest"."issue_id" = "direct_voter"."issue_id"
   1.102 +          LEFT JOIN "delegating_voter"
   1.103 +            ON "interest"."member_id" = "delegating_voter"."member_id"
   1.104 +            AND "interest"."issue_id" = "delegating_voter"."issue_id"
   1.105 +          WHERE "interest"."issue_id" = "issue_id_p"
   1.106 +          AND "interest"."autoreject" = TRUE
   1.107 +          AND "direct_voter"."member_id" ISNULL
   1.108 +          AND "delegating_voter"."member_id" ISNULL
   1.109 +        UNION SELECT "membership"."member_id"
   1.110 +          FROM "membership"
   1.111 +          LEFT JOIN "interest"
   1.112 +            ON "membership"."member_id" = "interest"."member_id"
   1.113 +            AND "interest"."issue_id" = "issue_id_p"
   1.114 +          LEFT JOIN "direct_voter"
   1.115 +            ON "membership"."member_id" = "direct_voter"."member_id"
   1.116 +            AND "direct_voter"."issue_id" = "issue_id_p"
   1.117 +          LEFT JOIN "delegating_voter"
   1.118 +            ON "membership"."member_id" = "delegating_voter"."member_id"
   1.119 +            AND "delegating_voter"."issue_id" = "issue_id_p"
   1.120 +          WHERE "membership"."area_id" = "issue_row"."area_id"
   1.121 +          AND "membership"."autoreject" = TRUE
   1.122 +          AND "interest"."autoreject" ISNULL
   1.123 +          AND "direct_voter"."member_id" ISNULL
   1.124 +          AND "delegating_voter"."member_id" ISNULL
   1.125 +      LOOP
   1.126 +        INSERT INTO "direct_voter"
   1.127 +          ("member_id", "issue_id", "weight", "autoreject") VALUES
   1.128 +          ("member_id_v", "issue_id_p", 1, TRUE);
   1.129 +        INSERT INTO "vote" (
   1.130 +          "member_id",
   1.131 +          "issue_id",
   1.132 +          "initiative_id",
   1.133 +          "grade"
   1.134 +          ) SELECT
   1.135 +            "member_id_v" AS "member_id",
   1.136 +            "issue_id_p"  AS "issue_id",
   1.137 +            "id"          AS "initiative_id",
   1.138 +            -1            AS "grade"
   1.139 +          FROM "initiative" WHERE "issue_id" = "issue_id_p";
   1.140 +      END LOOP;
   1.141 +      PERFORM "add_vote_delegations"("issue_id_p");
   1.142 +      UPDATE "issue" SET
   1.143 +        "closed" = now(),
   1.144 +        "voter_count" = (
   1.145 +          SELECT coalesce(sum("weight"), 0)
   1.146 +          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
   1.147 +        )
   1.148 +        WHERE "id" = "issue_id_p";
   1.149 +      UPDATE "initiative" SET
   1.150 +        "positive_votes" = "vote_counts"."positive_votes",
   1.151 +        "negative_votes" = "vote_counts"."negative_votes",
   1.152 +        "agreed" = CASE WHEN "majority_strict" THEN
   1.153 +          "vote_counts"."positive_votes" * "majority_den" >
   1.154 +          "majority_num" *
   1.155 +          ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
   1.156 +        ELSE
   1.157 +          "vote_counts"."positive_votes" * "majority_den" >=
   1.158 +          "majority_num" *
   1.159 +          ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
   1.160 +        END
   1.161 +        FROM
   1.162 +          ( SELECT
   1.163 +              "initiative"."id" AS "initiative_id",
   1.164 +              coalesce(
   1.165 +                sum(
   1.166 +                  CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
   1.167 +                ),
   1.168 +                0
   1.169 +              ) AS "positive_votes",
   1.170 +              coalesce(
   1.171 +                sum(
   1.172 +                  CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
   1.173 +                ),
   1.174 +                0
   1.175 +              ) AS "negative_votes"
   1.176 +            FROM "initiative"
   1.177 +            JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
   1.178 +            JOIN "policy" ON "issue"."policy_id" = "policy"."id"
   1.179 +            LEFT JOIN "direct_voter"
   1.180 +              ON "direct_voter"."issue_id" = "initiative"."issue_id"
   1.181 +            LEFT JOIN "vote"
   1.182 +              ON "vote"."initiative_id" = "initiative"."id"
   1.183 +              AND "vote"."member_id" = "direct_voter"."member_id"
   1.184 +            WHERE "initiative"."issue_id" = "issue_id_p"
   1.185 +            AND "initiative"."admitted"  -- NOTE: NULL case is handled too
   1.186 +            GROUP BY "initiative"."id"
   1.187 +          ) AS "vote_counts",
   1.188 +          "issue",
   1.189 +          "policy"
   1.190 +        WHERE "vote_counts"."initiative_id" = "initiative"."id"
   1.191 +        AND "issue"."id" = "initiative"."issue_id"
   1.192 +        AND "policy"."id" = "issue"."policy_id";
   1.193 +      -- NOTE: "closed" column of issue must be set at this point
   1.194 +      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
   1.195 +      INSERT INTO "battle" (
   1.196 +        "issue_id",
   1.197 +        "winning_initiative_id", "losing_initiative_id",
   1.198 +        "count"
   1.199 +      ) SELECT
   1.200 +        "issue_id",
   1.201 +        "winning_initiative_id", "losing_initiative_id",
   1.202 +        "count"
   1.203 +        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
   1.204 +    END;
   1.205 +  $$;
   1.206 +
   1.207 +COMMIT;

Impressum / About Us