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