liquid_feedback_core

diff update/core-update.v2.2.3-v2.2.4.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
children
line diff
     1.1 --- /dev/null	Thu Jan 01 00:00:00 1970 +0000
     1.2 +++ b/update/core-update.v2.2.3-v2.2.4.sql	Sat Apr 20 18:22:37 2013 +0200
     1.3 @@ -0,0 +1,261 @@
     1.4 +BEGIN;
     1.5 +
     1.6 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     1.7 +  SELECT * FROM (VALUES ('2.2.4', 2, 2, 4))
     1.8 +  AS "subquery"("string", "major", "minor", "revision");
     1.9 +
    1.10 +
    1.11 +ALTER TABLE "member" ADD COLUMN "last_delegation_check" TIMESTAMPTZ;
    1.12 +ALTER TABLE "member" ADD COLUMN "login_recovery_expiry" TIMESTAMPTZ;
    1.13 +
    1.14 +COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
    1.15 +COMMENT ON COLUMN "member"."login_recovery_expiry"        IS 'Date/time after which another login recovery attempt is allowed';
    1.16 +COMMENT ON COLUMN "member"."password_reset_secret"        IS 'Secret string sent via e-mail for password recovery';
    1.17 +COMMENT ON COLUMN "member"."password_reset_secret_expiry" IS 'Date/time until the password recovery secret is valid, and date/time after which another password recovery attempt is allowed';
    1.18 +
    1.19 +ALTER TABLE "session" ADD COLUMN "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE;
    1.20 +COMMENT ON COLUMN "session"."needs_delegation_check" IS 'Set to TRUE, if member must perform a delegation check to proceed with login; see column "last_delegation_check" in "member" table';
    1.21 + 
    1.22 +CREATE OR REPLACE VIEW "event_seen_by_member" AS
    1.23 +  SELECT
    1.24 +    "member"."id" AS "seen_by_member_id",
    1.25 +    CASE WHEN "event"."state" IN (
    1.26 +      'voting',
    1.27 +      'finished_without_winner',
    1.28 +      'finished_with_winner'
    1.29 +    ) THEN
    1.30 +      'voting'::"notify_level"
    1.31 +    ELSE
    1.32 +      CASE WHEN "event"."state" IN (
    1.33 +        'verification',
    1.34 +        'canceled_after_revocation_during_verification',
    1.35 +        'canceled_no_initiative_admitted'
    1.36 +      ) THEN
    1.37 +        'verification'::"notify_level"
    1.38 +      ELSE
    1.39 +        CASE WHEN "event"."state" IN (
    1.40 +          'discussion',
    1.41 +          'canceled_after_revocation_during_discussion'
    1.42 +        ) THEN
    1.43 +          'discussion'::"notify_level"
    1.44 +        ELSE
    1.45 +          'all'::"notify_level"
    1.46 +        END
    1.47 +      END
    1.48 +    END AS "notify_level",
    1.49 +    "event".*
    1.50 +  FROM "member" CROSS JOIN "event"
    1.51 +  LEFT JOIN "issue"
    1.52 +    ON "event"."issue_id" = "issue"."id"
    1.53 +  LEFT JOIN "membership"
    1.54 +    ON "member"."id" = "membership"."member_id"
    1.55 +    AND "issue"."area_id" = "membership"."area_id"
    1.56 +  LEFT JOIN "interest"
    1.57 +    ON "member"."id" = "interest"."member_id"
    1.58 +    AND "event"."issue_id" = "interest"."issue_id"
    1.59 +  LEFT JOIN "ignored_member"
    1.60 +    ON "member"."id" = "ignored_member"."member_id"
    1.61 +    AND "event"."member_id" = "ignored_member"."other_member_id"
    1.62 +  LEFT JOIN "ignored_initiative"
    1.63 +    ON "member"."id" = "ignored_initiative"."member_id"
    1.64 +    AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
    1.65 +  WHERE (
    1.66 +    "interest"."member_id" NOTNULL OR
    1.67 +    ( "membership"."member_id" NOTNULL AND
    1.68 +      "event"."event" IN (
    1.69 +        'issue_state_changed',
    1.70 +        'initiative_created_in_new_issue',
    1.71 +        'initiative_created_in_existing_issue',
    1.72 +        'initiative_revoked' ) ) )
    1.73 +  AND "ignored_member"."member_id" ISNULL
    1.74 +  AND "ignored_initiative"."member_id" ISNULL;
    1.75 +
    1.76 +CREATE OR REPLACE VIEW "selected_event_seen_by_member" AS
    1.77 +  SELECT
    1.78 +    "member"."id" AS "seen_by_member_id",
    1.79 +    CASE WHEN "event"."state" IN (
    1.80 +      'voting',
    1.81 +      'finished_without_winner',
    1.82 +      'finished_with_winner'
    1.83 +    ) THEN
    1.84 +      'voting'::"notify_level"
    1.85 +    ELSE
    1.86 +      CASE WHEN "event"."state" IN (
    1.87 +        'verification',
    1.88 +        'canceled_after_revocation_during_verification',
    1.89 +        'canceled_no_initiative_admitted'
    1.90 +      ) THEN
    1.91 +        'verification'::"notify_level"
    1.92 +      ELSE
    1.93 +        CASE WHEN "event"."state" IN (
    1.94 +          'discussion',
    1.95 +          'canceled_after_revocation_during_discussion'
    1.96 +        ) THEN
    1.97 +          'discussion'::"notify_level"
    1.98 +        ELSE
    1.99 +          'all'::"notify_level"
   1.100 +        END
   1.101 +      END
   1.102 +    END AS "notify_level",
   1.103 +    "event".*
   1.104 +  FROM "member" CROSS JOIN "event"
   1.105 +  LEFT JOIN "issue"
   1.106 +    ON "event"."issue_id" = "issue"."id"
   1.107 +  LEFT JOIN "membership"
   1.108 +    ON "member"."id" = "membership"."member_id"
   1.109 +    AND "issue"."area_id" = "membership"."area_id"
   1.110 +  LEFT JOIN "interest"
   1.111 +    ON "member"."id" = "interest"."member_id"
   1.112 +    AND "event"."issue_id" = "interest"."issue_id"
   1.113 +  LEFT JOIN "ignored_member"
   1.114 +    ON "member"."id" = "ignored_member"."member_id"
   1.115 +    AND "event"."member_id" = "ignored_member"."other_member_id"
   1.116 +  LEFT JOIN "ignored_initiative"
   1.117 +    ON "member"."id" = "ignored_initiative"."member_id"
   1.118 +    AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
   1.119 +  WHERE (
   1.120 +    ( "member"."notify_level" >= 'all' ) OR
   1.121 +    ( "member"."notify_level" >= 'voting' AND
   1.122 +      "event"."state" IN (
   1.123 +        'voting',
   1.124 +        'finished_without_winner',
   1.125 +        'finished_with_winner' ) ) OR
   1.126 +    ( "member"."notify_level" >= 'verification' AND
   1.127 +      "event"."state" IN (
   1.128 +        'verification',
   1.129 +        'canceled_after_revocation_during_verification',
   1.130 +        'canceled_no_initiative_admitted' ) ) OR
   1.131 +    ( "member"."notify_level" >= 'discussion' AND
   1.132 +      "event"."state" IN (
   1.133 +        'discussion',
   1.134 +        'canceled_after_revocation_during_discussion' ) ) )
   1.135 +  AND (
   1.136 +    "interest"."member_id" NOTNULL OR
   1.137 +    ( "membership"."member_id" NOTNULL AND
   1.138 +      "event"."event" IN (
   1.139 +        'issue_state_changed',
   1.140 +        'initiative_created_in_new_issue',
   1.141 +        'initiative_created_in_existing_issue',
   1.142 +        'initiative_revoked' ) ) )
   1.143 +  AND "ignored_member"."member_id" ISNULL
   1.144 +  AND "ignored_initiative"."member_id" ISNULL;
   1.145 +
   1.146 +CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
   1.147 +  RETURNS VOID
   1.148 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.149 +    BEGIN
   1.150 +      UPDATE "member" SET
   1.151 +        "last_login"                   = NULL,
   1.152 +        "last_delegation_check"        = NULL,
   1.153 +        "login"                        = NULL,
   1.154 +        "password"                     = NULL,
   1.155 +        "locked"                       = TRUE,
   1.156 +        "active"                       = FALSE,
   1.157 +        "notify_email"                 = NULL,
   1.158 +        "notify_email_unconfirmed"     = NULL,
   1.159 +        "notify_email_secret"          = NULL,
   1.160 +        "notify_email_secret_expiry"   = NULL,
   1.161 +        "notify_email_lock_expiry"     = NULL,
   1.162 +        "login_recovery_expiry"        = NULL,
   1.163 +        "password_reset_secret"        = NULL,
   1.164 +        "password_reset_secret_expiry" = NULL,
   1.165 +        "organizational_unit"          = NULL,
   1.166 +        "internal_posts"               = NULL,
   1.167 +        "realname"                     = NULL,
   1.168 +        "birthday"                     = NULL,
   1.169 +        "address"                      = NULL,
   1.170 +        "email"                        = NULL,
   1.171 +        "xmpp_address"                 = NULL,
   1.172 +        "website"                      = NULL,
   1.173 +        "phone"                        = NULL,
   1.174 +        "mobile_phone"                 = NULL,
   1.175 +        "profession"                   = NULL,
   1.176 +        "external_memberships"         = NULL,
   1.177 +        "external_posts"               = NULL,
   1.178 +        "statement"                    = NULL
   1.179 +        WHERE "id" = "member_id_p";
   1.180 +      -- "text_search_data" is updated by triggers
   1.181 +      DELETE FROM "setting"            WHERE "member_id" = "member_id_p";
   1.182 +      DELETE FROM "setting_map"        WHERE "member_id" = "member_id_p";
   1.183 +      DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
   1.184 +      DELETE FROM "member_image"       WHERE "member_id" = "member_id_p";
   1.185 +      DELETE FROM "contact"            WHERE "member_id" = "member_id_p";
   1.186 +      DELETE FROM "ignored_member"     WHERE "member_id" = "member_id_p";
   1.187 +      DELETE FROM "session"            WHERE "member_id" = "member_id_p";
   1.188 +      DELETE FROM "area_setting"       WHERE "member_id" = "member_id_p";
   1.189 +      DELETE FROM "issue_setting"      WHERE "member_id" = "member_id_p";
   1.190 +      DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
   1.191 +      DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
   1.192 +      DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
   1.193 +      DELETE FROM "membership"         WHERE "member_id" = "member_id_p";
   1.194 +      DELETE FROM "delegation"         WHERE "truster_id" = "member_id_p";
   1.195 +      DELETE FROM "non_voter"          WHERE "member_id" = "member_id_p";
   1.196 +      DELETE FROM "direct_voter" USING "issue"
   1.197 +        WHERE "direct_voter"."issue_id" = "issue"."id"
   1.198 +        AND "issue"."closed" ISNULL
   1.199 +        AND "member_id" = "member_id_p";
   1.200 +      RETURN;
   1.201 +    END;
   1.202 +  $$;
   1.203 +
   1.204 +CREATE OR REPLACE FUNCTION "delete_private_data"()
   1.205 +  RETURNS VOID
   1.206 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.207 +    BEGIN
   1.208 +      DELETE FROM "temporary_transaction_data";
   1.209 +      DELETE FROM "member" WHERE "activated" ISNULL;
   1.210 +      UPDATE "member" SET
   1.211 +        "invite_code"                  = NULL,
   1.212 +        "invite_code_expiry"           = NULL,
   1.213 +        "admin_comment"                = NULL,
   1.214 +        "last_login"                   = NULL,
   1.215 +        "last_delegation_check"        = NULL,
   1.216 +        "login"                        = NULL,
   1.217 +        "password"                     = NULL,
   1.218 +        "lang"                         = NULL,
   1.219 +        "notify_email"                 = NULL,
   1.220 +        "notify_email_unconfirmed"     = NULL,
   1.221 +        "notify_email_secret"          = NULL,
   1.222 +        "notify_email_secret_expiry"   = NULL,
   1.223 +        "notify_email_lock_expiry"     = NULL,
   1.224 +        "notify_level"                 = NULL,
   1.225 +        "login_recovery_expiry"        = NULL,
   1.226 +        "password_reset_secret"        = NULL,
   1.227 +        "password_reset_secret_expiry" = NULL,
   1.228 +        "organizational_unit"          = NULL,
   1.229 +        "internal_posts"               = NULL,
   1.230 +        "realname"                     = NULL,
   1.231 +        "birthday"                     = NULL,
   1.232 +        "address"                      = NULL,
   1.233 +        "email"                        = NULL,
   1.234 +        "xmpp_address"                 = NULL,
   1.235 +        "website"                      = NULL,
   1.236 +        "phone"                        = NULL,
   1.237 +        "mobile_phone"                 = NULL,
   1.238 +        "profession"                   = NULL,
   1.239 +        "external_memberships"         = NULL,
   1.240 +        "external_posts"               = NULL,
   1.241 +        "formatting_engine"            = NULL,
   1.242 +        "statement"                    = NULL;
   1.243 +      -- "text_search_data" is updated by triggers
   1.244 +      DELETE FROM "setting";
   1.245 +      DELETE FROM "setting_map";
   1.246 +      DELETE FROM "member_relation_setting";
   1.247 +      DELETE FROM "member_image";
   1.248 +      DELETE FROM "contact";
   1.249 +      DELETE FROM "ignored_member";
   1.250 +      DELETE FROM "session";
   1.251 +      DELETE FROM "area_setting";
   1.252 +      DELETE FROM "issue_setting";
   1.253 +      DELETE FROM "ignored_initiative";
   1.254 +      DELETE FROM "initiative_setting";
   1.255 +      DELETE FROM "suggestion_setting";
   1.256 +      DELETE FROM "non_voter";
   1.257 +      DELETE FROM "direct_voter" USING "issue"
   1.258 +        WHERE "direct_voter"."issue_id" = "issue"."id"
   1.259 +        AND "issue"."closed" ISNULL;
   1.260 +      RETURN;
   1.261 +    END;
   1.262 +  $$;
   1.263 +
   1.264 +COMMIT;

Impressum / About Us