rev |
line source |
jbe@520
|
1 BEGIN;
|
jbe@520
|
2
|
jbe@520
|
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
|
jbe@520
|
4 SELECT * FROM (VALUES ('3.2.2', 3, 2, 2))
|
jbe@520
|
5 AS "subquery"("string", "major", "minor", "revision");
|
jbe@520
|
6
|
jbe@520
|
7 CREATE OR REPLACE FUNCTION "featured_initiative"
|
jbe@520
|
8 ( "recipient_id_p" "member"."id"%TYPE,
|
jbe@520
|
9 "area_id_p" "area"."id"%TYPE )
|
jbe@520
|
10 RETURNS SETOF "initiative"."id"%TYPE
|
jbe@520
|
11 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@520
|
12 DECLARE
|
jbe@520
|
13 "counter_v" "member"."notification_counter"%TYPE;
|
jbe@520
|
14 "sample_size_v" "member"."notification_sample_size"%TYPE;
|
jbe@520
|
15 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
|
jbe@520
|
16 "match_v" BOOLEAN;
|
jbe@520
|
17 "member_id_v" "member"."id"%TYPE;
|
jbe@520
|
18 "seed_v" TEXT;
|
jbe@520
|
19 "initiative_id_v" "initiative"."id"%TYPE;
|
jbe@520
|
20 BEGIN
|
jbe@520
|
21 SELECT "notification_counter", "notification_sample_size"
|
jbe@520
|
22 INTO "counter_v", "sample_size_v"
|
jbe@520
|
23 FROM "member" WHERE "id" = "recipient_id_p";
|
jbe@520
|
24 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
|
jbe@520
|
25 RETURN;
|
jbe@520
|
26 END IF;
|
jbe@520
|
27 "initiative_id_ary" := '{}';
|
jbe@520
|
28 LOOP
|
jbe@520
|
29 "match_v" := FALSE;
|
jbe@520
|
30 FOR "member_id_v", "seed_v" IN
|
jbe@520
|
31 SELECT * FROM (
|
jbe@520
|
32 SELECT DISTINCT
|
jbe@520
|
33 "supporter"."member_id",
|
jbe@520
|
34 md5(
|
jbe@520
|
35 "recipient_id_p" || '-' ||
|
jbe@520
|
36 "counter_v" || '-' ||
|
jbe@520
|
37 "area_id_p" || '-' ||
|
jbe@520
|
38 "supporter"."member_id"
|
jbe@520
|
39 ) AS "seed"
|
jbe@520
|
40 FROM "supporter"
|
jbe@520
|
41 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
|
jbe@520
|
42 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
|
jbe@520
|
43 WHERE "supporter"."member_id" != "recipient_id_p"
|
jbe@520
|
44 AND "issue"."area_id" = "area_id_p"
|
jbe@520
|
45 AND "issue"."state" IN ('admission', 'discussion', 'verification')
|
jbe@520
|
46 ) AS "subquery"
|
jbe@520
|
47 ORDER BY "seed"
|
jbe@520
|
48 LOOP
|
jbe@520
|
49 SELECT "initiative"."id" INTO "initiative_id_v"
|
jbe@520
|
50 FROM "initiative"
|
jbe@520
|
51 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
|
jbe@520
|
52 JOIN "area" ON "area"."id" = "issue"."area_id"
|
jbe@520
|
53 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
|
jbe@520
|
54 LEFT JOIN "supporter" AS "self_support" ON
|
jbe@520
|
55 "self_support"."initiative_id" = "initiative"."id" AND
|
jbe@520
|
56 "self_support"."member_id" = "recipient_id_p"
|
jbe@520
|
57 LEFT JOIN "privilege" ON
|
jbe@520
|
58 "privilege"."member_id" = "recipient_id_p" AND
|
jbe@520
|
59 "privilege"."unit_id" = "area"."unit_id" AND
|
jbe@520
|
60 "privilege"."voting_right" = TRUE
|
jbe@520
|
61 LEFT JOIN "subscription" ON
|
jbe@520
|
62 "subscription"."member_id" = "recipient_id_p" AND
|
jbe@520
|
63 "subscription"."unit_id" = "area"."unit_id"
|
jbe@520
|
64 LEFT JOIN "ignored_initiative" ON
|
jbe@520
|
65 "ignored_initiative"."member_id" = "recipient_id_p" AND
|
jbe@520
|
66 "ignored_initiative"."initiative_id" = "initiative"."id"
|
jbe@520
|
67 WHERE "supporter"."member_id" = "member_id_v"
|
jbe@520
|
68 AND "issue"."area_id" = "area_id_p"
|
jbe@520
|
69 AND "issue"."state" IN ('admission', 'discussion', 'verification')
|
jbe@520
|
70 AND "initiative"."revoked" ISNULL
|
jbe@520
|
71 AND "self_support"."member_id" ISNULL
|
jbe@520
|
72 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
|
jbe@520
|
73 AND (
|
jbe@520
|
74 "privilege"."member_id" NOTNULL OR
|
jbe@520
|
75 "subscription"."member_id" NOTNULL )
|
jbe@520
|
76 AND "ignored_initiative"."member_id" ISNULL
|
jbe@520
|
77 AND NOT EXISTS (
|
jbe@520
|
78 SELECT NULL FROM "draft"
|
jbe@520
|
79 JOIN "ignored_member" ON
|
jbe@520
|
80 "ignored_member"."member_id" = "recipient_id_p" AND
|
jbe@520
|
81 "ignored_member"."other_member_id" = "draft"."author_id"
|
jbe@520
|
82 WHERE "draft"."initiative_id" = "initiative"."id"
|
jbe@520
|
83 )
|
jbe@520
|
84 ORDER BY md5("seed_v" || '-' || "initiative"."id")
|
jbe@520
|
85 LIMIT 1;
|
jbe@520
|
86 IF FOUND THEN
|
jbe@520
|
87 "match_v" := TRUE;
|
jbe@520
|
88 RETURN NEXT "initiative_id_v";
|
jbe@520
|
89 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
|
jbe@520
|
90 RETURN;
|
jbe@520
|
91 END IF;
|
jbe@520
|
92 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
|
jbe@520
|
93 END IF;
|
jbe@520
|
94 END LOOP;
|
jbe@520
|
95 EXIT WHEN NOT "match_v";
|
jbe@520
|
96 END LOOP;
|
jbe@520
|
97 RETURN;
|
jbe@520
|
98 END;
|
jbe@520
|
99 $$;
|
jbe@520
|
100
|
jbe@521
|
101 CREATE OR REPLACE VIEW "scheduled_notification_to_send" AS
|
jbe@521
|
102 SELECT * FROM (
|
jbe@521
|
103 SELECT
|
jbe@521
|
104 "id" AS "recipient_id",
|
jbe@521
|
105 now() - CASE WHEN "notification_dow" ISNULL THEN
|
jbe@521
|
106 ( "notification_sent"::DATE + CASE
|
jbe@521
|
107 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
|
jbe@521
|
108 THEN 0 ELSE 1 END
|
jbe@521
|
109 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
|
jbe@521
|
110 ELSE
|
jbe@521
|
111 ( "notification_sent"::DATE +
|
jbe@521
|
112 ( 7 + "notification_dow" -
|
jbe@521
|
113 EXTRACT(DOW FROM
|
jbe@521
|
114 ( "notification_sent"::DATE + CASE
|
jbe@521
|
115 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
|
jbe@521
|
116 THEN 0 ELSE 1 END
|
jbe@521
|
117 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
|
jbe@521
|
118 )::INTEGER
|
jbe@521
|
119 ) % 7 +
|
jbe@521
|
120 CASE
|
jbe@521
|
121 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
|
jbe@521
|
122 THEN 0 ELSE 1
|
jbe@521
|
123 END
|
jbe@521
|
124 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
|
jbe@521
|
125 END AS "pending"
|
jbe@521
|
126 FROM (
|
jbe@521
|
127 SELECT
|
jbe@521
|
128 "id",
|
jbe@521
|
129 COALESCE("notification_sent", "activated") AS "notification_sent",
|
jbe@521
|
130 "notification_dow",
|
jbe@521
|
131 "notification_hour"
|
jbe@521
|
132 FROM "member"
|
jbe@521
|
133 WHERE "locked" = FALSE
|
jbe@521
|
134 AND "disable_notifications" = FALSE
|
jbe@521
|
135 AND "notification_hour" NOTNULL
|
jbe@521
|
136 ) AS "subquery1"
|
jbe@521
|
137 ) AS "subquery2"
|
jbe@521
|
138 WHERE "pending" > '0'::INTERVAL;
|
jbe@521
|
139
|
jbe@522
|
140 CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
|
jbe@522
|
141 RETURNS VOID
|
jbe@522
|
142 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@522
|
143 BEGIN
|
jbe@522
|
144 UPDATE "member" SET
|
jbe@522
|
145 "last_login" = NULL,
|
jbe@522
|
146 "last_delegation_check" = NULL,
|
jbe@522
|
147 "login" = NULL,
|
jbe@522
|
148 "password" = NULL,
|
jbe@522
|
149 "authority" = NULL,
|
jbe@522
|
150 "authority_uid" = NULL,
|
jbe@522
|
151 "authority_login" = NULL,
|
jbe@522
|
152 "locked" = TRUE,
|
jbe@522
|
153 "active" = FALSE,
|
jbe@522
|
154 "notify_email" = NULL,
|
jbe@522
|
155 "notify_email_unconfirmed" = NULL,
|
jbe@522
|
156 "notify_email_secret" = NULL,
|
jbe@522
|
157 "notify_email_secret_expiry" = NULL,
|
jbe@522
|
158 "notify_email_lock_expiry" = NULL,
|
jbe@522
|
159 "disable_notifications" = TRUE,
|
jbe@522
|
160 "notification_counter" = DEFAULT,
|
jbe@522
|
161 "notification_sample_size" = 0,
|
jbe@522
|
162 "notification_dow" = NULL,
|
jbe@522
|
163 "notification_hour" = NULL,
|
jbe@522
|
164 "login_recovery_expiry" = NULL,
|
jbe@522
|
165 "password_reset_secret" = NULL,
|
jbe@522
|
166 "password_reset_secret_expiry" = NULL,
|
jbe@522
|
167 "organizational_unit" = NULL,
|
jbe@522
|
168 "internal_posts" = NULL,
|
jbe@522
|
169 "realname" = NULL,
|
jbe@522
|
170 "birthday" = NULL,
|
jbe@522
|
171 "address" = NULL,
|
jbe@522
|
172 "email" = NULL,
|
jbe@522
|
173 "xmpp_address" = NULL,
|
jbe@522
|
174 "website" = NULL,
|
jbe@522
|
175 "phone" = NULL,
|
jbe@522
|
176 "mobile_phone" = NULL,
|
jbe@522
|
177 "profession" = NULL,
|
jbe@522
|
178 "external_memberships" = NULL,
|
jbe@522
|
179 "external_posts" = NULL,
|
jbe@522
|
180 "statement" = NULL
|
jbe@522
|
181 WHERE "id" = "member_id_p";
|
jbe@522
|
182 -- "text_search_data" is updated by triggers
|
jbe@522
|
183 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
|
jbe@522
|
184 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
|
jbe@522
|
185 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
|
jbe@522
|
186 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
|
jbe@522
|
187 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
|
jbe@522
|
188 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
|
jbe@522
|
189 DELETE FROM "session" WHERE "member_id" = "member_id_p";
|
jbe@522
|
190 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
|
jbe@522
|
191 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
|
jbe@522
|
192 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
|
jbe@522
|
193 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
|
jbe@522
|
194 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
|
jbe@522
|
195 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
|
jbe@522
|
196 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
|
jbe@522
|
197 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
|
jbe@522
|
198 DELETE FROM "direct_voter" USING "issue"
|
jbe@522
|
199 WHERE "direct_voter"."issue_id" = "issue"."id"
|
jbe@522
|
200 AND "issue"."closed" ISNULL
|
jbe@522
|
201 AND "member_id" = "member_id_p";
|
jbe@522
|
202 RETURN;
|
jbe@522
|
203 END;
|
jbe@522
|
204 $$;
|
jbe@522
|
205
|
jbe@522
|
206 CREATE OR REPLACE FUNCTION "delete_private_data"()
|
jbe@522
|
207 RETURNS VOID
|
jbe@522
|
208 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@522
|
209 BEGIN
|
jbe@522
|
210 DELETE FROM "temporary_transaction_data";
|
jbe@522
|
211 DELETE FROM "member" WHERE "activated" ISNULL;
|
jbe@522
|
212 UPDATE "member" SET
|
jbe@522
|
213 "invite_code" = NULL,
|
jbe@522
|
214 "invite_code_expiry" = NULL,
|
jbe@522
|
215 "admin_comment" = NULL,
|
jbe@522
|
216 "last_login" = NULL,
|
jbe@522
|
217 "last_delegation_check" = NULL,
|
jbe@522
|
218 "login" = NULL,
|
jbe@522
|
219 "password" = NULL,
|
jbe@522
|
220 "authority" = NULL,
|
jbe@522
|
221 "authority_uid" = NULL,
|
jbe@522
|
222 "authority_login" = NULL,
|
jbe@522
|
223 "lang" = NULL,
|
jbe@522
|
224 "notify_email" = NULL,
|
jbe@522
|
225 "notify_email_unconfirmed" = NULL,
|
jbe@522
|
226 "notify_email_secret" = NULL,
|
jbe@522
|
227 "notify_email_secret_expiry" = NULL,
|
jbe@522
|
228 "notify_email_lock_expiry" = NULL,
|
jbe@522
|
229 "disable_notifications" = TRUE,
|
jbe@522
|
230 "notification_counter" = DEFAULT,
|
jbe@522
|
231 "notification_sample_size" = 0,
|
jbe@522
|
232 "notification_dow" = NULL,
|
jbe@522
|
233 "notification_hour" = NULL,
|
jbe@522
|
234 "login_recovery_expiry" = NULL,
|
jbe@522
|
235 "password_reset_secret" = NULL,
|
jbe@522
|
236 "password_reset_secret_expiry" = NULL,
|
jbe@522
|
237 "organizational_unit" = NULL,
|
jbe@522
|
238 "internal_posts" = NULL,
|
jbe@522
|
239 "realname" = NULL,
|
jbe@522
|
240 "birthday" = NULL,
|
jbe@522
|
241 "address" = NULL,
|
jbe@522
|
242 "email" = NULL,
|
jbe@522
|
243 "xmpp_address" = NULL,
|
jbe@522
|
244 "website" = NULL,
|
jbe@522
|
245 "phone" = NULL,
|
jbe@522
|
246 "mobile_phone" = NULL,
|
jbe@522
|
247 "profession" = NULL,
|
jbe@522
|
248 "external_memberships" = NULL,
|
jbe@522
|
249 "external_posts" = NULL,
|
jbe@522
|
250 "formatting_engine" = NULL,
|
jbe@522
|
251 "statement" = NULL;
|
jbe@522
|
252 -- "text_search_data" is updated by triggers
|
jbe@522
|
253 DELETE FROM "setting";
|
jbe@522
|
254 DELETE FROM "setting_map";
|
jbe@522
|
255 DELETE FROM "member_relation_setting";
|
jbe@522
|
256 DELETE FROM "member_image";
|
jbe@522
|
257 DELETE FROM "contact";
|
jbe@522
|
258 DELETE FROM "ignored_member";
|
jbe@522
|
259 DELETE FROM "session";
|
jbe@522
|
260 DELETE FROM "area_setting";
|
jbe@522
|
261 DELETE FROM "issue_setting";
|
jbe@522
|
262 DELETE FROM "ignored_initiative";
|
jbe@522
|
263 DELETE FROM "initiative_setting";
|
jbe@522
|
264 DELETE FROM "suggestion_setting";
|
jbe@522
|
265 DELETE FROM "non_voter";
|
jbe@522
|
266 DELETE FROM "direct_voter" USING "issue"
|
jbe@522
|
267 WHERE "direct_voter"."issue_id" = "issue"."id"
|
jbe@522
|
268 AND "issue"."closed" ISNULL;
|
jbe@522
|
269 RETURN;
|
jbe@522
|
270 END;
|
jbe@522
|
271 $$;
|
jbe@522
|
272
|
jbe@520
|
273 COMMIT;
|