| rev | 
   line source | 
| 
jbe@615
 | 
     1 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
 | 
| 
jbe@615
 | 
     2   SELECT * FROM (VALUES ('4.2.1-incomplete-update', 4, 2, -1))
 | 
| 
jbe@615
 | 
     3   AS "subquery"("string", "major", "minor", "revision");
 | 
| 
jbe@615
 | 
     4 
 | 
| 
jbe@615
 | 
     5 BEGIN;
 | 
| 
jbe@615
 | 
     6 
 | 
| 
jbe@615
 | 
     7 ALTER TABLE "unit" ADD COLUMN "member_weight" INT4;
 | 
| 
jbe@615
 | 
     8 COMMENT ON COLUMN "unit"."member_weight" IS 'Sum of active members'' voting weight';
 | 
| 
jbe@615
 | 
     9 
 | 
| 
jbe@615
 | 
    10 ALTER TABLE "snapshot_population" ADD COLUMN "weight" INT4 NOT NULL DEFAULT 1;
 | 
| 
jbe@615
 | 
    11 ALTER TABLE "snapshot_population" ALTER COLUMN "weight" DROP DEFAULT;
 | 
| 
jbe@615
 | 
    12  
 | 
| 
jbe@615
 | 
    13 ALTER TABLE "privilege" ADD COLUMN "weight" INT4 NOT NULL DEFAULT 1 CHECK ("weight" >= 0);
 | 
| 
jbe@615
 | 
    14 COMMENT ON COLUMN "privilege"."weight"           IS 'Voting weight of member in unit';
 | 
| 
jbe@615
 | 
    15 
 | 
| 
jbe@615
 | 
    16 CREATE TABLE "issue_privilege" (
 | 
| 
jbe@615
 | 
    17         PRIMARY KEY ("issue_id", "member_id"),
 | 
| 
jbe@615
 | 
    18         "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
 | 
| 
jbe@615
 | 
    19         "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
 | 
| 
jbe@615
 | 
    20         "initiative_right"      BOOLEAN,
 | 
| 
jbe@615
 | 
    21         "voting_right"          BOOLEAN,
 | 
| 
jbe@615
 | 
    22         "polling_right"         BOOLEAN,
 | 
| 
jbe@615
 | 
    23         "weight"                INT4            CHECK ("weight" >= 0) );
 | 
| 
jbe@615
 | 
    24 CREATE INDEX "issue_privilege_idx" ON "issue_privilege" ("member_id");
 | 
| 
jbe@615
 | 
    25 COMMENT ON TABLE "issue_privilege" IS 'Override of "privilege" table for rights of members in certain issues';
 | 
| 
jbe@615
 | 
    26  
 | 
| 
jbe@615
 | 
    27 ALTER TABLE "direct_interest_snapshot" ADD COLUMN "ownweight" INT4 NOT NULL DEFAULT 1;
 | 
| 
jbe@615
 | 
    28 ALTER TABLE "direct_interest_snapshot" ALTER COLUMN "ownweight" DROP DEFAULT;
 | 
| 
jbe@615
 | 
    29 COMMENT ON COLUMN "direct_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations';
 | 
| 
jbe@615
 | 
    30 COMMENT ON COLUMN "direct_interest_snapshot"."weight"    IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"';
 | 
| 
jbe@615
 | 
    31  
 | 
| 
jbe@615
 | 
    32 ALTER TABLE "delegating_interest_snapshot" ADD COLUMN "ownweight" INT4 NOT NULL DEFAULT 1;
 | 
| 
jbe@615
 | 
    33 ALTER TABLE "delegating_interest_snapshot" ALTER COLUMN "ownweight" DROP DEFAULT;
 | 
| 
jbe@615
 | 
    34 COMMENT ON COLUMN "delegating_interest_snapshot"."ownweight" IS 'Own voting weight of member, disregading delegations';
 | 
| 
jbe@615
 | 
    35 COMMENT ON COLUMN "delegating_interest_snapshot"."weight"    IS 'Intermediate voting weight considering incoming delegations';
 | 
| 
jbe@615
 | 
    36 
 | 
| 
jbe@615
 | 
    37 ALTER TABLE "direct_voter" ADD COLUMN "ownweight" INT4 DEFAULT 1;
 | 
| 
jbe@615
 | 
    38 ALTER TABLE "direct_voter" ALTER COLUMN "ownweight" DROP DEFAULT;
 | 
| 
jbe@615
 | 
    39 COMMENT ON COLUMN "direct_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations';
 | 
| 
jbe@615
 | 
    40 COMMENT ON COLUMN "direct_voter"."weight"    IS 'Voting weight of member according to own weight and "delegating_interest_snapshot"';
 | 
| 
jbe@615
 | 
    41 
 | 
| 
jbe@615
 | 
    42 ALTER TABLE "delegating_voter" ADD COLUMN "ownweight" INT4 NOT NULL DEFAULT 1;
 | 
| 
jbe@615
 | 
    43 ALTER TABLE "delegating_voter" ALTER COLUMN "ownweight" DROP DEFAULT;
 | 
| 
jbe@615
 | 
    44 COMMENT ON COLUMN "delegating_voter"."ownweight" IS 'Own voting weight of member, disregarding delegations';
 | 
| 
jbe@615
 | 
    45 COMMENT ON COLUMN "delegating_voter"."weight"    IS 'Intermediate voting weight considering incoming delegations';
 | 
| 
jbe@615
 | 
    46 
 | 
| 
jbe@615
 | 
    47 DROP VIEW "issue_delegation";
 | 
| 
jbe@615
 | 
    48 CREATE VIEW "issue_delegation" AS
 | 
| 
jbe@615
 | 
    49   SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
 | 
| 
jbe@615
 | 
    50     "issue"."id" AS "issue_id",
 | 
| 
jbe@615
 | 
    51     "delegation"."id",
 | 
| 
jbe@615
 | 
    52     "delegation"."truster_id",
 | 
| 
jbe@615
 | 
    53     "delegation"."trustee_id",
 | 
| 
jbe@615
 | 
    54     COALESCE("issue_privilege"."weight", "privilege"."weight") AS "weight",
 | 
| 
jbe@615
 | 
    55     "delegation"."scope"
 | 
| 
jbe@615
 | 
    56   FROM "issue"
 | 
| 
jbe@615
 | 
    57   JOIN "area"
 | 
| 
jbe@615
 | 
    58     ON "area"."id" = "issue"."area_id"
 | 
| 
jbe@615
 | 
    59   JOIN "delegation"
 | 
| 
jbe@615
 | 
    60     ON "delegation"."unit_id" = "area"."unit_id"
 | 
| 
jbe@615
 | 
    61     OR "delegation"."area_id" = "area"."id"
 | 
| 
jbe@615
 | 
    62     OR "delegation"."issue_id" = "issue"."id"
 | 
| 
jbe@615
 | 
    63   JOIN "member"
 | 
| 
jbe@615
 | 
    64     ON "delegation"."truster_id" = "member"."id"
 | 
| 
jbe@615
 | 
    65   LEFT JOIN "privilege"
 | 
| 
jbe@615
 | 
    66     ON "area"."unit_id" = "privilege"."unit_id"
 | 
| 
jbe@615
 | 
    67     AND "delegation"."truster_id" = "privilege"."member_id"
 | 
| 
jbe@615
 | 
    68   LEFT JOIN "issue_privilege"
 | 
| 
jbe@615
 | 
    69     ON "issue"."id" = "issue_privilege"."issue_id"
 | 
| 
jbe@615
 | 
    70     AND "delegation"."truster_id" = "issue_privilege"."member_id"
 | 
| 
jbe@615
 | 
    71   WHERE "member"."active"
 | 
| 
jbe@615
 | 
    72   AND COALESCE("issue_privilege"."voting_right", "privilege"."voting_right")
 | 
| 
jbe@615
 | 
    73   ORDER BY
 | 
| 
jbe@615
 | 
    74     "issue"."id",
 | 
| 
jbe@615
 | 
    75     "delegation"."truster_id",
 | 
| 
jbe@615
 | 
    76     "delegation"."scope" DESC;
 | 
| 
jbe@615
 | 
    77 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
 | 
| 
jbe@615
 | 
    78 
 | 
| 
jbe@615
 | 
    79 CREATE OR REPLACE VIEW "unit_member" AS
 | 
| 
jbe@615
 | 
    80   SELECT
 | 
| 
jbe@615
 | 
    81     "privilege"."unit_id" AS "unit_id",
 | 
| 
jbe@615
 | 
    82     "member"."id"         AS "member_id",
 | 
| 
jbe@615
 | 
    83     "privilege"."weight"
 | 
| 
jbe@615
 | 
    84   FROM "privilege" JOIN "member" ON "member"."id" = "privilege"."member_id"
 | 
| 
jbe@615
 | 
    85   WHERE "privilege"."voting_right" AND "member"."active";
 | 
| 
jbe@615
 | 
    86 
 | 
| 
jbe@615
 | 
    87 CREATE OR REPLACE VIEW "unit_member_count" AS
 | 
| 
jbe@615
 | 
    88   SELECT
 | 
| 
jbe@615
 | 
    89     "unit"."id" AS "unit_id",
 | 
| 
jbe@615
 | 
    90     count("unit_member"."member_id") AS "member_count",
 | 
| 
jbe@615
 | 
    91     sum("unit_member"."weight") AS "member_weight"
 | 
| 
jbe@615
 | 
    92   FROM "unit" LEFT JOIN "unit_member"
 | 
| 
jbe@615
 | 
    93   ON "unit"."id" = "unit_member"."unit_id"
 | 
| 
jbe@615
 | 
    94   GROUP BY "unit"."id";
 | 
| 
jbe@615
 | 
    95 
 | 
| 
jbe@615
 | 
    96 CREATE OR REPLACE VIEW "event_for_notification" AS
 | 
| 
jbe@615
 | 
    97   SELECT
 | 
| 
jbe@615
 | 
    98     "member"."id" AS "recipient_id",
 | 
| 
jbe@615
 | 
    99     "event".*
 | 
| 
jbe@615
 | 
   100   FROM "member" CROSS JOIN "event"
 | 
| 
jbe@615
 | 
   101   JOIN "issue" ON "issue"."id" = "event"."issue_id"
 | 
| 
jbe@615
 | 
   102   JOIN "area" ON "area"."id" = "issue"."area_id"
 | 
| 
jbe@615
 | 
   103   LEFT JOIN "privilege" ON
 | 
| 
jbe@615
 | 
   104     "privilege"."member_id" = "member"."id" AND
 | 
| 
jbe@615
 | 
   105     "privilege"."unit_id" = "area"."unit_id"
 | 
| 
jbe@615
 | 
   106   LEFT JOIN "issue_privilege" ON
 | 
| 
jbe@615
 | 
   107     "issue_privilege"."member_id" = "member"."id" AND
 | 
| 
jbe@615
 | 
   108     "issue_privilege"."issue_id" = "event"."issue_id"
 | 
| 
jbe@615
 | 
   109   LEFT JOIN "subscription" ON
 | 
| 
jbe@615
 | 
   110     "subscription"."member_id" = "member"."id" AND
 | 
| 
jbe@615
 | 
   111     "subscription"."unit_id" = "area"."unit_id"
 | 
| 
jbe@615
 | 
   112   LEFT JOIN "ignored_area" ON
 | 
| 
jbe@615
 | 
   113     "ignored_area"."member_id" = "member"."id" AND
 | 
| 
jbe@615
 | 
   114     "ignored_area"."area_id" = "issue"."area_id"
 | 
| 
jbe@615
 | 
   115   LEFT JOIN "interest" ON
 | 
| 
jbe@615
 | 
   116     "interest"."member_id" = "member"."id" AND
 | 
| 
jbe@615
 | 
   117     "interest"."issue_id" = "event"."issue_id"
 | 
| 
jbe@615
 | 
   118   LEFT JOIN "supporter" ON
 | 
| 
jbe@615
 | 
   119     "supporter"."member_id" = "member"."id" AND
 | 
| 
jbe@615
 | 
   120     "supporter"."initiative_id" = "event"."initiative_id"
 | 
| 
jbe@615
 | 
   121   WHERE (
 | 
| 
jbe@615
 | 
   122     COALESCE("issue_privilege"."voting_right", "privilege"."voting_right") OR
 | 
| 
jbe@615
 | 
   123     "subscription"."member_id" NOTNULL
 | 
| 
jbe@615
 | 
   124   ) AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
 | 
| 
jbe@615
 | 
   125   AND (
 | 
| 
jbe@615
 | 
   126     "event"."event" = 'issue_state_changed'::"event_type" OR
 | 
| 
jbe@615
 | 
   127     ( "event"."event" = 'initiative_revoked'::"event_type" AND
 | 
| 
jbe@615
 | 
   128       "supporter"."member_id" NOTNULL ) );
 | 
| 
jbe@615
 | 
   129 
 | 
| 
jbe@615
 | 
   130 CREATE OR REPLACE FUNCTION "featured_initiative"
 | 
| 
jbe@615
 | 
   131   ( "recipient_id_p" "member"."id"%TYPE,
 | 
| 
jbe@615
 | 
   132     "area_id_p"      "area"."id"%TYPE )
 | 
| 
jbe@615
 | 
   133   RETURNS SETOF "initiative"."id"%TYPE
 | 
| 
jbe@615
 | 
   134   LANGUAGE 'plpgsql' STABLE AS $$
 | 
| 
jbe@615
 | 
   135     DECLARE
 | 
| 
jbe@615
 | 
   136       "counter_v"         "member"."notification_counter"%TYPE;
 | 
| 
jbe@615
 | 
   137       "sample_size_v"     "member"."notification_sample_size"%TYPE;
 | 
| 
jbe@615
 | 
   138       "initiative_id_ary" INT4[];  --"initiative"."id"%TYPE[]
 | 
| 
jbe@615
 | 
   139       "match_v"           BOOLEAN;
 | 
| 
jbe@615
 | 
   140       "member_id_v"       "member"."id"%TYPE;
 | 
| 
jbe@615
 | 
   141       "seed_v"            TEXT;
 | 
| 
jbe@615
 | 
   142       "initiative_id_v"   "initiative"."id"%TYPE;
 | 
| 
jbe@615
 | 
   143     BEGIN
 | 
| 
jbe@615
 | 
   144       SELECT "notification_counter", "notification_sample_size"
 | 
| 
jbe@615
 | 
   145         INTO "counter_v", "sample_size_v"
 | 
| 
jbe@615
 | 
   146         FROM "member" WHERE "id" = "recipient_id_p";
 | 
| 
jbe@615
 | 
   147       IF COALESCE("sample_size_v" <= 0, TRUE) THEN
 | 
| 
jbe@615
 | 
   148         RETURN;
 | 
| 
jbe@615
 | 
   149       END IF;
 | 
| 
jbe@615
 | 
   150       "initiative_id_ary" := '{}';
 | 
| 
jbe@615
 | 
   151       LOOP
 | 
| 
jbe@615
 | 
   152         "match_v" := FALSE;
 | 
| 
jbe@615
 | 
   153         FOR "member_id_v", "seed_v" IN
 | 
| 
jbe@615
 | 
   154           SELECT * FROM (
 | 
| 
jbe@615
 | 
   155             SELECT DISTINCT
 | 
| 
jbe@615
 | 
   156               "supporter"."member_id",
 | 
| 
jbe@615
 | 
   157               md5(
 | 
| 
jbe@615
 | 
   158                 "recipient_id_p" || '-' ||
 | 
| 
jbe@615
 | 
   159                 "counter_v"      || '-' ||
 | 
| 
jbe@615
 | 
   160                 "area_id_p"      || '-' ||
 | 
| 
jbe@615
 | 
   161                 "supporter"."member_id"
 | 
| 
jbe@615
 | 
   162               ) AS "seed"
 | 
| 
jbe@615
 | 
   163             FROM "supporter"
 | 
| 
jbe@615
 | 
   164             JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
 | 
| 
jbe@615
 | 
   165             JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
 | 
| 
jbe@615
 | 
   166             WHERE "supporter"."member_id" != "recipient_id_p"
 | 
| 
jbe@615
 | 
   167             AND "issue"."area_id" = "area_id_p"
 | 
| 
jbe@615
 | 
   168             AND "issue"."state" IN ('admission', 'discussion', 'verification')
 | 
| 
jbe@615
 | 
   169           ) AS "subquery"
 | 
| 
jbe@615
 | 
   170           ORDER BY "seed"
 | 
| 
jbe@615
 | 
   171         LOOP
 | 
| 
jbe@615
 | 
   172           SELECT "initiative"."id" INTO "initiative_id_v"
 | 
| 
jbe@615
 | 
   173             FROM "initiative"
 | 
| 
jbe@615
 | 
   174             JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
 | 
| 
jbe@615
 | 
   175             JOIN "area" ON "area"."id" = "issue"."area_id"
 | 
| 
jbe@615
 | 
   176             JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
 | 
| 
jbe@615
 | 
   177             LEFT JOIN "supporter" AS "self_support" ON
 | 
| 
jbe@615
 | 
   178               "self_support"."initiative_id" = "initiative"."id" AND
 | 
| 
jbe@615
 | 
   179               "self_support"."member_id" = "recipient_id_p"
 | 
| 
jbe@615
 | 
   180             LEFT JOIN "privilege" ON
 | 
| 
jbe@615
 | 
   181               "privilege"."member_id" = "recipient_id_p" AND
 | 
| 
jbe@615
 | 
   182               "privilege"."unit_id" = "area"."unit_id"
 | 
| 
jbe@615
 | 
   183             LEFT JOIN "issue_privilege" ON
 | 
| 
jbe@615
 | 
   184               "privilege"."member_id" = "recipient_id_p" AND
 | 
| 
jbe@615
 | 
   185               "privilege"."issue_id" = "initiative"."issue_id"
 | 
| 
jbe@615
 | 
   186             LEFT JOIN "subscription" ON
 | 
| 
jbe@615
 | 
   187               "subscription"."member_id" = "recipient_id_p" AND
 | 
| 
jbe@615
 | 
   188               "subscription"."unit_id" = "area"."unit_id"
 | 
| 
jbe@615
 | 
   189             LEFT JOIN "ignored_initiative" ON
 | 
| 
jbe@615
 | 
   190               "ignored_initiative"."member_id" = "recipient_id_p" AND
 | 
| 
jbe@615
 | 
   191               "ignored_initiative"."initiative_id" = "initiative"."id"
 | 
| 
jbe@615
 | 
   192             WHERE "supporter"."member_id" = "member_id_v"
 | 
| 
jbe@615
 | 
   193             AND "issue"."area_id" = "area_id_p"
 | 
| 
jbe@615
 | 
   194             AND "issue"."state" IN ('admission', 'discussion', 'verification')
 | 
| 
jbe@615
 | 
   195             AND "initiative"."revoked" ISNULL
 | 
| 
jbe@615
 | 
   196             AND "self_support"."member_id" ISNULL
 | 
| 
jbe@615
 | 
   197             AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
 | 
| 
jbe@615
 | 
   198             AND (
 | 
| 
jbe@615
 | 
   199               COALESCE(
 | 
| 
jbe@615
 | 
   200                 "issue_privilege"."voting_right", "privilege"."voting_right"
 | 
| 
jbe@615
 | 
   201               ) OR "subscription"."member_id" NOTNULL )
 | 
| 
jbe@615
 | 
   202             AND "ignored_initiative"."member_id" ISNULL
 | 
| 
jbe@615
 | 
   203             AND NOT EXISTS (
 | 
| 
jbe@615
 | 
   204               SELECT NULL FROM "draft"
 | 
| 
jbe@615
 | 
   205               JOIN "ignored_member" ON
 | 
| 
jbe@615
 | 
   206                 "ignored_member"."member_id" = "recipient_id_p" AND
 | 
| 
jbe@615
 | 
   207                 "ignored_member"."other_member_id" = "draft"."author_id"
 | 
| 
jbe@615
 | 
   208               WHERE "draft"."initiative_id" = "initiative"."id"
 | 
| 
jbe@615
 | 
   209             )
 | 
| 
jbe@615
 | 
   210             ORDER BY md5("seed_v" || '-' || "initiative"."id")
 | 
| 
jbe@615
 | 
   211             LIMIT 1;
 | 
| 
jbe@615
 | 
   212           IF FOUND THEN
 | 
| 
jbe@615
 | 
   213             "match_v" := TRUE;
 | 
| 
jbe@615
 | 
   214             RETURN NEXT "initiative_id_v";
 | 
| 
jbe@615
 | 
   215             IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
 | 
| 
jbe@615
 | 
   216               RETURN;
 | 
| 
jbe@615
 | 
   217             END IF;
 | 
| 
jbe@615
 | 
   218             "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
 | 
| 
jbe@615
 | 
   219           END IF;
 | 
| 
jbe@615
 | 
   220         END LOOP;
 | 
| 
jbe@615
 | 
   221         EXIT WHEN NOT "match_v";
 | 
| 
jbe@615
 | 
   222       END LOOP;
 | 
| 
jbe@615
 | 
   223       RETURN;
 | 
| 
jbe@615
 | 
   224     END;
 | 
| 
jbe@615
 | 
   225   $$;
 | 
| 
jbe@615
 | 
   226 
 | 
| 
jbe@615
 | 
   227 CREATE OR REPLACE FUNCTION "delegation_chain"
 | 
| 
jbe@615
 | 
   228   ( "member_id_p"           "member"."id"%TYPE,
 | 
| 
jbe@615
 | 
   229     "unit_id_p"             "unit"."id"%TYPE,
 | 
| 
jbe@615
 | 
   230     "area_id_p"             "area"."id"%TYPE,
 | 
| 
jbe@615
 | 
   231     "issue_id_p"            "issue"."id"%TYPE,
 | 
| 
jbe@615
 | 
   232     "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
 | 
| 
jbe@615
 | 
   233     "simulate_default_p"    BOOLEAN            DEFAULT FALSE )
 | 
| 
jbe@615
 | 
   234   RETURNS SETOF "delegation_chain_row"
 | 
| 
jbe@615
 | 
   235   LANGUAGE 'plpgsql' STABLE AS $$
 | 
| 
jbe@615
 | 
   236     DECLARE
 | 
| 
jbe@615
 | 
   237       "scope_v"            "delegation_scope";
 | 
| 
jbe@615
 | 
   238       "unit_id_v"          "unit"."id"%TYPE;
 | 
| 
jbe@615
 | 
   239       "area_id_v"          "area"."id"%TYPE;
 | 
| 
jbe@615
 | 
   240       "issue_row"          "issue"%ROWTYPE;
 | 
| 
jbe@615
 | 
   241       "visited_member_ids" INT4[];  -- "member"."id"%TYPE[]
 | 
| 
jbe@615
 | 
   242       "loop_member_id_v"   "member"."id"%TYPE;
 | 
| 
jbe@615
 | 
   243       "output_row"         "delegation_chain_row";
 | 
| 
jbe@615
 | 
   244       "output_rows"        "delegation_chain_row"[];
 | 
| 
jbe@615
 | 
   245       "simulate_v"         BOOLEAN;
 | 
| 
jbe@615
 | 
   246       "simulate_here_v"    BOOLEAN;
 | 
| 
jbe@615
 | 
   247       "delegation_row"     "delegation"%ROWTYPE;
 | 
| 
jbe@615
 | 
   248       "row_count"          INT4;
 | 
| 
jbe@615
 | 
   249       "i"                  INT4;
 | 
| 
jbe@615
 | 
   250       "loop_v"             BOOLEAN;
 | 
| 
jbe@615
 | 
   251     BEGIN
 | 
| 
jbe@615
 | 
   252       IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
 | 
| 
jbe@615
 | 
   253         RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
 | 
| 
jbe@615
 | 
   254       END IF;
 | 
| 
jbe@615
 | 
   255       IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
 | 
| 
jbe@615
 | 
   256         "simulate_v" := TRUE;
 | 
| 
jbe@615
 | 
   257       ELSE
 | 
| 
jbe@615
 | 
   258         "simulate_v" := FALSE;
 | 
| 
jbe@615
 | 
   259       END IF;
 | 
| 
jbe@615
 | 
   260       IF
 | 
| 
jbe@615
 | 
   261         "unit_id_p" NOTNULL AND
 | 
| 
jbe@615
 | 
   262         "area_id_p" ISNULL AND
 | 
| 
jbe@615
 | 
   263         "issue_id_p" ISNULL
 | 
| 
jbe@615
 | 
   264       THEN
 | 
| 
jbe@615
 | 
   265         "scope_v" := 'unit';
 | 
| 
jbe@615
 | 
   266         "unit_id_v" := "unit_id_p";
 | 
| 
jbe@615
 | 
   267       ELSIF
 | 
| 
jbe@615
 | 
   268         "unit_id_p" ISNULL AND
 | 
| 
jbe@615
 | 
   269         "area_id_p" NOTNULL AND
 | 
| 
jbe@615
 | 
   270         "issue_id_p" ISNULL
 | 
| 
jbe@615
 | 
   271       THEN
 | 
| 
jbe@615
 | 
   272         "scope_v" := 'area';
 | 
| 
jbe@615
 | 
   273         "area_id_v" := "area_id_p";
 | 
| 
jbe@615
 | 
   274         SELECT "unit_id" INTO "unit_id_v"
 | 
| 
jbe@615
 | 
   275           FROM "area" WHERE "id" = "area_id_v";
 | 
| 
jbe@615
 | 
   276       ELSIF
 | 
| 
jbe@615
 | 
   277         "unit_id_p" ISNULL AND
 | 
| 
jbe@615
 | 
   278         "area_id_p" ISNULL AND
 | 
| 
jbe@615
 | 
   279         "issue_id_p" NOTNULL
 | 
| 
jbe@615
 | 
   280       THEN
 | 
| 
jbe@615
 | 
   281         SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   282         IF "issue_row"."id" ISNULL THEN
 | 
| 
jbe@615
 | 
   283           RETURN;
 | 
| 
jbe@615
 | 
   284         END IF;
 | 
| 
jbe@615
 | 
   285         IF "issue_row"."closed" NOTNULL THEN
 | 
| 
jbe@615
 | 
   286           IF "simulate_v" THEN
 | 
| 
jbe@615
 | 
   287             RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
 | 
| 
jbe@615
 | 
   288           END IF;
 | 
| 
jbe@615
 | 
   289           FOR "output_row" IN
 | 
| 
jbe@615
 | 
   290             SELECT * FROM
 | 
| 
jbe@615
 | 
   291             "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
 | 
| 
jbe@615
 | 
   292           LOOP
 | 
| 
jbe@615
 | 
   293             RETURN NEXT "output_row";
 | 
| 
jbe@615
 | 
   294           END LOOP;
 | 
| 
jbe@615
 | 
   295           RETURN;
 | 
| 
jbe@615
 | 
   296         END IF;
 | 
| 
jbe@615
 | 
   297         "scope_v" := 'issue';
 | 
| 
jbe@615
 | 
   298         SELECT "area_id" INTO "area_id_v"
 | 
| 
jbe@615
 | 
   299           FROM "issue" WHERE "id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   300         SELECT "unit_id" INTO "unit_id_v"
 | 
| 
jbe@615
 | 
   301           FROM "area"  WHERE "id" = "area_id_v";
 | 
| 
jbe@615
 | 
   302       ELSE
 | 
| 
jbe@615
 | 
   303         RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
 | 
| 
jbe@615
 | 
   304       END IF;
 | 
| 
jbe@615
 | 
   305       "visited_member_ids" := '{}';
 | 
| 
jbe@615
 | 
   306       "loop_member_id_v"   := NULL;
 | 
| 
jbe@615
 | 
   307       "output_rows"        := '{}';
 | 
| 
jbe@615
 | 
   308       "output_row"."index"         := 0;
 | 
| 
jbe@615
 | 
   309       "output_row"."member_id"     := "member_id_p";
 | 
| 
jbe@615
 | 
   310       "output_row"."member_valid"  := TRUE;
 | 
| 
jbe@615
 | 
   311       "output_row"."participation" := FALSE;
 | 
| 
jbe@615
 | 
   312       "output_row"."overridden"    := FALSE;
 | 
| 
jbe@615
 | 
   313       "output_row"."disabled_out"  := FALSE;
 | 
| 
jbe@615
 | 
   314       "output_row"."scope_out"     := NULL;
 | 
| 
jbe@615
 | 
   315       LOOP
 | 
| 
jbe@615
 | 
   316         IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
 | 
| 
jbe@615
 | 
   317           "loop_member_id_v" := "output_row"."member_id";
 | 
| 
jbe@615
 | 
   318         ELSE
 | 
| 
jbe@615
 | 
   319           "visited_member_ids" :=
 | 
| 
jbe@615
 | 
   320             "visited_member_ids" || "output_row"."member_id";
 | 
| 
jbe@615
 | 
   321         END IF;
 | 
| 
jbe@615
 | 
   322         IF "output_row"."participation" ISNULL THEN
 | 
| 
jbe@615
 | 
   323           "output_row"."overridden" := NULL;
 | 
| 
jbe@615
 | 
   324         ELSIF "output_row"."participation" THEN
 | 
| 
jbe@615
 | 
   325           "output_row"."overridden" := TRUE;
 | 
| 
jbe@615
 | 
   326         END IF;
 | 
| 
jbe@615
 | 
   327         "output_row"."scope_in" := "output_row"."scope_out";
 | 
| 
jbe@615
 | 
   328         "output_row"."member_valid" := EXISTS (
 | 
| 
jbe@615
 | 
   329           SELECT NULL FROM "member"
 | 
| 
jbe@615
 | 
   330           LEFT JOIN "privilege"
 | 
| 
jbe@615
 | 
   331           ON "privilege"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   332           AND "privilege"."unit_id" = "unit_id_v"
 | 
| 
jbe@615
 | 
   333           LEFT JOIN "issue_privilege"
 | 
| 
jbe@615
 | 
   334           ON "issue_privilege"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   335           AND "issue_privilege"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   336           WHERE "id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   337           AND "member"."active"
 | 
| 
jbe@615
 | 
   338           AND COALESCE(
 | 
| 
jbe@615
 | 
   339             "issue_privilege"."voting_right", "privilege"."voting_right")
 | 
| 
jbe@615
 | 
   340         );
 | 
| 
jbe@615
 | 
   341         "simulate_here_v" := (
 | 
| 
jbe@615
 | 
   342           "simulate_v" AND
 | 
| 
jbe@615
 | 
   343           "output_row"."member_id" = "member_id_p"
 | 
| 
jbe@615
 | 
   344         );
 | 
| 
jbe@615
 | 
   345         "delegation_row" := ROW(NULL);
 | 
| 
jbe@615
 | 
   346         IF "output_row"."member_valid" OR "simulate_here_v" THEN
 | 
| 
jbe@615
 | 
   347           IF "scope_v" = 'unit' THEN
 | 
| 
jbe@615
 | 
   348             IF NOT "simulate_here_v" THEN
 | 
| 
jbe@615
 | 
   349               SELECT * INTO "delegation_row" FROM "delegation"
 | 
| 
jbe@615
 | 
   350                 WHERE "truster_id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   351                 AND "unit_id" = "unit_id_v";
 | 
| 
jbe@615
 | 
   352             END IF;
 | 
| 
jbe@615
 | 
   353           ELSIF "scope_v" = 'area' THEN
 | 
| 
jbe@615
 | 
   354             IF "simulate_here_v" THEN
 | 
| 
jbe@615
 | 
   355               IF "simulate_trustee_id_p" ISNULL THEN
 | 
| 
jbe@615
 | 
   356                 SELECT * INTO "delegation_row" FROM "delegation"
 | 
| 
jbe@615
 | 
   357                   WHERE "truster_id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   358                   AND "unit_id" = "unit_id_v";
 | 
| 
jbe@615
 | 
   359               END IF;
 | 
| 
jbe@615
 | 
   360             ELSE
 | 
| 
jbe@615
 | 
   361               SELECT * INTO "delegation_row" FROM "delegation"
 | 
| 
jbe@615
 | 
   362                 WHERE "truster_id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   363                 AND (
 | 
| 
jbe@615
 | 
   364                   "unit_id" = "unit_id_v" OR
 | 
| 
jbe@615
 | 
   365                   "area_id" = "area_id_v"
 | 
| 
jbe@615
 | 
   366                 )
 | 
| 
jbe@615
 | 
   367                 ORDER BY "scope" DESC;
 | 
| 
jbe@615
 | 
   368             END IF;
 | 
| 
jbe@615
 | 
   369           ELSIF "scope_v" = 'issue' THEN
 | 
| 
jbe@615
 | 
   370             IF "issue_row"."fully_frozen" ISNULL THEN
 | 
| 
jbe@615
 | 
   371               "output_row"."participation" := EXISTS (
 | 
| 
jbe@615
 | 
   372                 SELECT NULL FROM "interest"
 | 
| 
jbe@615
 | 
   373                 WHERE "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   374                 AND "member_id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   375               );
 | 
| 
jbe@615
 | 
   376             ELSE
 | 
| 
jbe@615
 | 
   377               IF "output_row"."member_id" = "member_id_p" THEN
 | 
| 
jbe@615
 | 
   378                 "output_row"."participation" := EXISTS (
 | 
| 
jbe@615
 | 
   379                   SELECT NULL FROM "direct_voter"
 | 
| 
jbe@615
 | 
   380                   WHERE "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   381                   AND "member_id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   382                 );
 | 
| 
jbe@615
 | 
   383               ELSE
 | 
| 
jbe@615
 | 
   384                 "output_row"."participation" := NULL;
 | 
| 
jbe@615
 | 
   385               END IF;
 | 
| 
jbe@615
 | 
   386             END IF;
 | 
| 
jbe@615
 | 
   387             IF "simulate_here_v" THEN
 | 
| 
jbe@615
 | 
   388               IF "simulate_trustee_id_p" ISNULL THEN
 | 
| 
jbe@615
 | 
   389                 SELECT * INTO "delegation_row" FROM "delegation"
 | 
| 
jbe@615
 | 
   390                   WHERE "truster_id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   391                   AND (
 | 
| 
jbe@615
 | 
   392                     "unit_id" = "unit_id_v" OR
 | 
| 
jbe@615
 | 
   393                     "area_id" = "area_id_v"
 | 
| 
jbe@615
 | 
   394                   )
 | 
| 
jbe@615
 | 
   395                   ORDER BY "scope" DESC;
 | 
| 
jbe@615
 | 
   396               END IF;
 | 
| 
jbe@615
 | 
   397             ELSE
 | 
| 
jbe@615
 | 
   398               SELECT * INTO "delegation_row" FROM "delegation"
 | 
| 
jbe@615
 | 
   399                 WHERE "truster_id" = "output_row"."member_id"
 | 
| 
jbe@615
 | 
   400                 AND (
 | 
| 
jbe@615
 | 
   401                   "unit_id" = "unit_id_v" OR
 | 
| 
jbe@615
 | 
   402                   "area_id" = "area_id_v" OR
 | 
| 
jbe@615
 | 
   403                   "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   404                 )
 | 
| 
jbe@615
 | 
   405                 ORDER BY "scope" DESC;
 | 
| 
jbe@615
 | 
   406             END IF;
 | 
| 
jbe@615
 | 
   407           END IF;
 | 
| 
jbe@615
 | 
   408         ELSE
 | 
| 
jbe@615
 | 
   409           "output_row"."participation" := FALSE;
 | 
| 
jbe@615
 | 
   410         END IF;
 | 
| 
jbe@615
 | 
   411         IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
 | 
| 
jbe@615
 | 
   412           "output_row"."scope_out" := "scope_v";
 | 
| 
jbe@615
 | 
   413           "output_rows" := "output_rows" || "output_row";
 | 
| 
jbe@615
 | 
   414           "output_row"."member_id" := "simulate_trustee_id_p";
 | 
| 
jbe@615
 | 
   415         ELSIF "delegation_row"."trustee_id" NOTNULL THEN
 | 
| 
jbe@615
 | 
   416           "output_row"."scope_out" := "delegation_row"."scope";
 | 
| 
jbe@615
 | 
   417           "output_rows" := "output_rows" || "output_row";
 | 
| 
jbe@615
 | 
   418           "output_row"."member_id" := "delegation_row"."trustee_id";
 | 
| 
jbe@615
 | 
   419         ELSIF "delegation_row"."scope" NOTNULL THEN
 | 
| 
jbe@615
 | 
   420           "output_row"."scope_out" := "delegation_row"."scope";
 | 
| 
jbe@615
 | 
   421           "output_row"."disabled_out" := TRUE;
 | 
| 
jbe@615
 | 
   422           "output_rows" := "output_rows" || "output_row";
 | 
| 
jbe@615
 | 
   423           EXIT;
 | 
| 
jbe@615
 | 
   424         ELSE
 | 
| 
jbe@615
 | 
   425           "output_row"."scope_out" := NULL;
 | 
| 
jbe@615
 | 
   426           "output_rows" := "output_rows" || "output_row";
 | 
| 
jbe@615
 | 
   427           EXIT;
 | 
| 
jbe@615
 | 
   428         END IF;
 | 
| 
jbe@615
 | 
   429         EXIT WHEN "loop_member_id_v" NOTNULL;
 | 
| 
jbe@615
 | 
   430         "output_row"."index" := "output_row"."index" + 1;
 | 
| 
jbe@615
 | 
   431       END LOOP;
 | 
| 
jbe@615
 | 
   432       "row_count" := array_upper("output_rows", 1);
 | 
| 
jbe@615
 | 
   433       "i"      := 1;
 | 
| 
jbe@615
 | 
   434       "loop_v" := FALSE;
 | 
| 
jbe@615
 | 
   435       LOOP
 | 
| 
jbe@615
 | 
   436         "output_row" := "output_rows"["i"];
 | 
| 
jbe@615
 | 
   437         EXIT WHEN "output_row" ISNULL;  -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
 | 
| 
jbe@615
 | 
   438         IF "loop_v" THEN
 | 
| 
jbe@615
 | 
   439           IF "i" + 1 = "row_count" THEN
 | 
| 
jbe@615
 | 
   440             "output_row"."loop" := 'last';
 | 
| 
jbe@615
 | 
   441           ELSIF "i" = "row_count" THEN
 | 
| 
jbe@615
 | 
   442             "output_row"."loop" := 'repetition';
 | 
| 
jbe@615
 | 
   443           ELSE
 | 
| 
jbe@615
 | 
   444             "output_row"."loop" := 'intermediate';
 | 
| 
jbe@615
 | 
   445           END IF;
 | 
| 
jbe@615
 | 
   446         ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
 | 
| 
jbe@615
 | 
   447           "output_row"."loop" := 'first';
 | 
| 
jbe@615
 | 
   448           "loop_v" := TRUE;
 | 
| 
jbe@615
 | 
   449         END IF;
 | 
| 
jbe@615
 | 
   450         IF "scope_v" = 'unit' THEN
 | 
| 
jbe@615
 | 
   451           "output_row"."participation" := NULL;
 | 
| 
jbe@615
 | 
   452         END IF;
 | 
| 
jbe@615
 | 
   453         RETURN NEXT "output_row";
 | 
| 
jbe@615
 | 
   454         "i" := "i" + 1;
 | 
| 
jbe@615
 | 
   455       END LOOP;
 | 
| 
jbe@615
 | 
   456       RETURN;
 | 
| 
jbe@615
 | 
   457     END;
 | 
| 
jbe@615
 | 
   458   $$;
 | 
| 
jbe@615
 | 
   459 
 | 
| 
jbe@615
 | 
   460 CREATE OR REPLACE FUNCTION "calculate_member_counts"()
 | 
| 
jbe@615
 | 
   461   RETURNS VOID
 | 
| 
jbe@615
 | 
   462   LANGUAGE 'plpgsql' VOLATILE AS $$
 | 
| 
jbe@615
 | 
   463     BEGIN
 | 
| 
jbe@615
 | 
   464       PERFORM "require_transaction_isolation"();
 | 
| 
jbe@615
 | 
   465       DELETE FROM "member_count";
 | 
| 
jbe@615
 | 
   466       INSERT INTO "member_count" ("total_count")
 | 
| 
jbe@615
 | 
   467         SELECT "total_count" FROM "member_count_view";
 | 
| 
jbe@615
 | 
   468       UPDATE "unit" SET
 | 
| 
jbe@615
 | 
   469         "member_count" = "view"."member_count",
 | 
| 
jbe@615
 | 
   470         "member_weight" = "view"."member_weight"
 | 
| 
jbe@615
 | 
   471         FROM "unit_member_count" AS "view"
 | 
| 
jbe@615
 | 
   472         WHERE "view"."unit_id" = "unit"."id";
 | 
| 
jbe@615
 | 
   473       RETURN;
 | 
| 
jbe@615
 | 
   474     END;
 | 
| 
jbe@615
 | 
   475   $$;
 | 
| 
jbe@615
 | 
   476 COMMENT ON FUNCTION "calculate_member_counts"() IS 'Updates "member_count" table and "member_count" and "member_weight" columns of table "area" by materializing data from views "member_count_view" and "unit_member_count"';
 | 
| 
jbe@615
 | 
   477  
 | 
| 
jbe@615
 | 
   478 CREATE OR REPLACE FUNCTION "weight_of_added_delegations_for_snapshot"
 | 
| 
jbe@615
 | 
   479   ( "snapshot_id_p"         "snapshot"."id"%TYPE,
 | 
| 
jbe@615
 | 
   480     "issue_id_p"            "issue"."id"%TYPE,
 | 
| 
jbe@615
 | 
   481     "member_id_p"           "member"."id"%TYPE,
 | 
| 
jbe@615
 | 
   482     "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
 | 
| 
jbe@615
 | 
   483   RETURNS "direct_interest_snapshot"."weight"%TYPE
 | 
| 
jbe@615
 | 
   484   LANGUAGE 'plpgsql' VOLATILE AS $$
 | 
| 
jbe@615
 | 
   485     DECLARE
 | 
| 
jbe@615
 | 
   486       "issue_delegation_row"  "issue_delegation"%ROWTYPE;
 | 
| 
jbe@615
 | 
   487       "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
 | 
| 
jbe@615
 | 
   488       "weight_v"              INT4;
 | 
| 
jbe@615
 | 
   489       "sub_weight_v"          INT4;
 | 
| 
jbe@615
 | 
   490     BEGIN
 | 
| 
jbe@615
 | 
   491       PERFORM "require_transaction_isolation"();
 | 
| 
jbe@615
 | 
   492       "weight_v" := 0;
 | 
| 
jbe@615
 | 
   493       FOR "issue_delegation_row" IN
 | 
| 
jbe@615
 | 
   494         SELECT * FROM "issue_delegation"
 | 
| 
jbe@615
 | 
   495         WHERE "trustee_id" = "member_id_p"
 | 
| 
jbe@615
 | 
   496         AND "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   497       LOOP
 | 
| 
jbe@615
 | 
   498         IF NOT EXISTS (
 | 
| 
jbe@615
 | 
   499           SELECT NULL FROM "direct_interest_snapshot"
 | 
| 
jbe@615
 | 
   500           WHERE "snapshot_id" = "snapshot_id_p"
 | 
| 
jbe@615
 | 
   501           AND "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   502           AND "member_id" = "issue_delegation_row"."truster_id"
 | 
| 
jbe@615
 | 
   503         ) AND NOT EXISTS (
 | 
| 
jbe@615
 | 
   504           SELECT NULL FROM "delegating_interest_snapshot"
 | 
| 
jbe@615
 | 
   505           WHERE "snapshot_id" = "snapshot_id_p"
 | 
| 
jbe@615
 | 
   506           AND "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   507           AND "member_id" = "issue_delegation_row"."truster_id"
 | 
| 
jbe@615
 | 
   508         ) THEN
 | 
| 
jbe@615
 | 
   509           "delegate_member_ids_v" :=
 | 
| 
jbe@615
 | 
   510             "member_id_p" || "delegate_member_ids_p";
 | 
| 
jbe@615
 | 
   511           INSERT INTO "delegating_interest_snapshot" (
 | 
| 
jbe@615
 | 
   512               "snapshot_id",
 | 
| 
jbe@615
 | 
   513               "issue_id",
 | 
| 
jbe@615
 | 
   514               "member_id",
 | 
| 
jbe@615
 | 
   515               "ownweight",
 | 
| 
jbe@615
 | 
   516               "scope",
 | 
| 
jbe@615
 | 
   517               "delegate_member_ids"
 | 
| 
jbe@615
 | 
   518             ) VALUES (
 | 
| 
jbe@615
 | 
   519               "snapshot_id_p",
 | 
| 
jbe@615
 | 
   520               "issue_id_p",
 | 
| 
jbe@615
 | 
   521               "issue_delegation_row"."truster_id",
 | 
| 
jbe@615
 | 
   522               "issue_delegation_row"."weight",
 | 
| 
jbe@615
 | 
   523               "issue_delegation_row"."scope",
 | 
| 
jbe@615
 | 
   524               "delegate_member_ids_v"
 | 
| 
jbe@615
 | 
   525             );
 | 
| 
jbe@615
 | 
   526           "sub_weight_v" := "issue_delegation_row"."weight" +
 | 
| 
jbe@615
 | 
   527             "weight_of_added_delegations_for_snapshot"(
 | 
| 
jbe@615
 | 
   528               "snapshot_id_p",
 | 
| 
jbe@615
 | 
   529               "issue_id_p",
 | 
| 
jbe@615
 | 
   530               "issue_delegation_row"."truster_id",
 | 
| 
jbe@615
 | 
   531               "delegate_member_ids_v"
 | 
| 
jbe@615
 | 
   532             );
 | 
| 
jbe@615
 | 
   533           UPDATE "delegating_interest_snapshot"
 | 
| 
jbe@615
 | 
   534             SET "weight" = "sub_weight_v"
 | 
| 
jbe@615
 | 
   535             WHERE "snapshot_id" = "snapshot_id_p"
 | 
| 
jbe@615
 | 
   536             AND "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   537             AND "member_id" = "issue_delegation_row"."truster_id";
 | 
| 
jbe@615
 | 
   538           "weight_v" := "weight_v" + "sub_weight_v";
 | 
| 
jbe@615
 | 
   539         END IF;
 | 
| 
jbe@615
 | 
   540       END LOOP;
 | 
| 
jbe@615
 | 
   541       RETURN "weight_v";
 | 
| 
jbe@615
 | 
   542     END;
 | 
| 
jbe@615
 | 
   543   $$;
 | 
| 
jbe@615
 | 
   544 
 | 
| 
jbe@615
 | 
   545 CREATE OR REPLACE FUNCTION "take_snapshot"
 | 
| 
jbe@615
 | 
   546   ( "issue_id_p" "issue"."id"%TYPE,
 | 
| 
jbe@615
 | 
   547     "area_id_p"  "area"."id"%TYPE = NULL )
 | 
| 
jbe@615
 | 
   548   RETURNS "snapshot"."id"%TYPE
 | 
| 
jbe@615
 | 
   549   LANGUAGE 'plpgsql' VOLATILE AS $$
 | 
| 
jbe@615
 | 
   550     DECLARE
 | 
| 
jbe@615
 | 
   551       "area_id_v"     "area"."id"%TYPE;
 | 
| 
jbe@615
 | 
   552       "unit_id_v"     "unit"."id"%TYPE;
 | 
| 
jbe@615
 | 
   553       "snapshot_id_v" "snapshot"."id"%TYPE;
 | 
| 
jbe@615
 | 
   554       "issue_id_v"    "issue"."id"%TYPE;
 | 
| 
jbe@615
 | 
   555       "member_id_v"   "member"."id"%TYPE;
 | 
| 
jbe@615
 | 
   556     BEGIN
 | 
| 
jbe@615
 | 
   557       IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
 | 
| 
jbe@615
 | 
   558         RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
 | 
| 
jbe@615
 | 
   559       END IF;
 | 
| 
jbe@615
 | 
   560       PERFORM "require_transaction_isolation"();
 | 
| 
jbe@615
 | 
   561       IF "issue_id_p" ISNULL THEN
 | 
| 
jbe@615
 | 
   562         "area_id_v" := "area_id_p";
 | 
| 
jbe@615
 | 
   563       ELSE
 | 
| 
jbe@615
 | 
   564         SELECT "area_id" INTO "area_id_v"
 | 
| 
jbe@615
 | 
   565           FROM "issue" WHERE "id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   566       END IF;
 | 
| 
jbe@615
 | 
   567       SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
 | 
| 
jbe@615
 | 
   568       INSERT INTO "snapshot" ("area_id", "issue_id")
 | 
| 
jbe@615
 | 
   569         VALUES ("area_id_v", "issue_id_p")
 | 
| 
jbe@615
 | 
   570         RETURNING "id" INTO "snapshot_id_v";
 | 
| 
jbe@615
 | 
   571       INSERT INTO "snapshot_population" ("snapshot_id", "member_id", "weight")
 | 
| 
jbe@615
 | 
   572         SELECT
 | 
| 
jbe@615
 | 
   573           "snapshot_id_v",
 | 
| 
jbe@615
 | 
   574           "member"."id",
 | 
| 
jbe@615
 | 
   575           COALESCE("issue_privilege"."weight", "privilege"."weight")
 | 
| 
jbe@615
 | 
   576         FROM "member"
 | 
| 
jbe@615
 | 
   577         LEFT JOIN "privilege"
 | 
| 
jbe@615
 | 
   578         ON "privilege"."unit_id" = "unit_id_v"
 | 
| 
jbe@615
 | 
   579         AND "privilege"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   580         LEFT JOIN "issue_privilege"
 | 
| 
jbe@615
 | 
   581         ON "issue_privilege"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   582         AND "issue_privilege"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   583         WHERE "member"."active" AND COALESCE(
 | 
| 
jbe@615
 | 
   584           "issue_privilege"."voting_right", "privilege"."voting_right");
 | 
| 
jbe@615
 | 
   585       UPDATE "snapshot" SET
 | 
| 
jbe@615
 | 
   586         "population" = (
 | 
| 
jbe@615
 | 
   587           SELECT sum("weight") FROM "snapshot_population"
 | 
| 
jbe@615
 | 
   588           WHERE "snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   589         ) WHERE "id" = "snapshot_id_v";
 | 
| 
jbe@615
 | 
   590       FOR "issue_id_v" IN
 | 
| 
jbe@615
 | 
   591         SELECT "id" FROM "issue"
 | 
| 
jbe@615
 | 
   592         WHERE CASE WHEN "issue_id_p" ISNULL THEN
 | 
| 
jbe@615
 | 
   593           "area_id" = "area_id_p" AND
 | 
| 
jbe@615
 | 
   594           "state" = 'admission'
 | 
| 
jbe@615
 | 
   595         ELSE
 | 
| 
jbe@615
 | 
   596           "id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   597         END
 | 
| 
jbe@615
 | 
   598       LOOP
 | 
| 
jbe@615
 | 
   599         INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
 | 
| 
jbe@615
 | 
   600           VALUES ("snapshot_id_v", "issue_id_v");
 | 
| 
jbe@615
 | 
   601         INSERT INTO "direct_interest_snapshot"
 | 
| 
jbe@615
 | 
   602           ("snapshot_id", "issue_id", "member_id", "ownweight")
 | 
| 
jbe@615
 | 
   603           SELECT
 | 
| 
jbe@615
 | 
   604             "snapshot_id_v" AS "snapshot_id",
 | 
| 
jbe@615
 | 
   605             "issue_id_v"    AS "issue_id",
 | 
| 
jbe@615
 | 
   606             "member"."id"   AS "member_id",
 | 
| 
jbe@615
 | 
   607             COALESCE(
 | 
| 
jbe@615
 | 
   608               "issue_privilege"."weight", "privilege"."weight"
 | 
| 
jbe@615
 | 
   609             ) AS "ownweight"
 | 
| 
jbe@615
 | 
   610           FROM "issue"
 | 
| 
jbe@615
 | 
   611           JOIN "area" ON "issue"."area_id" = "area"."id"
 | 
| 
jbe@615
 | 
   612           JOIN "interest" ON "issue"."id" = "interest"."issue_id"
 | 
| 
jbe@615
 | 
   613           JOIN "member" ON "interest"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   614           LEFT JOIN "privilege"
 | 
| 
jbe@615
 | 
   615             ON "privilege"."unit_id" = "area"."unit_id"
 | 
| 
jbe@615
 | 
   616             AND "privilege"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   617           LEFT JOIN "issue_privilege"
 | 
| 
jbe@615
 | 
   618             ON "issue_privilege"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   619             AND "issue_privilege"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   620           WHERE "issue"."id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   621           AND "member"."active" AND COALESCE(
 | 
| 
jbe@615
 | 
   622             "issue_privilege"."voting_right", "privilege"."voting_right");
 | 
| 
jbe@615
 | 
   623         FOR "member_id_v" IN
 | 
| 
jbe@615
 | 
   624           SELECT "member_id" FROM "direct_interest_snapshot"
 | 
| 
jbe@615
 | 
   625           WHERE "snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   626           AND "issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   627         LOOP
 | 
| 
jbe@615
 | 
   628           UPDATE "direct_interest_snapshot" SET
 | 
| 
jbe@615
 | 
   629             "weight" = "ownweight" +
 | 
| 
jbe@615
 | 
   630               "weight_of_added_delegations_for_snapshot"(
 | 
| 
jbe@615
 | 
   631                 "snapshot_id_v",
 | 
| 
jbe@615
 | 
   632                 "issue_id_v",
 | 
| 
jbe@615
 | 
   633                 "member_id_v",
 | 
| 
jbe@615
 | 
   634                 '{}'
 | 
| 
jbe@615
 | 
   635               )
 | 
| 
jbe@615
 | 
   636             WHERE "snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   637             AND "issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   638             AND "member_id" = "member_id_v";
 | 
| 
jbe@615
 | 
   639         END LOOP;
 | 
| 
jbe@615
 | 
   640         INSERT INTO "direct_supporter_snapshot"
 | 
| 
jbe@615
 | 
   641           ( "snapshot_id", "issue_id", "initiative_id", "member_id",
 | 
| 
jbe@615
 | 
   642             "draft_id", "informed", "satisfied" )
 | 
| 
jbe@615
 | 
   643           SELECT
 | 
| 
jbe@615
 | 
   644             "snapshot_id_v"         AS "snapshot_id",
 | 
| 
jbe@615
 | 
   645             "issue_id_v"            AS "issue_id",
 | 
| 
jbe@615
 | 
   646             "initiative"."id"       AS "initiative_id",
 | 
| 
jbe@615
 | 
   647             "supporter"."member_id" AS "member_id",
 | 
| 
jbe@615
 | 
   648             "supporter"."draft_id"  AS "draft_id",
 | 
| 
jbe@615
 | 
   649             "supporter"."draft_id" = "current_draft"."id" AS "informed",
 | 
| 
jbe@615
 | 
   650             NOT EXISTS (
 | 
| 
jbe@615
 | 
   651               SELECT NULL FROM "critical_opinion"
 | 
| 
jbe@615
 | 
   652               WHERE "initiative_id" = "initiative"."id"
 | 
| 
jbe@615
 | 
   653               AND "member_id" = "supporter"."member_id"
 | 
| 
jbe@615
 | 
   654             ) AS "satisfied"
 | 
| 
jbe@615
 | 
   655           FROM "initiative"
 | 
| 
jbe@615
 | 
   656           JOIN "supporter"
 | 
| 
jbe@615
 | 
   657           ON "supporter"."initiative_id" = "initiative"."id"
 | 
| 
jbe@615
 | 
   658           JOIN "current_draft"
 | 
| 
jbe@615
 | 
   659           ON "initiative"."id" = "current_draft"."initiative_id"
 | 
| 
jbe@615
 | 
   660           JOIN "direct_interest_snapshot"
 | 
| 
jbe@615
 | 
   661           ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
 | 
| 
jbe@615
 | 
   662           AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
 | 
| 
jbe@615
 | 
   663           AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
 | 
| 
jbe@615
 | 
   664           WHERE "initiative"."issue_id" = "issue_id_v";
 | 
| 
jbe@615
 | 
   665         DELETE FROM "temporary_suggestion_counts";
 | 
| 
jbe@615
 | 
   666         INSERT INTO "temporary_suggestion_counts"
 | 
| 
jbe@615
 | 
   667           ( "id",
 | 
| 
jbe@615
 | 
   668             "minus2_unfulfilled_count", "minus2_fulfilled_count",
 | 
| 
jbe@615
 | 
   669             "minus1_unfulfilled_count", "minus1_fulfilled_count",
 | 
| 
jbe@615
 | 
   670             "plus1_unfulfilled_count", "plus1_fulfilled_count",
 | 
| 
jbe@615
 | 
   671             "plus2_unfulfilled_count", "plus2_fulfilled_count" )
 | 
| 
jbe@615
 | 
   672           SELECT
 | 
| 
jbe@615
 | 
   673             "suggestion"."id",
 | 
| 
jbe@615
 | 
   674             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   675               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   676               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   677               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   678               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   679               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   680               AND "opinion"."degree" = -2
 | 
| 
jbe@615
 | 
   681               AND "opinion"."fulfilled" = FALSE
 | 
| 
jbe@615
 | 
   682             ) AS "minus2_unfulfilled_count",
 | 
| 
jbe@615
 | 
   683             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   684               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   685               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   686               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   687               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   688               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   689               AND "opinion"."degree" = -2
 | 
| 
jbe@615
 | 
   690               AND "opinion"."fulfilled" = TRUE
 | 
| 
jbe@615
 | 
   691             ) AS "minus2_fulfilled_count",
 | 
| 
jbe@615
 | 
   692             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   693               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   694               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   695               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   696               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   697               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   698               AND "opinion"."degree" = -1
 | 
| 
jbe@615
 | 
   699               AND "opinion"."fulfilled" = FALSE
 | 
| 
jbe@615
 | 
   700             ) AS "minus1_unfulfilled_count",
 | 
| 
jbe@615
 | 
   701             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   702               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   703               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   704               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   705               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   706               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   707               AND "opinion"."degree" = -1
 | 
| 
jbe@615
 | 
   708               AND "opinion"."fulfilled" = TRUE
 | 
| 
jbe@615
 | 
   709             ) AS "minus1_fulfilled_count",
 | 
| 
jbe@615
 | 
   710             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   711               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   712               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   713               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   714               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   715               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   716               AND "opinion"."degree" = 1
 | 
| 
jbe@615
 | 
   717               AND "opinion"."fulfilled" = FALSE
 | 
| 
jbe@615
 | 
   718             ) AS "plus1_unfulfilled_count",
 | 
| 
jbe@615
 | 
   719             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   720               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   721               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   722               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   723               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   724               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   725               AND "opinion"."degree" = 1
 | 
| 
jbe@615
 | 
   726               AND "opinion"."fulfilled" = TRUE
 | 
| 
jbe@615
 | 
   727             ) AS "plus1_fulfilled_count",
 | 
| 
jbe@615
 | 
   728             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   729               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   730               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   731               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   732               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   733               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   734               AND "opinion"."degree" = 2
 | 
| 
jbe@615
 | 
   735               AND "opinion"."fulfilled" = FALSE
 | 
| 
jbe@615
 | 
   736             ) AS "plus2_unfulfilled_count",
 | 
| 
jbe@615
 | 
   737             ( SELECT coalesce(sum("di"."weight"), 0)
 | 
| 
jbe@615
 | 
   738               FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
 | 
| 
jbe@615
 | 
   739               ON "di"."snapshot_id" = "snapshot_id_v"
 | 
| 
jbe@615
 | 
   740               AND "di"."issue_id" = "issue_id_v"
 | 
| 
jbe@615
 | 
   741               AND "di"."member_id" = "opinion"."member_id"
 | 
| 
jbe@615
 | 
   742               WHERE "opinion"."suggestion_id" = "suggestion"."id"
 | 
| 
jbe@615
 | 
   743               AND "opinion"."degree" = 2
 | 
| 
jbe@615
 | 
   744               AND "opinion"."fulfilled" = TRUE
 | 
| 
jbe@615
 | 
   745             ) AS "plus2_fulfilled_count"
 | 
| 
jbe@615
 | 
   746             FROM "suggestion" JOIN "initiative"
 | 
| 
jbe@615
 | 
   747             ON "suggestion"."initiative_id" = "initiative"."id"
 | 
| 
jbe@615
 | 
   748             WHERE "initiative"."issue_id" = "issue_id_v";
 | 
| 
jbe@615
 | 
   749       END LOOP;
 | 
| 
jbe@615
 | 
   750       RETURN "snapshot_id_v";
 | 
| 
jbe@615
 | 
   751     END;
 | 
| 
jbe@615
 | 
   752   $$;
 | 
| 
jbe@615
 | 
   753 
 | 
| 
jbe@615
 | 
   754 CREATE OR REPLACE FUNCTION "weight_of_added_vote_delegations"
 | 
| 
jbe@615
 | 
   755   ( "issue_id_p"            "issue"."id"%TYPE,
 | 
| 
jbe@615
 | 
   756     "member_id_p"           "member"."id"%TYPE,
 | 
| 
jbe@615
 | 
   757     "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
 | 
| 
jbe@615
 | 
   758   RETURNS "direct_voter"."weight"%TYPE
 | 
| 
jbe@615
 | 
   759   LANGUAGE 'plpgsql' VOLATILE AS $$
 | 
| 
jbe@615
 | 
   760     DECLARE
 | 
| 
jbe@615
 | 
   761       "issue_delegation_row"  "issue_delegation"%ROWTYPE;
 | 
| 
jbe@615
 | 
   762       "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
 | 
| 
jbe@615
 | 
   763       "weight_v"              INT4;
 | 
| 
jbe@615
 | 
   764       "sub_weight_v"          INT4;
 | 
| 
jbe@615
 | 
   765     BEGIN
 | 
| 
jbe@615
 | 
   766       PERFORM "require_transaction_isolation"();
 | 
| 
jbe@615
 | 
   767       "weight_v" := 0;
 | 
| 
jbe@615
 | 
   768       FOR "issue_delegation_row" IN
 | 
| 
jbe@615
 | 
   769         SELECT * FROM "issue_delegation"
 | 
| 
jbe@615
 | 
   770         WHERE "trustee_id" = "member_id_p"
 | 
| 
jbe@615
 | 
   771         AND "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   772       LOOP
 | 
| 
jbe@615
 | 
   773         IF NOT EXISTS (
 | 
| 
jbe@615
 | 
   774           SELECT NULL FROM "direct_voter"
 | 
| 
jbe@615
 | 
   775           WHERE "member_id" = "issue_delegation_row"."truster_id"
 | 
| 
jbe@615
 | 
   776           AND "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   777         ) AND NOT EXISTS (
 | 
| 
jbe@615
 | 
   778           SELECT NULL FROM "delegating_voter"
 | 
| 
jbe@615
 | 
   779           WHERE "member_id" = "issue_delegation_row"."truster_id"
 | 
| 
jbe@615
 | 
   780           AND "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   781         ) THEN
 | 
| 
jbe@615
 | 
   782           "delegate_member_ids_v" :=
 | 
| 
jbe@615
 | 
   783             "member_id_p" || "delegate_member_ids_p";
 | 
| 
jbe@615
 | 
   784           INSERT INTO "delegating_voter" (
 | 
| 
jbe@615
 | 
   785               "issue_id",
 | 
| 
jbe@615
 | 
   786               "member_id",
 | 
| 
jbe@615
 | 
   787               "ownweight",
 | 
| 
jbe@615
 | 
   788               "scope",
 | 
| 
jbe@615
 | 
   789               "delegate_member_ids"
 | 
| 
jbe@615
 | 
   790             ) VALUES (
 | 
| 
jbe@615
 | 
   791               "issue_id_p",
 | 
| 
jbe@615
 | 
   792               "issue_delegation_row"."truster_id",
 | 
| 
jbe@615
 | 
   793               "issue_delegation_row"."weight",
 | 
| 
jbe@615
 | 
   794               "issue_delegation_row"."scope",
 | 
| 
jbe@615
 | 
   795               "delegate_member_ids_v"
 | 
| 
jbe@615
 | 
   796             );
 | 
| 
jbe@615
 | 
   797           "sub_weight_v" := "issue_delegation_row"."weight" +
 | 
| 
jbe@615
 | 
   798             "weight_of_added_vote_delegations"(
 | 
| 
jbe@615
 | 
   799               "issue_id_p",
 | 
| 
jbe@615
 | 
   800               "issue_delegation_row"."truster_id",
 | 
| 
jbe@615
 | 
   801               "delegate_member_ids_v"
 | 
| 
jbe@615
 | 
   802             );
 | 
| 
jbe@615
 | 
   803           UPDATE "delegating_voter"
 | 
| 
jbe@615
 | 
   804             SET "weight" = "sub_weight_v"
 | 
| 
jbe@615
 | 
   805             WHERE "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   806             AND "member_id" = "issue_delegation_row"."truster_id";
 | 
| 
jbe@615
 | 
   807           "weight_v" := "weight_v" + "sub_weight_v";
 | 
| 
jbe@615
 | 
   808         END IF;
 | 
| 
jbe@615
 | 
   809       END LOOP;
 | 
| 
jbe@615
 | 
   810       RETURN "weight_v";
 | 
| 
jbe@615
 | 
   811     END;
 | 
| 
jbe@615
 | 
   812   $$;
 | 
| 
jbe@615
 | 
   813 
 | 
| 
jbe@615
 | 
   814 CREATE OR REPLACE FUNCTION "add_vote_delegations"
 | 
| 
jbe@615
 | 
   815   ( "issue_id_p" "issue"."id"%TYPE )
 | 
| 
jbe@615
 | 
   816   RETURNS VOID
 | 
| 
jbe@615
 | 
   817   LANGUAGE 'plpgsql' VOLATILE AS $$
 | 
| 
jbe@615
 | 
   818     DECLARE
 | 
| 
jbe@615
 | 
   819       "member_id_v" "member"."id"%TYPE;
 | 
| 
jbe@615
 | 
   820     BEGIN
 | 
| 
jbe@615
 | 
   821       PERFORM "require_transaction_isolation"();
 | 
| 
jbe@615
 | 
   822       FOR "member_id_v" IN
 | 
| 
jbe@615
 | 
   823         SELECT "member_id" FROM "direct_voter"
 | 
| 
jbe@615
 | 
   824         WHERE "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   825       LOOP
 | 
| 
jbe@615
 | 
   826         UPDATE "direct_voter" SET
 | 
| 
jbe@615
 | 
   827           "weight" = "ownweight" + "weight_of_added_vote_delegations"(
 | 
| 
jbe@615
 | 
   828             "issue_id_p",
 | 
| 
jbe@615
 | 
   829             "member_id_v",
 | 
| 
jbe@615
 | 
   830             '{}'
 | 
| 
jbe@615
 | 
   831           )
 | 
| 
jbe@615
 | 
   832           WHERE "member_id" = "member_id_v"
 | 
| 
jbe@615
 | 
   833           AND "issue_id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   834       END LOOP;
 | 
| 
jbe@615
 | 
   835       RETURN;
 | 
| 
jbe@615
 | 
   836     END;
 | 
| 
jbe@615
 | 
   837   $$;
 | 
| 
jbe@615
 | 
   838 
 | 
| 
jbe@615
 | 
   839 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
 | 
| 
jbe@615
 | 
   840   RETURNS VOID
 | 
| 
jbe@615
 | 
   841   LANGUAGE 'plpgsql' VOLATILE AS $$
 | 
| 
jbe@615
 | 
   842     DECLARE
 | 
| 
jbe@615
 | 
   843       "area_id_v"   "area"."id"%TYPE;
 | 
| 
jbe@615
 | 
   844       "unit_id_v"   "unit"."id"%TYPE;
 | 
| 
jbe@615
 | 
   845       "member_id_v" "member"."id"%TYPE;
 | 
| 
jbe@615
 | 
   846     BEGIN
 | 
| 
jbe@615
 | 
   847       PERFORM "require_transaction_isolation"();
 | 
| 
jbe@615
 | 
   848       SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   849       SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
 | 
| 
jbe@615
 | 
   850       -- override protection triggers:
 | 
| 
jbe@615
 | 
   851       INSERT INTO "temporary_transaction_data" ("key", "value")
 | 
| 
jbe@615
 | 
   852         VALUES ('override_protection_triggers', TRUE::TEXT);
 | 
| 
jbe@615
 | 
   853       -- delete timestamp of voting comment:
 | 
| 
jbe@615
 | 
   854       UPDATE "direct_voter" SET "comment_changed" = NULL
 | 
| 
jbe@615
 | 
   855         WHERE "issue_id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   856       -- delete delegating votes (in cases of manual reset of issue state):
 | 
| 
jbe@615
 | 
   857       DELETE FROM "delegating_voter"
 | 
| 
jbe@615
 | 
   858         WHERE "issue_id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   859       -- delete votes from non-privileged voters:
 | 
| 
jbe@615
 | 
   860       DELETE FROM "direct_voter"
 | 
| 
jbe@615
 | 
   861         USING (
 | 
| 
jbe@615
 | 
   862           SELECT "direct_voter"."member_id"
 | 
| 
jbe@615
 | 
   863           FROM "direct_voter"
 | 
| 
jbe@615
 | 
   864           JOIN "member" ON "direct_voter"."member_id" = "member"."id"
 | 
| 
jbe@615
 | 
   865           LEFT JOIN "privilege"
 | 
| 
jbe@615
 | 
   866           ON "privilege"."unit_id" = "unit_id_v"
 | 
| 
jbe@615
 | 
   867           AND "privilege"."member_id" = "direct_voter"."member_id"
 | 
| 
jbe@615
 | 
   868           LEFT JOIN "issue_privilege"
 | 
| 
jbe@615
 | 
   869           ON "issue_privilege"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   870           AND "issue_privilege"."member_id" = "direct_voter"."member_id"
 | 
| 
jbe@615
 | 
   871           WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
 | 
| 
jbe@615
 | 
   872             "member"."active" = FALSE OR
 | 
| 
jbe@615
 | 
   873             COALESCE(
 | 
| 
jbe@615
 | 
   874               "issue_privilege"."voting_right",
 | 
| 
jbe@615
 | 
   875               "privilege"."voting_right",
 | 
| 
jbe@615
 | 
   876               FALSE
 | 
| 
jbe@615
 | 
   877             ) = FALSE
 | 
| 
jbe@615
 | 
   878           )
 | 
| 
jbe@615
 | 
   879         ) AS "subquery"
 | 
| 
jbe@615
 | 
   880         WHERE "direct_voter"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   881         AND "direct_voter"."member_id" = "subquery"."member_id";
 | 
| 
jbe@615
 | 
   882       -- consider voting weight and delegations:
 | 
| 
jbe@615
 | 
   883       UPDATE "direct_voter" SET "ownweight" = "privilege"."weight"
 | 
| 
jbe@615
 | 
   884         FROM "privilege"
 | 
| 
jbe@615
 | 
   885         WHERE "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   886         AND "privilege"."unit_id" = "unit_id_v"
 | 
| 
jbe@615
 | 
   887         AND "privilege"."member_id" = "direct_voter"."member_id";
 | 
| 
jbe@615
 | 
   888       UPDATE "direct_voter" SET "ownweight" = "issue_privilege"."weight"
 | 
| 
jbe@615
 | 
   889         FROM "issue_privilege"
 | 
| 
jbe@615
 | 
   890         WHERE "direct_voter"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   891         AND "issue_privilege"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   892         AND "issue_privilege"."member_id" = "direct_voter"."member_id";
 | 
| 
jbe@615
 | 
   893       PERFORM "add_vote_delegations"("issue_id_p");
 | 
| 
jbe@615
 | 
   894       -- mark first preferences:
 | 
| 
jbe@615
 | 
   895       UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
 | 
| 
jbe@615
 | 
   896         FROM (
 | 
| 
jbe@615
 | 
   897           SELECT
 | 
| 
jbe@615
 | 
   898             "vote"."initiative_id",
 | 
| 
jbe@615
 | 
   899             "vote"."member_id",
 | 
| 
jbe@615
 | 
   900             CASE WHEN "vote"."grade" > 0 THEN
 | 
| 
jbe@615
 | 
   901               CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
 | 
| 
jbe@615
 | 
   902             ELSE NULL
 | 
| 
jbe@615
 | 
   903             END AS "first_preference"
 | 
| 
jbe@615
 | 
   904           FROM "vote"
 | 
| 
jbe@615
 | 
   905           JOIN "initiative"  -- NOTE: due to missing index on issue_id
 | 
| 
jbe@615
 | 
   906           ON "vote"."issue_id" = "initiative"."issue_id"
 | 
| 
jbe@615
 | 
   907           JOIN "vote" AS "agg"
 | 
| 
jbe@615
 | 
   908           ON "initiative"."id" = "agg"."initiative_id"
 | 
| 
jbe@615
 | 
   909           AND "vote"."member_id" = "agg"."member_id"
 | 
| 
jbe@615
 | 
   910           GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
 | 
| 
jbe@615
 | 
   911         ) AS "subquery"
 | 
| 
jbe@615
 | 
   912         WHERE "vote"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   913         AND "vote"."initiative_id" = "subquery"."initiative_id"
 | 
| 
jbe@615
 | 
   914         AND "vote"."member_id" = "subquery"."member_id";
 | 
| 
jbe@615
 | 
   915       -- finish overriding protection triggers (avoids garbage):
 | 
| 
jbe@615
 | 
   916       DELETE FROM "temporary_transaction_data"
 | 
| 
jbe@615
 | 
   917         WHERE "key" = 'override_protection_triggers';
 | 
| 
jbe@615
 | 
   918       -- materialize battle_view:
 | 
| 
jbe@615
 | 
   919       -- NOTE: "closed" column of issue must be set at this point
 | 
| 
jbe@615
 | 
   920       DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   921       INSERT INTO "battle" (
 | 
| 
jbe@615
 | 
   922         "issue_id",
 | 
| 
jbe@615
 | 
   923         "winning_initiative_id", "losing_initiative_id",
 | 
| 
jbe@615
 | 
   924         "count"
 | 
| 
jbe@615
 | 
   925       ) SELECT
 | 
| 
jbe@615
 | 
   926         "issue_id",
 | 
| 
jbe@615
 | 
   927         "winning_initiative_id", "losing_initiative_id",
 | 
| 
jbe@615
 | 
   928         "count"
 | 
| 
jbe@615
 | 
   929         FROM "battle_view" WHERE "issue_id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   930       -- set voter count:
 | 
| 
jbe@615
 | 
   931       UPDATE "issue" SET
 | 
| 
jbe@615
 | 
   932         "voter_count" = (
 | 
| 
jbe@615
 | 
   933           SELECT coalesce(sum("weight"), 0)
 | 
| 
jbe@615
 | 
   934           FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   935         )
 | 
| 
jbe@615
 | 
   936         WHERE "id" = "issue_id_p";
 | 
| 
jbe@615
 | 
   937       -- copy "positive_votes" and "negative_votes" from "battle" table:
 | 
| 
jbe@615
 | 
   938       -- NOTE: "first_preference_votes" is set to a default of 0 at this step
 | 
| 
jbe@615
 | 
   939       UPDATE "initiative" SET
 | 
| 
jbe@615
 | 
   940         "first_preference_votes" = 0,
 | 
| 
jbe@615
 | 
   941         "positive_votes" = "battle_win"."count",
 | 
| 
jbe@615
 | 
   942         "negative_votes" = "battle_lose"."count"
 | 
| 
jbe@615
 | 
   943         FROM "battle" AS "battle_win", "battle" AS "battle_lose"
 | 
| 
jbe@615
 | 
   944         WHERE
 | 
| 
jbe@615
 | 
   945           "battle_win"."issue_id" = "issue_id_p" AND
 | 
| 
jbe@615
 | 
   946           "battle_win"."winning_initiative_id" = "initiative"."id" AND
 | 
| 
jbe@615
 | 
   947           "battle_win"."losing_initiative_id" ISNULL AND
 | 
| 
jbe@615
 | 
   948           "battle_lose"."issue_id" = "issue_id_p" AND
 | 
| 
jbe@615
 | 
   949           "battle_lose"."losing_initiative_id" = "initiative"."id" AND
 | 
| 
jbe@615
 | 
   950           "battle_lose"."winning_initiative_id" ISNULL;
 | 
| 
jbe@615
 | 
   951       -- calculate "first_preference_votes":
 | 
| 
jbe@615
 | 
   952       -- NOTE: will only set values not equal to zero
 | 
| 
jbe@615
 | 
   953       UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
 | 
| 
jbe@615
 | 
   954         FROM (
 | 
| 
jbe@615
 | 
   955           SELECT "vote"."initiative_id", sum("direct_voter"."weight")
 | 
| 
jbe@615
 | 
   956           FROM "vote" JOIN "direct_voter"
 | 
| 
jbe@615
 | 
   957           ON "vote"."issue_id" = "direct_voter"."issue_id"
 | 
| 
jbe@615
 | 
   958           AND "vote"."member_id" = "direct_voter"."member_id"
 | 
| 
jbe@615
 | 
   959           WHERE "vote"."first_preference"
 | 
| 
jbe@615
 | 
   960           GROUP BY "vote"."initiative_id"
 | 
| 
jbe@615
 | 
   961         ) AS "subquery"
 | 
| 
jbe@615
 | 
   962         WHERE "initiative"."issue_id" = "issue_id_p"
 | 
| 
jbe@615
 | 
   963         AND "initiative"."admitted"
 | 
| 
jbe@615
 | 
   964         AND "initiative"."id" = "subquery"."initiative_id";
 | 
| 
jbe@615
 | 
   965     END;
 | 
| 
jbe@615
 | 
   966   $$;
 | 
| 
jbe@615
 | 
   967 
 | 
| 
jbe@615
 | 
   968 COMMIT;
 |