liquid_feedback_core

view update/core-update.v2.0.11-v2.1.0.sql @ 285:4868a7d591de

Moved voting comment to table "direct_voter"
author jbe
date Sun Aug 19 20:29:44 2012 +0200 (2012-08-19)
parents 4f935e989ff6
children 3ac6d4259387
line source
1 BEGIN;
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
4 SELECT * FROM (VALUES ('2.1.0', 2, 1, 0))
5 AS "subquery"("string", "major", "minor", "revision");
7 ALTER TABLE "policy" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE;
8 ALTER TABLE "policy" ALTER COLUMN "admission_time" DROP NOT NULL;
9 ALTER TABLE "policy" ALTER COLUMN "discussion_time" DROP NOT NULL;
10 ALTER TABLE "policy" ALTER COLUMN "verification_time" DROP NOT NULL;
11 ALTER TABLE "policy" ALTER COLUMN "voting_time" DROP NOT NULL;
12 ALTER TABLE "policy" ADD CONSTRAINT "timing" CHECK (
13 ( "polling" = FALSE AND
14 "admission_time" NOTNULL AND "discussion_time" NOTNULL AND
15 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
16 ( "polling" = TRUE AND
17 "admission_time" ISNULL AND "discussion_time" NOTNULL AND
18 "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR
19 ( "polling" = TRUE AND
20 "admission_time" ISNULL AND "discussion_time" ISNULL AND
21 "verification_time" ISNULL AND "voting_time" ISNULL ) );
22 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)';
24 ALTER TABLE "initiative" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE;
25 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';
27 ALTER TABLE "privilege" RENAME COLUMN "voting_right_manager" TO "member_manager";
28 ALTER TABLE "privilege" ADD COLUMN "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE;
29 ALTER TABLE "privilege" ADD COLUMN "polling_right" BOOLEAN NOT NULL DEFAULT FALSE;
30 UPDATE "privilege" SET "initiative_right" = "voting_right";
31 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
32 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
33 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
34 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
35 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create polls (see "policy"."polling" and "initiative"."polling")';
37 ALTER TABLE "direct_voter" ADD COLUMN "comment_changed" TIMESTAMPTZ;
38 ALTER TABLE "direct_voter" ADD COLUMN "formatting_engine" TEXT;
39 ALTER TABLE "direct_voter" ADD COLUMN "comment" TEXT;
40 ALTER TABLE "direct_voter" ADD COLUMN "text_search_data" TSVECTOR;
41 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
42 CREATE TRIGGER "update_text_search_data"
43 BEFORE INSERT OR UPDATE ON "direct_voter"
44 FOR EACH ROW EXECUTE PROCEDURE
45 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
47 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';
48 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';
49 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.';
51 CREATE TABLE "rendered_voter_comment" (
52 PRIMARY KEY ("issue_id", "member_id", "format"),
53 FOREIGN KEY ("issue_id", "member_id")
54 REFERENCES "direct_voter" ("issue_id", "member_id")
55 ON DELETE CASCADE ON UPDATE CASCADE,
56 "issue_id" INT4,
57 "member_id" INT4,
58 "format" TEXT,
59 "content" TEXT NOT NULL );
61 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)';
64 DROP TABLE "rendered_issue_comment";
65 DROP TABLE "issue_comment";
66 DROP TABLE "rendered_voting_comment";
67 DROP TABLE "voting_comment";
69 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
70 RETURNS TRIGGER
71 LANGUAGE 'plpgsql' VOLATILE AS $$
72 BEGIN
73 DELETE FROM "direct_voter"
74 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
75 RETURN NULL;
76 END;
77 $$;
79 CREATE TRIGGER "non_voter_deletes_direct_voter"
80 AFTER INSERT OR UPDATE ON "non_voter"
81 FOR EACH ROW EXECUTE PROCEDURE
82 "non_voter_deletes_direct_voter_trigger"();
84 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
85 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")';
87 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
88 RETURNS TRIGGER
89 LANGUAGE 'plpgsql' VOLATILE AS $$
90 BEGIN
91 DELETE FROM "non_voter"
92 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
93 RETURN NULL;
94 END;
95 $$;
97 CREATE TRIGGER "direct_voter_deletes_non_voter"
98 AFTER INSERT OR UPDATE ON "direct_voter"
99 FOR EACH ROW EXECUTE PROCEDURE
100 "direct_voter_deletes_non_voter_trigger"();
102 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
103 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")';
105 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
106 RETURNS TRIGGER
107 LANGUAGE 'plpgsql' VOLATILE AS $$
108 BEGIN
109 IF NEW."comment" ISNULL THEN
110 NEW."comment_changed" := NULL;
111 NEW."formatting_engine" := NULL;
112 END IF;
113 RETURN NEW;
114 END;
115 $$;
117 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
118 BEFORE INSERT OR UPDATE ON "direct_voter"
119 FOR EACH ROW EXECUTE PROCEDURE
120 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
122 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"';
123 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.';
125 CREATE OR REPLACE FUNCTION "freeze_after_snapshot"
126 ( "issue_id_p" "issue"."id"%TYPE )
127 RETURNS VOID
128 LANGUAGE 'plpgsql' VOLATILE AS $$
129 DECLARE
130 "issue_row" "issue"%ROWTYPE;
131 "policy_row" "policy"%ROWTYPE;
132 "initiative_row" "initiative"%ROWTYPE;
133 BEGIN
134 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
135 SELECT * INTO "policy_row"
136 FROM "policy" WHERE "id" = "issue_row"."policy_id";
137 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
138 FOR "initiative_row" IN
139 SELECT * FROM "initiative"
140 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
141 LOOP
142 IF
143 "initiative_row"."polling" OR (
144 "initiative_row"."satisfied_supporter_count" > 0 AND
145 "initiative_row"."satisfied_supporter_count" *
146 "policy_row"."initiative_quorum_den" >=
147 "issue_row"."population" * "policy_row"."initiative_quorum_num"
148 )
149 THEN
150 UPDATE "initiative" SET "admitted" = TRUE
151 WHERE "id" = "initiative_row"."id";
152 ELSE
153 UPDATE "initiative" SET "admitted" = FALSE
154 WHERE "id" = "initiative_row"."id";
155 END IF;
156 END LOOP;
157 IF EXISTS (
158 SELECT NULL FROM "initiative"
159 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
160 ) THEN
161 UPDATE "issue" SET
162 "state" = 'voting',
163 "accepted" = coalesce("accepted", now()),
164 "half_frozen" = coalesce("half_frozen", now()),
165 "fully_frozen" = now()
166 WHERE "id" = "issue_id_p";
167 ELSE
168 UPDATE "issue" SET
169 "state" = 'canceled_no_initiative_admitted',
170 "accepted" = coalesce("accepted", now()),
171 "half_frozen" = coalesce("half_frozen", now()),
172 "fully_frozen" = now(),
173 "closed" = now(),
174 "ranks_available" = TRUE
175 WHERE "id" = "issue_id_p";
176 -- NOTE: The following DELETE statements have effect only when
177 -- issue state has been manipulated
178 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
179 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
180 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
181 END IF;
182 RETURN;
183 END;
184 $$;
186 CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
187 RETURNS VOID
188 LANGUAGE 'plpgsql' VOLATILE AS $$
189 DECLARE
190 "issue_row" "issue"%ROWTYPE;
191 BEGIN
192 SELECT * INTO "issue_row"
193 FROM "issue" WHERE "id" = "issue_id_p"
194 FOR UPDATE;
195 IF "issue_row"."cleaned" ISNULL THEN
196 UPDATE "issue" SET
197 "state" = 'voting',
198 "closed" = NULL,
199 "ranks_available" = FALSE
200 WHERE "id" = "issue_id_p";
201 DELETE FROM "delegating_voter"
202 WHERE "issue_id" = "issue_id_p";
203 DELETE FROM "direct_voter"
204 WHERE "issue_id" = "issue_id_p";
205 DELETE FROM "delegating_interest_snapshot"
206 WHERE "issue_id" = "issue_id_p";
207 DELETE FROM "direct_interest_snapshot"
208 WHERE "issue_id" = "issue_id_p";
209 DELETE FROM "delegating_population_snapshot"
210 WHERE "issue_id" = "issue_id_p";
211 DELETE FROM "direct_population_snapshot"
212 WHERE "issue_id" = "issue_id_p";
213 DELETE FROM "non_voter"
214 WHERE "issue_id" = "issue_id_p";
215 DELETE FROM "delegation"
216 WHERE "issue_id" = "issue_id_p";
217 DELETE FROM "supporter"
218 WHERE "issue_id" = "issue_id_p";
219 UPDATE "issue" SET
220 "state" = "issue_row"."state",
221 "closed" = "issue_row"."closed",
222 "ranks_available" = "issue_row"."ranks_available",
223 "cleaned" = now()
224 WHERE "id" = "issue_id_p";
225 END IF;
226 RETURN;
227 END;
228 $$;
230 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
231 RETURNS VOID
232 LANGUAGE 'plpgsql' VOLATILE AS $$
233 DECLARE
234 "area_id_v" "area"."id"%TYPE;
235 "unit_id_v" "unit"."id"%TYPE;
236 "member_id_v" "member"."id"%TYPE;
237 BEGIN
238 PERFORM "lock_issue"("issue_id_p");
239 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
240 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
241 -- delete timestamp of voting comment:
242 UPDATE "direct_voter" SET "comment_changed" = NULL
243 WHERE "issue_id" = "issue_id_p";
244 -- delete delegating votes (in cases of manual reset of issue state):
245 DELETE FROM "delegating_voter"
246 WHERE "issue_id" = "issue_id_p";
247 -- delete votes from non-privileged voters:
248 DELETE FROM "direct_voter"
249 USING (
250 SELECT
251 "direct_voter"."member_id"
252 FROM "direct_voter"
253 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
254 LEFT JOIN "privilege"
255 ON "privilege"."unit_id" = "unit_id_v"
256 AND "privilege"."member_id" = "direct_voter"."member_id"
257 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
258 "member"."active" = FALSE OR
259 "privilege"."voting_right" ISNULL OR
260 "privilege"."voting_right" = FALSE
261 )
262 ) AS "subquery"
263 WHERE "direct_voter"."issue_id" = "issue_id_p"
264 AND "direct_voter"."member_id" = "subquery"."member_id";
265 -- consider delegations:
266 UPDATE "direct_voter" SET "weight" = 1
267 WHERE "issue_id" = "issue_id_p";
268 PERFORM "add_vote_delegations"("issue_id_p");
269 -- set voter count and mark issue as being calculated:
270 UPDATE "issue" SET
271 "state" = 'calculation',
272 "closed" = now(),
273 "voter_count" = (
274 SELECT coalesce(sum("weight"), 0)
275 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
276 )
277 WHERE "id" = "issue_id_p";
278 -- materialize battle_view:
279 -- NOTE: "closed" column of issue must be set at this point
280 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
281 INSERT INTO "battle" (
282 "issue_id",
283 "winning_initiative_id", "losing_initiative_id",
284 "count"
285 ) SELECT
286 "issue_id",
287 "winning_initiative_id", "losing_initiative_id",
288 "count"
289 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
290 -- copy "positive_votes" and "negative_votes" from "battle" table:
291 UPDATE "initiative" SET
292 "positive_votes" = "battle_win"."count",
293 "negative_votes" = "battle_lose"."count"
294 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
295 WHERE
296 "battle_win"."issue_id" = "issue_id_p" AND
297 "battle_win"."winning_initiative_id" = "initiative"."id" AND
298 "battle_win"."losing_initiative_id" ISNULL AND
299 "battle_lose"."issue_id" = "issue_id_p" AND
300 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
301 "battle_lose"."winning_initiative_id" ISNULL;
302 END;
303 $$;
305 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.';
307 COMMIT;

Impressum / About Us