liquid_feedback_core

view update/core-update.v2.2.2-v2.2.3.sql @ 387:ae69cf82c05f

Added support for delegation checks and login recovery; Removed unnecessary join in event views
author jbe
date Sat Apr 20 18:22:37 2013 +0200 (2013-04-20)
parents e474e9e1240a
children
line source
1 BEGIN;
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
4 SELECT * FROM (VALUES ('2.2.3', 2, 2, 3))
5 AS "subquery"("string", "major", "minor", "revision");
7 DROP TABLE "internal_session_store";
9 CREATE TABLE "temporary_transaction_data" (
10 PRIMARY KEY ("txid", "key"),
11 "txid" INT8 DEFAULT txid_current(),
12 "key" TEXT,
13 "value" TEXT NOT NULL );
15 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
17 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
19 CREATE OR REPLACE FUNCTION "forbid_changes_on_closed_issue_trigger"()
20 RETURNS TRIGGER
21 LANGUAGE 'plpgsql' VOLATILE AS $$
22 DECLARE
23 "issue_id_v" "issue"."id"%TYPE;
24 "issue_row" "issue"%ROWTYPE;
25 BEGIN
26 IF EXISTS (
27 SELECT NULL FROM "temporary_transaction_data"
28 WHERE "txid" = txid_current()
29 AND "key" = 'override_protection_triggers'
30 AND "value" = TRUE::TEXT
31 ) THEN
32 RETURN NULL;
33 END IF;
34 IF TG_OP = 'DELETE' THEN
35 "issue_id_v" := OLD."issue_id";
36 ELSE
37 "issue_id_v" := NEW."issue_id";
38 END IF;
39 SELECT INTO "issue_row" * FROM "issue"
40 WHERE "id" = "issue_id_v" FOR SHARE;
41 IF (
42 "issue_row"."closed" NOTNULL OR (
43 "issue_row"."state" = 'voting' AND
44 "issue_row"."phase_finished" NOTNULL
45 )
46 ) THEN
47 IF
48 TG_RELID = 'direct_voter'::regclass AND
49 TG_OP = 'UPDATE'
50 THEN
51 IF
52 OLD."issue_id" = NEW."issue_id" AND
53 OLD."member_id" = NEW."member_id" AND
54 OLD."weight" = NEW."weight"
55 THEN
56 RETURN NULL; -- allows changing of voter comment
57 END IF;
58 END IF;
59 RAISE EXCEPTION 'Tried to modify data after voting has been closed.';
60 END IF;
61 RETURN NULL;
62 END;
63 $$;
65 CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
66 RETURNS VOID
67 LANGUAGE 'plpgsql' VOLATILE AS $$
68 DECLARE
69 "area_id_v" "area"."id"%TYPE;
70 "unit_id_v" "unit"."id"%TYPE;
71 "member_id_v" "member"."id"%TYPE;
72 BEGIN
73 PERFORM "require_transaction_isolation"();
74 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
75 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
76 -- override protection triggers:
77 INSERT INTO "temporary_transaction_data" ("key", "value")
78 VALUES ('override_protection_triggers', TRUE::TEXT);
79 -- delete timestamp of voting comment:
80 UPDATE "direct_voter" SET "comment_changed" = NULL
81 WHERE "issue_id" = "issue_id_p";
82 -- delete delegating votes (in cases of manual reset of issue state):
83 DELETE FROM "delegating_voter"
84 WHERE "issue_id" = "issue_id_p";
85 -- delete votes from non-privileged voters:
86 DELETE FROM "direct_voter"
87 USING (
88 SELECT
89 "direct_voter"."member_id"
90 FROM "direct_voter"
91 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
92 LEFT JOIN "privilege"
93 ON "privilege"."unit_id" = "unit_id_v"
94 AND "privilege"."member_id" = "direct_voter"."member_id"
95 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
96 "member"."active" = FALSE OR
97 "privilege"."voting_right" ISNULL OR
98 "privilege"."voting_right" = FALSE
99 )
100 ) AS "subquery"
101 WHERE "direct_voter"."issue_id" = "issue_id_p"
102 AND "direct_voter"."member_id" = "subquery"."member_id";
103 -- consider delegations:
104 UPDATE "direct_voter" SET "weight" = 1
105 WHERE "issue_id" = "issue_id_p";
106 PERFORM "add_vote_delegations"("issue_id_p");
107 -- finish overriding protection triggers (avoids garbage):
108 DELETE FROM "temporary_transaction_data"
109 WHERE "key" = 'override_protection_triggers';
110 -- materialize battle_view:
111 -- NOTE: "closed" column of issue must be set at this point
112 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
113 INSERT INTO "battle" (
114 "issue_id",
115 "winning_initiative_id", "losing_initiative_id",
116 "count"
117 ) SELECT
118 "issue_id",
119 "winning_initiative_id", "losing_initiative_id",
120 "count"
121 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
122 -- set voter count:
123 UPDATE "issue" SET
124 "voter_count" = (
125 SELECT coalesce(sum("weight"), 0)
126 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
127 )
128 WHERE "id" = "issue_id_p";
129 -- copy "positive_votes" and "negative_votes" from "battle" table:
130 UPDATE "initiative" SET
131 "positive_votes" = "battle_win"."count",
132 "negative_votes" = "battle_lose"."count"
133 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
134 WHERE
135 "battle_win"."issue_id" = "issue_id_p" AND
136 "battle_win"."winning_initiative_id" = "initiative"."id" AND
137 "battle_win"."losing_initiative_id" ISNULL AND
138 "battle_lose"."issue_id" = "issue_id_p" AND
139 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
140 "battle_lose"."winning_initiative_id" ISNULL;
141 END;
142 $$;
144 CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
145 RETURNS VOID
146 LANGUAGE 'plpgsql' VOLATILE AS $$
147 BEGIN
148 IF EXISTS (
149 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
150 ) THEN
151 -- override protection triggers:
152 INSERT INTO "temporary_transaction_data" ("key", "value")
153 VALUES ('override_protection_triggers', TRUE::TEXT);
154 -- clean data:
155 DELETE FROM "delegating_voter"
156 WHERE "issue_id" = "issue_id_p";
157 DELETE FROM "direct_voter"
158 WHERE "issue_id" = "issue_id_p";
159 DELETE FROM "delegating_interest_snapshot"
160 WHERE "issue_id" = "issue_id_p";
161 DELETE FROM "direct_interest_snapshot"
162 WHERE "issue_id" = "issue_id_p";
163 DELETE FROM "delegating_population_snapshot"
164 WHERE "issue_id" = "issue_id_p";
165 DELETE FROM "direct_population_snapshot"
166 WHERE "issue_id" = "issue_id_p";
167 DELETE FROM "non_voter"
168 WHERE "issue_id" = "issue_id_p";
169 DELETE FROM "delegation"
170 WHERE "issue_id" = "issue_id_p";
171 DELETE FROM "supporter"
172 USING "initiative" -- NOTE: due to missing index on issue_id
173 WHERE "initiative"."issue_id" = "issue_id_p"
174 AND "supporter"."initiative_id" = "initiative_id";
175 -- mark issue as cleaned:
176 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
177 -- finish overriding protection triggers (avoids garbage):
178 DELETE FROM "temporary_transaction_data"
179 WHERE "key" = 'override_protection_triggers';
180 END IF;
181 RETURN;
182 END;
183 $$;
185 CREATE OR REPLACE FUNCTION "delete_private_data"()
186 RETURNS VOID
187 LANGUAGE 'plpgsql' VOLATILE AS $$
188 BEGIN
189 DELETE FROM "temporary_transaction_data";
190 DELETE FROM "member" WHERE "activated" ISNULL;
191 UPDATE "member" SET
192 "invite_code" = NULL,
193 "invite_code_expiry" = NULL,
194 "admin_comment" = NULL,
195 "last_login" = NULL,
196 "login" = NULL,
197 "password" = NULL,
198 "lang" = NULL,
199 "notify_email" = NULL,
200 "notify_email_unconfirmed" = NULL,
201 "notify_email_secret" = NULL,
202 "notify_email_secret_expiry" = NULL,
203 "notify_email_lock_expiry" = NULL,
204 "notify_level" = NULL,
205 "password_reset_secret" = NULL,
206 "password_reset_secret_expiry" = NULL,
207 "organizational_unit" = NULL,
208 "internal_posts" = NULL,
209 "realname" = NULL,
210 "birthday" = NULL,
211 "address" = NULL,
212 "email" = NULL,
213 "xmpp_address" = NULL,
214 "website" = NULL,
215 "phone" = NULL,
216 "mobile_phone" = NULL,
217 "profession" = NULL,
218 "external_memberships" = NULL,
219 "external_posts" = NULL,
220 "formatting_engine" = NULL,
221 "statement" = NULL;
222 -- "text_search_data" is updated by triggers
223 DELETE FROM "setting";
224 DELETE FROM "setting_map";
225 DELETE FROM "member_relation_setting";
226 DELETE FROM "member_image";
227 DELETE FROM "contact";
228 DELETE FROM "ignored_member";
229 DELETE FROM "session";
230 DELETE FROM "area_setting";
231 DELETE FROM "issue_setting";
232 DELETE FROM "ignored_initiative";
233 DELETE FROM "initiative_setting";
234 DELETE FROM "suggestion_setting";
235 DELETE FROM "non_voter";
236 DELETE FROM "direct_voter" USING "issue"
237 WHERE "direct_voter"."issue_id" = "issue"."id"
238 AND "issue"."closed" ISNULL;
239 RETURN;
240 END;
241 $$;
243 COMMIT;

Impressum / About Us