liquid_feedback_core
view update/core-update.v2.2.1-v2.2.2.sql @ 398:806561cce3b1
New table "issue_order" for ordering fields to avoid a bottleneck with locking
| author | jbe | 
|---|---|
| date | Fri Oct 11 20:07:41 2013 +0200 (2013-10-11) | 
| parents | 1c991490f075 | 
| children | 
 line source
     1 BEGIN;
     3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     4   SELECT * FROM (VALUES ('2.2.2', 2, 2, 2))
     5   AS "subquery"("string", "major", "minor", "revision");
     7 CREATE TABLE "internal_session_store" (
     8         PRIMARY KEY ("backend_pid", "key"),
     9         "backend_pid"           INT4,
    10         "key"                   TEXT,
    11         "value"                 TEXT            NOT NULL );
    13 COMMENT ON TABLE "internal_session_store" IS 'Table to store session variables; shall be emptied before a transaction is committed';
    15 COMMENT ON COLUMN "internal_session_store"."backend_pid" IS 'Value returned by function pg_backend_pid()';
    17 CREATE OR REPLACE FUNCTION "forbid_changes_on_closed_issue_trigger"()
    18   RETURNS TRIGGER
    19   LANGUAGE 'plpgsql' VOLATILE AS $$
    20     DECLARE
    21       "issue_id_v" "issue"."id"%TYPE;
    22       "issue_row"  "issue"%ROWTYPE;
    23     BEGIN
    24       IF EXISTS (
    25         SELECT NULL FROM "internal_session_store"
    26         WHERE "backend_pid" = pg_backend_pid()
    27         AND "key" = 'override_protection_triggers'
    28         AND "value" = TRUE::TEXT
    29       ) THEN
    30         RETURN NULL;
    31       END IF;
    32       IF TG_OP = 'DELETE' THEN
    33         "issue_id_v" := OLD."issue_id";
    34       ELSE
    35         "issue_id_v" := NEW."issue_id";
    36       END IF;
    37       SELECT INTO "issue_row" * FROM "issue"
    38         WHERE "id" = "issue_id_v" FOR SHARE;
    39       IF (
    40         "issue_row"."closed" NOTNULL OR (
    41           "issue_row"."state" = 'voting' AND
    42           "issue_row"."phase_finished" NOTNULL
    43         )
    44       ) THEN
    45         IF
    46           TG_RELID = 'direct_voter'::regclass AND
    47           TG_OP = 'UPDATE'
    48         THEN
    49           IF
    50             OLD."issue_id"  = NEW."issue_id"  AND
    51             OLD."member_id" = NEW."member_id" AND
    52             OLD."weight" = NEW."weight"
    53           THEN
    54             RETURN NULL;  -- allows changing of voter comment
    55           END IF;
    56         END IF;
    57         RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
    58       END IF;
    59       RETURN NULL;
    60     END;
    61   $$;
    63 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
    64   RETURNS VOID
    65   LANGUAGE 'plpgsql' VOLATILE AS $$
    66     DECLARE
    67       "area_id_v"   "area"."id"%TYPE;
    68       "unit_id_v"   "unit"."id"%TYPE;
    69       "member_id_v" "member"."id"%TYPE;
    70     BEGIN
    71       PERFORM "require_transaction_isolation"();
    72       SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
    73       SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
    74       -- override protection triggers:
    75       DELETE FROM "internal_session_store";
    76       INSERT INTO "internal_session_store" ("backend_pid", "key", "value")
    77         VALUES (pg_backend_pid(), 'override_protection_triggers', TRUE::TEXT);
    78       -- delete timestamp of voting comment:
    79       UPDATE "direct_voter" SET "comment_changed" = NULL
    80         WHERE "issue_id" = "issue_id_p";
    81       -- delete delegating votes (in cases of manual reset of issue state):
    82       DELETE FROM "delegating_voter"
    83         WHERE "issue_id" = "issue_id_p";
    84       -- delete votes from non-privileged voters:
    85       DELETE FROM "direct_voter"
    86         USING (
    87           SELECT
    88             "direct_voter"."member_id"
    89           FROM "direct_voter"
    90           JOIN "member" ON "direct_voter"."member_id" = "member"."id"
    91           LEFT JOIN "privilege"
    92           ON "privilege"."unit_id" = "unit_id_v"
    93           AND "privilege"."member_id" = "direct_voter"."member_id"
    94           WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
    95             "member"."active" = FALSE OR
    96             "privilege"."voting_right" ISNULL OR
    97             "privilege"."voting_right" = FALSE
    98           )
    99         ) AS "subquery"
   100         WHERE "direct_voter"."issue_id" = "issue_id_p"
   101         AND "direct_voter"."member_id" = "subquery"."member_id";
   102       -- consider delegations:
   103       UPDATE "direct_voter" SET "weight" = 1
   104         WHERE "issue_id" = "issue_id_p";
   105       PERFORM "add_vote_delegations"("issue_id_p");
   106       -- finish overriding protection triggers (mandatory, as pids may be reused):
   107       DELETE FROM "internal_session_store";
   108       -- materialize battle_view:
   109       -- NOTE: "closed" column of issue must be set at this point
   110       DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
   111       INSERT INTO "battle" (
   112         "issue_id",
   113         "winning_initiative_id", "losing_initiative_id",
   114         "count"
   115       ) SELECT
   116         "issue_id",
   117         "winning_initiative_id", "losing_initiative_id",
   118         "count"
   119         FROM "battle_view" WHERE "issue_id" = "issue_id_p";
   120       -- set voter count:
   121       UPDATE "issue" SET
   122         "voter_count" = (
   123           SELECT coalesce(sum("weight"), 0)
   124           FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
   125         )
   126         WHERE "id" = "issue_id_p";
   127       -- copy "positive_votes" and "negative_votes" from "battle" table:
   128       UPDATE "initiative" SET
   129         "positive_votes" = "battle_win"."count",
   130         "negative_votes" = "battle_lose"."count"
   131         FROM "battle" AS "battle_win", "battle" AS "battle_lose"
   132         WHERE
   133           "battle_win"."issue_id" = "issue_id_p" AND
   134           "battle_win"."winning_initiative_id" = "initiative"."id" AND
   135           "battle_win"."losing_initiative_id" ISNULL AND
   136           "battle_lose"."issue_id" = "issue_id_p" AND
   137           "battle_lose"."losing_initiative_id" = "initiative"."id" AND
   138           "battle_lose"."winning_initiative_id" ISNULL;
   139     END;
   140   $$;
   142 COMMIT;
