rev |
line source |
jbe@453
|
1 BEGIN;
|
jbe@453
|
2
|
jbe@453
|
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
|
jbe@453
|
4 SELECT * FROM (VALUES ('3.1.0', 3, 1, 0))
|
jbe@453
|
5 AS "subquery"("string", "major", "minor", "revision");
|
jbe@453
|
6
|
jbe@453
|
7 ALTER TABLE "member" DROP CONSTRAINT "authority_requires_uid_and_vice_versa";
|
jbe@453
|
8 ALTER TABLE "member" ADD CONSTRAINT "authority_requires_uid_and_vice_versa" CHECK (
|
jbe@453
|
9 ("authority" NOTNULL) = ("authority_uid" NOTNULL) );
|
jbe@453
|
10
|
jbe@453
|
11 DROP TABLE "member_application";
|
jbe@453
|
12 DROP TYPE "application_access_level";
|
jbe@453
|
13
|
jbe@453
|
14 ALTER TABLE "policy" ADD COLUMN "min_admission_time" INTERVAL DEFAULT '0';
|
jbe@453
|
15 ALTER TABLE "policy" ALTER COLUMN "min_admission_time" DROP DEFAULT;
|
jbe@453
|
16 ALTER TABLE "policy" RENAME COLUMN "admission_time" TO "max_admission_time";
|
jbe@453
|
17
|
jbe@453
|
18 ALTER TABLE "policy" DROP CONSTRAINT "timing";
|
jbe@453
|
19 ALTER TABLE "policy" ADD CONSTRAINT "timing" CHECK (
|
jbe@453
|
20 ( "polling" = FALSE AND
|
jbe@453
|
21 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
|
jbe@455
|
22 "min_admission_time" <= "max_admission_time" AND
|
jbe@453
|
23 "discussion_time" NOTNULL AND
|
jbe@453
|
24 "verification_time" NOTNULL AND
|
jbe@453
|
25 "voting_time" NOTNULL ) OR
|
jbe@453
|
26 ( "polling" = TRUE AND
|
jbe@453
|
27 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
|
jbe@453
|
28 "discussion_time" NOTNULL AND
|
jbe@453
|
29 "verification_time" NOTNULL AND
|
jbe@453
|
30 "voting_time" NOTNULL ) OR
|
jbe@453
|
31 ( "polling" = TRUE AND
|
jbe@453
|
32 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
|
jbe@453
|
33 "discussion_time" ISNULL AND
|
jbe@453
|
34 "verification_time" ISNULL AND
|
jbe@453
|
35 "voting_time" ISNULL ) );
|
jbe@453
|
36
|
jbe@453
|
37 ALTER TABLE "policy" DROP CONSTRAINT "issue_quorum_if_and_only_if_not_polling";
|
jbe@453
|
38 ALTER TABLE "policy" ADD CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
|
jbe@453
|
39 "polling" = ("issue_quorum_num" ISNULL) AND
|
jbe@453
|
40 "polling" = ("issue_quorum_den" ISNULL) );
|
jbe@453
|
41
|
jbe@453
|
42 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "min_admission_time" and "max_admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
|
jbe@453
|
43 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open';
|
jbe@453
|
44
|
jbe@453
|
45 ALTER TABLE "issue" ADD COLUMN "min_admission_time" INTERVAL DEFAULT '0';
|
jbe@453
|
46 ALTER TABLE "issue" ALTER COLUMN "min_admission_time" DROP DEFAULT;
|
jbe@453
|
47 ALTER TABLE "issue" RENAME COLUMN "admission_time" TO "max_admission_time";
|
jbe@453
|
48
|
jbe@453
|
49 ALTER TABLE "issue" DROP CONSTRAINT "admission_time_not_null_unless_instantly_accepted";
|
jbe@453
|
50 ALTER TABLE "issue" ADD CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
|
jbe@453
|
51 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
|
jbe@453
|
52 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) );
|
jbe@453
|
53
|
jbe@453
|
54 ALTER TABLE "issue" DROP CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event";
|
jbe@453
|
55 ALTER TABLE "issue" ADD CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event" CHECK (
|
jbe@453
|
56 (("snapshot" NOTNULL) = ("latest_snapshot_event" NOTNULL)) );
|
jbe@453
|
57
|
jbe@453
|
58 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "max_admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.';
|
jbe@453
|
59 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@453
|
60
|
jbe@453
|
61 DROP TRIGGER "update_text_search_data" ON "initiative";
|
jbe@453
|
62 ALTER TABLE "initiative" DROP COLUMN "discussion_url";
|
jbe@453
|
63
|
jbe@453
|
64 ALTER TABLE "initiative" DROP CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null";
|
jbe@453
|
65 ALTER TABLE "initiative" ADD CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null" CHECK (
|
jbe@453
|
66 ("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL) );
|
jbe@453
|
67
|
jbe@453
|
68 CREATE TRIGGER "update_text_search_data"
|
jbe@453
|
69 BEFORE INSERT OR UPDATE ON "initiative"
|
jbe@453
|
70 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@453
|
71 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
|
jbe@453
|
72
|
jbe@453
|
73 ALTER TABLE "event" DROP CONSTRAINT "null_constraints_for_issue_state_changed";
|
jbe@453
|
74 ALTER TABLE "event" DROP CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft";
|
jbe@453
|
75 ALTER TABLE "event" DROP CONSTRAINT "null_constraints_for_suggestion_creation";
|
jbe@453
|
76
|
jbe@453
|
77 ALTER TABLE "event" ADD CONSTRAINT "null_constr_for_issue_state_changed" CHECK (
|
jbe@453
|
78 "event" != 'issue_state_changed' OR (
|
jbe@453
|
79 "member_id" ISNULL AND
|
jbe@453
|
80 "issue_id" NOTNULL AND
|
jbe@453
|
81 "state" NOTNULL AND
|
jbe@453
|
82 "initiative_id" ISNULL AND
|
jbe@453
|
83 "draft_id" ISNULL AND
|
jbe@453
|
84 "suggestion_id" ISNULL ) );
|
jbe@453
|
85 ALTER TABLE "event" ADD CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
|
jbe@453
|
86 "event" NOT IN (
|
jbe@453
|
87 'initiative_created_in_new_issue',
|
jbe@453
|
88 'initiative_created_in_existing_issue',
|
jbe@453
|
89 'initiative_revoked',
|
jbe@453
|
90 'new_draft_created'
|
jbe@453
|
91 ) OR (
|
jbe@453
|
92 "member_id" NOTNULL AND
|
jbe@453
|
93 "issue_id" NOTNULL AND
|
jbe@453
|
94 "state" NOTNULL AND
|
jbe@453
|
95 "initiative_id" NOTNULL AND
|
jbe@453
|
96 "draft_id" NOTNULL AND
|
jbe@453
|
97 "suggestion_id" ISNULL ) );
|
jbe@453
|
98 ALTER TABLE "event" ADD CONSTRAINT "null_constr_for_suggestion_creation" CHECK (
|
jbe@453
|
99 "event" != 'suggestion_created' OR (
|
jbe@453
|
100 "member_id" NOTNULL AND
|
jbe@453
|
101 "issue_id" NOTNULL AND
|
jbe@453
|
102 "state" NOTNULL AND
|
jbe@453
|
103 "initiative_id" NOTNULL AND
|
jbe@453
|
104 "draft_id" ISNULL AND
|
jbe@453
|
105 "suggestion_id" NOTNULL ) );
|
jbe@453
|
106
|
jbe@453
|
107 CREATE OR REPLACE FUNCTION "copy_timings_trigger"()
|
jbe@453
|
108 RETURNS TRIGGER
|
jbe@453
|
109 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@453
|
110 DECLARE
|
jbe@453
|
111 "policy_row" "policy"%ROWTYPE;
|
jbe@453
|
112 BEGIN
|
jbe@453
|
113 SELECT * INTO "policy_row" FROM "policy"
|
jbe@453
|
114 WHERE "id" = NEW."policy_id";
|
jbe@453
|
115 IF NEW."min_admission_time" ISNULL THEN
|
jbe@453
|
116 NEW."min_admission_time" := "policy_row"."min_admission_time";
|
jbe@453
|
117 END IF;
|
jbe@453
|
118 IF NEW."max_admission_time" ISNULL THEN
|
jbe@453
|
119 NEW."max_admission_time" := "policy_row"."max_admission_time";
|
jbe@453
|
120 END IF;
|
jbe@453
|
121 IF NEW."discussion_time" ISNULL THEN
|
jbe@453
|
122 NEW."discussion_time" := "policy_row"."discussion_time";
|
jbe@453
|
123 END IF;
|
jbe@453
|
124 IF NEW."verification_time" ISNULL THEN
|
jbe@453
|
125 NEW."verification_time" := "policy_row"."verification_time";
|
jbe@453
|
126 END IF;
|
jbe@453
|
127 IF NEW."voting_time" ISNULL THEN
|
jbe@453
|
128 NEW."voting_time" := "policy_row"."voting_time";
|
jbe@453
|
129 END IF;
|
jbe@453
|
130 RETURN NEW;
|
jbe@453
|
131 END;
|
jbe@453
|
132 $$;
|
jbe@453
|
133
|
jbe@453
|
134 CREATE OR REPLACE FUNCTION "check_issue"
|
jbe@453
|
135 ( "issue_id_p" "issue"."id"%TYPE,
|
jbe@453
|
136 "persist" "check_issue_persistence" )
|
jbe@453
|
137 RETURNS "check_issue_persistence"
|
jbe@453
|
138 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@453
|
139 DECLARE
|
jbe@453
|
140 "issue_row" "issue"%ROWTYPE;
|
jbe@453
|
141 "policy_row" "policy"%ROWTYPE;
|
jbe@453
|
142 "initiative_row" "initiative"%ROWTYPE;
|
jbe@453
|
143 "state_v" "issue_state";
|
jbe@453
|
144 BEGIN
|
jbe@453
|
145 PERFORM "require_transaction_isolation"();
|
jbe@453
|
146 IF "persist" ISNULL THEN
|
jbe@453
|
147 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
|
jbe@453
|
148 FOR UPDATE;
|
jbe@453
|
149 IF "issue_row"."closed" NOTNULL THEN
|
jbe@453
|
150 RETURN NULL;
|
jbe@453
|
151 END IF;
|
jbe@453
|
152 "persist"."state" := "issue_row"."state";
|
jbe@453
|
153 IF
|
jbe@453
|
154 ( "issue_row"."state" = 'admission' AND now() >=
|
jbe@453
|
155 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
|
jbe@453
|
156 ( "issue_row"."state" = 'discussion' AND now() >=
|
jbe@453
|
157 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
|
jbe@453
|
158 ( "issue_row"."state" = 'verification' AND now() >=
|
jbe@453
|
159 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
|
jbe@453
|
160 ( "issue_row"."state" = 'voting' AND now() >=
|
jbe@453
|
161 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
|
jbe@453
|
162 THEN
|
jbe@453
|
163 "persist"."phase_finished" := TRUE;
|
jbe@453
|
164 ELSE
|
jbe@453
|
165 "persist"."phase_finished" := FALSE;
|
jbe@453
|
166 END IF;
|
jbe@453
|
167 IF
|
jbe@453
|
168 NOT EXISTS (
|
jbe@453
|
169 -- all initiatives are revoked
|
jbe@453
|
170 SELECT NULL FROM "initiative"
|
jbe@453
|
171 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
|
jbe@453
|
172 ) AND (
|
jbe@453
|
173 -- and issue has not been accepted yet
|
jbe@453
|
174 "persist"."state" = 'admission' OR
|
jbe@453
|
175 -- or verification time has elapsed
|
jbe@453
|
176 ( "persist"."state" = 'verification' AND
|
jbe@453
|
177 "persist"."phase_finished" ) OR
|
jbe@453
|
178 -- or no initiatives have been revoked lately
|
jbe@453
|
179 NOT EXISTS (
|
jbe@453
|
180 SELECT NULL FROM "initiative"
|
jbe@453
|
181 WHERE "issue_id" = "issue_id_p"
|
jbe@453
|
182 AND now() < "revoked" + "issue_row"."verification_time"
|
jbe@453
|
183 )
|
jbe@453
|
184 )
|
jbe@453
|
185 THEN
|
jbe@453
|
186 "persist"."issue_revoked" := TRUE;
|
jbe@453
|
187 ELSE
|
jbe@453
|
188 "persist"."issue_revoked" := FALSE;
|
jbe@453
|
189 END IF;
|
jbe@453
|
190 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
|
jbe@453
|
191 UPDATE "issue" SET "phase_finished" = now()
|
jbe@453
|
192 WHERE "id" = "issue_row"."id";
|
jbe@453
|
193 RETURN "persist";
|
jbe@453
|
194 ELSIF
|
jbe@453
|
195 "persist"."state" IN ('admission', 'discussion', 'verification')
|
jbe@453
|
196 THEN
|
jbe@453
|
197 RETURN "persist";
|
jbe@453
|
198 ELSE
|
jbe@453
|
199 RETURN NULL;
|
jbe@453
|
200 END IF;
|
jbe@453
|
201 END IF;
|
jbe@453
|
202 IF
|
jbe@453
|
203 "persist"."state" IN ('admission', 'discussion', 'verification') AND
|
jbe@453
|
204 coalesce("persist"."snapshot_created", FALSE) = FALSE
|
jbe@453
|
205 THEN
|
jbe@453
|
206 PERFORM "create_snapshot"("issue_id_p");
|
jbe@453
|
207 "persist"."snapshot_created" = TRUE;
|
jbe@453
|
208 IF "persist"."phase_finished" THEN
|
jbe@453
|
209 IF "persist"."state" = 'admission' THEN
|
jbe@453
|
210 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
|
jbe@453
|
211 ELSIF "persist"."state" = 'discussion' THEN
|
jbe@453
|
212 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
|
jbe@453
|
213 ELSIF "persist"."state" = 'verification' THEN
|
jbe@453
|
214 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
|
jbe@453
|
215 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@453
|
216 SELECT * INTO "policy_row" FROM "policy"
|
jbe@453
|
217 WHERE "id" = "issue_row"."policy_id";
|
jbe@453
|
218 FOR "initiative_row" IN
|
jbe@453
|
219 SELECT * FROM "initiative"
|
jbe@453
|
220 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
|
jbe@453
|
221 FOR UPDATE
|
jbe@453
|
222 LOOP
|
jbe@453
|
223 IF
|
jbe@453
|
224 "initiative_row"."polling" OR (
|
jbe@453
|
225 "initiative_row"."satisfied_supporter_count" > 0 AND
|
jbe@453
|
226 "initiative_row"."satisfied_supporter_count" *
|
jbe@453
|
227 "policy_row"."initiative_quorum_den" >=
|
jbe@453
|
228 "issue_row"."population" * "policy_row"."initiative_quorum_num"
|
jbe@453
|
229 )
|
jbe@453
|
230 THEN
|
jbe@453
|
231 UPDATE "initiative" SET "admitted" = TRUE
|
jbe@453
|
232 WHERE "id" = "initiative_row"."id";
|
jbe@453
|
233 ELSE
|
jbe@453
|
234 UPDATE "initiative" SET "admitted" = FALSE
|
jbe@453
|
235 WHERE "id" = "initiative_row"."id";
|
jbe@453
|
236 END IF;
|
jbe@453
|
237 END LOOP;
|
jbe@453
|
238 END IF;
|
jbe@453
|
239 END IF;
|
jbe@453
|
240 RETURN "persist";
|
jbe@453
|
241 END IF;
|
jbe@453
|
242 IF
|
jbe@453
|
243 "persist"."state" IN ('admission', 'discussion', 'verification') AND
|
jbe@453
|
244 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
|
jbe@453
|
245 THEN
|
jbe@453
|
246 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
|
jbe@453
|
247 "persist"."harmonic_weights_set" = TRUE;
|
jbe@453
|
248 IF
|
jbe@453
|
249 "persist"."phase_finished" OR
|
jbe@453
|
250 "persist"."issue_revoked" OR
|
jbe@453
|
251 "persist"."state" = 'admission'
|
jbe@453
|
252 THEN
|
jbe@453
|
253 RETURN "persist";
|
jbe@453
|
254 ELSE
|
jbe@453
|
255 RETURN NULL;
|
jbe@453
|
256 END IF;
|
jbe@453
|
257 END IF;
|
jbe@453
|
258 IF "persist"."issue_revoked" THEN
|
jbe@453
|
259 IF "persist"."state" = 'admission' THEN
|
jbe@453
|
260 "state_v" := 'canceled_revoked_before_accepted';
|
jbe@453
|
261 ELSIF "persist"."state" = 'discussion' THEN
|
jbe@453
|
262 "state_v" := 'canceled_after_revocation_during_discussion';
|
jbe@453
|
263 ELSIF "persist"."state" = 'verification' THEN
|
jbe@453
|
264 "state_v" := 'canceled_after_revocation_during_verification';
|
jbe@453
|
265 END IF;
|
jbe@453
|
266 UPDATE "issue" SET
|
jbe@453
|
267 "state" = "state_v",
|
jbe@453
|
268 "closed" = "phase_finished",
|
jbe@453
|
269 "phase_finished" = NULL
|
jbe@453
|
270 WHERE "id" = "issue_id_p";
|
jbe@453
|
271 RETURN NULL;
|
jbe@453
|
272 END IF;
|
jbe@453
|
273 IF "persist"."state" = 'admission' THEN
|
jbe@453
|
274 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
|
jbe@453
|
275 FOR UPDATE;
|
jbe@453
|
276 SELECT * INTO "policy_row"
|
jbe@453
|
277 FROM "policy" WHERE "id" = "issue_row"."policy_id";
|
jbe@453
|
278 IF
|
jbe@453
|
279 ( now() >=
|
jbe@453
|
280 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
|
jbe@453
|
281 EXISTS (
|
jbe@453
|
282 SELECT NULL FROM "initiative"
|
jbe@453
|
283 WHERE "issue_id" = "issue_id_p"
|
jbe@453
|
284 AND "supporter_count" > 0
|
jbe@453
|
285 AND "supporter_count" * "policy_row"."issue_quorum_den"
|
jbe@453
|
286 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
|
jbe@453
|
287 )
|
jbe@453
|
288 THEN
|
jbe@453
|
289 UPDATE "issue" SET
|
jbe@453
|
290 "state" = 'discussion',
|
jbe@453
|
291 "accepted" = coalesce("phase_finished", now()),
|
jbe@453
|
292 "phase_finished" = NULL
|
jbe@453
|
293 WHERE "id" = "issue_id_p";
|
jbe@453
|
294 ELSIF "issue_row"."phase_finished" NOTNULL THEN
|
jbe@453
|
295 UPDATE "issue" SET
|
jbe@453
|
296 "state" = 'canceled_issue_not_accepted',
|
jbe@453
|
297 "closed" = "phase_finished",
|
jbe@453
|
298 "phase_finished" = NULL
|
jbe@453
|
299 WHERE "id" = "issue_id_p";
|
jbe@453
|
300 END IF;
|
jbe@453
|
301 RETURN NULL;
|
jbe@453
|
302 END IF;
|
jbe@453
|
303 IF "persist"."phase_finished" THEN
|
jbe@453
|
304 IF "persist"."state" = 'discussion' THEN
|
jbe@453
|
305 UPDATE "issue" SET
|
jbe@453
|
306 "state" = 'verification',
|
jbe@453
|
307 "half_frozen" = "phase_finished",
|
jbe@453
|
308 "phase_finished" = NULL
|
jbe@453
|
309 WHERE "id" = "issue_id_p";
|
jbe@453
|
310 RETURN NULL;
|
jbe@453
|
311 END IF;
|
jbe@453
|
312 IF "persist"."state" = 'verification' THEN
|
jbe@453
|
313 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
|
jbe@453
|
314 FOR UPDATE;
|
jbe@453
|
315 SELECT * INTO "policy_row" FROM "policy"
|
jbe@453
|
316 WHERE "id" = "issue_row"."policy_id";
|
jbe@453
|
317 IF EXISTS (
|
jbe@453
|
318 SELECT NULL FROM "initiative"
|
jbe@453
|
319 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
|
jbe@453
|
320 ) THEN
|
jbe@453
|
321 UPDATE "issue" SET
|
jbe@453
|
322 "state" = 'voting',
|
jbe@453
|
323 "fully_frozen" = "phase_finished",
|
jbe@453
|
324 "phase_finished" = NULL
|
jbe@453
|
325 WHERE "id" = "issue_id_p";
|
jbe@453
|
326 ELSE
|
jbe@453
|
327 UPDATE "issue" SET
|
jbe@453
|
328 "state" = 'canceled_no_initiative_admitted',
|
jbe@453
|
329 "fully_frozen" = "phase_finished",
|
jbe@453
|
330 "closed" = "phase_finished",
|
jbe@453
|
331 "phase_finished" = NULL
|
jbe@453
|
332 WHERE "id" = "issue_id_p";
|
jbe@453
|
333 -- NOTE: The following DELETE statements have effect only when
|
jbe@453
|
334 -- issue state has been manipulated
|
jbe@453
|
335 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
|
jbe@453
|
336 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
|
jbe@453
|
337 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
|
jbe@453
|
338 END IF;
|
jbe@453
|
339 RETURN NULL;
|
jbe@453
|
340 END IF;
|
jbe@453
|
341 IF "persist"."state" = 'voting' THEN
|
jbe@453
|
342 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
|
jbe@453
|
343 PERFORM "close_voting"("issue_id_p");
|
jbe@453
|
344 "persist"."closed_voting" = TRUE;
|
jbe@453
|
345 RETURN "persist";
|
jbe@453
|
346 END IF;
|
jbe@453
|
347 PERFORM "calculate_ranks"("issue_id_p");
|
jbe@453
|
348 RETURN NULL;
|
jbe@453
|
349 END IF;
|
jbe@453
|
350 END IF;
|
jbe@453
|
351 RAISE WARNING 'should not happen';
|
jbe@453
|
352 RETURN NULL;
|
jbe@453
|
353 END;
|
jbe@453
|
354 $$;
|
jbe@453
|
355
|
jbe@453
|
356 COMMIT;
|