liquid_feedback_core

view update/core-update.v4.1.0-v4.2.0.sql @ 602:9570aeabf4fc

Added update script to version 4.2.0
author jbe
date Fri Feb 07 10:52:37 2020 +0100 (2020-02-07)
parents
children 617ac1725557
line source
1 BEGIN;
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
4 SELECT * FROM (VALUES ('4.2.0-incomplete-update', 4, 2, -1))
5 AS "subquery"("string", "major", "minor", "revision");
7 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'posting_created';
9 COMMIT;
11 BEGIN;
13 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
14 SELECT * FROM (VALUES ('4.2.0', 4, 2, 0))
15 AS "subquery"("string", "major", "minor", "revision");
17 DROP VIEW "newsletter_to_send";
18 DROP VIEW "scheduled_notification_to_send";
19 DROP VIEW "member_contingent_left";
20 DROP VIEW "member_contingent";
21 DROP VIEW "expired_snapshot";
22 DROP VIEW "current_draft";
23 DROP VIEW "opening_draft";
24 DROP VIEW "area_with_unaccepted_issues";
25 DROP VIEW "member_to_notify";
26 DROP VIEW "member_eligible_to_be_notified";
28 CREATE EXTENSION IF NOT EXISTS btree_gist;
29 CREATE EXTENSION IF NOT EXISTS conflux;
31 DROP FUNCTION "text_search_query" (TEXT);
33 ALTER TABLE "system_setting" DROP COLUMN "snapshot_retention";
35 CREATE TABLE "file" (
36 "id" SERIAL8 PRIMARY KEY,
37 UNIQUE ("content_type", "hash"),
38 "content_type" TEXT NOT NULL,
39 "hash" TEXT NOT NULL,
40 "data" BYTEA NOT NULL,
41 "preview_content_type" TEXT,
42 "preview_data" BYTEA );
44 COMMENT ON TABLE "file" IS 'Table holding file contents for draft attachments';
46 COMMENT ON COLUMN "file"."content_type" IS 'Content type of "data"';
47 COMMENT ON COLUMN "file"."hash" IS 'Hash of "data" to avoid storing duplicates where content-type and data is identical';
48 COMMENT ON COLUMN "file"."data" IS 'Binary content';
49 COMMENT ON COLUMN "file"."preview_content_type" IS 'Content type of "preview_data"';
50 COMMENT ON COLUMN "file"."preview_data" IS 'Preview (e.g. preview image)';
52 ALTER TABLE "member" DROP COLUMN "text_search_data";
53 DROP TRIGGER "update_text_search_data" ON "member";
55 CREATE INDEX "member_useterms_member_id_contract_identifier" ON "member_useterms" ("member_id", "contract_identifier");
57 ALTER TABLE "member_profile" DROP COLUMN "text_search_data";
58 DROP TRIGGER "update_text_search_data" ON "member_profile";
60 ALTER TABLE "contact" ADD COLUMN "following" BOOLEAN NOT NULL DEFAULT TRUE;
62 COMMENT ON COLUMN "contact"."following" IS 'TRUE = actions of contact are shown in personal timeline';
64 ALTER TABLE "unit" DROP COLUMN "text_search_data";
65 DROP TRIGGER "update_text_search_data" ON "unit";
67 ALTER TABLE "area" DROP COLUMN "text_search_data";
68 DROP TRIGGER "update_text_search_data" ON "area";
70 DROP INDEX "issue_accepted_idx";
71 DROP INDEX "issue_half_frozen_idx";
72 DROP INDEX "issue_fully_frozen_idx";
73 ALTER INDEX "issue_created_idx_open" RENAME TO "issue_open_created_idx";
74 DROP INDEX "issue_closed_idx_canceled";
75 ALTER INDEX "issue_latest_snapshot_id" RENAME TO "issue_latest_snapshot_id_idx";
76 ALTER INDEX "issue_admission_snapshot_id" RENAME TO "issue_admission_snapshot_id_idx";
77 ALTER INDEX "issue_half_freeze_snapshot_id" RENAME TO "issue_half_freeze_snapshot_id_idx";
78 ALTER INDEX "issue_full_freeze_snapshot_id" RENAME TO "issue_full_freeze_snapshot_id_idx";
80 ALTER TABLE "initiative" ADD COLUMN "content" TEXT;
81 ALTER TABLE "initiative" DROP COLUMN "text_search_data";
82 ALTER TABLE "initiative" DROP COLUMN "draft_text_search_data";
83 DROP INDEX "initiative_revoked_idx";
84 DROP TRIGGER "update_text_search_data" ON "initiative";
86 COMMENT ON COLUMN "initiative"."content" IS 'Initiative text (automatically copied from most recent draft)';
88 ALTER TABLE "battle" DROP CONSTRAINT "initiative_ids_not_equal";
89 ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK (
90 "winning_initiative_id" != "losing_initiative_id" AND
91 ("winning_initiative_id" NOTNULL OR "losing_initiative_id" NOTNULL) );
93 ALTER TABLE "draft" DROP COLUMN "text_search_data";
94 DROP TRIGGER "update_text_search_data" ON "draft";
96 CREATE TABLE "draft_attachment" (
97 "id" SERIAL8 PRIMARY KEY,
98 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
99 "file_id" INT8 REFERENCES "file" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
100 "content_type" TEXT,
101 "title" TEXT,
102 "description" TEXT );
104 COMMENT ON TABLE "draft_attachment" IS 'Binary attachments for a draft (images, PDF file, etc.); Implicitly ordered through ''id'' column';
106 ALTER TABLE "suggestion" DROP COLUMN "text_search_data";
107 DROP TRIGGER "update_text_search_data" ON "suggestion";
109 ALTER TABLE "direct_voter" DROP COLUMN "text_search_data";
110 DROP TRIGGER "update_text_search_data" ON "direct_voter";
112 CREATE TABLE "posting" (
113 UNIQUE ("author_id", "id"), -- index needed for foreign-key on table "posting_lexeme"
114 "id" SERIAL8 PRIMARY KEY,
115 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
116 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
117 "message" TEXT NOT NULL,
118 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
119 "area_id" INT4,
120 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
121 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
122 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
123 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
124 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
125 "initiative_id" INT4,
126 "suggestion_id" INT8,
127 -- NOTE: no referential integrity for suggestions because those are
128 -- actually deleted
129 -- FOREIGN KEY ("initiative_id", "suggestion_id")
130 -- REFERENCES "suggestion" ("initiative_id", "id")
131 -- ON DELETE CASCADE ON UPDATE CASCADE,
132 CONSTRAINT "area_requires_unit" CHECK (
133 "area_id" ISNULL OR "unit_id" NOTNULL ),
134 CONSTRAINT "policy_set_when_issue_set" CHECK (
135 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
136 CONSTRAINT "issue_requires_area" CHECK (
137 "issue_id" ISNULL OR "area_id" NOTNULL ),
138 CONSTRAINT "initiative_requires_issue" CHECK (
139 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
140 CONSTRAINT "suggestion_requires_initiative" CHECK (
141 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
142 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
143 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
144 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
145 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
146 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
147 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
148 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
149 COMMENT ON TABLE "posting" IS 'Text postings of members; a text posting may optionally be associated to a unit, area, policy, issue, initiative, or suggestion';
151 CREATE TABLE "posting_lexeme" (
152 PRIMARY KEY ("posting_id", "lexeme"),
153 FOREIGN KEY ("posting_id", "author_id") REFERENCES "posting" ("id", "author_id") ON DELETE CASCADE ON UPDATE CASCADE,
154 "posting_id" INT8,
155 "lexeme" TEXT,
156 "author_id" INT4 );
157 CREATE INDEX "posting_lexeme_idx" ON "posting_lexeme" USING gist ("lexeme", (pstamp("author_id", "posting_id")));
159 COMMENT ON TABLE "posting_lexeme" IS 'Helper table to allow searches for hashtags.';
161 ALTER TABLE "event" ADD COLUMN "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
162 ALTER TABLE "event" DROP CONSTRAINT "constr_for_issue_state_changed";
163 ALTER TABLE "event" DROP CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft";
164 ALTER TABLE "event" DROP CONSTRAINT "constr_for_suggestion_creation";
165 ALTER TABLE "event" DROP CONSTRAINT "constr_for_suggestion_removal";
166 ALTER TABLE "event" DROP CONSTRAINT "constr_for_value_less_member_event";
167 ALTER TABLE "event" DROP CONSTRAINT "constr_for_member_active";
168 ALTER TABLE "event" DROP CONSTRAINT "constr_for_member_name_updated";
169 ALTER TABLE "event" DROP CONSTRAINT "constr_for_interest";
170 ALTER TABLE "event" DROP CONSTRAINT "constr_for_initiator";
171 ALTER TABLE "event" DROP CONSTRAINT "constr_for_support";
172 ALTER TABLE "event" DROP CONSTRAINT "constr_for_support_updated";
173 ALTER TABLE "event" DROP CONSTRAINT "constr_for_suggestion_rated";
174 ALTER TABLE "event" DROP CONSTRAINT "constr_for_delegation";
175 ALTER TABLE "event" DROP CONSTRAINT "constr_for_contact";
176 ALTER TABLE "event" ADD
177 CONSTRAINT "constr_for_issue_state_changed" CHECK (
178 "event" != 'issue_state_changed' OR (
179 "posting_id" ISNULL AND
180 "member_id" ISNULL AND
181 "other_member_id" ISNULL AND
182 "scope" ISNULL AND
183 "unit_id" NOTNULL AND
184 "area_id" NOTNULL AND
185 "policy_id" NOTNULL AND
186 "issue_id" NOTNULL AND
187 "state" NOTNULL AND
188 "initiative_id" ISNULL AND
189 "draft_id" ISNULL AND
190 "suggestion_id" ISNULL AND
191 "boolean_value" ISNULL AND
192 "numeric_value" ISNULL AND
193 "text_value" ISNULL AND
194 "old_text_value" ISNULL ));
195 ALTER TABLE "event" ADD
196 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
197 "event" NOT IN (
198 'initiative_created_in_new_issue',
199 'initiative_created_in_existing_issue',
200 'initiative_revoked',
201 'new_draft_created'
202 ) OR (
203 "posting_id" ISNULL AND
204 "member_id" NOTNULL AND
205 "other_member_id" ISNULL AND
206 "scope" ISNULL AND
207 "unit_id" NOTNULL AND
208 "area_id" NOTNULL AND
209 "policy_id" NOTNULL AND
210 "issue_id" NOTNULL AND
211 "state" NOTNULL AND
212 "initiative_id" NOTNULL AND
213 "draft_id" NOTNULL AND
214 "suggestion_id" ISNULL AND
215 "boolean_value" ISNULL AND
216 "numeric_value" ISNULL AND
217 "text_value" ISNULL AND
218 "old_text_value" ISNULL ));
219 ALTER TABLE "event" ADD
220 CONSTRAINT "constr_for_suggestion_creation" CHECK (
221 "event" != 'suggestion_created' OR (
222 "posting_id" ISNULL AND
223 "member_id" NOTNULL AND
224 "other_member_id" ISNULL AND
225 "scope" ISNULL AND
226 "unit_id" NOTNULL AND
227 "area_id" NOTNULL AND
228 "policy_id" NOTNULL AND
229 "issue_id" NOTNULL AND
230 "state" NOTNULL AND
231 "initiative_id" NOTNULL AND
232 "draft_id" ISNULL AND
233 "suggestion_id" NOTNULL AND
234 "boolean_value" ISNULL AND
235 "numeric_value" ISNULL AND
236 "text_value" ISNULL AND
237 "old_text_value" ISNULL ));
238 ALTER TABLE "event" ADD
239 CONSTRAINT "constr_for_suggestion_removal" CHECK (
240 "event" != 'suggestion_deleted' OR (
241 "posting_id" ISNULL AND
242 "member_id" ISNULL AND
243 "other_member_id" ISNULL AND
244 "scope" ISNULL AND
245 "unit_id" NOTNULL AND
246 "area_id" NOTNULL AND
247 "policy_id" NOTNULL AND
248 "issue_id" NOTNULL AND
249 "state" NOTNULL AND
250 "initiative_id" NOTNULL AND
251 "draft_id" ISNULL AND
252 "suggestion_id" NOTNULL AND
253 "boolean_value" ISNULL AND
254 "numeric_value" ISNULL AND
255 "text_value" ISNULL AND
256 "old_text_value" ISNULL ));
257 ALTER TABLE "event" ADD
258 CONSTRAINT "constr_for_value_less_member_event" CHECK (
259 "event" NOT IN (
260 'member_activated',
261 'member_deleted',
262 'member_profile_updated',
263 'member_image_updated'
264 ) OR (
265 "posting_id" ISNULL AND
266 "member_id" NOTNULL AND
267 "other_member_id" ISNULL AND
268 "scope" ISNULL AND
269 "unit_id" ISNULL AND
270 "area_id" ISNULL AND
271 "policy_id" ISNULL AND
272 "issue_id" ISNULL AND
273 "state" ISNULL AND
274 "initiative_id" ISNULL AND
275 "draft_id" ISNULL AND
276 "suggestion_id" ISNULL AND
277 "boolean_value" ISNULL AND
278 "numeric_value" ISNULL AND
279 "text_value" ISNULL AND
280 "old_text_value" ISNULL ));
281 ALTER TABLE "event" ADD
282 CONSTRAINT "constr_for_member_active" CHECK (
283 "event" != 'member_active' OR (
284 "posting_id" ISNULL AND
285 "member_id" NOTNULL AND
286 "other_member_id" ISNULL AND
287 "scope" ISNULL AND
288 "unit_id" ISNULL AND
289 "area_id" ISNULL AND
290 "policy_id" ISNULL AND
291 "issue_id" ISNULL AND
292 "state" ISNULL AND
293 "initiative_id" ISNULL AND
294 "draft_id" ISNULL AND
295 "suggestion_id" ISNULL AND
296 "boolean_value" NOTNULL AND
297 "numeric_value" ISNULL AND
298 "text_value" ISNULL AND
299 "old_text_value" ISNULL ));
300 ALTER TABLE "event" ADD
301 CONSTRAINT "constr_for_member_name_updated" CHECK (
302 "event" != 'member_name_updated' OR (
303 "posting_id" ISNULL AND
304 "member_id" NOTNULL AND
305 "other_member_id" ISNULL AND
306 "scope" ISNULL AND
307 "unit_id" ISNULL AND
308 "area_id" ISNULL AND
309 "policy_id" ISNULL AND
310 "issue_id" ISNULL AND
311 "state" ISNULL AND
312 "initiative_id" ISNULL AND
313 "draft_id" ISNULL AND
314 "suggestion_id" ISNULL AND
315 "boolean_value" ISNULL AND
316 "numeric_value" ISNULL AND
317 "text_value" NOTNULL AND
318 "old_text_value" NOTNULL ));
319 ALTER TABLE "event" ADD
320 CONSTRAINT "constr_for_interest" CHECK (
321 "event" != 'interest' OR (
322 "posting_id" ISNULL AND
323 "member_id" NOTNULL AND
324 "other_member_id" ISNULL AND
325 "scope" ISNULL AND
326 "unit_id" NOTNULL AND
327 "area_id" NOTNULL AND
328 "policy_id" NOTNULL AND
329 "issue_id" NOTNULL AND
330 "state" NOTNULL AND
331 "initiative_id" ISNULL AND
332 "draft_id" ISNULL AND
333 "suggestion_id" ISNULL AND
334 "boolean_value" NOTNULL AND
335 "numeric_value" ISNULL AND
336 "text_value" ISNULL AND
337 "old_text_value" ISNULL ));
338 ALTER TABLE "event" ADD
339 CONSTRAINT "constr_for_initiator" CHECK (
340 "event" != 'initiator' OR (
341 "posting_id" ISNULL AND
342 "member_id" NOTNULL AND
343 "other_member_id" ISNULL AND
344 "scope" ISNULL AND
345 "unit_id" NOTNULL AND
346 "area_id" NOTNULL AND
347 "policy_id" NOTNULL AND
348 "issue_id" NOTNULL AND
349 "state" NOTNULL AND
350 "initiative_id" NOTNULL AND
351 "draft_id" ISNULL AND
352 "suggestion_id" ISNULL AND
353 "boolean_value" NOTNULL AND
354 "numeric_value" ISNULL AND
355 "text_value" ISNULL AND
356 "old_text_value" ISNULL ));
357 ALTER TABLE "event" ADD
358 CONSTRAINT "constr_for_support" CHECK (
359 "event" != 'support' OR (
360 "posting_id" ISNULL AND
361 "member_id" NOTNULL AND
362 "other_member_id" ISNULL AND
363 "scope" ISNULL AND
364 "unit_id" NOTNULL AND
365 "area_id" NOTNULL AND
366 "policy_id" NOTNULL AND
367 "issue_id" NOTNULL AND
368 "state" NOTNULL AND
369 "initiative_id" NOTNULL AND
370 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
371 "suggestion_id" ISNULL AND
372 "boolean_value" NOTNULL AND
373 "numeric_value" ISNULL AND
374 "text_value" ISNULL AND
375 "old_text_value" ISNULL ));
376 ALTER TABLE "event" ADD
377 CONSTRAINT "constr_for_support_updated" CHECK (
378 "event" != 'support_updated' OR (
379 "posting_id" ISNULL AND
380 "member_id" NOTNULL AND
381 "other_member_id" ISNULL AND
382 "scope" ISNULL AND
383 "unit_id" NOTNULL AND
384 "area_id" NOTNULL AND
385 "policy_id" NOTNULL AND
386 "issue_id" NOTNULL AND
387 "state" NOTNULL AND
388 "initiative_id" NOTNULL AND
389 "draft_id" NOTNULL AND
390 "suggestion_id" ISNULL AND
391 "boolean_value" ISNULL AND
392 "numeric_value" ISNULL AND
393 "text_value" ISNULL AND
394 "old_text_value" ISNULL ));
395 ALTER TABLE "event" ADD
396 CONSTRAINT "constr_for_suggestion_rated" CHECK (
397 "event" != 'suggestion_rated' OR (
398 "posting_id" ISNULL AND
399 "member_id" NOTNULL AND
400 "other_member_id" ISNULL AND
401 "scope" ISNULL AND
402 "unit_id" NOTNULL AND
403 "area_id" NOTNULL AND
404 "policy_id" NOTNULL AND
405 "issue_id" NOTNULL AND
406 "state" NOTNULL AND
407 "initiative_id" NOTNULL AND
408 "draft_id" ISNULL AND
409 "suggestion_id" NOTNULL AND
410 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
411 "numeric_value" NOTNULL AND
412 "numeric_value" IN (-2, -1, 0, 1, 2) AND
413 "text_value" ISNULL AND
414 "old_text_value" ISNULL ));
415 ALTER TABLE "event" ADD
416 CONSTRAINT "constr_for_delegation" CHECK (
417 "event" != 'delegation' OR (
418 "posting_id" ISNULL AND
419 "member_id" NOTNULL AND
420 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
421 "scope" NOTNULL AND
422 "unit_id" NOTNULL AND
423 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
424 "policy_id" ISNULL AND
425 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
426 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
427 "initiative_id" ISNULL AND
428 "draft_id" ISNULL AND
429 "suggestion_id" ISNULL AND
430 "boolean_value" NOTNULL AND
431 "numeric_value" ISNULL AND
432 "text_value" ISNULL AND
433 "old_text_value" ISNULL ));
434 ALTER TABLE "event" ADD
435 CONSTRAINT "constr_for_contact" CHECK (
436 "event" != 'contact' OR (
437 "posting_id" ISNULL AND
438 "member_id" NOTNULL AND
439 "other_member_id" NOTNULL AND
440 "scope" ISNULL AND
441 "unit_id" ISNULL AND
442 "area_id" ISNULL AND
443 "policy_id" ISNULL AND
444 "issue_id" ISNULL AND
445 "state" ISNULL AND
446 "initiative_id" ISNULL AND
447 "draft_id" ISNULL AND
448 "suggestion_id" ISNULL AND
449 "boolean_value" NOTNULL AND
450 "numeric_value" ISNULL AND
451 "text_value" ISNULL AND
452 "old_text_value" ISNULL ));
453 ALTER TABLE "event" ADD
454 CONSTRAINT "constr_for_posting_created" CHECK (
455 "event" != 'posting_created' OR (
456 "posting_id" NOTNULL AND
457 "member_id" NOTNULL AND
458 "other_member_id" ISNULL AND
459 "scope" ISNULL AND
460 "state" ISNULL AND
461 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
462 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
463 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
464 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
465 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
466 "draft_id" ISNULL AND
467 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
468 "boolean_value" ISNULL AND
469 "numeric_value" ISNULL AND
470 "text_value" ISNULL AND
471 "old_text_value" ISNULL ));
473 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
474 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
475 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
476 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
477 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
478 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
479 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
481 CREATE OR REPLACE FUNCTION "highlight"
482 ( "body_p" TEXT,
483 "query_text_p" TEXT )
484 RETURNS TEXT
485 LANGUAGE 'plpgsql' IMMUTABLE AS $$
486 BEGIN
487 RETURN ts_headline(
488 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
489 "plainto_tsquery"("query_text_p"),
490 'StartSel=* StopSel=* HighlightAll=TRUE' );
491 END;
492 $$;
494 CREATE FUNCTION "to_tsvector"("member") RETURNS TSVECTOR
495 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
496 $1."name",
497 $1."identification"
498 )) $$;
499 CREATE INDEX "member_to_tsvector_idx" ON "member" USING gin
500 (("to_tsvector"("member".*)));
502 CREATE FUNCTION "to_tsvector"("member_profile") RETURNS TSVECTOR
503 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
504 $1."statement",
505 $1."profile_text_data"
506 )) $$;
507 CREATE INDEX "member_profile_to_tsvector_idx" ON "member_profile" USING gin
508 (("to_tsvector"("member_profile".*)));
510 CREATE FUNCTION "to_tsvector"("unit") RETURNS TSVECTOR
511 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
512 $1."name",
513 $1."description"
514 )) $$;
515 CREATE INDEX "unit_to_tsvector_idx" ON "unit" USING gin
516 (("to_tsvector"("unit".*)));
518 CREATE FUNCTION "to_tsvector"("area") RETURNS TSVECTOR
519 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
520 $1."name",
521 $1."description"
522 )) $$;
523 CREATE INDEX "area_to_tsvector_idx" ON "area" USING gin
524 (("to_tsvector"("area".*)));
526 CREATE FUNCTION "to_tsvector"("initiative") RETURNS TSVECTOR
527 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
528 $1."name",
529 $1."content"
530 )) $$;
531 CREATE INDEX "initiative_to_tsvector_idx" ON "initiative" USING gin
532 (("to_tsvector"("initiative".*)));
534 CREATE FUNCTION "to_tsvector"("draft") RETURNS TSVECTOR
535 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
536 $1."content"
537 )) $$;
538 CREATE INDEX "draft_to_tsvector_idx" ON "draft" USING gin
539 (("to_tsvector"("draft".*)));
541 CREATE FUNCTION "to_tsvector"("suggestion") RETURNS TSVECTOR
542 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
543 $1."name",
544 $1."content"
545 )) $$;
546 CREATE INDEX "suggestion_to_tsvector_idx" ON "suggestion" USING gin
547 (("to_tsvector"("suggestion".*)));
549 CREATE FUNCTION "to_tsvector"("direct_voter") RETURNS TSVECTOR
550 LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ',
551 $1."comment"
552 )) $$;
553 CREATE INDEX "direct_voter_to_tsvector_idx" ON "direct_voter" USING gin
554 (("to_tsvector"("direct_voter".*)));
556 CREATE FUNCTION "update_posting_lexeme_trigger"()
557 RETURNS TRIGGER
558 LANGUAGE 'plpgsql' VOLATILE AS $$
559 DECLARE
560 "lexeme_v" TEXT;
561 BEGIN
562 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
563 DELETE FROM "posting_lexeme" WHERE "posting_id" = OLD."id";
564 END IF;
565 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
566 FOR "lexeme_v" IN
567 SELECT regexp_matches[1]
568 FROM regexp_matches(NEW."message", '#[^\s.,;:]+')
569 LOOP
570 INSERT INTO "posting_lexeme" ("posting_id", "author_id", "lexeme")
571 VALUES (
572 NEW."id",
573 NEW."author_id",
574 "lexeme_v" )
575 ON CONFLICT ("posting_id", "lexeme") DO NOTHING;
576 END LOOP;
577 END IF;
578 RETURN NULL;
579 END;
580 $$;
582 CREATE TRIGGER "update_posting_lexeme"
583 AFTER INSERT OR UPDATE OR DELETE ON "posting"
584 FOR EACH ROW EXECUTE PROCEDURE "update_posting_lexeme_trigger"();
586 COMMENT ON FUNCTION "update_posting_lexeme_trigger"() IS 'Implementation of trigger "update_posting_lexeme" on table "posting"';
587 COMMENT ON TRIGGER "update_posting_lexeme" ON "posting" IS 'Keeps table "posting_lexeme" up to date';
589 CREATE FUNCTION "write_event_posting_trigger"()
590 RETURNS TRIGGER
591 LANGUAGE 'plpgsql' VOLATILE AS $$
592 BEGIN
593 INSERT INTO "event" (
594 "event", "posting_id", "member_id",
595 "unit_id", "area_id", "policy_id",
596 "issue_id", "initiative_id", "suggestion_id"
597 ) VALUES (
598 'posting_created', NEW."id", NEW."author_id",
599 NEW."unit_id", NEW."area_id", NEW."policy_id",
600 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
601 );
602 RETURN NULL;
603 END;
604 $$;
606 CREATE TRIGGER "write_event_posting"
607 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
608 "write_event_posting_trigger"();
610 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
611 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
613 CREATE FUNCTION "file_requires_reference_trigger"()
614 RETURNS TRIGGER
615 LANGUAGE 'plpgsql' VOLATILE AS $$
616 BEGIN
617 IF NOT EXISTS (
618 SELECT NULL FROM "draft_attachment" WHERE "file_id" = NEW."id"
619 ) THEN
620 RAISE EXCEPTION 'Cannot create an unreferenced file.' USING
621 ERRCODE = 'integrity_constraint_violation',
622 HINT = 'Create file and its reference in another table within the same transaction.';
623 END IF;
624 RETURN NULL;
625 END;
626 $$;
628 CREATE CONSTRAINT TRIGGER "file_requires_reference"
629 AFTER INSERT OR UPDATE ON "file" DEFERRABLE INITIALLY DEFERRED
630 FOR EACH ROW EXECUTE PROCEDURE
631 "file_requires_reference_trigger"();
633 COMMENT ON FUNCTION "file_requires_reference_trigger"() IS 'Implementation of trigger "file_requires_reference" on table "file"';
634 COMMENT ON TRIGGER "file_requires_reference" ON "file" IS 'Ensure that files are always referenced';
636 CREATE FUNCTION "last_reference_deletes_file_trigger"()
637 RETURNS TRIGGER
638 LANGUAGE 'plpgsql' VOLATILE AS $$
639 DECLARE
640 "reference_lost" BOOLEAN;
641 BEGIN
642 IF TG_OP = 'DELETE' THEN
643 "reference_lost" := TRUE;
644 ELSE
645 "reference_lost" := NEW."file_id" != OLD."file_id";
646 END IF;
647 IF
648 "reference_lost" AND NOT EXISTS (
649 SELECT NULL FROM "draft_attachment" WHERE "file_id" = OLD."file_id"
650 )
651 THEN
652 DELETE FROM "file" WHERE "id" = OLD."file_id";
653 END IF;
654 RETURN NULL;
655 END;
656 $$;
658 CREATE CONSTRAINT TRIGGER "last_reference_deletes_file"
659 AFTER UPDATE OR DELETE ON "draft_attachment" DEFERRABLE INITIALLY DEFERRED
660 FOR EACH ROW EXECUTE PROCEDURE
661 "last_reference_deletes_file_trigger"();
663 COMMENT ON FUNCTION "last_reference_deletes_file_trigger"() IS 'Implementation of trigger "last_reference_deletes_file" on table "draft_attachment"';
664 COMMENT ON TRIGGER "last_reference_deletes_file" ON "draft_attachment" IS 'Removing the last reference to a file deletes the file';
666 CREATE OR REPLACE FUNCTION "copy_current_draft_data"
667 ("initiative_id_p" "initiative"."id"%TYPE )
668 RETURNS VOID
669 LANGUAGE 'plpgsql' VOLATILE AS $$
670 BEGIN
671 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
672 FOR UPDATE;
673 UPDATE "initiative" SET
674 "location" = "draft"."location",
675 "content" = "draft"."content"
676 FROM "current_draft" AS "draft"
677 WHERE "initiative"."id" = "initiative_id_p"
678 AND "draft"."initiative_id" = "initiative_id_p";
679 END;
680 $$;
682 CREATE VIEW "follower" AS
683 SELECT
684 "id" AS "follower_id",
685 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
686 FROM "contact"
687 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
688 AS "following_ids"
689 FROM "member";
691 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
693 CREATE OR REPLACE FUNCTION "check_issue"
694 ( "issue_id_p" "issue"."id"%TYPE,
695 "persist" "check_issue_persistence" )
696 RETURNS "check_issue_persistence"
697 LANGUAGE 'plpgsql' VOLATILE AS $$
698 DECLARE
699 "issue_row" "issue"%ROWTYPE;
700 "last_calculated_v" "snapshot"."calculated"%TYPE;
701 "policy_row" "policy"%ROWTYPE;
702 "initiative_row" "initiative"%ROWTYPE;
703 "state_v" "issue_state";
704 BEGIN
705 PERFORM "require_transaction_isolation"();
706 IF "persist" ISNULL THEN
707 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
708 FOR UPDATE;
709 SELECT "calculated" INTO "last_calculated_v"
710 FROM "snapshot" JOIN "snapshot_issue"
711 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
712 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
713 ORDER BY "snapshot"."id" DESC;
714 IF "issue_row"."closed" NOTNULL THEN
715 RETURN NULL;
716 END IF;
717 "persist"."state" := "issue_row"."state";
718 IF
719 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
720 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
721 ( "issue_row"."state" = 'discussion' AND now() >=
722 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
723 ( "issue_row"."state" = 'verification' AND now() >=
724 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
725 ( "issue_row"."state" = 'voting' AND now() >=
726 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
727 THEN
728 "persist"."phase_finished" := TRUE;
729 ELSE
730 "persist"."phase_finished" := FALSE;
731 END IF;
732 IF
733 NOT EXISTS (
734 -- all initiatives are revoked
735 SELECT NULL FROM "initiative"
736 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
737 ) AND (
738 -- and issue has not been accepted yet
739 "persist"."state" = 'admission' OR
740 -- or verification time has elapsed
741 ( "persist"."state" = 'verification' AND
742 "persist"."phase_finished" ) OR
743 -- or no initiatives have been revoked lately
744 NOT EXISTS (
745 SELECT NULL FROM "initiative"
746 WHERE "issue_id" = "issue_id_p"
747 AND now() < "revoked" + "issue_row"."verification_time"
748 )
749 )
750 THEN
751 "persist"."issue_revoked" := TRUE;
752 ELSE
753 "persist"."issue_revoked" := FALSE;
754 END IF;
755 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
756 UPDATE "issue" SET "phase_finished" = now()
757 WHERE "id" = "issue_row"."id";
758 RETURN "persist";
759 ELSIF
760 "persist"."state" IN ('admission', 'discussion', 'verification')
761 THEN
762 RETURN "persist";
763 ELSE
764 RETURN NULL;
765 END IF;
766 END IF;
767 IF
768 "persist"."state" IN ('admission', 'discussion', 'verification') AND
769 coalesce("persist"."snapshot_created", FALSE) = FALSE
770 THEN
771 IF "persist"."state" != 'admission' THEN
772 PERFORM "take_snapshot"("issue_id_p");
773 PERFORM "finish_snapshot"("issue_id_p");
774 ELSE
775 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
776 FROM "issue_quorum"
777 WHERE "id" = "issue_id_p"
778 AND "issue_quorum"."issue_id" = "issue_id_p";
779 END IF;
780 "persist"."snapshot_created" = TRUE;
781 IF "persist"."phase_finished" THEN
782 IF "persist"."state" = 'admission' THEN
783 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
784 WHERE "id" = "issue_id_p";
785 ELSIF "persist"."state" = 'discussion' THEN
786 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
787 WHERE "id" = "issue_id_p";
788 ELSIF "persist"."state" = 'verification' THEN
789 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
790 WHERE "id" = "issue_id_p";
791 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
792 FOR "initiative_row" IN
793 SELECT * FROM "initiative"
794 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
795 FOR UPDATE
796 LOOP
797 IF
798 "initiative_row"."polling" OR
799 "initiative_row"."satisfied_supporter_count" >=
800 "issue_row"."initiative_quorum"
801 THEN
802 UPDATE "initiative" SET "admitted" = TRUE
803 WHERE "id" = "initiative_row"."id";
804 ELSE
805 UPDATE "initiative" SET "admitted" = FALSE
806 WHERE "id" = "initiative_row"."id";
807 END IF;
808 END LOOP;
809 END IF;
810 END IF;
811 RETURN "persist";
812 END IF;
813 IF
814 "persist"."state" IN ('admission', 'discussion', 'verification') AND
815 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
816 THEN
817 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
818 "persist"."harmonic_weights_set" = TRUE;
819 IF
820 "persist"."phase_finished" OR
821 "persist"."issue_revoked" OR
822 "persist"."state" = 'admission'
823 THEN
824 RETURN "persist";
825 ELSE
826 RETURN NULL;
827 END IF;
828 END IF;
829 IF "persist"."issue_revoked" THEN
830 IF "persist"."state" = 'admission' THEN
831 "state_v" := 'canceled_revoked_before_accepted';
832 ELSIF "persist"."state" = 'discussion' THEN
833 "state_v" := 'canceled_after_revocation_during_discussion';
834 ELSIF "persist"."state" = 'verification' THEN
835 "state_v" := 'canceled_after_revocation_during_verification';
836 END IF;
837 UPDATE "issue" SET
838 "state" = "state_v",
839 "closed" = "phase_finished",
840 "phase_finished" = NULL
841 WHERE "id" = "issue_id_p";
842 RETURN NULL;
843 END IF;
844 IF "persist"."state" = 'admission' THEN
845 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
846 FOR UPDATE;
847 IF "issue_row"."phase_finished" NOTNULL THEN
848 UPDATE "issue" SET
849 "state" = 'canceled_issue_not_accepted',
850 "closed" = "phase_finished",
851 "phase_finished" = NULL
852 WHERE "id" = "issue_id_p";
853 END IF;
854 RETURN NULL;
855 END IF;
856 IF "persist"."phase_finished" THEN
857 IF "persist"."state" = 'discussion' THEN
858 UPDATE "issue" SET
859 "state" = 'verification',
860 "half_frozen" = "phase_finished",
861 "phase_finished" = NULL
862 WHERE "id" = "issue_id_p";
863 RETURN NULL;
864 END IF;
865 IF "persist"."state" = 'verification' THEN
866 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
867 FOR UPDATE;
868 SELECT * INTO "policy_row" FROM "policy"
869 WHERE "id" = "issue_row"."policy_id";
870 IF EXISTS (
871 SELECT NULL FROM "initiative"
872 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
873 ) THEN
874 UPDATE "issue" SET
875 "state" = 'voting',
876 "fully_frozen" = "phase_finished",
877 "phase_finished" = NULL
878 WHERE "id" = "issue_id_p";
879 ELSE
880 UPDATE "issue" SET
881 "state" = 'canceled_no_initiative_admitted',
882 "fully_frozen" = "phase_finished",
883 "closed" = "phase_finished",
884 "phase_finished" = NULL
885 WHERE "id" = "issue_id_p";
886 -- NOTE: The following DELETE statements have effect only when
887 -- issue state has been manipulated
888 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
889 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
890 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
891 END IF;
892 RETURN NULL;
893 END IF;
894 IF "persist"."state" = 'voting' THEN
895 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
896 PERFORM "close_voting"("issue_id_p");
897 "persist"."closed_voting" = TRUE;
898 RETURN "persist";
899 END IF;
900 PERFORM "calculate_ranks"("issue_id_p");
901 RETURN NULL;
902 END IF;
903 END IF;
904 RAISE WARNING 'should not happen';
905 RETURN NULL;
906 END;
907 $$;
909 CREATE OR REPLACE FUNCTION "check_everything"()
910 RETURNS VOID
911 LANGUAGE 'plpgsql' VOLATILE AS $$
912 DECLARE
913 "area_id_v" "area"."id"%TYPE;
914 "snapshot_id_v" "snapshot"."id"%TYPE;
915 "issue_id_v" "issue"."id"%TYPE;
916 "persist_v" "check_issue_persistence";
917 BEGIN
918 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
919 DELETE FROM "expired_session";
920 DELETE FROM "expired_token";
921 DELETE FROM "unused_snapshot";
922 PERFORM "check_activity"();
923 PERFORM "calculate_member_counts"();
924 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
925 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
926 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
927 WHERE "snapshot_id" = "snapshot_id_v";
928 LOOP
929 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
930 END LOOP;
931 END LOOP;
932 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
933 "persist_v" := NULL;
934 LOOP
935 "persist_v" := "check_issue"("issue_id_v", "persist_v");
936 EXIT WHEN "persist_v" ISNULL;
937 END LOOP;
938 END LOOP;
939 DELETE FROM "unused_snapshot";
940 RETURN;
941 END;
942 $$;
944 CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
945 RETURNS VOID
946 LANGUAGE 'plpgsql' VOLATILE AS $$
947 BEGIN
948 UPDATE "member" SET
949 "last_login" = NULL,
950 "last_delegation_check" = NULL,
951 "login" = NULL,
952 "password" = NULL,
953 "authority" = NULL,
954 "authority_uid" = NULL,
955 "authority_login" = NULL,
956 "deleted" = coalesce("deleted", now()),
957 "locked" = TRUE,
958 "active" = FALSE,
959 "notify_email" = NULL,
960 "notify_email_unconfirmed" = NULL,
961 "notify_email_secret" = NULL,
962 "notify_email_secret_expiry" = NULL,
963 "notify_email_lock_expiry" = NULL,
964 "disable_notifications" = TRUE,
965 "notification_counter" = DEFAULT,
966 "notification_sample_size" = 0,
967 "notification_dow" = NULL,
968 "notification_hour" = NULL,
969 "notification_sent" = NULL,
970 "login_recovery_expiry" = NULL,
971 "password_reset_secret" = NULL,
972 "password_reset_secret_expiry" = NULL,
973 "location" = NULL
974 WHERE "id" = "member_id_p";
975 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
976 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
977 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
978 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
979 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
980 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
981 DELETE FROM "session" WHERE "member_id" = "member_id_p";
982 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
983 DELETE FROM "token" WHERE "member_id" = "member_id_p";
984 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
985 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
986 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
987 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
988 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
989 DELETE FROM "direct_voter" USING "issue"
990 WHERE "direct_voter"."issue_id" = "issue"."id"
991 AND "issue"."closed" ISNULL
992 AND "member_id" = "member_id_p";
993 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
994 RETURN;
995 END;
996 $$;
998 CREATE OR REPLACE FUNCTION "delete_private_data"()
999 RETURNS VOID
1000 LANGUAGE 'plpgsql' VOLATILE AS $$
1001 BEGIN
1002 DELETE FROM "temporary_transaction_data";
1003 DELETE FROM "temporary_suggestion_counts";
1004 DELETE FROM "member" WHERE "activated" ISNULL;
1005 UPDATE "member" SET
1006 "invite_code" = NULL,
1007 "invite_code_expiry" = NULL,
1008 "admin_comment" = NULL,
1009 "last_login" = NULL,
1010 "last_delegation_check" = NULL,
1011 "login" = NULL,
1012 "password" = NULL,
1013 "authority" = NULL,
1014 "authority_uid" = NULL,
1015 "authority_login" = NULL,
1016 "lang" = NULL,
1017 "notify_email" = NULL,
1018 "notify_email_unconfirmed" = NULL,
1019 "notify_email_secret" = NULL,
1020 "notify_email_secret_expiry" = NULL,
1021 "notify_email_lock_expiry" = NULL,
1022 "disable_notifications" = TRUE,
1023 "notification_counter" = DEFAULT,
1024 "notification_sample_size" = 0,
1025 "notification_dow" = NULL,
1026 "notification_hour" = NULL,
1027 "notification_sent" = NULL,
1028 "login_recovery_expiry" = NULL,
1029 "password_reset_secret" = NULL,
1030 "password_reset_secret_expiry" = NULL,
1031 "location" = NULL;
1032 DELETE FROM "verification";
1033 DELETE FROM "member_settings";
1034 DELETE FROM "member_useterms";
1035 DELETE FROM "member_profile";
1036 DELETE FROM "rendered_member_statement";
1037 DELETE FROM "member_image";
1038 DELETE FROM "contact";
1039 DELETE FROM "ignored_member";
1040 DELETE FROM "session";
1041 DELETE FROM "system_application";
1042 DELETE FROM "system_application_redirect_uri";
1043 DELETE FROM "dynamic_application_scope";
1044 DELETE FROM "member_application";
1045 DELETE FROM "token";
1046 DELETE FROM "subscription";
1047 DELETE FROM "ignored_area";
1048 DELETE FROM "ignored_initiative";
1049 DELETE FROM "non_voter";
1050 DELETE FROM "direct_voter" USING "issue"
1051 WHERE "direct_voter"."issue_id" = "issue"."id"
1052 AND "issue"."closed" ISNULL;
1053 DELETE FROM "event_processed";
1054 DELETE FROM "notification_initiative_sent";
1055 DELETE FROM "newsletter";
1056 RETURN;
1057 END;
1058 $$;
1060 CREATE VIEW "member_eligible_to_be_notified" AS
1061 SELECT * FROM "member"
1062 WHERE "activated" NOTNULL AND "locked" = FALSE;
1064 COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")';
1066 CREATE VIEW "member_to_notify" AS
1067 SELECT * FROM "member_eligible_to_be_notified"
1068 WHERE "disable_notifications" = FALSE;
1070 COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)';
1072 CREATE VIEW "area_with_unaccepted_issues" AS
1073 SELECT DISTINCT ON ("area"."id") "area".*
1074 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
1075 WHERE "issue"."state" = 'admission';
1077 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
1079 CREATE VIEW "opening_draft" AS
1080 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
1081 ORDER BY "initiative_id", "id";
1083 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
1085 CREATE VIEW "current_draft" AS
1086 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
1087 ORDER BY "initiative_id", "id" DESC;
1089 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
1091 CREATE VIEW "member_contingent" AS
1092 SELECT
1093 "member"."id" AS "member_id",
1094 "contingent"."polling",
1095 "contingent"."time_frame",
1096 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
1098 SELECT count(1) FROM "draft"
1099 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
1100 WHERE "draft"."author_id" = "member"."id"
1101 AND "initiative"."polling" = "contingent"."polling"
1102 AND "draft"."created" > now() - "contingent"."time_frame"
1103 ) + (
1104 SELECT count(1) FROM "suggestion"
1105 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
1106 WHERE "suggestion"."author_id" = "member"."id"
1107 AND "contingent"."polling" = FALSE
1108 AND "suggestion"."created" > now() - "contingent"."time_frame"
1110 ELSE NULL END AS "text_entry_count",
1111 "contingent"."text_entry_limit",
1112 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
1113 SELECT count(1) FROM "opening_draft" AS "draft"
1114 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
1115 WHERE "draft"."author_id" = "member"."id"
1116 AND "initiative"."polling" = "contingent"."polling"
1117 AND "draft"."created" > now() - "contingent"."time_frame"
1118 ) ELSE NULL END AS "initiative_count",
1119 "contingent"."initiative_limit"
1120 FROM "member" CROSS JOIN "contingent";
1122 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
1124 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
1125 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
1127 CREATE VIEW "member_contingent_left" AS
1128 SELECT
1129 "member_id",
1130 "polling",
1131 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
1132 max("initiative_limit" - "initiative_count") AS "initiatives_left"
1133 FROM "member_contingent" GROUP BY "member_id", "polling";
1135 COMMENT ON VIEW "member_contingent_left" IS 'Amount of text entries or initiatives which can be posted now instantly by a member. This view should be used by a frontend to determine, if the contingent for posting is exhausted.';
1137 CREATE VIEW "scheduled_notification_to_send" AS
1138 SELECT * FROM (
1139 SELECT
1140 "id" AS "recipient_id",
1141 now() - CASE WHEN "notification_dow" ISNULL THEN
1142 ( "notification_sent"::DATE + CASE
1143 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
1144 THEN 0 ELSE 1 END
1145 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
1146 ELSE
1147 ( "notification_sent"::DATE +
1148 ( 7 + "notification_dow" -
1149 EXTRACT(DOW FROM
1150 ( "notification_sent"::DATE + CASE
1151 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
1152 THEN 0 ELSE 1 END
1153 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
1154 )::INTEGER
1155 ) % 7 +
1156 CASE
1157 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
1158 THEN 0 ELSE 1
1159 END
1160 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
1161 END AS "pending"
1162 FROM (
1163 SELECT
1164 "id",
1165 COALESCE("notification_sent", "activated") AS "notification_sent",
1166 "notification_dow",
1167 "notification_hour"
1168 FROM "member_to_notify"
1169 WHERE "notification_hour" NOTNULL
1170 ) AS "subquery1"
1171 ) AS "subquery2"
1172 WHERE "pending" > '0'::INTERVAL;
1174 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
1176 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
1177 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
1179 CREATE VIEW "newsletter_to_send" AS
1180 SELECT
1181 "member"."id" AS "recipient_id",
1182 "newsletter"."id" AS "newsletter_id",
1183 "newsletter"."published"
1184 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
1185 LEFT JOIN "privilege" ON
1186 "privilege"."member_id" = "member"."id" AND
1187 "privilege"."unit_id" = "newsletter"."unit_id" AND
1188 "privilege"."voting_right" = TRUE
1189 LEFT JOIN "subscription" ON
1190 "subscription"."member_id" = "member"."id" AND
1191 "subscription"."unit_id" = "newsletter"."unit_id"
1192 WHERE "newsletter"."published" <= now()
1193 AND "newsletter"."sent" ISNULL
1194 AND (
1195 "member"."disable_notifications" = FALSE OR
1196 "newsletter"."include_all_members" = TRUE )
1197 AND (
1198 "newsletter"."unit_id" ISNULL OR
1199 "privilege"."member_id" NOTNULL OR
1200 "subscription"."member_id" NOTNULL );
1202 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
1204 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
1206 SELECT "copy_current_draft_data" ("id") FROM "initiative";
1208 END;

Impressum / About Us