liquid_feedback_core

annotate update/core-update.v3.2.1-v3.2.2.sql @ 523:30b67ca0c242

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

Impressum / About Us