liquid_feedback_core

view update/core-update.v2.0.11-v2.1.0.sql @ 290:2301a1f2acfa

Modified function "forbid_changes_on_closed_issue_trigger" to allow voting comments to be changed after voting has finished
author jbe
date Sun Aug 19 23:37:37 2012 +0200 (2012-08-19)
parents f2292b94fc58
children 86f231bd6906
line source
1 BEGIN;
4 -- update version number
6 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
7 SELECT * FROM (VALUES ('2.1.0', 2, 1, 0))
8 AS "subquery"("string", "major", "minor", "revision");
11 -- old API tables are now deprecated
13 COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API';
14 COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API';
17 -- new polling mode and changed privileges
19 ALTER TABLE "policy" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE;
20 ALTER TABLE "policy" ALTER COLUMN "admission_time" DROP NOT NULL;
21 ALTER TABLE "policy" ALTER COLUMN "discussion_time" DROP NOT NULL;
22 ALTER TABLE "policy" ALTER COLUMN "verification_time" DROP NOT NULL;
23 ALTER TABLE "policy" ALTER COLUMN "voting_time" DROP NOT NULL;
24 ALTER TABLE "policy" ADD CONSTRAINT "timing" CHECK (
25 ( "polling" = FALSE AND
26 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
27 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
28 ( "polling" = TRUE AND
29 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
30 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
31 ( "polling" = TRUE AND
32 "admission_time" ISNULL AND "discussion_time" ISNULL AND
33 "verification_time" ISNULL AND "voting_time" ISNULL ) );
34 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
36 ALTER TABLE "initiative" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE;
37 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
39 ALTER TABLE "privilege" RENAME COLUMN "voting_right_manager" TO "member_manager";
40 ALTER TABLE "privilege" ADD COLUMN "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE;
41 ALTER TABLE "privilege" ADD COLUMN "polling_right" BOOLEAN NOT NULL DEFAULT FALSE;
42 UPDATE "privilege" SET "initiative_right" = "voting_right";
43 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
44 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
45 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
46 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
47 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues';
49 CREATE OR REPLACE FUNCTION "freeze_after_snapshot"
50 ( "issue_id_p" "issue"."id"%TYPE )
51 RETURNS VOID
52 LANGUAGE 'plpgsql' VOLATILE AS $$
53 DECLARE
54 "issue_row" "issue"%ROWTYPE;
55 "policy_row" "policy"%ROWTYPE;
56 "initiative_row" "initiative"%ROWTYPE;
57 BEGIN
58 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
59 SELECT * INTO "policy_row"
60 FROM "policy" WHERE "id" = "issue_row"."policy_id";
61 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
62 FOR "initiative_row" IN
63 SELECT * FROM "initiative"
64 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
65 LOOP
66 IF
67 "initiative_row"."polling" OR (
68 "initiative_row"."satisfied_supporter_count" > 0 AND
69 "initiative_row"."satisfied_supporter_count" *
70 "policy_row"."initiative_quorum_den" >=
71 "issue_row"."population" * "policy_row"."initiative_quorum_num"
72 )
73 THEN
74 UPDATE "initiative" SET "admitted" = TRUE
75 WHERE "id" = "initiative_row"."id";
76 ELSE
77 UPDATE "initiative" SET "admitted" = FALSE
78 WHERE "id" = "initiative_row"."id";
79 END IF;
80 END LOOP;
81 IF EXISTS (
82 SELECT NULL FROM "initiative"
83 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
84 ) THEN
85 UPDATE "issue" SET
86 "state" = 'voting',
87 "accepted" = coalesce("accepted", now()),
88 "half_frozen" = coalesce("half_frozen", now()),
89 "fully_frozen" = now()
90 WHERE "id" = "issue_id_p";
91 ELSE
92 UPDATE "issue" SET
93 "state" = 'canceled_no_initiative_admitted',
94 "accepted" = coalesce("accepted", now()),
95 "half_frozen" = coalesce("half_frozen", now()),
96 "fully_frozen" = now(),
97 "closed" = now(),
98 "ranks_available" = TRUE
99 WHERE "id" = "issue_id_p";
100 -- NOTE: The following DELETE statements have effect only when
101 -- issue state has been manipulated
102 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
103 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
104 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
105 END IF;
106 RETURN;
107 END;
108 $$;
111 -- issue comments removed, voting comments integrated in "direct_voter" table
113 ALTER TABLE "direct_voter" ADD COLUMN "comment_changed" TIMESTAMPTZ;
114 ALTER TABLE "direct_voter" ADD COLUMN "formatting_engine" TEXT;
115 ALTER TABLE "direct_voter" ADD COLUMN "comment" TEXT;
116 ALTER TABLE "direct_voter" ADD COLUMN "text_search_data" TSVECTOR;
117 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
118 CREATE TRIGGER "update_text_search_data"
119 BEFORE INSERT OR UPDATE ON "direct_voter"
120 FOR EACH ROW EXECUTE PROCEDURE
121 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
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';
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';
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.';
127 CREATE TABLE "rendered_voter_comment" (
128 PRIMARY KEY ("issue_id", "member_id", "format"),
129 FOREIGN KEY ("issue_id", "member_id")
130 REFERENCES "direct_voter" ("issue_id", "member_id")
131 ON DELETE CASCADE ON UPDATE CASCADE,
132 "issue_id" INT4,
133 "member_id" INT4,
134 "format" TEXT,
135 "content" TEXT NOT NULL );
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)';
139 DROP TABLE "rendered_issue_comment";
140 DROP TABLE "issue_comment";
141 DROP TABLE "rendered_voting_comment";
142 DROP TABLE "voting_comment";
144 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
145 RETURNS TRIGGER
146 LANGUAGE 'plpgsql' VOLATILE AS $$
147 BEGIN
148 IF NEW."comment" ISNULL THEN
149 NEW."comment_changed" := NULL;
150 NEW."formatting_engine" := NULL;
151 END IF;
152 RETURN NEW;
153 END;
154 $$;
156 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
157 BEFORE INSERT OR UPDATE ON "direct_voter"
158 FOR EACH ROW EXECUTE PROCEDURE
159 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
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"';
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.';
164 CREATE OR REPLACE FUNCTION "forbid_changes_on_closed_issue_trigger"()
165 RETURNS TRIGGER
166 LANGUAGE 'plpgsql' VOLATILE AS $$
167 DECLARE
168 "issue_id_v" "issue"."id"%TYPE;
169 "issue_row" "issue"%ROWTYPE;
170 BEGIN
171 IF TG_RELID = 'direct_voter'::regclass AND TG_OP = 'UPDATE' THEN
172 IF
173 OLD."issue_id" = NEW."issue_id" AND
174 OLD."member_id" = NEW."member_id" AND
175 OLD."weight" = NEW."weight"
176 THEN
177 RETURN NULL; -- allows changing of voter comment
178 END IF;
179 END IF;
180 IF TG_OP = 'DELETE' THEN
181 "issue_id_v" := OLD."issue_id";
182 ELSE
183 "issue_id_v" := NEW."issue_id";
184 END IF;
185 SELECT INTO "issue_row" * FROM "issue"
186 WHERE "id" = "issue_id_v" FOR SHARE;
187 IF "issue_row"."closed" NOTNULL THEN
188 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
189 END IF;
190 RETURN NULL;
191 END;
192 $$;
194 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
195 RETURNS VOID
196 LANGUAGE 'plpgsql' VOLATILE AS $$
197 DECLARE
198 "area_id_v" "area"."id"%TYPE;
199 "unit_id_v" "unit"."id"%TYPE;
200 "member_id_v" "member"."id"%TYPE;
201 BEGIN
202 PERFORM "lock_issue"("issue_id_p");
203 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
204 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
205 -- delete timestamp of voting comment:
206 UPDATE "direct_voter" SET "comment_changed" = NULL
207 WHERE "issue_id" = "issue_id_p";
208 -- delete delegating votes (in cases of manual reset of issue state):
209 DELETE FROM "delegating_voter"
210 WHERE "issue_id" = "issue_id_p";
211 -- delete votes from non-privileged voters:
212 DELETE FROM "direct_voter"
213 USING (
214 SELECT
215 "direct_voter"."member_id"
216 FROM "direct_voter"
217 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
218 LEFT JOIN "privilege"
219 ON "privilege"."unit_id" = "unit_id_v"
220 AND "privilege"."member_id" = "direct_voter"."member_id"
221 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
222 "member"."active" = FALSE OR
223 "privilege"."voting_right" ISNULL OR
224 "privilege"."voting_right" = FALSE
225 )
226 ) AS "subquery"
227 WHERE "direct_voter"."issue_id" = "issue_id_p"
228 AND "direct_voter"."member_id" = "subquery"."member_id";
229 -- consider delegations:
230 UPDATE "direct_voter" SET "weight" = 1
231 WHERE "issue_id" = "issue_id_p";
232 PERFORM "add_vote_delegations"("issue_id_p");
233 -- set voter count and mark issue as being calculated:
234 UPDATE "issue" SET
235 "state" = 'calculation',
236 "closed" = now(),
237 "voter_count" = (
238 SELECT coalesce(sum("weight"), 0)
239 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
240 )
241 WHERE "id" = "issue_id_p";
242 -- materialize battle_view:
243 -- NOTE: "closed" column of issue must be set at this point
244 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
245 INSERT INTO "battle" (
246 "issue_id",
247 "winning_initiative_id", "losing_initiative_id",
248 "count"
249 ) SELECT
250 "issue_id",
251 "winning_initiative_id", "losing_initiative_id",
252 "count"
253 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
254 -- copy "positive_votes" and "negative_votes" from "battle" table:
255 UPDATE "initiative" SET
256 "positive_votes" = "battle_win"."count",
257 "negative_votes" = "battle_lose"."count"
258 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
259 WHERE
260 "battle_win"."issue_id" = "issue_id_p" AND
261 "battle_win"."winning_initiative_id" = "initiative"."id" AND
262 "battle_win"."losing_initiative_id" ISNULL AND
263 "battle_lose"."issue_id" = "issue_id_p" AND
264 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
265 "battle_lose"."winning_initiative_id" ISNULL;
266 END;
267 $$;
269 CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
270 RETURNS VOID
271 LANGUAGE 'plpgsql' VOLATILE AS $$
272 DECLARE
273 "issue_row" "issue"%ROWTYPE;
274 BEGIN
275 SELECT * INTO "issue_row"
276 FROM "issue" WHERE "id" = "issue_id_p"
277 FOR UPDATE;
278 IF "issue_row"."cleaned" ISNULL THEN
279 UPDATE "issue" SET
280 "state" = 'voting',
281 "closed" = NULL,
282 "ranks_available" = FALSE
283 WHERE "id" = "issue_id_p";
284 DELETE FROM "delegating_voter"
285 WHERE "issue_id" = "issue_id_p";
286 DELETE FROM "direct_voter"
287 WHERE "issue_id" = "issue_id_p";
288 DELETE FROM "delegating_interest_snapshot"
289 WHERE "issue_id" = "issue_id_p";
290 DELETE FROM "direct_interest_snapshot"
291 WHERE "issue_id" = "issue_id_p";
292 DELETE FROM "delegating_population_snapshot"
293 WHERE "issue_id" = "issue_id_p";
294 DELETE FROM "direct_population_snapshot"
295 WHERE "issue_id" = "issue_id_p";
296 DELETE FROM "non_voter"
297 WHERE "issue_id" = "issue_id_p";
298 DELETE FROM "delegation"
299 WHERE "issue_id" = "issue_id_p";
300 DELETE FROM "supporter"
301 WHERE "issue_id" = "issue_id_p";
302 UPDATE "issue" SET
303 "state" = "issue_row"."state",
304 "closed" = "issue_row"."closed",
305 "ranks_available" = "issue_row"."ranks_available",
306 "cleaned" = now()
307 WHERE "id" = "issue_id_p";
308 END IF;
309 RETURN;
310 END;
311 $$;
314 -- "non_voter" deletes "direct_voter" and vice versa
316 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
317 RETURNS TRIGGER
318 LANGUAGE 'plpgsql' VOLATILE AS $$
319 BEGIN
320 DELETE FROM "direct_voter"
321 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
322 RETURN NULL;
323 END;
324 $$;
326 CREATE TRIGGER "non_voter_deletes_direct_voter"
327 AFTER INSERT OR UPDATE ON "non_voter"
328 FOR EACH ROW EXECUTE PROCEDURE
329 "non_voter_deletes_direct_voter_trigger"();
331 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
332 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")';
334 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
335 RETURNS TRIGGER
336 LANGUAGE 'plpgsql' VOLATILE AS $$
337 BEGIN
338 DELETE FROM "non_voter"
339 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
340 RETURN NULL;
341 END;
342 $$;
344 CREATE TRIGGER "direct_voter_deletes_non_voter"
345 AFTER INSERT OR UPDATE ON "direct_voter"
346 FOR EACH ROW EXECUTE PROCEDURE
347 "direct_voter_deletes_non_voter_trigger"();
349 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
350 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")';
353 -- new comment on function "delete_private_data"()
355 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.';
358 COMMIT;

Impressum / About Us