liquid_feedback_core

annotate update/core-update.v1.4.0-v1.5.0.sql @ 180:1024224df943

Update script to v1.5.0: Drop contraints on table "initiative" before changing columns
author jbe
date Wed Jun 08 20:53:36 2011 +0200 (2011-06-08)
parents fb2394116b39
children 4c03ef70dd92
rev   line source
jbe@178 1 SELECT "calculate_ranks"("id") FROM "issue_with_ranks_missing";
jbe@178 2
jbe@177 3 BEGIN;
jbe@177 4
jbe@177 5 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
jbe@177 6 SELECT * FROM (VALUES ('1.5.0_devel', 1, 5, -1))
jbe@177 7 AS "subquery"("string", "major", "minor", "revision");
jbe@177 8
jbe@177 9 ALTER TABLE "member" ADD COLUMN "formatting_engine" TEXT;
jbe@177 10 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
jbe@177 11
jbe@177 12 CREATE TABLE "rendered_member_statement" (
jbe@177 13 PRIMARY KEY ("member_id", "format"),
jbe@177 14 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@177 15 "format" TEXT,
jbe@177 16 "content" TEXT NOT NULL );
jbe@177 17
jbe@177 18 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)';
jbe@177 19
jbe@177 20 ALTER TABLE "policy" ADD COLUMN "direct_majority_num" INT4 NOT NULL DEFAULT 1;
jbe@177 21 ALTER TABLE "policy" ADD COLUMN "direct_majority_den" INT4 NOT NULL DEFAULT 2;
jbe@177 22 ALTER TABLE "policy" ADD COLUMN "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE;
jbe@177 23 ALTER TABLE "policy" ADD COLUMN "direct_majority_positive" INT4 NOT NULL DEFAULT 0;
jbe@177 24 ALTER TABLE "policy" ADD COLUMN "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0;
jbe@177 25 ALTER TABLE "policy" ADD COLUMN "indirect_majority_num" INT4 NOT NULL DEFAULT 1;
jbe@177 26 ALTER TABLE "policy" ADD COLUMN "indirect_majority_den" INT4 NOT NULL DEFAULT 2;
jbe@177 27 ALTER TABLE "policy" ADD COLUMN "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE;
jbe@177 28 ALTER TABLE "policy" ADD COLUMN "indirect_majority_positive" INT4 NOT NULL DEFAULT 0;
jbe@177 29 ALTER TABLE "policy" ADD COLUMN "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0;
jbe@177 30 ALTER TABLE "policy" ADD COLUMN "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE;
jbe@177 31 ALTER TABLE "policy" ADD COLUMN "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE;
jbe@177 32
jbe@177 33 UPDATE "policy" SET
jbe@177 34 "direct_majority_num" = "majority_num",
jbe@177 35 "direct_majority_den" = "majority_den",
jbe@177 36 "direct_majority_strict" = "majority_strict",
jbe@177 37 "indirect_majority_num" = "majority_num",
jbe@177 38 "indirect_majority_den" = "majority_den",
jbe@177 39 "indirect_majority_strict" = "majority_strict";
jbe@177 40
jbe@177 41 ALTER TABLE "policy" DROP COLUMN "majority_num";
jbe@177 42 ALTER TABLE "policy" DROP COLUMN "majority_den";
jbe@177 43 ALTER TABLE "policy" DROP COLUMN "majority_strict";
jbe@177 44
jbe@177 45 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
jbe@177 46 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
jbe@177 47 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.';
jbe@177 48 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
jbe@177 49 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';
jbe@177 50 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';
jbe@177 51 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';
jbe@177 52 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.';
jbe@177 53 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';
jbe@177 54 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';
jbe@177 55 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.';
jbe@177 56 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").';
jbe@177 57
jbe@177 58 ALTER TABLE "area" DROP COLUMN "autoreject_weight";
jbe@177 59
jbe@177 60 DROP VIEW "open_issue";
jbe@177 61 DROP VIEW "issue_with_ranks_missing";
jbe@177 62
jbe@177 63 ALTER TABLE "issue" DROP COLUMN "vote_now";
jbe@177 64 ALTER TABLE "issue" DROP COLUMN "vote_later";
jbe@177 65 ALTER TABLE "issue" ADD COLUMN "status_quo_schulze_rank" INT4;
jbe@177 66
jbe@177 67 CREATE VIEW "open_issue" AS
jbe@177 68 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@177 69
jbe@177 70 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@177 71
jbe@177 72 CREATE VIEW "issue_with_ranks_missing" AS
jbe@177 73 SELECT * FROM "issue"
jbe@177 74 WHERE "fully_frozen" NOTNULL
jbe@177 75 AND "closed" NOTNULL
jbe@177 76 AND "ranks_available" = FALSE;
jbe@177 77
jbe@177 78 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
jbe@177 79
jbe@177 80 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.';
jbe@177 81 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
jbe@177 82 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
jbe@177 83
jbe@179 84 DROP VIEW "battle_view";
jbe@179 85
jbe@180 86 ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
jbe@180 87 ALTER TABLE "initiative" DROP CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null";
jbe@180 88 ALTER TABLE "initiative" DROP CONSTRAINT "non_agreed_initiatives_cant_get_a_rank";
jbe@180 89
jbe@178 90 ALTER TABLE "initiative" DROP COLUMN "agreed";
jbe@177 91 ALTER TABLE "initiative" ADD COLUMN "direct_majority" BOOLEAN;
jbe@177 92 ALTER TABLE "initiative" ADD COLUMN "indirect_majority" BOOLEAN;
jbe@177 93 ALTER TABLE "initiative" ADD COLUMN "schulze_rank" INT4;
jbe@177 94 ALTER TABLE "initiative" ADD COLUMN "better_than_status_quo" BOOLEAN;
jbe@177 95 ALTER TABLE "initiative" ADD COLUMN "worse_than_status_quo" BOOLEAN;
jbe@177 96 ALTER TABLE "initiative" ADD COLUMN "reverse_beat_path" BOOLEAN;
jbe@177 97 ALTER TABLE "initiative" ADD COLUMN "multistage_majority" BOOLEAN;
jbe@177 98 ALTER TABLE "initiative" ADD COLUMN "eligible" BOOLEAN;
jbe@177 99 ALTER TABLE "initiative" ADD COLUMN "winner" BOOLEAN;
jbe@177 100
jbe@177 101 ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
jbe@177 102 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
jbe@177 103 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
jbe@177 104 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
jbe@177 105 "schulze_rank" ISNULL AND
jbe@177 106 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
jbe@177 107 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
jbe@177 108 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
jbe@177 109 ALTER TABLE "initiative" ADD CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo"));
jbe@177 110 ALTER TABLE "initiative" ADD CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
jbe@177 111 "eligible" = FALSE OR
jbe@177 112 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") );
jbe@177 113 ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE);
jbe@177 114 ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1);
jbe@177 115 ALTER TABLE "initiative" ADD CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE);
jbe@177 116 ALTER TABLE "initiative" ADD CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank");
jbe@177 117
jbe@177 118 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"';
jbe@177 119 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
jbe@177 120 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
jbe@177 121 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
jbe@177 122 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
jbe@177 123 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';
jbe@177 124 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';
jbe@177 125 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
jbe@177 126 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
jbe@177 127 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';
jbe@177 128
jbe@177 129 ALTER TABLE "battle" DROP CONSTRAINT "battle_pkey";
jbe@177 130 ALTER TABLE "battle" ALTER COLUMN "issue_id" SET NOT NULL;
jbe@177 131 ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK (
jbe@177 132 "winning_initiative_id" != "losing_initiative_id" OR
jbe@177 133 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
jbe@177 134 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) );
jbe@177 135
jbe@177 136 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
jbe@177 137 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
jbe@177 138 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
jbe@177 139
jbe@177 140 ALTER TABLE "suggestion" ADD COLUMN "draft_id" INT8;
jbe@177 141 -- more later
jbe@177 142
jbe@177 143 ALTER TABLE "suggestion" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
jbe@177 144 ALTER TABLE "suggestion" ADD COLUMN "formatting_engine" TEXT;
jbe@177 145 ALTER TABLE "suggestion" RENAME COLUMN "description" TO "content";
jbe@177 146
jbe@177 147 DROP TRIGGER "update_text_search_data" ON "suggestion";
jbe@177 148
jbe@177 149 CREATE TRIGGER "update_text_search_data"
jbe@177 150 BEFORE INSERT OR UPDATE ON "suggestion"
jbe@177 151 FOR EACH ROW EXECUTE PROCEDURE
jbe@177 152 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@177 153 "name", "content");
jbe@177 154
jbe@177 155 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")';
jbe@177 156
jbe@177 157 CREATE TABLE "rendered_suggestion" (
jbe@177 158 PRIMARY KEY ("suggestion_id", "format"),
jbe@177 159 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@177 160 "format" TEXT,
jbe@177 161 "content" TEXT NOT NULL );
jbe@177 162
jbe@177 163 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)';
jbe@177 164
jbe@177 165 DROP VIEW "area_member_count";
jbe@177 166
jbe@177 167 ALTER TABLE "membership" DROP COLUMN "autoreject";
jbe@177 168
jbe@177 169 ALTER TABLE "interest" DROP COLUMN "autoreject";
jbe@177 170 ALTER TABLE "interest" DROP COLUMN "voting_requested";
jbe@177 171
jbe@177 172 ALTER TABLE "supporter" DROP CONSTRAINT "supporter_initiative_id_fkey";
jbe@177 173 ALTER TABLE "supporter" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
jbe@177 174
jbe@177 175 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")';
jbe@177 176
jbe@177 177 ALTER TABLE "direct_interest_snapshot" DROP COLUMN "voting_requested";
jbe@177 178 ALTER TABLE "direct_voter" DROP COLUMN "autoreject";
jbe@177 179
jbe@177 180 DROP TRIGGER "default_for_draft_id" ON "supporter";
jbe@177 181 DROP FUNCTION "supporter_default_for_draft_id_trigger"();
jbe@177 182
jbe@177 183 CREATE FUNCTION "default_for_draft_id_trigger"()
jbe@177 184 RETURNS TRIGGER
jbe@177 185 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@177 186 BEGIN
jbe@177 187 IF NEW."draft_id" ISNULL THEN
jbe@177 188 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@177 189 WHERE "initiative_id" = NEW."initiative_id";
jbe@177 190 END IF;
jbe@177 191 RETURN NEW;
jbe@177 192 END;
jbe@177 193 $$;
jbe@177 194
jbe@177 195 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
jbe@177 196 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@177 197 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@177 198 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@177 199
jbe@177 200 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
jbe@177 201 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';
jbe@177 202 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';
jbe@177 203
jbe@177 204 CREATE VIEW "area_member_count" AS
jbe@177 205 SELECT
jbe@177 206 "area"."id" AS "area_id",
jbe@177 207 count("member"."id") AS "direct_member_count",
jbe@177 208 coalesce(
jbe@177 209 sum(
jbe@177 210 CASE WHEN "member"."id" NOTNULL THEN
jbe@177 211 "membership_weight"("area"."id", "member"."id")
jbe@177 212 ELSE 0 END
jbe@177 213 )
jbe@177 214 ) AS "member_weight"
jbe@177 215 FROM "area"
jbe@177 216 LEFT JOIN "membership"
jbe@177 217 ON "area"."id" = "membership"."area_id"
jbe@177 218 LEFT JOIN "privilege"
jbe@177 219 ON "privilege"."unit_id" = "area"."unit_id"
jbe@177 220 AND "privilege"."member_id" = "membership"."member_id"
jbe@177 221 AND "privilege"."voting_right"
jbe@177 222 LEFT JOIN "member"
jbe@177 223 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
jbe@177 224 AND "member"."active"
jbe@177 225 GROUP BY "area"."id";
jbe@177 226
jbe@177 227 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
jbe@177 228
jbe@177 229 CREATE VIEW "battle_participant" AS
jbe@177 230 SELECT "initiative"."id", "initiative"."issue_id"
jbe@177 231 FROM "issue" JOIN "initiative"
jbe@177 232 ON "issue"."id" = "initiative"."issue_id"
jbe@177 233 WHERE "initiative"."admitted"
jbe@177 234 UNION ALL
jbe@177 235 SELECT NULL, "id" AS "issue_id"
jbe@177 236 FROM "issue";
jbe@177 237
jbe@177 238 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
jbe@177 239
jbe@179 240 CREATE VIEW "battle_view" AS
jbe@177 241 SELECT
jbe@177 242 "issue"."id" AS "issue_id",
jbe@177 243 "winning_initiative"."id" AS "winning_initiative_id",
jbe@177 244 "losing_initiative"."id" AS "losing_initiative_id",
jbe@177 245 sum(
jbe@177 246 CASE WHEN
jbe@177 247 coalesce("better_vote"."grade", 0) >
jbe@177 248 coalesce("worse_vote"."grade", 0)
jbe@177 249 THEN "direct_voter"."weight" ELSE 0 END
jbe@177 250 ) AS "count"
jbe@177 251 FROM "issue"
jbe@177 252 LEFT JOIN "direct_voter"
jbe@177 253 ON "issue"."id" = "direct_voter"."issue_id"
jbe@177 254 JOIN "battle_participant" AS "winning_initiative"
jbe@177 255 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@177 256 JOIN "battle_participant" AS "losing_initiative"
jbe@177 257 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@177 258 LEFT JOIN "vote" AS "better_vote"
jbe@177 259 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@177 260 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@177 261 LEFT JOIN "vote" AS "worse_vote"
jbe@177 262 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@177 263 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@177 264 WHERE "issue"."closed" NOTNULL
jbe@177 265 AND "issue"."cleaned" ISNULL
jbe@177 266 AND (
jbe@177 267 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@177 268 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@177 269 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@177 270 GROUP BY
jbe@177 271 "issue"."id",
jbe@177 272 "winning_initiative"."id",
jbe@177 273 "losing_initiative"."id";
jbe@177 274
jbe@177 275 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';
jbe@177 276
jbe@177 277 CREATE OR REPLACE FUNCTION "create_interest_snapshot"
jbe@177 278 ( "issue_id_p" "issue"."id"%TYPE )
jbe@177 279 RETURNS VOID
jbe@177 280 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@177 281 DECLARE
jbe@177 282 "member_id_v" "member"."id"%TYPE;
jbe@177 283 BEGIN
jbe@177 284 DELETE FROM "direct_interest_snapshot"
jbe@177 285 WHERE "issue_id" = "issue_id_p"
jbe@177 286 AND "event" = 'periodic';
jbe@177 287 DELETE FROM "delegating_interest_snapshot"
jbe@177 288 WHERE "issue_id" = "issue_id_p"
jbe@177 289 AND "event" = 'periodic';
jbe@177 290 DELETE FROM "direct_supporter_snapshot"
jbe@177 291 WHERE "issue_id" = "issue_id_p"
jbe@177 292 AND "event" = 'periodic';
jbe@177 293 INSERT INTO "direct_interest_snapshot"
jbe@177 294 ("issue_id", "event", "member_id")
jbe@177 295 SELECT
jbe@177 296 "issue_id_p" AS "issue_id",
jbe@177 297 'periodic' AS "event",
jbe@177 298 "member"."id" AS "member_id"
jbe@177 299 FROM "issue"
jbe@177 300 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@177 301 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@177 302 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@177 303 JOIN "privilege"
jbe@177 304 ON "privilege"."unit_id" = "area"."unit_id"
jbe@177 305 AND "privilege"."member_id" = "member"."id"
jbe@177 306 WHERE "issue"."id" = "issue_id_p"
jbe@177 307 AND "member"."active" AND "privilege"."voting_right";
jbe@177 308 FOR "member_id_v" IN
jbe@177 309 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@177 310 WHERE "issue_id" = "issue_id_p"
jbe@177 311 AND "event" = 'periodic'
jbe@177 312 LOOP
jbe@177 313 UPDATE "direct_interest_snapshot" SET
jbe@177 314 "weight" = 1 +
jbe@177 315 "weight_of_added_delegations_for_interest_snapshot"(
jbe@177 316 "issue_id_p",
jbe@177 317 "member_id_v",
jbe@177 318 '{}'
jbe@177 319 )
jbe@177 320 WHERE "issue_id" = "issue_id_p"
jbe@177 321 AND "event" = 'periodic'
jbe@177 322 AND "member_id" = "member_id_v";
jbe@177 323 END LOOP;
jbe@177 324 INSERT INTO "direct_supporter_snapshot"
jbe@177 325 ( "issue_id", "initiative_id", "event", "member_id",
jbe@177 326 "informed", "satisfied" )
jbe@177 327 SELECT
jbe@177 328 "issue_id_p" AS "issue_id",
jbe@177 329 "initiative"."id" AS "initiative_id",
jbe@177 330 'periodic' AS "event",
jbe@177 331 "supporter"."member_id" AS "member_id",
jbe@177 332 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@177 333 NOT EXISTS (
jbe@177 334 SELECT NULL FROM "critical_opinion"
jbe@177 335 WHERE "initiative_id" = "initiative"."id"
jbe@177 336 AND "member_id" = "supporter"."member_id"
jbe@177 337 ) AS "satisfied"
jbe@177 338 FROM "initiative"
jbe@177 339 JOIN "supporter"
jbe@177 340 ON "supporter"."initiative_id" = "initiative"."id"
jbe@177 341 JOIN "current_draft"
jbe@177 342 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@177 343 JOIN "direct_interest_snapshot"
jbe@177 344 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@177 345 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@177 346 AND "event" = 'periodic'
jbe@177 347 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@177 348 RETURN;
jbe@177 349 END;
jbe@177 350 $$;
jbe@177 351
jbe@177 352 CREATE OR REPLACE FUNCTION "create_snapshot"
jbe@177 353 ( "issue_id_p" "issue"."id"%TYPE )
jbe@177 354 RETURNS VOID
jbe@177 355 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@177 356 DECLARE
jbe@177 357 "initiative_id_v" "initiative"."id"%TYPE;
jbe@177 358 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@177 359 BEGIN
jbe@177 360 PERFORM "lock_issue"("issue_id_p");
jbe@177 361 PERFORM "create_population_snapshot"("issue_id_p");
jbe@177 362 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@177 363 UPDATE "issue" SET
jbe@177 364 "snapshot" = now(),
jbe@177 365 "latest_snapshot_event" = 'periodic',
jbe@177 366 "population" = (
jbe@177 367 SELECT coalesce(sum("weight"), 0)
jbe@177 368 FROM "direct_population_snapshot"
jbe@177 369 WHERE "issue_id" = "issue_id_p"
jbe@177 370 AND "event" = 'periodic'
jbe@177 371 )
jbe@177 372 WHERE "id" = "issue_id_p";
jbe@177 373 FOR "initiative_id_v" IN
jbe@177 374 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@177 375 LOOP
jbe@177 376 UPDATE "initiative" SET
jbe@177 377 "supporter_count" = (
jbe@177 378 SELECT coalesce(sum("di"."weight"), 0)
jbe@177 379 FROM "direct_interest_snapshot" AS "di"
jbe@177 380 JOIN "direct_supporter_snapshot" AS "ds"
jbe@177 381 ON "di"."member_id" = "ds"."member_id"
jbe@177 382 WHERE "di"."issue_id" = "issue_id_p"
jbe@177 383 AND "di"."event" = 'periodic'
jbe@177 384 AND "ds"."initiative_id" = "initiative_id_v"
jbe@177 385 AND "ds"."event" = 'periodic'
jbe@177 386 ),
jbe@177 387 "informed_supporter_count" = (
jbe@177 388 SELECT coalesce(sum("di"."weight"), 0)
jbe@177 389 FROM "direct_interest_snapshot" AS "di"
jbe@177 390 JOIN "direct_supporter_snapshot" AS "ds"
jbe@177 391 ON "di"."member_id" = "ds"."member_id"
jbe@177 392 WHERE "di"."issue_id" = "issue_id_p"
jbe@177 393 AND "di"."event" = 'periodic'
jbe@177 394 AND "ds"."initiative_id" = "initiative_id_v"
jbe@177 395 AND "ds"."event" = 'periodic'
jbe@177 396 AND "ds"."informed"
jbe@177 397 ),
jbe@177 398 "satisfied_supporter_count" = (
jbe@177 399 SELECT coalesce(sum("di"."weight"), 0)
jbe@177 400 FROM "direct_interest_snapshot" AS "di"
jbe@177 401 JOIN "direct_supporter_snapshot" AS "ds"
jbe@177 402 ON "di"."member_id" = "ds"."member_id"
jbe@177 403 WHERE "di"."issue_id" = "issue_id_p"
jbe@177 404 AND "di"."event" = 'periodic'
jbe@177 405 AND "ds"."initiative_id" = "initiative_id_v"
jbe@177 406 AND "ds"."event" = 'periodic'
jbe@177 407 AND "ds"."satisfied"
jbe@177 408 ),
jbe@177 409 "satisfied_informed_supporter_count" = (
jbe@177 410 SELECT coalesce(sum("di"."weight"), 0)
jbe@177 411 FROM "direct_interest_snapshot" AS "di"
jbe@177 412 JOIN "direct_supporter_snapshot" AS "ds"
jbe@177 413 ON "di"."member_id" = "ds"."member_id"
jbe@177 414 WHERE "di"."issue_id" = "issue_id_p"
jbe@177 415 AND "di"."event" = 'periodic'
jbe@177 416 AND "ds"."initiative_id" = "initiative_id_v"
jbe@177 417 AND "ds"."event" = 'periodic'
jbe@177 418 AND "ds"."informed"
jbe@177 419 AND "ds"."satisfied"
jbe@177 420 )
jbe@177 421 WHERE "id" = "initiative_id_v";
jbe@177 422 FOR "suggestion_id_v" IN
jbe@177 423 SELECT "id" FROM "suggestion"
jbe@177 424 WHERE "initiative_id" = "initiative_id_v"
jbe@177 425 LOOP
jbe@177 426 UPDATE "suggestion" SET
jbe@177 427 "minus2_unfulfilled_count" = (
jbe@177 428 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 429 FROM "issue" CROSS JOIN "opinion"
jbe@177 430 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 431 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 432 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 433 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 434 WHERE "issue"."id" = "issue_id_p"
jbe@177 435 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 436 AND "opinion"."degree" = -2
jbe@177 437 AND "opinion"."fulfilled" = FALSE
jbe@177 438 ),
jbe@177 439 "minus2_fulfilled_count" = (
jbe@177 440 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 441 FROM "issue" CROSS JOIN "opinion"
jbe@177 442 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 443 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 444 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 445 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 446 WHERE "issue"."id" = "issue_id_p"
jbe@177 447 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 448 AND "opinion"."degree" = -2
jbe@177 449 AND "opinion"."fulfilled" = TRUE
jbe@177 450 ),
jbe@177 451 "minus1_unfulfilled_count" = (
jbe@177 452 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 453 FROM "issue" CROSS JOIN "opinion"
jbe@177 454 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 455 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 456 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 457 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 458 WHERE "issue"."id" = "issue_id_p"
jbe@177 459 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 460 AND "opinion"."degree" = -1
jbe@177 461 AND "opinion"."fulfilled" = FALSE
jbe@177 462 ),
jbe@177 463 "minus1_fulfilled_count" = (
jbe@177 464 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 465 FROM "issue" CROSS JOIN "opinion"
jbe@177 466 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 467 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 468 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 469 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 470 WHERE "issue"."id" = "issue_id_p"
jbe@177 471 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 472 AND "opinion"."degree" = -1
jbe@177 473 AND "opinion"."fulfilled" = TRUE
jbe@177 474 ),
jbe@177 475 "plus1_unfulfilled_count" = (
jbe@177 476 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 477 FROM "issue" CROSS JOIN "opinion"
jbe@177 478 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 479 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 480 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 481 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 482 WHERE "issue"."id" = "issue_id_p"
jbe@177 483 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 484 AND "opinion"."degree" = 1
jbe@177 485 AND "opinion"."fulfilled" = FALSE
jbe@177 486 ),
jbe@177 487 "plus1_fulfilled_count" = (
jbe@177 488 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 489 FROM "issue" CROSS JOIN "opinion"
jbe@177 490 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 491 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 492 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 493 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 494 WHERE "issue"."id" = "issue_id_p"
jbe@177 495 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 496 AND "opinion"."degree" = 1
jbe@177 497 AND "opinion"."fulfilled" = TRUE
jbe@177 498 ),
jbe@177 499 "plus2_unfulfilled_count" = (
jbe@177 500 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 501 FROM "issue" CROSS JOIN "opinion"
jbe@177 502 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 503 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 504 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 505 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 506 WHERE "issue"."id" = "issue_id_p"
jbe@177 507 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 508 AND "opinion"."degree" = 2
jbe@177 509 AND "opinion"."fulfilled" = FALSE
jbe@177 510 ),
jbe@177 511 "plus2_fulfilled_count" = (
jbe@177 512 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@177 513 FROM "issue" CROSS JOIN "opinion"
jbe@177 514 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@177 515 ON "snapshot"."issue_id" = "issue"."id"
jbe@177 516 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@177 517 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@177 518 WHERE "issue"."id" = "issue_id_p"
jbe@177 519 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@177 520 AND "opinion"."degree" = 2
jbe@177 521 AND "opinion"."fulfilled" = TRUE
jbe@177 522 )
jbe@177 523 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@177 524 END LOOP;
jbe@177 525 END LOOP;
jbe@177 526 RETURN;
jbe@177 527 END;
jbe@177 528 $$;
jbe@177 529
jbe@177 530 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@177 531 RETURNS VOID
jbe@177 532 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@177 533 DECLARE
jbe@177 534 "area_id_v" "area"."id"%TYPE;
jbe@177 535 "unit_id_v" "unit"."id"%TYPE;
jbe@177 536 "member_id_v" "member"."id"%TYPE;
jbe@177 537 BEGIN
jbe@177 538 PERFORM "lock_issue"("issue_id_p");
jbe@177 539 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@177 540 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@177 541 -- delete delegating votes (in cases of manual reset of issue state):
jbe@177 542 DELETE FROM "delegating_voter"
jbe@177 543 WHERE "issue_id" = "issue_id_p";
jbe@177 544 -- delete votes from non-privileged voters:
jbe@177 545 DELETE FROM "direct_voter"
jbe@177 546 USING (
jbe@177 547 SELECT
jbe@177 548 "direct_voter"."member_id"
jbe@177 549 FROM "direct_voter"
jbe@177 550 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@177 551 LEFT JOIN "privilege"
jbe@177 552 ON "privilege"."unit_id" = "unit_id_v"
jbe@177 553 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@177 554 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@177 555 "member"."active" = FALSE OR
jbe@177 556 "privilege"."voting_right" ISNULL OR
jbe@177 557 "privilege"."voting_right" = FALSE
jbe@177 558 )
jbe@177 559 ) AS "subquery"
jbe@177 560 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@177 561 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@177 562 -- consider delegations:
jbe@177 563 UPDATE "direct_voter" SET "weight" = 1
jbe@177 564 WHERE "issue_id" = "issue_id_p";
jbe@177 565 PERFORM "add_vote_delegations"("issue_id_p");
jbe@177 566 -- set voter count and mark issue as being calculated:
jbe@177 567 UPDATE "issue" SET
jbe@177 568 "state" = 'calculation',
jbe@177 569 "closed" = now(),
jbe@177 570 "voter_count" = (
jbe@177 571 SELECT coalesce(sum("weight"), 0)
jbe@177 572 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@177 573 )
jbe@177 574 WHERE "id" = "issue_id_p";
jbe@177 575 -- materialize battle_view:
jbe@177 576 -- NOTE: "closed" column of issue must be set at this point
jbe@177 577 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@177 578 INSERT INTO "battle" (
jbe@177 579 "issue_id",
jbe@177 580 "winning_initiative_id", "losing_initiative_id",
jbe@177 581 "count"
jbe@177 582 ) SELECT
jbe@177 583 "issue_id",
jbe@177 584 "winning_initiative_id", "losing_initiative_id",
jbe@177 585 "count"
jbe@177 586 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@177 587 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@177 588 UPDATE "initiative" SET
jbe@177 589 "positive_votes" = "battle_win"."count",
jbe@177 590 "negative_votes" = "battle_lose"."count"
jbe@177 591 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@177 592 WHERE
jbe@177 593 "battle_win"."issue_id" = "issue_id_p" AND
jbe@177 594 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@177 595 "battle_win"."losing_initiative_id" ISNULL AND
jbe@177 596 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@177 597 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@177 598 "battle_lose"."winning_initiative_id" ISNULL;
jbe@177 599 END;
jbe@177 600 $$;
jbe@177 601
jbe@177 602 DROP FUNCTION "array_init_string"(INTEGER);
jbe@177 603 DROP FUNCTION "square_matrix_init_string"(INTEGER);
jbe@177 604
jbe@177 605 CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@177 606 RETURNS VOID
jbe@177 607 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@177 608 DECLARE
jbe@177 609 "issue_row" "issue"%ROWTYPE;
jbe@177 610 "policy_row" "policy"%ROWTYPE;
jbe@177 611 "dimension_v" INTEGER;
jbe@177 612 "vote_matrix" INT4[][]; -- absolute votes
jbe@177 613 "matrix" INT8[][]; -- defeat strength / best paths
jbe@177 614 "i" INTEGER;
jbe@177 615 "j" INTEGER;
jbe@177 616 "k" INTEGER;
jbe@177 617 "battle_row" "battle"%ROWTYPE;
jbe@177 618 "rank_ary" INT4[];
jbe@177 619 "rank_v" INT4;
jbe@177 620 "done_v" INTEGER;
jbe@177 621 "winners_ary" INTEGER[];
jbe@177 622 "initiative_id_v" "initiative"."id"%TYPE;
jbe@177 623 BEGIN
jbe@177 624 SELECT * INTO "issue_row"
jbe@177 625 FROM "issue" WHERE "id" = "issue_id_p"
jbe@177 626 FOR UPDATE;
jbe@177 627 SELECT * INTO "policy_row"
jbe@177 628 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@177 629 SELECT count(1) INTO "dimension_v"
jbe@177 630 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@177 631 -- Create "vote_matrix" with absolute number of votes in pairwise
jbe@177 632 -- comparison:
jbe@177 633 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@177 634 "i" := 1;
jbe@177 635 "j" := 2;
jbe@177 636 FOR "battle_row" IN
jbe@177 637 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@177 638 ORDER BY
jbe@177 639 "winning_initiative_id" NULLS LAST,
jbe@177 640 "losing_initiative_id" NULLS LAST
jbe@177 641 LOOP
jbe@177 642 "vote_matrix"["i"]["j"] := "battle_row"."count";
jbe@177 643 IF "j" = "dimension_v" THEN
jbe@177 644 "i" := "i" + 1;
jbe@177 645 "j" := 1;
jbe@177 646 ELSE
jbe@177 647 "j" := "j" + 1;
jbe@177 648 IF "j" = "i" THEN
jbe@177 649 "j" := "j" + 1;
jbe@177 650 END IF;
jbe@177 651 END IF;
jbe@177 652 END LOOP;
jbe@177 653 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@177 654 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@177 655 END IF;
jbe@177 656 -- Store defeat strengths in "matrix" using "defeat_strength"
jbe@177 657 -- function:
jbe@177 658 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@177 659 "i" := 1;
jbe@177 660 LOOP
jbe@177 661 "j" := 1;
jbe@177 662 LOOP
jbe@177 663 IF "i" != "j" THEN
jbe@177 664 "matrix"["i"]["j"] := "defeat_strength"(
jbe@177 665 "vote_matrix"["i"]["j"],
jbe@177 666 "vote_matrix"["j"]["i"]
jbe@177 667 );
jbe@177 668 END IF;
jbe@177 669 EXIT WHEN "j" = "dimension_v";
jbe@177 670 "j" := "j" + 1;
jbe@177 671 END LOOP;
jbe@177 672 EXIT WHEN "i" = "dimension_v";
jbe@177 673 "i" := "i" + 1;
jbe@177 674 END LOOP;
jbe@177 675 -- Find best paths:
jbe@177 676 "i" := 1;
jbe@177 677 LOOP
jbe@177 678 "j" := 1;
jbe@177 679 LOOP
jbe@177 680 IF "i" != "j" THEN
jbe@177 681 "k" := 1;
jbe@177 682 LOOP
jbe@177 683 IF "i" != "k" AND "j" != "k" THEN
jbe@177 684 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
jbe@177 685 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
jbe@177 686 "matrix"["j"]["k"] := "matrix"["j"]["i"];
jbe@177 687 END IF;
jbe@177 688 ELSE
jbe@177 689 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
jbe@177 690 "matrix"["j"]["k"] := "matrix"["i"]["k"];
jbe@177 691 END IF;
jbe@177 692 END IF;
jbe@177 693 END IF;
jbe@177 694 EXIT WHEN "k" = "dimension_v";
jbe@177 695 "k" := "k" + 1;
jbe@177 696 END LOOP;
jbe@177 697 END IF;
jbe@177 698 EXIT WHEN "j" = "dimension_v";
jbe@177 699 "j" := "j" + 1;
jbe@177 700 END LOOP;
jbe@177 701 EXIT WHEN "i" = "dimension_v";
jbe@177 702 "i" := "i" + 1;
jbe@177 703 END LOOP;
jbe@177 704 -- Determine order of winners:
jbe@177 705 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@177 706 "rank_v" := 1;
jbe@177 707 "done_v" := 0;
jbe@177 708 LOOP
jbe@177 709 "winners_ary" := '{}';
jbe@177 710 "i" := 1;
jbe@177 711 LOOP
jbe@177 712 IF "rank_ary"["i"] ISNULL THEN
jbe@177 713 "j" := 1;
jbe@177 714 LOOP
jbe@177 715 IF
jbe@177 716 "i" != "j" AND
jbe@177 717 "rank_ary"["j"] ISNULL AND
jbe@177 718 "matrix"["j"]["i"] > "matrix"["i"]["j"]
jbe@177 719 THEN
jbe@177 720 -- someone else is better
jbe@177 721 EXIT;
jbe@177 722 END IF;
jbe@177 723 IF "j" = "dimension_v" THEN
jbe@177 724 -- noone is better
jbe@177 725 "winners_ary" := "winners_ary" || "i";
jbe@177 726 EXIT;
jbe@177 727 END IF;
jbe@177 728 "j" := "j" + 1;
jbe@177 729 END LOOP;
jbe@177 730 END IF;
jbe@177 731 EXIT WHEN "i" = "dimension_v";
jbe@177 732 "i" := "i" + 1;
jbe@177 733 END LOOP;
jbe@177 734 "i" := 1;
jbe@177 735 LOOP
jbe@177 736 "rank_ary"["winners_ary"["i"]] := "rank_v";
jbe@177 737 "done_v" := "done_v" + 1;
jbe@177 738 EXIT WHEN "i" = array_upper("winners_ary", 1);
jbe@177 739 "i" := "i" + 1;
jbe@177 740 END LOOP;
jbe@177 741 EXIT WHEN "done_v" = "dimension_v";
jbe@177 742 "rank_v" := "rank_v" + 1;
jbe@177 743 END LOOP;
jbe@177 744 -- write preliminary results:
jbe@177 745 "i" := 1;
jbe@177 746 FOR "initiative_id_v" IN
jbe@177 747 SELECT "id" FROM "initiative"
jbe@177 748 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@177 749 ORDER BY "id"
jbe@177 750 LOOP
jbe@177 751 UPDATE "initiative" SET
jbe@177 752 "direct_majority" =
jbe@177 753 CASE WHEN "policy_row"."direct_majority_strict" THEN
jbe@177 754 "positive_votes" * "policy_row"."direct_majority_den" >
jbe@177 755 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@177 756 ELSE
jbe@177 757 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@177 758 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@177 759 END
jbe@177 760 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@177 761 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@177 762 "policy_row"."direct_majority_non_negative",
jbe@177 763 "indirect_majority" =
jbe@177 764 CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@177 765 "positive_votes" * "policy_row"."indirect_majority_den" >
jbe@177 766 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@177 767 ELSE
jbe@177 768 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@177 769 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@177 770 END
jbe@177 771 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@177 772 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@177 773 "policy_row"."indirect_majority_non_negative",
jbe@177 774 "schulze_rank" = "rank_ary"["i"],
jbe@177 775 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
jbe@177 776 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
jbe@177 777 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
jbe@177 778 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
jbe@177 779 "winner" = FALSE
jbe@177 780 WHERE "id" = "initiative_id_v";
jbe@177 781 "i" := "i" + 1;
jbe@177 782 END LOOP;
jbe@177 783 IF "i" != "dimension_v" THEN
jbe@177 784 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@177 785 END IF;
jbe@177 786 -- take indirect majorities into account:
jbe@177 787 LOOP
jbe@177 788 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@177 789 FROM (
jbe@177 790 SELECT "new_initiative"."id" AS "initiative_id"
jbe@177 791 FROM "initiative" "old_initiative"
jbe@177 792 JOIN "initiative" "new_initiative"
jbe@177 793 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@177 794 AND "new_initiative"."indirect_majority" = FALSE
jbe@177 795 JOIN "battle" "battle_win"
jbe@177 796 ON "battle_win"."issue_id" = "issue_id_p"
jbe@177 797 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@177 798 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@177 799 JOIN "battle" "battle_lose"
jbe@177 800 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@177 801 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@177 802 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@177 803 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@177 804 AND "old_initiative"."indirect_majority" = TRUE
jbe@177 805 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@177 806 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@177 807 "policy_row"."indirect_majority_num" *
jbe@177 808 ("battle_win"."count"+"battle_lose"."count")
jbe@177 809 ELSE
jbe@177 810 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@177 811 "policy_row"."indirect_majority_num" *
jbe@177 812 ("battle_win"."count"+"battle_lose"."count")
jbe@177 813 END
jbe@177 814 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@177 815 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@177 816 "policy_row"."indirect_majority_non_negative"
jbe@177 817 ) AS "subquery"
jbe@177 818 WHERE "id" = "subquery"."initiative_id";
jbe@177 819 EXIT WHEN NOT FOUND;
jbe@177 820 END LOOP;
jbe@177 821 -- set "multistage_majority" for remaining matching initiatives:
jbe@177 822 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@177 823 FROM (
jbe@177 824 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@177 825 FROM "initiative" "losing_initiative"
jbe@177 826 JOIN "initiative" "winning_initiative"
jbe@177 827 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@177 828 AND "winning_initiative"."admitted"
jbe@177 829 JOIN "battle" "battle_win"
jbe@177 830 ON "battle_win"."issue_id" = "issue_id_p"
jbe@177 831 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@177 832 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@177 833 JOIN "battle" "battle_lose"
jbe@177 834 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@177 835 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@177 836 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@177 837 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@177 838 AND "losing_initiative"."admitted"
jbe@177 839 AND "winning_initiative"."schulze_rank" <
jbe@177 840 "losing_initiative"."schulze_rank"
jbe@177 841 AND "battle_win"."count" > "battle_lose"."count"
jbe@177 842 AND (
jbe@177 843 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@177 844 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@177 845 ) AS "subquery"
jbe@177 846 WHERE "id" = "subquery"."initiative_id";
jbe@177 847 -- mark eligible initiatives:
jbe@177 848 UPDATE "initiative" SET "eligible" = TRUE
jbe@177 849 WHERE "issue_id" = "issue_id_p"
jbe@177 850 AND "initiative"."direct_majority"
jbe@177 851 AND "initiative"."indirect_majority"
jbe@177 852 AND "initiative"."better_than_status_quo"
jbe@177 853 AND (
jbe@177 854 "policy_row"."no_multistage_majority" = FALSE OR
jbe@177 855 "initiative"."multistage_majority" = FALSE )
jbe@177 856 AND (
jbe@177 857 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@177 858 "initiative"."reverse_beat_path" = FALSE );
jbe@177 859 -- mark final winner:
jbe@177 860 UPDATE "initiative" SET "winner" = TRUE
jbe@177 861 FROM (
jbe@177 862 SELECT "id" AS "initiative_id"
jbe@177 863 FROM "initiative"
jbe@177 864 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@177 865 ORDER BY "schulze_rank", "id"
jbe@177 866 LIMIT 1
jbe@177 867 ) AS "subquery"
jbe@177 868 WHERE "id" = "subquery"."initiative_id";
jbe@177 869 -- write (final) ranks:
jbe@177 870 "rank_v" := 1;
jbe@177 871 FOR "initiative_id_v" IN
jbe@177 872 SELECT "id"
jbe@177 873 FROM "initiative"
jbe@177 874 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@177 875 ORDER BY
jbe@177 876 "winner" DESC,
jbe@177 877 ("direct_majority" AND "indirect_majority") DESC,
jbe@177 878 "schulze_rank",
jbe@177 879 "id"
jbe@177 880 LOOP
jbe@177 881 UPDATE "initiative" SET "rank" = "rank_v"
jbe@177 882 WHERE "id" = "initiative_id_v";
jbe@177 883 "rank_v" := "rank_v" + 1;
jbe@177 884 END LOOP;
jbe@177 885 -- set schulze rank of status quo and mark issue as finished:
jbe@177 886 UPDATE "issue" SET
jbe@177 887 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
jbe@177 888 "state" =
jbe@177 889 CASE WHEN EXISTS (
jbe@177 890 SELECT NULL FROM "initiative"
jbe@177 891 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@177 892 ) THEN
jbe@177 893 'finished_with_winner'::"issue_state"
jbe@177 894 ELSE
jbe@177 895 'finished_without_winner'::"issue_state"
jbe@177 896 END,
jbe@177 897 "ranks_available" = TRUE
jbe@177 898 WHERE "id" = "issue_id_p";
jbe@177 899 RETURN;
jbe@177 900 END;
jbe@177 901 $$;
jbe@177 902
jbe@177 903 CREATE OR REPLACE FUNCTION "check_issue"
jbe@177 904 ( "issue_id_p" "issue"."id"%TYPE )
jbe@177 905 RETURNS VOID
jbe@177 906 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@177 907 DECLARE
jbe@177 908 "issue_row" "issue"%ROWTYPE;
jbe@177 909 "policy_row" "policy"%ROWTYPE;
jbe@177 910 BEGIN
jbe@177 911 PERFORM "lock_issue"("issue_id_p");
jbe@177 912 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@177 913 -- only process open issues:
jbe@177 914 IF "issue_row"."closed" ISNULL THEN
jbe@177 915 SELECT * INTO "policy_row" FROM "policy"
jbe@177 916 WHERE "id" = "issue_row"."policy_id";
jbe@177 917 -- create a snapshot, unless issue is already fully frozen:
jbe@177 918 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@177 919 PERFORM "create_snapshot"("issue_id_p");
jbe@177 920 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@177 921 END IF;
jbe@177 922 -- eventually close or accept issues, which have not been accepted:
jbe@177 923 IF "issue_row"."accepted" ISNULL THEN
jbe@177 924 IF EXISTS (
jbe@177 925 SELECT NULL FROM "initiative"
jbe@177 926 WHERE "issue_id" = "issue_id_p"
jbe@177 927 AND "supporter_count" > 0
jbe@177 928 AND "supporter_count" * "policy_row"."issue_quorum_den"
jbe@177 929 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
jbe@177 930 ) THEN
jbe@177 931 -- accept issues, if supporter count is high enough
jbe@177 932 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@177 933 -- NOTE: "issue_row" used later
jbe@177 934 "issue_row"."state" := 'discussion';
jbe@177 935 "issue_row"."accepted" := now();
jbe@177 936 UPDATE "issue" SET
jbe@177 937 "state" = "issue_row"."state",
jbe@177 938 "accepted" = "issue_row"."accepted"
jbe@177 939 WHERE "id" = "issue_row"."id";
jbe@177 940 ELSIF
jbe@177 941 now() >= "issue_row"."created" + "issue_row"."admission_time"
jbe@177 942 THEN
jbe@177 943 -- close issues, if admission time has expired
jbe@177 944 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@177 945 UPDATE "issue" SET
jbe@177 946 "state" = 'canceled_issue_not_accepted',
jbe@177 947 "closed" = now()
jbe@177 948 WHERE "id" = "issue_row"."id";
jbe@177 949 END IF;
jbe@177 950 END IF;
jbe@177 951 -- eventually half freeze issues:
jbe@177 952 IF
jbe@177 953 -- NOTE: issue can't be closed at this point, if it has been accepted
jbe@177 954 "issue_row"."accepted" NOTNULL AND
jbe@177 955 "issue_row"."half_frozen" ISNULL
jbe@177 956 THEN
jbe@177 957 IF
jbe@177 958 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
jbe@177 959 THEN
jbe@177 960 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@177 961 -- NOTE: "issue_row" used later
jbe@177 962 "issue_row"."state" := 'verification';
jbe@177 963 "issue_row"."half_frozen" := now();
jbe@177 964 UPDATE "issue" SET
jbe@177 965 "state" = "issue_row"."state",
jbe@177 966 "half_frozen" = "issue_row"."half_frozen"
jbe@177 967 WHERE "id" = "issue_row"."id";
jbe@177 968 END IF;
jbe@177 969 END IF;
jbe@177 970 -- close issues after some time, if all initiatives have been revoked:
jbe@177 971 IF
jbe@177 972 "issue_row"."closed" ISNULL AND
jbe@177 973 NOT EXISTS (
jbe@177 974 -- all initiatives are revoked
jbe@177 975 SELECT NULL FROM "initiative"
jbe@177 976 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@177 977 ) AND (
jbe@177 978 -- and issue has not been accepted yet
jbe@177 979 "issue_row"."accepted" ISNULL OR
jbe@177 980 NOT EXISTS (
jbe@177 981 -- or no initiatives have been revoked lately
jbe@177 982 SELECT NULL FROM "initiative"
jbe@177 983 WHERE "issue_id" = "issue_id_p"
jbe@177 984 AND now() < "revoked" + "issue_row"."verification_time"
jbe@177 985 ) OR (
jbe@177 986 -- or verification time has elapsed
jbe@177 987 "issue_row"."half_frozen" NOTNULL AND
jbe@177 988 "issue_row"."fully_frozen" ISNULL AND
jbe@177 989 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@177 990 )
jbe@177 991 )
jbe@177 992 THEN
jbe@177 993 -- NOTE: "issue_row" used later
jbe@177 994 IF "issue_row"."accepted" ISNULL THEN
jbe@177 995 "issue_row"."state" := 'canceled_revoked_before_accepted';
jbe@177 996 ELSIF "issue_row"."half_frozen" ISNULL THEN
jbe@177 997 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
jbe@177 998 ELSE
jbe@177 999 "issue_row"."state" := 'canceled_after_revocation_during_verification';
jbe@177 1000 END IF;
jbe@177 1001 "issue_row"."closed" := now();
jbe@177 1002 UPDATE "issue" SET
jbe@177 1003 "state" = "issue_row"."state",
jbe@177 1004 "closed" = "issue_row"."closed"
jbe@177 1005 WHERE "id" = "issue_row"."id";
jbe@177 1006 END IF;
jbe@177 1007 -- fully freeze issue after verification time:
jbe@177 1008 IF
jbe@177 1009 "issue_row"."half_frozen" NOTNULL AND
jbe@177 1010 "issue_row"."fully_frozen" ISNULL AND
jbe@177 1011 "issue_row"."closed" ISNULL AND
jbe@177 1012 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@177 1013 THEN
jbe@177 1014 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@177 1015 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
jbe@177 1016 END IF;
jbe@177 1017 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@177 1018 -- close issue by calling close_voting(...) after voting time:
jbe@177 1019 IF
jbe@177 1020 "issue_row"."closed" ISNULL AND
jbe@177 1021 "issue_row"."fully_frozen" NOTNULL AND
jbe@177 1022 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
jbe@177 1023 THEN
jbe@177 1024 PERFORM "close_voting"("issue_id_p");
jbe@177 1025 -- calculate ranks will not consume much time and can be done now
jbe@177 1026 PERFORM "calculate_ranks"("issue_id_p");
jbe@177 1027 END IF;
jbe@177 1028 END IF;
jbe@177 1029 RETURN;
jbe@177 1030 END;
jbe@177 1031 $$;
jbe@177 1032
jbe@178 1033 COMMIT;
jbe@178 1034
jbe@178 1035 BEGIN;
jbe@178 1036
jbe@178 1037 UPDATE "initiative" SET
jbe@178 1038 "direct_majority" = "rank" NOTNULL,
jbe@178 1039 "indirect_majority" = "rank" NOTNULL,
jbe@178 1040 "schulze_rank" = "rank",
jbe@178 1041 "better_than_status_quo" = "rank" NOTNULL,
jbe@178 1042 "worse_than_status_quo" = "rank" ISNULL,
jbe@178 1043 "reverse_beat_path" = "rank" ISNULL,
jbe@178 1044 "multistage_majority" = "rank" ISNULL,
jbe@178 1045 "eligible" = "rank" NOTNULL,
jbe@178 1046 "winner" = ("rank" = 1)
jbe@178 1047 FROM "issue"
jbe@178 1048 WHERE "issue"."id" = "initiative"."issue_id"
jbe@178 1049 AND "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
jbe@178 1050 AND "initiative"."admitted";
jbe@177 1051
jbe@178 1052 UPDATE "issue" SET "status_quo_schulze_rank" = "subquery"."rank"
jbe@178 1053 FROM (
jbe@178 1054 SELECT
jbe@178 1055 "issue"."id" AS "issue_id",
jbe@178 1056 COALESCE(max("initiative"."rank") + 1) AS "rank"
jbe@178 1057 FROM "issue" JOIN "initiative"
jbe@178 1058 ON "issue"."id" = "initiative"."issue_id"
jbe@178 1059 WHERE "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
jbe@178 1060 AND "initiative"."admitted"
jbe@178 1061 GROUP BY "issue"."id"
jbe@178 1062 ) AS "subquery"
jbe@178 1063 WHERE "issue"."id" = "subquery"."issue_id";
jbe@178 1064
jbe@178 1065 CREATE FUNCTION "update__set_remaining_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@178 1066 RETURNS VOID
jbe@178 1067 LANGUAGE 'plpgsql' AS $$
jbe@178 1068 DECLARE
jbe@178 1069 "rank_v" INT4;
jbe@178 1070 "initiative_id_v" INT4;
jbe@178 1071 BEGIN
jbe@178 1072 SELECT "status_quo_schulze_rank" INTO "rank_v"
jbe@178 1073 FROM "issue" WHERE "id" = "issue_id_p";
jbe@178 1074 FOR "initiative_id_v" IN
jbe@178 1075 SELECT "id" FROM "initiative"
jbe@178 1076 WHERE "issue_id" = "issue_id_p" AND "admitted" AND "rank" ISNULL
jbe@178 1077 ORDER BY "vote_ratio"("positive_votes", "negative_votes") DESC
jbe@178 1078 LOOP
jbe@178 1079 UPDATE "initiative" SET
jbe@178 1080 "schulze_rank" = "rank_v" + 1,
jbe@178 1081 "rank" = "rank_v"
jbe@178 1082 WHERE "id" = "initiative_id_v";
jbe@178 1083 "rank_v" := "rank_v" + 1;
jbe@178 1084 END LOOP;
jbe@178 1085 RETURN;
jbe@178 1086 END;
jbe@178 1087 $$;
jbe@178 1088
jbe@178 1089 SELECT "update__set_remaining_ranks"("id") FROM "issue"
jbe@178 1090 WHERE "state" IN ('finished_without_winner', 'finished_with_winner');
jbe@178 1091
jbe@178 1092 DROP FUNCTION "update__set_remaining_ranks"("issue"."id"%TYPE);
jbe@177 1093
jbe@177 1094 UPDATE "suggestion" SET "draft_id" = "subquery"."draft_id"
jbe@177 1095 FROM (
jbe@177 1096 SELECT DISTINCT ON ("suggestion"."id")
jbe@177 1097 "suggestion"."id" AS "suggestion_id",
jbe@177 1098 "draft"."id" AS "draft_id"
jbe@177 1099 FROM "suggestion" JOIN "draft"
jbe@177 1100 ON "suggestion"."initiative_id" = "draft"."initiative_id"
jbe@177 1101 WHERE "draft"."created" <= "suggestion"."created"
jbe@177 1102 ORDER BY "suggestion"."id", "draft"."created" DESC
jbe@177 1103 ) AS "subquery"
jbe@177 1104 WHERE "suggestion"."id" = "subquery"."suggestion_id";
jbe@177 1105
jbe@178 1106 COMMIT;
jbe@178 1107
jbe@177 1108 ALTER TABLE "suggestion" ALTER COLUMN "draft_id" SET NOT NULL;

Impressum / About Us