liquid_feedback_core

changeset 177:9975ce3f20ee

First version of update script from v1.4.0 to v1.5.0
author jbe
date Wed Jun 08 17:31:00 2011 +0200 (2011-06-08)
parents b2d87fbb123b
children 184b023a5b1d
files update/core-update.v1.4.0-v1.5.0.sql
line diff
     1.1 --- /dev/null	Thu Jan 01 00:00:00 1970 +0000
     1.2 +++ b/update/core-update.v1.4.0-v1.5.0.sql	Wed Jun 08 17:31:00 2011 +0200
     1.3 @@ -0,0 +1,1044 @@
     1.4 +BEGIN;
     1.5 +
     1.6 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     1.7 +  SELECT * FROM (VALUES ('1.5.0_devel', 1, 5, -1))
     1.8 +  AS "subquery"("string", "major", "minor", "revision");
     1.9 +
    1.10 +ALTER TABLE "member" ADD COLUMN "formatting_engine" TEXT;
    1.11 +COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
    1.12 +
    1.13 +CREATE TABLE "rendered_member_statement" (
    1.14 +        PRIMARY KEY ("member_id", "format"),
    1.15 +        "member_id"             INT8            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
    1.16 +        "format"                TEXT,
    1.17 +        "content"               TEXT            NOT NULL );
    1.18 +
    1.19 +COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)';
    1.20 +
    1.21 +ALTER TABLE "policy" ADD COLUMN "direct_majority_num"            INT4    NOT NULL DEFAULT 1;
    1.22 +ALTER TABLE "policy" ADD COLUMN "direct_majority_den"            INT4    NOT NULL DEFAULT 2;
    1.23 +ALTER TABLE "policy" ADD COLUMN "direct_majority_strict"         BOOLEAN NOT NULL DEFAULT TRUE;
    1.24 +ALTER TABLE "policy" ADD COLUMN "direct_majority_positive"       INT4    NOT NULL DEFAULT 0;
    1.25 +ALTER TABLE "policy" ADD COLUMN "direct_majority_non_negative"   INT4    NOT NULL DEFAULT 0;
    1.26 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_num"          INT4    NOT NULL DEFAULT 1;
    1.27 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_den"          INT4    NOT NULL DEFAULT 2;
    1.28 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_strict"       BOOLEAN NOT NULL DEFAULT TRUE;
    1.29 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_positive"     INT4    NOT NULL DEFAULT 0;
    1.30 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_non_negative" INT4    NOT NULL DEFAULT 0;
    1.31 +ALTER TABLE "policy" ADD COLUMN "no_reverse_beat_path"           BOOLEAN NOT NULL DEFAULT TRUE;
    1.32 +ALTER TABLE "policy" ADD COLUMN "no_multistage_majority"         BOOLEAN NOT NULL DEFAULT FALSE;
    1.33 +
    1.34 +UPDATE "policy" SET
    1.35 +  "direct_majority_num"      = "majority_num",
    1.36 +  "direct_majority_den"      = "majority_den",
    1.37 +  "direct_majority_strict"   = "majority_strict",
    1.38 +  "indirect_majority_num"    = "majority_num",
    1.39 +  "indirect_majority_den"    = "majority_den",
    1.40 +  "indirect_majority_strict" = "majority_strict";
    1.41 +
    1.42 +ALTER TABLE "policy" DROP COLUMN "majority_num";
    1.43 +ALTER TABLE "policy" DROP COLUMN "majority_den";
    1.44 +ALTER TABLE "policy" DROP COLUMN "majority_strict";
    1.45 +
    1.46 +COMMENT ON COLUMN "policy"."direct_majority_num"            IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
    1.47 +COMMENT ON COLUMN "policy"."direct_majority_den"            IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
    1.48 +COMMENT ON COLUMN "policy"."direct_majority_strict"         IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.';
    1.49 +COMMENT ON COLUMN "policy"."direct_majority_positive"       IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
    1.50 +COMMENT ON COLUMN "policy"."direct_majority_non_negative"   IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner';
    1.51 +COMMENT ON COLUMN "policy"."indirect_majority_num"          IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
    1.52 +COMMENT ON COLUMN "policy"."indirect_majority_den"          IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
    1.53 +COMMENT ON COLUMN "policy"."indirect_majority_strict"       IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.';
    1.54 +COMMENT ON COLUMN "policy"."indirect_majority_positive"     IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner';
    1.55 +COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner';
    1.56 +COMMENT ON COLUMN "policy"."no_reverse_beat_path"           IS 'Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
    1.57 +COMMENT ON COLUMN "policy"."no_multistage_majority"         IS 'Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
    1.58 +
    1.59 +ALTER TABLE "area" DROP COLUMN "autoreject_weight";
    1.60 +
    1.61 +DROP VIEW "open_issue";
    1.62 +DROP VIEW "issue_with_ranks_missing";
    1.63 +
    1.64 +ALTER TABLE "issue" DROP COLUMN "vote_now";
    1.65 +ALTER TABLE "issue" DROP COLUMN "vote_later";
    1.66 +ALTER TABLE "issue" ADD COLUMN "status_quo_schulze_rank" INT4;
    1.67 +
    1.68 +CREATE VIEW "open_issue" AS
    1.69 +  SELECT * FROM "issue" WHERE "closed" ISNULL;
    1.70 +
    1.71 +COMMENT ON VIEW "open_issue" IS 'All open issues';
    1.72 +
    1.73 +CREATE VIEW "issue_with_ranks_missing" AS
    1.74 +  SELECT * FROM "issue"
    1.75 +  WHERE "fully_frozen" NOTNULL
    1.76 +  AND "closed" NOTNULL
    1.77 +  AND "ranks_available" = FALSE;
    1.78 +
    1.79 +COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
    1.80 +
    1.81 +COMMENT ON COLUMN "issue"."half_frozen"             IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
    1.82 +COMMENT ON COLUMN "issue"."snapshot"                IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
    1.83 +COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
    1.84 +
    1.85 +ALTER TABLE "initiative" ADD COLUMN "direct_majority"        BOOLEAN;
    1.86 +ALTER TABLE "initiative" ADD COLUMN "indirect_majority"      BOOLEAN;
    1.87 +ALTER TABLE "initiative" ADD COLUMN "schulze_rank"           INT4;
    1.88 +ALTER TABLE "initiative" ADD COLUMN "better_than_status_quo" BOOLEAN;
    1.89 +ALTER TABLE "initiative" ADD COLUMN "worse_than_status_quo"  BOOLEAN;
    1.90 +ALTER TABLE "initiative" ADD COLUMN "reverse_beat_path"      BOOLEAN;
    1.91 +ALTER TABLE "initiative" ADD COLUMN "multistage_majority"    BOOLEAN;
    1.92 +ALTER TABLE "initiative" ADD COLUMN "eligible"               BOOLEAN;
    1.93 +ALTER TABLE "initiative" ADD COLUMN "winner"                 BOOLEAN;
    1.94 +
    1.95 +ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
    1.96 +ALTER TABLE "initiative" DROP CONSTRAINT  "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null";
    1.97 +ALTER TABLE "initiative" DROP CONSTRAINT "non_agreed_initiatives_cant_get_a_rank";
    1.98 +
    1.99 +ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
   1.100 +  ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
   1.101 +  ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
   1.102 +    "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
   1.103 +    "schulze_rank" ISNULL AND
   1.104 +    "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
   1.105 +    "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
   1.106 +    "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
   1.107 +ALTER TABLE "initiative" ADD CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo"));
   1.108 +ALTER TABLE "initiative" ADD CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
   1.109 +  "eligible" = FALSE OR
   1.110 +("direct_majority" AND "indirect_majority" AND "better_than_status_quo") );
   1.111 +ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE);
   1.112 +ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1);
   1.113 +ALTER TABLE "initiative" ADD CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE);
   1.114 +ALTER TABLE "initiative" ADD CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank");
   1.115 +
   1.116 +COMMENT ON COLUMN "initiative"."direct_majority"         IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
   1.117 +COMMENT ON COLUMN "initiative"."indirect_majority"       IS 'Same as "direct_majority", but also considering indirect beat paths';
   1.118 +COMMENT ON COLUMN "initiative"."schulze_rank"            IS 'Schulze-Ranking without tie-breaking';
   1.119 +COMMENT ON COLUMN "initiative"."better_than_status_quo"  IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
   1.120 +COMMENT ON COLUMN "initiative"."worse_than_status_quo"   IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
   1.121 +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';
   1.122 +COMMENT ON COLUMN "initiative"."multistage_majority"     IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
   1.123 +COMMENT ON COLUMN "initiative"."eligible"                IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
   1.124 +COMMENT ON COLUMN "initiative"."winner"                  IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
   1.125 +COMMENT ON COLUMN "initiative"."rank"                    IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
   1.126 +
   1.127 +ALTER TABLE "battle" DROP CONSTRAINT "battle_pkey";
   1.128 +ALTER TABLE "battle" ALTER COLUMN "issue_id" SET NOT NULL;
   1.129 +ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK (
   1.130 +  "winning_initiative_id" != "losing_initiative_id" OR
   1.131 +  ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
   1.132 +    ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) );
   1.133 +
   1.134 +CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
   1.135 +CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
   1.136 +CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
   1.137 +
   1.138 +ALTER TABLE "suggestion" ADD COLUMN "draft_id" INT8;
   1.139 +-- more later
   1.140 +
   1.141 +ALTER TABLE "suggestion" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
   1.142 +ALTER TABLE "suggestion" ADD COLUMN "formatting_engine" TEXT;
   1.143 +ALTER TABLE "suggestion" RENAME COLUMN "description" TO "content";
   1.144 +
   1.145 +DROP TRIGGER "update_text_search_data" ON "suggestion";
   1.146 +
   1.147 +CREATE TRIGGER "update_text_search_data"
   1.148 +  BEFORE INSERT OR UPDATE ON "suggestion"
   1.149 +  FOR EACH ROW EXECUTE PROCEDURE
   1.150 +  tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
   1.151 +    "name", "content");
   1.152 +
   1.153 +COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
   1.154 +
   1.155 +CREATE TABLE "rendered_suggestion" (
   1.156 +        PRIMARY KEY ("suggestion_id", "format"),
   1.157 +        "suggestion_id"         INT8            REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.158 +        "format"                TEXT,
   1.159 +        "content"               TEXT            NOT NULL );
   1.160 +
   1.161 +COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
   1.162 +
   1.163 +DROP VIEW "area_member_count";
   1.164 +
   1.165 +ALTER TABLE "membership" DROP COLUMN "autoreject";
   1.166 +
   1.167 +ALTER TABLE "interest" DROP COLUMN "autoreject";
   1.168 +ALTER TABLE "interest" DROP COLUMN "voting_requested";
   1.169 +
   1.170 +ALTER TABLE "supporter" DROP CONSTRAINT "supporter_initiative_id_fkey";
   1.171 +ALTER TABLE "supporter" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
   1.172 +
   1.173 +COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
   1.174 +
   1.175 +ALTER TABLE "direct_interest_snapshot" DROP COLUMN "voting_requested";
   1.176 +ALTER TABLE "direct_voter" DROP COLUMN "autoreject";
   1.177 +
   1.178 +DROP TRIGGER "default_for_draft_id" ON "supporter";
   1.179 +DROP FUNCTION "supporter_default_for_draft_id_trigger"();
   1.180 +
   1.181 +CREATE FUNCTION "default_for_draft_id_trigger"()
   1.182 +  RETURNS TRIGGER
   1.183 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.184 +    BEGIN
   1.185 +      IF NEW."draft_id" ISNULL THEN
   1.186 +        SELECT "id" INTO NEW."draft_id" FROM "current_draft"
   1.187 +          WHERE "initiative_id" = NEW."initiative_id";
   1.188 +      END IF;
   1.189 +      RETURN NEW;
   1.190 +    END;
   1.191 +  $$;
   1.192 +
   1.193 +CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
   1.194 +  FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
   1.195 +CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
   1.196 +  FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
   1.197 +
   1.198 +COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
   1.199 +COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
   1.200 +COMMENT ON TRIGGER "default_for_draft_id" ON "supporter"  IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
   1.201 +
   1.202 +CREATE VIEW "area_member_count" AS
   1.203 +  SELECT
   1.204 +    "area"."id" AS "area_id",
   1.205 +    count("member"."id") AS "direct_member_count",
   1.206 +    coalesce(
   1.207 +      sum(
   1.208 +        CASE WHEN "member"."id" NOTNULL THEN
   1.209 +          "membership_weight"("area"."id", "member"."id")
   1.210 +        ELSE 0 END
   1.211 +      )
   1.212 +    ) AS "member_weight"
   1.213 +  FROM "area"
   1.214 +  LEFT JOIN "membership"
   1.215 +  ON "area"."id" = "membership"."area_id"
   1.216 +  LEFT JOIN "privilege"
   1.217 +  ON "privilege"."unit_id" = "area"."unit_id"
   1.218 +  AND "privilege"."member_id" = "membership"."member_id"
   1.219 +  AND "privilege"."voting_right"
   1.220 +  LEFT JOIN "member"
   1.221 +  ON "member"."id" = "privilege"."member_id"  -- NOTE: no membership here!
   1.222 +  AND "member"."active"
   1.223 +  GROUP BY "area"."id";
   1.224 +
   1.225 +COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
   1.226 +
   1.227 +CREATE VIEW "battle_participant" AS
   1.228 +    SELECT "initiative"."id", "initiative"."issue_id"
   1.229 +    FROM "issue" JOIN "initiative"
   1.230 +    ON "issue"."id" = "initiative"."issue_id"
   1.231 +    WHERE "initiative"."admitted"
   1.232 +  UNION ALL
   1.233 +    SELECT NULL, "id" AS "issue_id"
   1.234 +    FROM "issue";
   1.235 +
   1.236 +COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
   1.237 +
   1.238 +CREATE OR REPLACE VIEW "battle_view" AS
   1.239 +  SELECT
   1.240 +    "issue"."id" AS "issue_id",
   1.241 +    "winning_initiative"."id" AS "winning_initiative_id",
   1.242 +    "losing_initiative"."id" AS "losing_initiative_id",
   1.243 +    sum(
   1.244 +      CASE WHEN
   1.245 +        coalesce("better_vote"."grade", 0) >
   1.246 +        coalesce("worse_vote"."grade", 0)
   1.247 +      THEN "direct_voter"."weight" ELSE 0 END
   1.248 +    ) AS "count"
   1.249 +  FROM "issue"
   1.250 +  LEFT JOIN "direct_voter"
   1.251 +  ON "issue"."id" = "direct_voter"."issue_id"
   1.252 +  JOIN "battle_participant" AS "winning_initiative"
   1.253 +    ON "issue"."id" = "winning_initiative"."issue_id"
   1.254 +  JOIN "battle_participant" AS "losing_initiative"
   1.255 +    ON "issue"."id" = "losing_initiative"."issue_id"
   1.256 +  LEFT JOIN "vote" AS "better_vote"
   1.257 +    ON "direct_voter"."member_id" = "better_vote"."member_id"
   1.258 +    AND "winning_initiative"."id" = "better_vote"."initiative_id"
   1.259 +  LEFT JOIN "vote" AS "worse_vote"
   1.260 +    ON "direct_voter"."member_id" = "worse_vote"."member_id"
   1.261 +    AND "losing_initiative"."id" = "worse_vote"."initiative_id"
   1.262 +  WHERE "issue"."closed" NOTNULL
   1.263 +  AND "issue"."cleaned" ISNULL
   1.264 +  AND (
   1.265 +    "winning_initiative"."id" != "losing_initiative"."id" OR
   1.266 +    ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
   1.267 +      ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
   1.268 +  GROUP BY
   1.269 +    "issue"."id",
   1.270 +    "winning_initiative"."id",
   1.271 +    "losing_initiative"."id";
   1.272 +
   1.273 +COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative (or status-quo) to another initiative (or status-quo); Used to fill "battle" table';
   1.274 +
   1.275 +CREATE OR REPLACE FUNCTION "create_interest_snapshot"
   1.276 +  ( "issue_id_p" "issue"."id"%TYPE )
   1.277 +  RETURNS VOID
   1.278 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.279 +    DECLARE
   1.280 +      "member_id_v" "member"."id"%TYPE;
   1.281 +    BEGIN
   1.282 +      DELETE FROM "direct_interest_snapshot"
   1.283 +        WHERE "issue_id" = "issue_id_p"
   1.284 +        AND "event" = 'periodic';
   1.285 +      DELETE FROM "delegating_interest_snapshot"
   1.286 +        WHERE "issue_id" = "issue_id_p"
   1.287 +        AND "event" = 'periodic';
   1.288 +      DELETE FROM "direct_supporter_snapshot"
   1.289 +        WHERE "issue_id" = "issue_id_p"
   1.290 +        AND "event" = 'periodic';
   1.291 +      INSERT INTO "direct_interest_snapshot"
   1.292 +        ("issue_id", "event", "member_id")
   1.293 +        SELECT
   1.294 +          "issue_id_p"  AS "issue_id",
   1.295 +          'periodic'    AS "event",
   1.296 +          "member"."id" AS "member_id"
   1.297 +        FROM "issue"
   1.298 +        JOIN "area" ON "issue"."area_id" = "area"."id"
   1.299 +        JOIN "interest" ON "issue"."id" = "interest"."issue_id"
   1.300 +        JOIN "member" ON "interest"."member_id" = "member"."id"
   1.301 +        JOIN "privilege"
   1.302 +          ON "privilege"."unit_id" = "area"."unit_id"
   1.303 +          AND "privilege"."member_id" = "member"."id"
   1.304 +        WHERE "issue"."id" = "issue_id_p"
   1.305 +        AND "member"."active" AND "privilege"."voting_right";
   1.306 +      FOR "member_id_v" IN
   1.307 +        SELECT "member_id" FROM "direct_interest_snapshot"
   1.308 +        WHERE "issue_id" = "issue_id_p"
   1.309 +        AND "event" = 'periodic'
   1.310 +      LOOP
   1.311 +        UPDATE "direct_interest_snapshot" SET
   1.312 +          "weight" = 1 +
   1.313 +            "weight_of_added_delegations_for_interest_snapshot"(
   1.314 +              "issue_id_p",
   1.315 +              "member_id_v",
   1.316 +              '{}'
   1.317 +            )
   1.318 +          WHERE "issue_id" = "issue_id_p"
   1.319 +          AND "event" = 'periodic'
   1.320 +          AND "member_id" = "member_id_v";
   1.321 +      END LOOP;
   1.322 +      INSERT INTO "direct_supporter_snapshot"
   1.323 +        ( "issue_id", "initiative_id", "event", "member_id",
   1.324 +          "informed", "satisfied" )
   1.325 +        SELECT
   1.326 +          "issue_id_p"            AS "issue_id",
   1.327 +          "initiative"."id"       AS "initiative_id",
   1.328 +          'periodic'              AS "event",
   1.329 +          "supporter"."member_id" AS "member_id",
   1.330 +          "supporter"."draft_id" = "current_draft"."id" AS "informed",
   1.331 +          NOT EXISTS (
   1.332 +            SELECT NULL FROM "critical_opinion"
   1.333 +            WHERE "initiative_id" = "initiative"."id"
   1.334 +            AND "member_id" = "supporter"."member_id"
   1.335 +          ) AS "satisfied"
   1.336 +        FROM "initiative"
   1.337 +        JOIN "supporter"
   1.338 +        ON "supporter"."initiative_id" = "initiative"."id"
   1.339 +        JOIN "current_draft"
   1.340 +        ON "initiative"."id" = "current_draft"."initiative_id"
   1.341 +        JOIN "direct_interest_snapshot"
   1.342 +        ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
   1.343 +        AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
   1.344 +        AND "event" = 'periodic'
   1.345 +        WHERE "initiative"."issue_id" = "issue_id_p";
   1.346 +      RETURN;
   1.347 +    END;
   1.348 +  $$;
   1.349 +
   1.350 +CREATE OR REPLACE FUNCTION "create_snapshot"
   1.351 +  ( "issue_id_p" "issue"."id"%TYPE )
   1.352 +  RETURNS VOID
   1.353 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.354 +    DECLARE
   1.355 +      "initiative_id_v"    "initiative"."id"%TYPE;
   1.356 +      "suggestion_id_v"    "suggestion"."id"%TYPE;
   1.357 +    BEGIN
   1.358 +      PERFORM "lock_issue"("issue_id_p");
   1.359 +      PERFORM "create_population_snapshot"("issue_id_p");
   1.360 +      PERFORM "create_interest_snapshot"("issue_id_p");
   1.361 +      UPDATE "issue" SET
   1.362 +        "snapshot" = now(),
   1.363 +        "latest_snapshot_event" = 'periodic',
   1.364 +        "population" = (
   1.365 +          SELECT coalesce(sum("weight"), 0)
   1.366 +          FROM "direct_population_snapshot"
   1.367 +          WHERE "issue_id" = "issue_id_p"
   1.368 +          AND "event" = 'periodic'
   1.369 +        )
   1.370 +        WHERE "id" = "issue_id_p";
   1.371 +      FOR "initiative_id_v" IN
   1.372 +        SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
   1.373 +      LOOP
   1.374 +        UPDATE "initiative" SET
   1.375 +          "supporter_count" = (
   1.376 +            SELECT coalesce(sum("di"."weight"), 0)
   1.377 +            FROM "direct_interest_snapshot" AS "di"
   1.378 +            JOIN "direct_supporter_snapshot" AS "ds"
   1.379 +            ON "di"."member_id" = "ds"."member_id"
   1.380 +            WHERE "di"."issue_id" = "issue_id_p"
   1.381 +            AND "di"."event" = 'periodic'
   1.382 +            AND "ds"."initiative_id" = "initiative_id_v"
   1.383 +            AND "ds"."event" = 'periodic'
   1.384 +          ),
   1.385 +          "informed_supporter_count" = (
   1.386 +            SELECT coalesce(sum("di"."weight"), 0)
   1.387 +            FROM "direct_interest_snapshot" AS "di"
   1.388 +            JOIN "direct_supporter_snapshot" AS "ds"
   1.389 +            ON "di"."member_id" = "ds"."member_id"
   1.390 +            WHERE "di"."issue_id" = "issue_id_p"
   1.391 +            AND "di"."event" = 'periodic'
   1.392 +            AND "ds"."initiative_id" = "initiative_id_v"
   1.393 +            AND "ds"."event" = 'periodic'
   1.394 +            AND "ds"."informed"
   1.395 +          ),
   1.396 +          "satisfied_supporter_count" = (
   1.397 +            SELECT coalesce(sum("di"."weight"), 0)
   1.398 +            FROM "direct_interest_snapshot" AS "di"
   1.399 +            JOIN "direct_supporter_snapshot" AS "ds"
   1.400 +            ON "di"."member_id" = "ds"."member_id"
   1.401 +            WHERE "di"."issue_id" = "issue_id_p"
   1.402 +            AND "di"."event" = 'periodic'
   1.403 +            AND "ds"."initiative_id" = "initiative_id_v"
   1.404 +            AND "ds"."event" = 'periodic'
   1.405 +            AND "ds"."satisfied"
   1.406 +          ),
   1.407 +          "satisfied_informed_supporter_count" = (
   1.408 +            SELECT coalesce(sum("di"."weight"), 0)
   1.409 +            FROM "direct_interest_snapshot" AS "di"
   1.410 +            JOIN "direct_supporter_snapshot" AS "ds"
   1.411 +            ON "di"."member_id" = "ds"."member_id"
   1.412 +            WHERE "di"."issue_id" = "issue_id_p"
   1.413 +            AND "di"."event" = 'periodic'
   1.414 +            AND "ds"."initiative_id" = "initiative_id_v"
   1.415 +            AND "ds"."event" = 'periodic'
   1.416 +            AND "ds"."informed"
   1.417 +            AND "ds"."satisfied"
   1.418 +          )
   1.419 +          WHERE "id" = "initiative_id_v";
   1.420 +        FOR "suggestion_id_v" IN
   1.421 +          SELECT "id" FROM "suggestion"
   1.422 +          WHERE "initiative_id" = "initiative_id_v"
   1.423 +        LOOP
   1.424 +          UPDATE "suggestion" SET
   1.425 +            "minus2_unfulfilled_count" = (
   1.426 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.427 +              FROM "issue" CROSS JOIN "opinion"
   1.428 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.429 +              ON "snapshot"."issue_id" = "issue"."id"
   1.430 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.431 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.432 +              WHERE "issue"."id" = "issue_id_p"
   1.433 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.434 +              AND "opinion"."degree" = -2
   1.435 +              AND "opinion"."fulfilled" = FALSE
   1.436 +            ),
   1.437 +            "minus2_fulfilled_count" = (
   1.438 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.439 +              FROM "issue" CROSS JOIN "opinion"
   1.440 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.441 +              ON "snapshot"."issue_id" = "issue"."id"
   1.442 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.443 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.444 +              WHERE "issue"."id" = "issue_id_p"
   1.445 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.446 +              AND "opinion"."degree" = -2
   1.447 +              AND "opinion"."fulfilled" = TRUE
   1.448 +            ),
   1.449 +            "minus1_unfulfilled_count" = (
   1.450 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.451 +              FROM "issue" CROSS JOIN "opinion"
   1.452 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.453 +              ON "snapshot"."issue_id" = "issue"."id"
   1.454 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.455 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.456 +              WHERE "issue"."id" = "issue_id_p"
   1.457 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.458 +              AND "opinion"."degree" = -1
   1.459 +              AND "opinion"."fulfilled" = FALSE
   1.460 +            ),
   1.461 +            "minus1_fulfilled_count" = (
   1.462 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.463 +              FROM "issue" CROSS JOIN "opinion"
   1.464 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.465 +              ON "snapshot"."issue_id" = "issue"."id"
   1.466 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.467 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.468 +              WHERE "issue"."id" = "issue_id_p"
   1.469 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.470 +              AND "opinion"."degree" = -1
   1.471 +              AND "opinion"."fulfilled" = TRUE
   1.472 +            ),
   1.473 +            "plus1_unfulfilled_count" = (
   1.474 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.475 +              FROM "issue" CROSS JOIN "opinion"
   1.476 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.477 +              ON "snapshot"."issue_id" = "issue"."id"
   1.478 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.479 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.480 +              WHERE "issue"."id" = "issue_id_p"
   1.481 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.482 +              AND "opinion"."degree" = 1
   1.483 +              AND "opinion"."fulfilled" = FALSE
   1.484 +            ),
   1.485 +            "plus1_fulfilled_count" = (
   1.486 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.487 +              FROM "issue" CROSS JOIN "opinion"
   1.488 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.489 +              ON "snapshot"."issue_id" = "issue"."id"
   1.490 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.491 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.492 +              WHERE "issue"."id" = "issue_id_p"
   1.493 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.494 +              AND "opinion"."degree" = 1
   1.495 +              AND "opinion"."fulfilled" = TRUE
   1.496 +            ),
   1.497 +            "plus2_unfulfilled_count" = (
   1.498 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.499 +              FROM "issue" CROSS JOIN "opinion"
   1.500 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.501 +              ON "snapshot"."issue_id" = "issue"."id"
   1.502 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.503 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.504 +              WHERE "issue"."id" = "issue_id_p"
   1.505 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.506 +              AND "opinion"."degree" = 2
   1.507 +              AND "opinion"."fulfilled" = FALSE
   1.508 +            ),
   1.509 +            "plus2_fulfilled_count" = (
   1.510 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   1.511 +              FROM "issue" CROSS JOIN "opinion"
   1.512 +              JOIN "direct_interest_snapshot" AS "snapshot"
   1.513 +              ON "snapshot"."issue_id" = "issue"."id"
   1.514 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   1.515 +              AND "snapshot"."member_id" = "opinion"."member_id"
   1.516 +              WHERE "issue"."id" = "issue_id_p"
   1.517 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   1.518 +              AND "opinion"."degree" = 2
   1.519 +              AND "opinion"."fulfilled" = TRUE
   1.520 +            )
   1.521 +            WHERE "suggestion"."id" = "suggestion_id_v";
   1.522 +        END LOOP;
   1.523 +      END LOOP;
   1.524 +      RETURN;
   1.525 +    END;
   1.526 +  $$;
   1.527 +
   1.528 +CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
   1.529 +  RETURNS VOID
   1.530 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.531 +    DECLARE
   1.532 +      "area_id_v"   "area"."id"%TYPE;
   1.533 +      "unit_id_v"   "unit"."id"%TYPE;
   1.534 +      "member_id_v" "member"."id"%TYPE;
   1.535 +    BEGIN
   1.536 +      PERFORM "lock_issue"("issue_id_p");
   1.537 +      SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
   1.538 +      SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
   1.539 +      -- delete delegating votes (in cases of manual reset of issue state):
   1.540 +      DELETE FROM "delegating_voter"
   1.541 +        WHERE "issue_id" = "issue_id_p";
   1.542 +      -- delete votes from non-privileged voters:
   1.543 +      DELETE FROM "direct_voter"
   1.544 +        USING (
   1.545 +          SELECT
   1.546 +            "direct_voter"."member_id"
   1.547 +          FROM "direct_voter"
   1.548 +          JOIN "member" ON "direct_voter"."member_id" = "member"."id"
   1.549 +          LEFT JOIN "privilege"
   1.550 +          ON "privilege"."unit_id" = "unit_id_v"
   1.551 +          AND "privilege"."member_id" = "direct_voter"."member_id"
   1.552 +          WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
   1.553 +            "member"."active" = FALSE OR
   1.554 +            "privilege"."voting_right" ISNULL OR
   1.555 +            "privilege"."voting_right" = FALSE
   1.556 +          )
   1.557 +        ) AS "subquery"
   1.558 +        WHERE "direct_voter"."issue_id" = "issue_id_p"
   1.559 +        AND "direct_voter"."member_id" = "subquery"."member_id";
   1.560 +      -- consider delegations:
   1.561 +      UPDATE "direct_voter" SET "weight" = 1
   1.562 +        WHERE "issue_id" = "issue_id_p";
   1.563 +      PERFORM "add_vote_delegations"("issue_id_p");
   1.564 +      -- set voter count and mark issue as being calculated:
   1.565 +      UPDATE "issue" SET
   1.566 +        "state"  = 'calculation',
   1.567 +        "closed" = now(),
   1.568 +        "voter_count" = (
   1.569 +          SELECT coalesce(sum("weight"), 0)
   1.570 +          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
   1.571 +        )
   1.572 +        WHERE "id" = "issue_id_p";
   1.573 +      -- materialize battle_view:
   1.574 +      -- NOTE: "closed" column of issue must be set at this point
   1.575 +      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
   1.576 +      INSERT INTO "battle" (
   1.577 +        "issue_id",
   1.578 +        "winning_initiative_id", "losing_initiative_id",
   1.579 +        "count"
   1.580 +      ) SELECT
   1.581 +        "issue_id",
   1.582 +        "winning_initiative_id", "losing_initiative_id",
   1.583 +        "count"
   1.584 +        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
   1.585 +      -- copy "positive_votes" and "negative_votes" from "battle" table:
   1.586 +      UPDATE "initiative" SET
   1.587 +        "positive_votes" = "battle_win"."count",
   1.588 +        "negative_votes" = "battle_lose"."count"
   1.589 +        FROM "battle" AS "battle_win", "battle" AS "battle_lose"
   1.590 +        WHERE
   1.591 +          "battle_win"."issue_id" = "issue_id_p" AND
   1.592 +          "battle_win"."winning_initiative_id" = "initiative"."id" AND
   1.593 +          "battle_win"."losing_initiative_id" ISNULL AND
   1.594 +          "battle_lose"."issue_id" = "issue_id_p" AND
   1.595 +          "battle_lose"."losing_initiative_id" = "initiative"."id" AND
   1.596 +          "battle_lose"."winning_initiative_id" ISNULL;
   1.597 +    END;
   1.598 +  $$;
   1.599 +
   1.600 +DROP FUNCTION "array_init_string"(INTEGER);
   1.601 +DROP FUNCTION "square_matrix_init_string"(INTEGER);
   1.602 +
   1.603 +CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
   1.604 +  RETURNS VOID
   1.605 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.606 +    DECLARE
   1.607 +      "issue_row"         "issue"%ROWTYPE;
   1.608 +      "policy_row"        "policy"%ROWTYPE;
   1.609 +      "dimension_v"       INTEGER;
   1.610 +      "vote_matrix"       INT4[][];  -- absolute votes
   1.611 +      "matrix"            INT8[][];  -- defeat strength / best paths
   1.612 +      "i"                 INTEGER;
   1.613 +      "j"                 INTEGER;
   1.614 +      "k"                 INTEGER;
   1.615 +      "battle_row"        "battle"%ROWTYPE;
   1.616 +      "rank_ary"          INT4[];
   1.617 +      "rank_v"            INT4;
   1.618 +      "done_v"            INTEGER;
   1.619 +      "winners_ary"       INTEGER[];
   1.620 +      "initiative_id_v"   "initiative"."id"%TYPE;
   1.621 +    BEGIN
   1.622 +      SELECT * INTO "issue_row"
   1.623 +        FROM "issue" WHERE "id" = "issue_id_p"
   1.624 +        FOR UPDATE;
   1.625 +      SELECT * INTO "policy_row"
   1.626 +        FROM "policy" WHERE "id" = "issue_row"."policy_id";
   1.627 +      SELECT count(1) INTO "dimension_v"
   1.628 +        FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
   1.629 +      -- Create "vote_matrix" with absolute number of votes in pairwise
   1.630 +      -- comparison:
   1.631 +      "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
   1.632 +      "i" := 1;
   1.633 +      "j" := 2;
   1.634 +      FOR "battle_row" IN
   1.635 +        SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
   1.636 +        ORDER BY
   1.637 +        "winning_initiative_id" NULLS LAST,
   1.638 +        "losing_initiative_id" NULLS LAST
   1.639 +      LOOP
   1.640 +        "vote_matrix"["i"]["j"] := "battle_row"."count";
   1.641 +        IF "j" = "dimension_v" THEN
   1.642 +          "i" := "i" + 1;
   1.643 +          "j" := 1;
   1.644 +        ELSE
   1.645 +          "j" := "j" + 1;
   1.646 +          IF "j" = "i" THEN
   1.647 +            "j" := "j" + 1;
   1.648 +          END IF;
   1.649 +        END IF;
   1.650 +      END LOOP;
   1.651 +      IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
   1.652 +        RAISE EXCEPTION 'Wrong battle count (should not happen)';
   1.653 +      END IF;
   1.654 +      -- Store defeat strengths in "matrix" using "defeat_strength"
   1.655 +      -- function:
   1.656 +      "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
   1.657 +      "i" := 1;
   1.658 +      LOOP
   1.659 +        "j" := 1;
   1.660 +        LOOP
   1.661 +          IF "i" != "j" THEN
   1.662 +            "matrix"["i"]["j"] := "defeat_strength"(
   1.663 +              "vote_matrix"["i"]["j"],
   1.664 +              "vote_matrix"["j"]["i"]
   1.665 +            );
   1.666 +          END IF;
   1.667 +          EXIT WHEN "j" = "dimension_v";
   1.668 +          "j" := "j" + 1;
   1.669 +        END LOOP;
   1.670 +        EXIT WHEN "i" = "dimension_v";
   1.671 +        "i" := "i" + 1;
   1.672 +      END LOOP;
   1.673 +      -- Find best paths:
   1.674 +      "i" := 1;
   1.675 +      LOOP
   1.676 +        "j" := 1;
   1.677 +        LOOP
   1.678 +          IF "i" != "j" THEN
   1.679 +            "k" := 1;
   1.680 +            LOOP
   1.681 +              IF "i" != "k" AND "j" != "k" THEN
   1.682 +                IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
   1.683 +                  IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
   1.684 +                    "matrix"["j"]["k"] := "matrix"["j"]["i"];
   1.685 +                  END IF;
   1.686 +                ELSE
   1.687 +                  IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
   1.688 +                    "matrix"["j"]["k"] := "matrix"["i"]["k"];
   1.689 +                  END IF;
   1.690 +                END IF;
   1.691 +              END IF;
   1.692 +              EXIT WHEN "k" = "dimension_v";
   1.693 +              "k" := "k" + 1;
   1.694 +            END LOOP;
   1.695 +          END IF;
   1.696 +          EXIT WHEN "j" = "dimension_v";
   1.697 +          "j" := "j" + 1;
   1.698 +        END LOOP;
   1.699 +        EXIT WHEN "i" = "dimension_v";
   1.700 +        "i" := "i" + 1;
   1.701 +      END LOOP;
   1.702 +      -- Determine order of winners:
   1.703 +      "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
   1.704 +      "rank_v" := 1;
   1.705 +      "done_v" := 0;
   1.706 +      LOOP
   1.707 +        "winners_ary" := '{}';
   1.708 +        "i" := 1;
   1.709 +        LOOP
   1.710 +          IF "rank_ary"["i"] ISNULL THEN
   1.711 +            "j" := 1;
   1.712 +            LOOP
   1.713 +              IF
   1.714 +                "i" != "j" AND
   1.715 +                "rank_ary"["j"] ISNULL AND
   1.716 +                "matrix"["j"]["i"] > "matrix"["i"]["j"]
   1.717 +              THEN
   1.718 +                -- someone else is better
   1.719 +                EXIT;
   1.720 +              END IF;
   1.721 +              IF "j" = "dimension_v" THEN
   1.722 +                -- noone is better
   1.723 +                "winners_ary" := "winners_ary" || "i";
   1.724 +                EXIT;
   1.725 +              END IF;
   1.726 +              "j" := "j" + 1;
   1.727 +            END LOOP;
   1.728 +          END IF;
   1.729 +          EXIT WHEN "i" = "dimension_v";
   1.730 +          "i" := "i" + 1;
   1.731 +        END LOOP;
   1.732 +        "i" := 1;
   1.733 +        LOOP
   1.734 +          "rank_ary"["winners_ary"["i"]] := "rank_v";
   1.735 +          "done_v" := "done_v" + 1;
   1.736 +          EXIT WHEN "i" = array_upper("winners_ary", 1);
   1.737 +          "i" := "i" + 1;
   1.738 +        END LOOP;
   1.739 +        EXIT WHEN "done_v" = "dimension_v";
   1.740 +        "rank_v" := "rank_v" + 1;
   1.741 +      END LOOP;
   1.742 +      -- write preliminary results:
   1.743 +      "i" := 1;
   1.744 +      FOR "initiative_id_v" IN
   1.745 +        SELECT "id" FROM "initiative"
   1.746 +        WHERE "issue_id" = "issue_id_p" AND "admitted"
   1.747 +        ORDER BY "id"
   1.748 +      LOOP
   1.749 +        UPDATE "initiative" SET
   1.750 +          "direct_majority" =
   1.751 +            CASE WHEN "policy_row"."direct_majority_strict" THEN
   1.752 +              "positive_votes" * "policy_row"."direct_majority_den" >
   1.753 +              "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
   1.754 +            ELSE
   1.755 +              "positive_votes" * "policy_row"."direct_majority_den" >=
   1.756 +              "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
   1.757 +            END
   1.758 +            AND "positive_votes" >= "policy_row"."direct_majority_positive"
   1.759 +            AND "issue_row"."voter_count"-"negative_votes" >=
   1.760 +                "policy_row"."direct_majority_non_negative",
   1.761 +            "indirect_majority" =
   1.762 +            CASE WHEN "policy_row"."indirect_majority_strict" THEN
   1.763 +              "positive_votes" * "policy_row"."indirect_majority_den" >
   1.764 +              "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
   1.765 +            ELSE
   1.766 +              "positive_votes" * "policy_row"."indirect_majority_den" >=
   1.767 +              "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
   1.768 +            END
   1.769 +            AND "positive_votes" >= "policy_row"."indirect_majority_positive"
   1.770 +            AND "issue_row"."voter_count"-"negative_votes" >=
   1.771 +                "policy_row"."indirect_majority_non_negative",
   1.772 +          "schulze_rank"           = "rank_ary"["i"],
   1.773 +          "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
   1.774 +          "worse_than_status_quo"  = "rank_ary"["i"] > "rank_ary"["dimension_v"],
   1.775 +          "multistage_majority"    = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
   1.776 +          "reverse_beat_path"      = "matrix"["dimension_v"]["i"] >= 0,
   1.777 +          "winner"                 = FALSE
   1.778 +          WHERE "id" = "initiative_id_v";
   1.779 +        "i" := "i" + 1;
   1.780 +      END LOOP;
   1.781 +      IF "i" != "dimension_v" THEN
   1.782 +        RAISE EXCEPTION 'Wrong winner count (should not happen)';
   1.783 +      END IF;
   1.784 +      -- take indirect majorities into account:
   1.785 +      LOOP
   1.786 +        UPDATE "initiative" SET "indirect_majority" = TRUE
   1.787 +          FROM (
   1.788 +            SELECT "new_initiative"."id" AS "initiative_id"
   1.789 +            FROM "initiative" "old_initiative"
   1.790 +            JOIN "initiative" "new_initiative"
   1.791 +              ON "new_initiative"."issue_id" = "issue_id_p"
   1.792 +              AND "new_initiative"."indirect_majority" = FALSE
   1.793 +            JOIN "battle" "battle_win"
   1.794 +              ON "battle_win"."issue_id" = "issue_id_p"
   1.795 +              AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
   1.796 +              AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
   1.797 +            JOIN "battle" "battle_lose"
   1.798 +              ON "battle_lose"."issue_id" = "issue_id_p"
   1.799 +              AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
   1.800 +              AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
   1.801 +            WHERE "old_initiative"."issue_id" = "issue_id_p"
   1.802 +            AND "old_initiative"."indirect_majority" = TRUE
   1.803 +            AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
   1.804 +              "battle_win"."count" * "policy_row"."indirect_majority_den" >
   1.805 +              "policy_row"."indirect_majority_num" *
   1.806 +              ("battle_win"."count"+"battle_lose"."count")
   1.807 +            ELSE
   1.808 +              "battle_win"."count" * "policy_row"."indirect_majority_den" >=
   1.809 +              "policy_row"."indirect_majority_num" *
   1.810 +              ("battle_win"."count"+"battle_lose"."count")
   1.811 +            END
   1.812 +            AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
   1.813 +            AND "issue_row"."voter_count"-"battle_lose"."count" >=
   1.814 +                "policy_row"."indirect_majority_non_negative"
   1.815 +          ) AS "subquery"
   1.816 +          WHERE "id" = "subquery"."initiative_id";
   1.817 +        EXIT WHEN NOT FOUND;
   1.818 +      END LOOP;
   1.819 +      -- set "multistage_majority" for remaining matching initiatives:
   1.820 +       UPDATE "initiative" SET "multistage_majority" = TRUE
   1.821 +        FROM (
   1.822 +          SELECT "losing_initiative"."id" AS "initiative_id"
   1.823 +          FROM "initiative" "losing_initiative"
   1.824 +          JOIN "initiative" "winning_initiative"
   1.825 +            ON "winning_initiative"."issue_id" = "issue_id_p"
   1.826 +            AND "winning_initiative"."admitted"
   1.827 +          JOIN "battle" "battle_win"
   1.828 +            ON "battle_win"."issue_id" = "issue_id_p"
   1.829 +            AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
   1.830 +            AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
   1.831 +          JOIN "battle" "battle_lose"
   1.832 +            ON "battle_lose"."issue_id" = "issue_id_p"
   1.833 +            AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
   1.834 +            AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
   1.835 +          WHERE "losing_initiative"."issue_id" = "issue_id_p"
   1.836 +          AND "losing_initiative"."admitted"
   1.837 +          AND "winning_initiative"."schulze_rank" <
   1.838 +              "losing_initiative"."schulze_rank"
   1.839 +          AND "battle_win"."count" > "battle_lose"."count"
   1.840 +          AND (
   1.841 +            "battle_win"."count" > "winning_initiative"."positive_votes" OR
   1.842 +            "battle_lose"."count" < "losing_initiative"."negative_votes" )
   1.843 +        ) AS "subquery"
   1.844 +        WHERE "id" = "subquery"."initiative_id";
   1.845 +      -- mark eligible initiatives:
   1.846 +      UPDATE "initiative" SET "eligible" = TRUE
   1.847 +        WHERE "issue_id" = "issue_id_p"
   1.848 +        AND "initiative"."direct_majority"
   1.849 +        AND "initiative"."indirect_majority"
   1.850 +        AND "initiative"."better_than_status_quo"
   1.851 +        AND (
   1.852 +          "policy_row"."no_multistage_majority" = FALSE OR
   1.853 +          "initiative"."multistage_majority" = FALSE )
   1.854 +        AND (
   1.855 +          "policy_row"."no_reverse_beat_path" = FALSE OR
   1.856 +          "initiative"."reverse_beat_path" = FALSE );
   1.857 +      -- mark final winner:
   1.858 +      UPDATE "initiative" SET "winner" = TRUE
   1.859 +        FROM (
   1.860 +          SELECT "id" AS "initiative_id"
   1.861 +          FROM "initiative"
   1.862 +          WHERE "issue_id" = "issue_id_p" AND "eligible"
   1.863 +          ORDER BY "schulze_rank", "id"
   1.864 +          LIMIT 1
   1.865 +        ) AS "subquery"
   1.866 +        WHERE "id" = "subquery"."initiative_id";
   1.867 +      -- write (final) ranks:
   1.868 +      "rank_v" := 1;
   1.869 +      FOR "initiative_id_v" IN
   1.870 +        SELECT "id"
   1.871 +        FROM "initiative"
   1.872 +        WHERE "issue_id" = "issue_id_p" AND "admitted"
   1.873 +        ORDER BY
   1.874 +          "winner" DESC,
   1.875 +          ("direct_majority" AND "indirect_majority") DESC,
   1.876 +          "schulze_rank",
   1.877 +          "id"
   1.878 +      LOOP
   1.879 +        UPDATE "initiative" SET "rank" = "rank_v"
   1.880 +          WHERE "id" = "initiative_id_v";
   1.881 +        "rank_v" := "rank_v" + 1;
   1.882 +      END LOOP;
   1.883 +      -- set schulze rank of status quo and mark issue as finished:
   1.884 +      UPDATE "issue" SET
   1.885 +        "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
   1.886 +        "state" =
   1.887 +          CASE WHEN EXISTS (
   1.888 +            SELECT NULL FROM "initiative"
   1.889 +            WHERE "issue_id" = "issue_id_p" AND "winner"
   1.890 +          ) THEN
   1.891 +            'finished_with_winner'::"issue_state"
   1.892 +          ELSE
   1.893 +            'finished_without_winner'::"issue_state"
   1.894 +          END,
   1.895 +        "ranks_available" = TRUE
   1.896 +        WHERE "id" = "issue_id_p";
   1.897 +      RETURN;
   1.898 +    END;
   1.899 +  $$;
   1.900 +
   1.901 +CREATE OR REPLACE FUNCTION "check_issue"
   1.902 +  ( "issue_id_p" "issue"."id"%TYPE )
   1.903 +  RETURNS VOID
   1.904 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.905 +    DECLARE
   1.906 +      "issue_row"         "issue"%ROWTYPE;
   1.907 +      "policy_row"        "policy"%ROWTYPE;
   1.908 +    BEGIN
   1.909 +      PERFORM "lock_issue"("issue_id_p");
   1.910 +      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
   1.911 +      -- only process open issues:
   1.912 +      IF "issue_row"."closed" ISNULL THEN
   1.913 +        SELECT * INTO "policy_row" FROM "policy"
   1.914 +          WHERE "id" = "issue_row"."policy_id";
   1.915 +        -- create a snapshot, unless issue is already fully frozen:
   1.916 +        IF "issue_row"."fully_frozen" ISNULL THEN
   1.917 +          PERFORM "create_snapshot"("issue_id_p");
   1.918 +          SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
   1.919 +        END IF;
   1.920 +        -- eventually close or accept issues, which have not been accepted:
   1.921 +        IF "issue_row"."accepted" ISNULL THEN
   1.922 +          IF EXISTS (
   1.923 +            SELECT NULL FROM "initiative"
   1.924 +            WHERE "issue_id" = "issue_id_p"
   1.925 +            AND "supporter_count" > 0
   1.926 +            AND "supporter_count" * "policy_row"."issue_quorum_den"
   1.927 +            >= "issue_row"."population" * "policy_row"."issue_quorum_num"
   1.928 +          ) THEN
   1.929 +            -- accept issues, if supporter count is high enough
   1.930 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
   1.931 +            -- NOTE: "issue_row" used later
   1.932 +            "issue_row"."state" := 'discussion';
   1.933 +            "issue_row"."accepted" := now();
   1.934 +            UPDATE "issue" SET
   1.935 +              "state"    = "issue_row"."state",
   1.936 +              "accepted" = "issue_row"."accepted"
   1.937 +              WHERE "id" = "issue_row"."id";
   1.938 +          ELSIF
   1.939 +            now() >= "issue_row"."created" + "issue_row"."admission_time"
   1.940 +          THEN
   1.941 +            -- close issues, if admission time has expired
   1.942 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
   1.943 +            UPDATE "issue" SET
   1.944 +              "state" = 'canceled_issue_not_accepted',
   1.945 +              "closed" = now()
   1.946 +              WHERE "id" = "issue_row"."id";
   1.947 +          END IF;
   1.948 +        END IF;
   1.949 +        -- eventually half freeze issues:
   1.950 +        IF
   1.951 +          -- NOTE: issue can't be closed at this point, if it has been accepted
   1.952 +          "issue_row"."accepted" NOTNULL AND
   1.953 +          "issue_row"."half_frozen" ISNULL
   1.954 +        THEN
   1.955 +          IF
   1.956 +            now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
   1.957 +          THEN
   1.958 +            PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
   1.959 +            -- NOTE: "issue_row" used later
   1.960 +            "issue_row"."state" := 'verification';
   1.961 +            "issue_row"."half_frozen" := now();
   1.962 +            UPDATE "issue" SET
   1.963 +              "state"       = "issue_row"."state",
   1.964 +              "half_frozen" = "issue_row"."half_frozen"
   1.965 +              WHERE "id" = "issue_row"."id";
   1.966 +          END IF;
   1.967 +        END IF;
   1.968 +        -- close issues after some time, if all initiatives have been revoked:
   1.969 +        IF
   1.970 +          "issue_row"."closed" ISNULL AND
   1.971 +          NOT EXISTS (
   1.972 +            -- all initiatives are revoked
   1.973 +            SELECT NULL FROM "initiative"
   1.974 +            WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
   1.975 +          ) AND (
   1.976 +            -- and issue has not been accepted yet
   1.977 +            "issue_row"."accepted" ISNULL OR
   1.978 +            NOT EXISTS (
   1.979 +              -- or no initiatives have been revoked lately
   1.980 +              SELECT NULL FROM "initiative"
   1.981 +              WHERE "issue_id" = "issue_id_p"
   1.982 +              AND now() < "revoked" + "issue_row"."verification_time"
   1.983 +            ) OR (
   1.984 +              -- or verification time has elapsed
   1.985 +              "issue_row"."half_frozen" NOTNULL AND
   1.986 +              "issue_row"."fully_frozen" ISNULL AND
   1.987 +              now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
   1.988 +            )
   1.989 +          )
   1.990 +        THEN
   1.991 +          -- NOTE: "issue_row" used later
   1.992 +          IF "issue_row"."accepted" ISNULL THEN
   1.993 +            "issue_row"."state" := 'canceled_revoked_before_accepted';
   1.994 +          ELSIF "issue_row"."half_frozen" ISNULL THEN
   1.995 +            "issue_row"."state" := 'canceled_after_revocation_during_discussion';
   1.996 +          ELSE
   1.997 +            "issue_row"."state" := 'canceled_after_revocation_during_verification';
   1.998 +          END IF;
   1.999 +          "issue_row"."closed" := now();
  1.1000 +          UPDATE "issue" SET
  1.1001 +            "state"  = "issue_row"."state",
  1.1002 +            "closed" = "issue_row"."closed"
  1.1003 +            WHERE "id" = "issue_row"."id";
  1.1004 +        END IF;
  1.1005 +        -- fully freeze issue after verification time:
  1.1006 +        IF
  1.1007 +          "issue_row"."half_frozen" NOTNULL AND
  1.1008 +          "issue_row"."fully_frozen" ISNULL AND
  1.1009 +          "issue_row"."closed" ISNULL AND
  1.1010 +          now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  1.1011 +        THEN
  1.1012 +          PERFORM "freeze_after_snapshot"("issue_id_p");
  1.1013 +          -- NOTE: "issue" might change, thus "issue_row" has to be updated below
  1.1014 +        END IF;
  1.1015 +        SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1016 +        -- close issue by calling close_voting(...) after voting time:
  1.1017 +        IF
  1.1018 +          "issue_row"."closed" ISNULL AND
  1.1019 +          "issue_row"."fully_frozen" NOTNULL AND
  1.1020 +          now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
  1.1021 +        THEN
  1.1022 +          PERFORM "close_voting"("issue_id_p");
  1.1023 +          -- calculate ranks will not consume much time and can be done now
  1.1024 +          PERFORM "calculate_ranks"("issue_id_p");
  1.1025 +        END IF;
  1.1026 +      END IF;
  1.1027 +      RETURN;
  1.1028 +    END;
  1.1029 +  $$;
  1.1030 +
  1.1031 +-- TODO: recalculate voting results
  1.1032 +
  1.1033 +COMMIT;
  1.1034 +
  1.1035 +UPDATE "suggestion" SET "draft_id" = "subquery"."draft_id"
  1.1036 +  FROM (
  1.1037 +    SELECT DISTINCT ON ("suggestion"."id")
  1.1038 +      "suggestion"."id" AS "suggestion_id",
  1.1039 +      "draft"."id" AS "draft_id"
  1.1040 +    FROM "suggestion" JOIN "draft"
  1.1041 +    ON "suggestion"."initiative_id" = "draft"."initiative_id"
  1.1042 +    WHERE "draft"."created" <= "suggestion"."created"
  1.1043 +    ORDER BY "suggestion"."id", "draft"."created" DESC
  1.1044 +  ) AS "subquery"
  1.1045 +  WHERE "suggestion"."id" = "subquery"."suggestion_id";
  1.1046 +
  1.1047 +ALTER TABLE "suggestion" ALTER COLUMN "draft_id" SET NOT NULL;

Impressum / About Us