liquid_feedback_core

annotate update/core-update.v2.0.11-v2.1.0.sql @ 288:fb66e74d94b8

Changed order of "close_voting" and "clean_issue" functions in update/core-update.v2.0.11-v2.1.0.sql
author jbe
date Sun Aug 19 21:40:57 2012 +0200 (2012-08-19)
parents 13a9f609c3de
children f2292b94fc58
rev   line source
jbe@262 1 BEGIN;
jbe@262 2
jbe@287 3
jbe@287 4 -- update version number
jbe@287 5
jbe@262 6 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
jbe@262 7 SELECT * FROM (VALUES ('2.1.0', 2, 1, 0))
jbe@262 8 AS "subquery"("string", "major", "minor", "revision");
jbe@262 9
jbe@287 10
jbe@287 11 -- old API tables are now deprecated
jbe@287 12
jbe@286 13 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
jbe@286 14 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
jbe@286 15
jbe@287 16
jbe@287 17 -- new polling mode and changed privileges
jbe@287 18
jbe@262 19 ALTER TABLE "policy" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE;
jbe@262 20 ALTER TABLE "policy" ALTER COLUMN "admission_time" DROP NOT NULL;
jbe@262 21 ALTER TABLE "policy" ALTER COLUMN "discussion_time" DROP NOT NULL;
jbe@262 22 ALTER TABLE "policy" ALTER COLUMN "verification_time" DROP NOT NULL;
jbe@262 23 ALTER TABLE "policy" ALTER COLUMN "voting_time" DROP NOT NULL;
jbe@262 24 ALTER TABLE "policy" ADD CONSTRAINT "timing" CHECK (
jbe@262 25 ( "polling" = FALSE AND
jbe@262 26 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
jbe@262 27 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
jbe@262 28 ( "polling" = TRUE AND
jbe@263 29 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
jbe@262 30 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
jbe@262 31 ( "polling" = TRUE AND
jbe@262 32 "admission_time" ISNULL AND "discussion_time" ISNULL AND
jbe@262 33 "verification_time" ISNULL AND "voting_time" ISNULL ) );
jbe@263 34 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues, i.e. polls ("admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for issues)';
jbe@262 35
jbe@262 36 ALTER TABLE "initiative" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE;
jbe@262 37 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative is an option for a poll (see "policy"."polling"), and does not need to pass the initiative quorum';
jbe@262 38
jbe@262 39 ALTER TABLE "privilege" RENAME COLUMN "voting_right_manager" TO "member_manager";
jbe@262 40 ALTER TABLE "privilege" ADD COLUMN "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE;
jbe@262 41 ALTER TABLE "privilege" ADD COLUMN "polling_right" BOOLEAN NOT NULL DEFAULT FALSE;
jbe@262 42 UPDATE "privilege" SET "initiative_right" = "voting_right";
jbe@262 43 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
jbe@262 44 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
jbe@262 45 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
jbe@262 46 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
jbe@262 47 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create polls (see "policy"."polling" and "initiative"."polling")';
jbe@262 48
jbe@262 49 CREATE OR REPLACE FUNCTION "freeze_after_snapshot"
jbe@262 50 ( "issue_id_p" "issue"."id"%TYPE )
jbe@262 51 RETURNS VOID
jbe@262 52 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@262 53 DECLARE
jbe@262 54 "issue_row" "issue"%ROWTYPE;
jbe@262 55 "policy_row" "policy"%ROWTYPE;
jbe@262 56 "initiative_row" "initiative"%ROWTYPE;
jbe@262 57 BEGIN
jbe@262 58 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@262 59 SELECT * INTO "policy_row"
jbe@262 60 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@262 61 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@262 62 FOR "initiative_row" IN
jbe@262 63 SELECT * FROM "initiative"
jbe@262 64 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@262 65 LOOP
jbe@262 66 IF
jbe@262 67 "initiative_row"."polling" OR (
jbe@262 68 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@262 69 "initiative_row"."satisfied_supporter_count" *
jbe@262 70 "policy_row"."initiative_quorum_den" >=
jbe@262 71 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@262 72 )
jbe@262 73 THEN
jbe@262 74 UPDATE "initiative" SET "admitted" = TRUE
jbe@262 75 WHERE "id" = "initiative_row"."id";
jbe@262 76 ELSE
jbe@262 77 UPDATE "initiative" SET "admitted" = FALSE
jbe@262 78 WHERE "id" = "initiative_row"."id";
jbe@262 79 END IF;
jbe@262 80 END LOOP;
jbe@262 81 IF EXISTS (
jbe@262 82 SELECT NULL FROM "initiative"
jbe@262 83 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@262 84 ) THEN
jbe@262 85 UPDATE "issue" SET
jbe@262 86 "state" = 'voting',
jbe@262 87 "accepted" = coalesce("accepted", now()),
jbe@262 88 "half_frozen" = coalesce("half_frozen", now()),
jbe@262 89 "fully_frozen" = now()
jbe@262 90 WHERE "id" = "issue_id_p";
jbe@262 91 ELSE
jbe@262 92 UPDATE "issue" SET
jbe@262 93 "state" = 'canceled_no_initiative_admitted',
jbe@262 94 "accepted" = coalesce("accepted", now()),
jbe@262 95 "half_frozen" = coalesce("half_frozen", now()),
jbe@262 96 "fully_frozen" = now(),
jbe@262 97 "closed" = now(),
jbe@262 98 "ranks_available" = TRUE
jbe@262 99 WHERE "id" = "issue_id_p";
jbe@262 100 -- NOTE: The following DELETE statements have effect only when
jbe@262 101 -- issue state has been manipulated
jbe@262 102 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@262 103 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@262 104 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@262 105 END IF;
jbe@262 106 RETURN;
jbe@262 107 END;
jbe@262 108 $$;
jbe@262 109
jbe@287 110
jbe@287 111 -- issue comments removed, voting comments integrated in "direct_voter" table
jbe@287 112
jbe@287 113 ALTER TABLE "direct_voter" ADD COLUMN "comment_changed" TIMESTAMPTZ;
jbe@287 114 ALTER TABLE "direct_voter" ADD COLUMN "formatting_engine" TEXT;
jbe@287 115 ALTER TABLE "direct_voter" ADD COLUMN "comment" TEXT;
jbe@287 116 ALTER TABLE "direct_voter" ADD COLUMN "text_search_data" TSVECTOR;
jbe@287 117 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
jbe@287 118 CREATE TRIGGER "update_text_search_data"
jbe@287 119 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@287 120 FOR EACH ROW EXECUTE PROCEDURE
jbe@287 121 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
jbe@287 122
jbe@287 123 COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL';
jbe@287 124 COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL';
jbe@287 125 COMMENT ON COLUMN "direct_voter"."comment" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
jbe@287 126
jbe@287 127 CREATE TABLE "rendered_voter_comment" (
jbe@287 128 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@287 129 FOREIGN KEY ("issue_id", "member_id")
jbe@287 130 REFERENCES "direct_voter" ("issue_id", "member_id")
jbe@287 131 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@287 132 "issue_id" INT4,
jbe@287 133 "member_id" INT4,
jbe@287 134 "format" TEXT,
jbe@287 135 "content" TEXT NOT NULL );
jbe@287 136
jbe@287 137 COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)';
jbe@287 138
jbe@287 139 DROP TABLE "rendered_issue_comment";
jbe@287 140 DROP TABLE "issue_comment";
jbe@287 141 DROP TABLE "rendered_voting_comment";
jbe@287 142 DROP TABLE "voting_comment";
jbe@287 143
jbe@287 144 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
jbe@287 145 RETURNS TRIGGER
jbe@287 146 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@287 147 BEGIN
jbe@287 148 IF NEW."comment" ISNULL THEN
jbe@287 149 NEW."comment_changed" := NULL;
jbe@287 150 NEW."formatting_engine" := NULL;
jbe@287 151 END IF;
jbe@287 152 RETURN NEW;
jbe@287 153 END;
jbe@287 154 $$;
jbe@287 155
jbe@287 156 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
jbe@287 157 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@287 158 FOR EACH ROW EXECUTE PROCEDURE
jbe@287 159 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
jbe@287 160
jbe@287 161 COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"';
jbe@287 162 COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.';
jbe@287 163
jbe@285 164 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@285 165 RETURNS VOID
jbe@285 166 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@285 167 DECLARE
jbe@285 168 "area_id_v" "area"."id"%TYPE;
jbe@285 169 "unit_id_v" "unit"."id"%TYPE;
jbe@285 170 "member_id_v" "member"."id"%TYPE;
jbe@285 171 BEGIN
jbe@285 172 PERFORM "lock_issue"("issue_id_p");
jbe@285 173 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@285 174 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@285 175 -- delete timestamp of voting comment:
jbe@285 176 UPDATE "direct_voter" SET "comment_changed" = NULL
jbe@285 177 WHERE "issue_id" = "issue_id_p";
jbe@285 178 -- delete delegating votes (in cases of manual reset of issue state):
jbe@285 179 DELETE FROM "delegating_voter"
jbe@285 180 WHERE "issue_id" = "issue_id_p";
jbe@285 181 -- delete votes from non-privileged voters:
jbe@285 182 DELETE FROM "direct_voter"
jbe@285 183 USING (
jbe@285 184 SELECT
jbe@285 185 "direct_voter"."member_id"
jbe@285 186 FROM "direct_voter"
jbe@285 187 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@285 188 LEFT JOIN "privilege"
jbe@285 189 ON "privilege"."unit_id" = "unit_id_v"
jbe@285 190 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@285 191 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@285 192 "member"."active" = FALSE OR
jbe@285 193 "privilege"."voting_right" ISNULL OR
jbe@285 194 "privilege"."voting_right" = FALSE
jbe@285 195 )
jbe@285 196 ) AS "subquery"
jbe@285 197 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@285 198 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@285 199 -- consider delegations:
jbe@285 200 UPDATE "direct_voter" SET "weight" = 1
jbe@285 201 WHERE "issue_id" = "issue_id_p";
jbe@285 202 PERFORM "add_vote_delegations"("issue_id_p");
jbe@285 203 -- set voter count and mark issue as being calculated:
jbe@285 204 UPDATE "issue" SET
jbe@285 205 "state" = 'calculation',
jbe@285 206 "closed" = now(),
jbe@285 207 "voter_count" = (
jbe@285 208 SELECT coalesce(sum("weight"), 0)
jbe@285 209 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@285 210 )
jbe@285 211 WHERE "id" = "issue_id_p";
jbe@285 212 -- materialize battle_view:
jbe@285 213 -- NOTE: "closed" column of issue must be set at this point
jbe@285 214 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@285 215 INSERT INTO "battle" (
jbe@285 216 "issue_id",
jbe@285 217 "winning_initiative_id", "losing_initiative_id",
jbe@285 218 "count"
jbe@285 219 ) SELECT
jbe@285 220 "issue_id",
jbe@285 221 "winning_initiative_id", "losing_initiative_id",
jbe@285 222 "count"
jbe@285 223 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@285 224 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@285 225 UPDATE "initiative" SET
jbe@285 226 "positive_votes" = "battle_win"."count",
jbe@285 227 "negative_votes" = "battle_lose"."count"
jbe@285 228 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@285 229 WHERE
jbe@285 230 "battle_win"."issue_id" = "issue_id_p" AND
jbe@285 231 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@285 232 "battle_win"."losing_initiative_id" ISNULL AND
jbe@285 233 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@285 234 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@285 235 "battle_lose"."winning_initiative_id" ISNULL;
jbe@285 236 END;
jbe@285 237 $$;
jbe@285 238
jbe@288 239 CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@288 240 RETURNS VOID
jbe@288 241 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@288 242 DECLARE
jbe@288 243 "issue_row" "issue"%ROWTYPE;
jbe@288 244 BEGIN
jbe@288 245 SELECT * INTO "issue_row"
jbe@288 246 FROM "issue" WHERE "id" = "issue_id_p"
jbe@288 247 FOR UPDATE;
jbe@288 248 IF "issue_row"."cleaned" ISNULL THEN
jbe@288 249 UPDATE "issue" SET
jbe@288 250 "state" = 'voting',
jbe@288 251 "closed" = NULL,
jbe@288 252 "ranks_available" = FALSE
jbe@288 253 WHERE "id" = "issue_id_p";
jbe@288 254 DELETE FROM "delegating_voter"
jbe@288 255 WHERE "issue_id" = "issue_id_p";
jbe@288 256 DELETE FROM "direct_voter"
jbe@288 257 WHERE "issue_id" = "issue_id_p";
jbe@288 258 DELETE FROM "delegating_interest_snapshot"
jbe@288 259 WHERE "issue_id" = "issue_id_p";
jbe@288 260 DELETE FROM "direct_interest_snapshot"
jbe@288 261 WHERE "issue_id" = "issue_id_p";
jbe@288 262 DELETE FROM "delegating_population_snapshot"
jbe@288 263 WHERE "issue_id" = "issue_id_p";
jbe@288 264 DELETE FROM "direct_population_snapshot"
jbe@288 265 WHERE "issue_id" = "issue_id_p";
jbe@288 266 DELETE FROM "non_voter"
jbe@288 267 WHERE "issue_id" = "issue_id_p";
jbe@288 268 DELETE FROM "delegation"
jbe@288 269 WHERE "issue_id" = "issue_id_p";
jbe@288 270 DELETE FROM "supporter"
jbe@288 271 WHERE "issue_id" = "issue_id_p";
jbe@288 272 UPDATE "issue" SET
jbe@288 273 "state" = "issue_row"."state",
jbe@288 274 "closed" = "issue_row"."closed",
jbe@288 275 "ranks_available" = "issue_row"."ranks_available",
jbe@288 276 "cleaned" = now()
jbe@288 277 WHERE "id" = "issue_id_p";
jbe@288 278 END IF;
jbe@288 279 RETURN;
jbe@288 280 END;
jbe@288 281 $$;
jbe@288 282
jbe@287 283
jbe@287 284 -- "non_voter" deletes "direct_voter" and vice versa
jbe@287 285
jbe@287 286 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
jbe@287 287 RETURNS TRIGGER
jbe@287 288 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@287 289 BEGIN
jbe@287 290 DELETE FROM "direct_voter"
jbe@287 291 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@287 292 RETURN NULL;
jbe@287 293 END;
jbe@287 294 $$;
jbe@287 295
jbe@287 296 CREATE TRIGGER "non_voter_deletes_direct_voter"
jbe@287 297 AFTER INSERT OR UPDATE ON "non_voter"
jbe@287 298 FOR EACH ROW EXECUTE PROCEDURE
jbe@287 299 "non_voter_deletes_direct_voter_trigger"();
jbe@287 300
jbe@287 301 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
jbe@287 302 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
jbe@287 303
jbe@287 304 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
jbe@287 305 RETURNS TRIGGER
jbe@287 306 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@287 307 BEGIN
jbe@287 308 DELETE FROM "non_voter"
jbe@287 309 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@287 310 RETURN NULL;
jbe@287 311 END;
jbe@287 312 $$;
jbe@287 313
jbe@287 314 CREATE TRIGGER "direct_voter_deletes_non_voter"
jbe@287 315 AFTER INSERT OR UPDATE ON "direct_voter"
jbe@287 316 FOR EACH ROW EXECUTE PROCEDURE
jbe@287 317 "direct_voter_deletes_non_voter_trigger"();
jbe@287 318
jbe@287 319 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
jbe@287 320 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
jbe@287 321
jbe@287 322
jbe@287 323 -- new comment on function "delete_private_data"()
jbe@287 324
jbe@283 325 COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
jbe@283 326
jbe@287 327
jbe@262 328 COMMIT;

Impressum / About Us