jbe@420: -- NOTICE: This update script disables the "no_reserve_beat_path" setting for jbe@420: -- all policies. If this is not intended, please edit this script jbe@420: -- before applying it to your database. jbe@420: jbe@416: BEGIN; jbe@416: jbe@416: CREATE OR REPLACE VIEW "liquid_feedback_version" AS jbe@416: SELECT * FROM (VALUES ('3.0.1', 3, 0, 1)) jbe@416: AS "subquery"("string", "major", "minor", "revision"); jbe@416: jbe@420: ALTER TABLE "policy" ALTER COLUMN "no_reverse_beat_path" SET DEFAULT FALSE; jbe@420: jbe@420: UPDATE "policy" SET "no_reverse_beat_path" = FALSE; -- recommended jbe@420: jbe@420: COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: 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.'; jbe@420: jbe@420: COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: 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").'; jbe@420: jbe@416: ALTER TABLE "initiative" ADD COLUMN "first_preference_votes" INT4; jbe@416: jbe@416: ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results"; jbe@416: ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK ( jbe@416: ( "admitted" NOTNULL AND "admitted" = TRUE ) OR jbe@416: ( "first_preference_votes" ISNULL AND jbe@416: "positive_votes" ISNULL AND "negative_votes" ISNULL AND jbe@416: "direct_majority" ISNULL AND "indirect_majority" ISNULL AND jbe@416: "schulze_rank" ISNULL AND jbe@416: "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND jbe@416: "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND jbe@416: "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ); jbe@416: jbe@416: COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice'; jbe@416: COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo'; jbe@416: COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo'; jbe@416: jbe@416: -- UPDATE TABLE "vote" SET "grade" = 0 WHERE "grade" ISNULL; -- should not be necessary jbe@416: ALTER TABLE "vote" ALTER COLUMN "grade" SET NOT NULL; jbe@416: jbe@416: ALTER TABLE "vote" ADD COLUMN "first_preference" BOOLEAN; jbe@416: jbe@416: ALTER TABLE "vote" ADD jbe@416: CONSTRAINT "first_preference_flag_only_set_on_positive_grades" jbe@416: CHECK ("grade" > 0 OR "first_preference" ISNULL); jbe@416: jbe@416: COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.'; jbe@416: jbe@416: INSERT INTO "temporary_transaction_data" ("key", "value") jbe@416: VALUES ('override_protection_triggers', TRUE::TEXT); jbe@416: jbe@416: UPDATE "vote" SET "first_preference" = "subquery"."first_preference" jbe@416: FROM ( jbe@416: SELECT jbe@416: "vote"."initiative_id", jbe@416: "vote"."member_id", jbe@416: CASE WHEN "vote"."grade" > 0 THEN jbe@416: CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END jbe@416: ELSE NULL jbe@416: END AS "first_preference" jbe@416: FROM "vote" jbe@416: JOIN "initiative" -- NOTE: due to missing index on issue_id jbe@416: ON "vote"."issue_id" = "initiative"."issue_id" jbe@416: JOIN "vote" AS "agg" jbe@416: ON "initiative"."id" = "agg"."initiative_id" jbe@416: AND "vote"."member_id" = "agg"."member_id" jbe@416: GROUP BY "vote"."initiative_id", "vote"."member_id" jbe@416: ) AS "subquery" jbe@416: WHERE "vote"."initiative_id" = "subquery"."initiative_id" jbe@416: AND "vote"."member_id" = "subquery"."member_id"; jbe@416: jbe@416: DELETE FROM "temporary_transaction_data" jbe@416: WHERE "key" = 'override_protection_triggers'; jbe@416: jbe@416: UPDATE "initiative" jbe@416: SET "first_preference_votes" = coalesce("subquery"."sum", 0) jbe@416: FROM ( jbe@416: SELECT "vote"."initiative_id", sum("direct_voter"."weight") jbe@416: FROM "vote" JOIN "direct_voter" jbe@416: ON "vote"."issue_id" = "direct_voter"."issue_id" jbe@416: AND "vote"."member_id" = "direct_voter"."member_id" jbe@416: WHERE "vote"."first_preference" jbe@416: GROUP BY "vote"."initiative_id" jbe@416: ) AS "subquery" jbe@416: WHERE "initiative"."admitted" jbe@416: AND "initiative"."id" = "subquery"."initiative_id"; jbe@416: jbe@418: -- reconstruct battle data (originating from LiquidFeedback Core before v2.0.0) jbe@418: -- to avoid future data loss when executing "clean_issue" to delete voting data: jbe@417: INSERT INTO "battle" ( jbe@417: "issue_id", jbe@417: "winning_initiative_id", jbe@417: "losing_initiative_id", jbe@417: "count" jbe@417: ) SELECT jbe@417: "battle_view"."issue_id", jbe@417: "battle_view"."winning_initiative_id", jbe@417: "battle_view"."losing_initiative_id", jbe@417: "battle_view"."count" jbe@418: FROM ( jbe@418: SELECT jbe@418: "issue"."id" AS "issue_id", jbe@418: "winning_initiative"."id" AS "winning_initiative_id", jbe@418: "losing_initiative"."id" AS "losing_initiative_id", jbe@418: sum( jbe@418: CASE WHEN jbe@418: coalesce("better_vote"."grade", 0) > jbe@418: coalesce("worse_vote"."grade", 0) jbe@418: THEN "direct_voter"."weight" ELSE 0 END jbe@418: ) AS "count" jbe@418: FROM "issue" jbe@418: LEFT JOIN "direct_voter" jbe@418: ON "issue"."id" = "direct_voter"."issue_id" jbe@418: JOIN "battle_participant" AS "winning_initiative" jbe@418: ON "issue"."id" = "winning_initiative"."issue_id" jbe@418: JOIN "battle_participant" AS "losing_initiative" jbe@418: ON "issue"."id" = "losing_initiative"."issue_id" jbe@418: LEFT JOIN "vote" AS "better_vote" jbe@418: ON "direct_voter"."member_id" = "better_vote"."member_id" jbe@418: AND "winning_initiative"."id" = "better_vote"."initiative_id" jbe@418: LEFT JOIN "vote" AS "worse_vote" jbe@418: ON "direct_voter"."member_id" = "worse_vote"."member_id" jbe@418: AND "losing_initiative"."id" = "worse_vote"."initiative_id" jbe@418: WHERE "issue"."state" IN ('finished_with_winner', 'finished_without_winner') jbe@418: AND "winning_initiative"."id" != "losing_initiative"."id" jbe@418: -- NOTE: comparisons with status-quo are intentionally omitted to mark jbe@418: -- issues that were counted prior LiquidFeedback Core v2.0.0 jbe@418: GROUP BY jbe@418: "issue"."id", jbe@418: "winning_initiative"."id", jbe@418: "losing_initiative"."id" jbe@418: ) AS "battle_view" jbe@417: LEFT JOIN "battle" jbe@417: ON "battle_view"."winning_initiative_id" = "battle"."winning_initiative_id" jbe@417: AND "battle_view"."losing_initiative_id" = "battle"."losing_initiative_id" jbe@417: WHERE "battle" ISNULL; jbe@417: jbe@416: CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE) jbe@416: RETURNS VOID jbe@416: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@416: DECLARE jbe@416: "area_id_v" "area"."id"%TYPE; jbe@416: "unit_id_v" "unit"."id"%TYPE; jbe@416: "member_id_v" "member"."id"%TYPE; jbe@416: BEGIN jbe@416: PERFORM "require_transaction_isolation"(); jbe@416: SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p"; jbe@416: SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v"; jbe@416: -- override protection triggers: jbe@416: INSERT INTO "temporary_transaction_data" ("key", "value") jbe@416: VALUES ('override_protection_triggers', TRUE::TEXT); jbe@416: -- delete timestamp of voting comment: jbe@416: UPDATE "direct_voter" SET "comment_changed" = NULL jbe@416: WHERE "issue_id" = "issue_id_p"; jbe@416: -- delete delegating votes (in cases of manual reset of issue state): jbe@416: DELETE FROM "delegating_voter" jbe@416: WHERE "issue_id" = "issue_id_p"; jbe@416: -- delete votes from non-privileged voters: jbe@416: DELETE FROM "direct_voter" jbe@416: USING ( jbe@416: SELECT jbe@416: "direct_voter"."member_id" jbe@416: FROM "direct_voter" jbe@416: JOIN "member" ON "direct_voter"."member_id" = "member"."id" jbe@416: LEFT JOIN "privilege" jbe@416: ON "privilege"."unit_id" = "unit_id_v" jbe@416: AND "privilege"."member_id" = "direct_voter"."member_id" jbe@416: WHERE "direct_voter"."issue_id" = "issue_id_p" AND ( jbe@416: "member"."active" = FALSE OR jbe@416: "privilege"."voting_right" ISNULL OR jbe@416: "privilege"."voting_right" = FALSE jbe@416: ) jbe@416: ) AS "subquery" jbe@416: WHERE "direct_voter"."issue_id" = "issue_id_p" jbe@416: AND "direct_voter"."member_id" = "subquery"."member_id"; jbe@416: -- consider delegations: jbe@416: UPDATE "direct_voter" SET "weight" = 1 jbe@416: WHERE "issue_id" = "issue_id_p"; jbe@416: PERFORM "add_vote_delegations"("issue_id_p"); jbe@416: -- mark first preferences: jbe@416: UPDATE "vote" SET "first_preference" = "subquery"."first_preference" jbe@416: FROM ( jbe@416: SELECT jbe@416: "vote"."initiative_id", jbe@416: "vote"."member_id", jbe@416: CASE WHEN "vote"."grade" > 0 THEN jbe@416: CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END jbe@416: ELSE NULL jbe@416: END AS "first_preference" jbe@416: FROM "vote" jbe@416: JOIN "initiative" -- NOTE: due to missing index on issue_id jbe@416: ON "vote"."issue_id" = "initiative"."issue_id" jbe@416: JOIN "vote" AS "agg" jbe@416: ON "initiative"."id" = "agg"."initiative_id" jbe@416: AND "vote"."member_id" = "agg"."member_id" jbe@416: GROUP BY "vote"."initiative_id", "vote"."member_id" jbe@416: ) AS "subquery" jbe@416: WHERE "vote"."issue_id" = "issue_id_p" jbe@416: AND "vote"."initiative_id" = "subquery"."initiative_id" jbe@416: AND "vote"."member_id" = "subquery"."member_id"; jbe@416: -- finish overriding protection triggers (avoids garbage): jbe@416: DELETE FROM "temporary_transaction_data" jbe@416: WHERE "key" = 'override_protection_triggers'; jbe@416: -- materialize battle_view: jbe@416: -- NOTE: "closed" column of issue must be set at this point jbe@416: DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; jbe@416: INSERT INTO "battle" ( jbe@416: "issue_id", jbe@416: "winning_initiative_id", "losing_initiative_id", jbe@416: "count" jbe@416: ) SELECT jbe@416: "issue_id", jbe@416: "winning_initiative_id", "losing_initiative_id", jbe@416: "count" jbe@416: FROM "battle_view" WHERE "issue_id" = "issue_id_p"; jbe@416: -- set voter count: jbe@416: UPDATE "issue" SET jbe@416: "voter_count" = ( jbe@416: SELECT coalesce(sum("weight"), 0) jbe@416: FROM "direct_voter" WHERE "issue_id" = "issue_id_p" jbe@416: ) jbe@416: WHERE "id" = "issue_id_p"; jbe@416: -- calculate "first_preference_votes": jbe@416: UPDATE "initiative" jbe@416: SET "first_preference_votes" = coalesce("subquery"."sum", 0) jbe@416: FROM ( jbe@416: SELECT "vote"."initiative_id", sum("direct_voter"."weight") jbe@416: FROM "vote" JOIN "direct_voter" jbe@416: ON "vote"."issue_id" = "direct_voter"."issue_id" jbe@416: AND "vote"."member_id" = "direct_voter"."member_id" jbe@416: WHERE "vote"."first_preference" jbe@416: GROUP BY "vote"."initiative_id" jbe@416: ) AS "subquery" jbe@416: WHERE "initiative"."issue_id" = "issue_id_p" jbe@416: AND "initiative"."admitted" jbe@416: AND "initiative"."id" = "subquery"."initiative_id"; jbe@416: -- copy "positive_votes" and "negative_votes" from "battle" table: jbe@416: UPDATE "initiative" SET jbe@416: "positive_votes" = "battle_win"."count", jbe@416: "negative_votes" = "battle_lose"."count" jbe@416: FROM "battle" AS "battle_win", "battle" AS "battle_lose" jbe@416: WHERE jbe@416: "battle_win"."issue_id" = "issue_id_p" AND jbe@416: "battle_win"."winning_initiative_id" = "initiative"."id" AND jbe@416: "battle_win"."losing_initiative_id" ISNULL AND jbe@416: "battle_lose"."issue_id" = "issue_id_p" AND jbe@416: "battle_lose"."losing_initiative_id" = "initiative"."id" AND jbe@416: "battle_lose"."winning_initiative_id" ISNULL; jbe@416: END; jbe@416: $$; jbe@416: jbe@416: COMMIT;