liquid_feedback_core
diff update/core-update.v2.2.2-v2.2.3.sql @ 385:e474e9e1240a
Code cleanup regarding temporary storage of session/transaction data to disable protection triggers
author | jbe |
---|---|
date | Sat Mar 23 13:05:43 2013 +0100 (2013-03-23) |
parents | |
children |
line diff
1.1 --- /dev/null Thu Jan 01 00:00:00 1970 +0000 1.2 +++ b/update/core-update.v2.2.2-v2.2.3.sql Sat Mar 23 13:05:43 2013 +0100 1.3 @@ -0,0 +1,243 @@ 1.4 +BEGIN; 1.5 + 1.6 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS 1.7 + SELECT * FROM (VALUES ('2.2.3', 2, 2, 3)) 1.8 + AS "subquery"("string", "major", "minor", "revision"); 1.9 + 1.10 +DROP TABLE "internal_session_store"; 1.11 + 1.12 +CREATE TABLE "temporary_transaction_data" ( 1.13 + PRIMARY KEY ("txid", "key"), 1.14 + "txid" INT8 DEFAULT txid_current(), 1.15 + "key" TEXT, 1.16 + "value" TEXT NOT NULL ); 1.17 + 1.18 +COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed'; 1.19 + 1.20 +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'; 1.21 + 1.22 +CREATE OR REPLACE FUNCTION "forbid_changes_on_closed_issue_trigger"() 1.23 + RETURNS TRIGGER 1.24 + LANGUAGE 'plpgsql' VOLATILE AS $$ 1.25 + DECLARE 1.26 + "issue_id_v" "issue"."id"%TYPE; 1.27 + "issue_row" "issue"%ROWTYPE; 1.28 + BEGIN 1.29 + IF EXISTS ( 1.30 + SELECT NULL FROM "temporary_transaction_data" 1.31 + WHERE "txid" = txid_current() 1.32 + AND "key" = 'override_protection_triggers' 1.33 + AND "value" = TRUE::TEXT 1.34 + ) THEN 1.35 + RETURN NULL; 1.36 + END IF; 1.37 + IF TG_OP = 'DELETE' THEN 1.38 + "issue_id_v" := OLD."issue_id"; 1.39 + ELSE 1.40 + "issue_id_v" := NEW."issue_id"; 1.41 + END IF; 1.42 + SELECT INTO "issue_row" * FROM "issue" 1.43 + WHERE "id" = "issue_id_v" FOR SHARE; 1.44 + IF ( 1.45 + "issue_row"."closed" NOTNULL OR ( 1.46 + "issue_row"."state" = 'voting' AND 1.47 + "issue_row"."phase_finished" NOTNULL 1.48 + ) 1.49 + ) THEN 1.50 + IF 1.51 + TG_RELID = 'direct_voter'::regclass AND 1.52 + TG_OP = 'UPDATE' 1.53 + THEN 1.54 + IF 1.55 + OLD."issue_id" = NEW."issue_id" AND 1.56 + OLD."member_id" = NEW."member_id" AND 1.57 + OLD."weight" = NEW."weight" 1.58 + THEN 1.59 + RETURN NULL; -- allows changing of voter comment 1.60 + END IF; 1.61 + END IF; 1.62 + RAISE EXCEPTION 'Tried to modify data after voting has been closed.'; 1.63 + END IF; 1.64 + RETURN NULL; 1.65 + END; 1.66 + $$; 1.67 + 1.68 +CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE) 1.69 + RETURNS VOID 1.70 + LANGUAGE 'plpgsql' VOLATILE AS $$ 1.71 + DECLARE 1.72 + "area_id_v" "area"."id"%TYPE; 1.73 + "unit_id_v" "unit"."id"%TYPE; 1.74 + "member_id_v" "member"."id"%TYPE; 1.75 + BEGIN 1.76 + PERFORM "require_transaction_isolation"(); 1.77 + SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p"; 1.78 + SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v"; 1.79 + -- override protection triggers: 1.80 + INSERT INTO "temporary_transaction_data" ("key", "value") 1.81 + VALUES ('override_protection_triggers', TRUE::TEXT); 1.82 + -- delete timestamp of voting comment: 1.83 + UPDATE "direct_voter" SET "comment_changed" = NULL 1.84 + WHERE "issue_id" = "issue_id_p"; 1.85 + -- delete delegating votes (in cases of manual reset of issue state): 1.86 + DELETE FROM "delegating_voter" 1.87 + WHERE "issue_id" = "issue_id_p"; 1.88 + -- delete votes from non-privileged voters: 1.89 + DELETE FROM "direct_voter" 1.90 + USING ( 1.91 + SELECT 1.92 + "direct_voter"."member_id" 1.93 + FROM "direct_voter" 1.94 + JOIN "member" ON "direct_voter"."member_id" = "member"."id" 1.95 + LEFT JOIN "privilege" 1.96 + ON "privilege"."unit_id" = "unit_id_v" 1.97 + AND "privilege"."member_id" = "direct_voter"."member_id" 1.98 + WHERE "direct_voter"."issue_id" = "issue_id_p" AND ( 1.99 + "member"."active" = FALSE OR 1.100 + "privilege"."voting_right" ISNULL OR 1.101 + "privilege"."voting_right" = FALSE 1.102 + ) 1.103 + ) AS "subquery" 1.104 + WHERE "direct_voter"."issue_id" = "issue_id_p" 1.105 + AND "direct_voter"."member_id" = "subquery"."member_id"; 1.106 + -- consider delegations: 1.107 + UPDATE "direct_voter" SET "weight" = 1 1.108 + WHERE "issue_id" = "issue_id_p"; 1.109 + PERFORM "add_vote_delegations"("issue_id_p"); 1.110 + -- finish overriding protection triggers (avoids garbage): 1.111 + DELETE FROM "temporary_transaction_data" 1.112 + WHERE "key" = 'override_protection_triggers'; 1.113 + -- materialize battle_view: 1.114 + -- NOTE: "closed" column of issue must be set at this point 1.115 + DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; 1.116 + INSERT INTO "battle" ( 1.117 + "issue_id", 1.118 + "winning_initiative_id", "losing_initiative_id", 1.119 + "count" 1.120 + ) SELECT 1.121 + "issue_id", 1.122 + "winning_initiative_id", "losing_initiative_id", 1.123 + "count" 1.124 + FROM "battle_view" WHERE "issue_id" = "issue_id_p"; 1.125 + -- set voter count: 1.126 + UPDATE "issue" SET 1.127 + "voter_count" = ( 1.128 + SELECT coalesce(sum("weight"), 0) 1.129 + FROM "direct_voter" WHERE "issue_id" = "issue_id_p" 1.130 + ) 1.131 + WHERE "id" = "issue_id_p"; 1.132 + -- copy "positive_votes" and "negative_votes" from "battle" table: 1.133 + UPDATE "initiative" SET 1.134 + "positive_votes" = "battle_win"."count", 1.135 + "negative_votes" = "battle_lose"."count" 1.136 + FROM "battle" AS "battle_win", "battle" AS "battle_lose" 1.137 + WHERE 1.138 + "battle_win"."issue_id" = "issue_id_p" AND 1.139 + "battle_win"."winning_initiative_id" = "initiative"."id" AND 1.140 + "battle_win"."losing_initiative_id" ISNULL AND 1.141 + "battle_lose"."issue_id" = "issue_id_p" AND 1.142 + "battle_lose"."losing_initiative_id" = "initiative"."id" AND 1.143 + "battle_lose"."winning_initiative_id" ISNULL; 1.144 + END; 1.145 + $$; 1.146 + 1.147 +CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE) 1.148 + RETURNS VOID 1.149 + LANGUAGE 'plpgsql' VOLATILE AS $$ 1.150 + BEGIN 1.151 + IF EXISTS ( 1.152 + SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL 1.153 + ) THEN 1.154 + -- override protection triggers: 1.155 + INSERT INTO "temporary_transaction_data" ("key", "value") 1.156 + VALUES ('override_protection_triggers', TRUE::TEXT); 1.157 + -- clean data: 1.158 + DELETE FROM "delegating_voter" 1.159 + WHERE "issue_id" = "issue_id_p"; 1.160 + DELETE FROM "direct_voter" 1.161 + WHERE "issue_id" = "issue_id_p"; 1.162 + DELETE FROM "delegating_interest_snapshot" 1.163 + WHERE "issue_id" = "issue_id_p"; 1.164 + DELETE FROM "direct_interest_snapshot" 1.165 + WHERE "issue_id" = "issue_id_p"; 1.166 + DELETE FROM "delegating_population_snapshot" 1.167 + WHERE "issue_id" = "issue_id_p"; 1.168 + DELETE FROM "direct_population_snapshot" 1.169 + WHERE "issue_id" = "issue_id_p"; 1.170 + DELETE FROM "non_voter" 1.171 + WHERE "issue_id" = "issue_id_p"; 1.172 + DELETE FROM "delegation" 1.173 + WHERE "issue_id" = "issue_id_p"; 1.174 + DELETE FROM "supporter" 1.175 + USING "initiative" -- NOTE: due to missing index on issue_id 1.176 + WHERE "initiative"."issue_id" = "issue_id_p" 1.177 + AND "supporter"."initiative_id" = "initiative_id"; 1.178 + -- mark issue as cleaned: 1.179 + UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p"; 1.180 + -- finish overriding protection triggers (avoids garbage): 1.181 + DELETE FROM "temporary_transaction_data" 1.182 + WHERE "key" = 'override_protection_triggers'; 1.183 + END IF; 1.184 + RETURN; 1.185 + END; 1.186 + $$; 1.187 + 1.188 +CREATE OR REPLACE FUNCTION "delete_private_data"() 1.189 + RETURNS VOID 1.190 + LANGUAGE 'plpgsql' VOLATILE AS $$ 1.191 + BEGIN 1.192 + DELETE FROM "temporary_transaction_data"; 1.193 + DELETE FROM "member" WHERE "activated" ISNULL; 1.194 + UPDATE "member" SET 1.195 + "invite_code" = NULL, 1.196 + "invite_code_expiry" = NULL, 1.197 + "admin_comment" = NULL, 1.198 + "last_login" = NULL, 1.199 + "login" = NULL, 1.200 + "password" = NULL, 1.201 + "lang" = NULL, 1.202 + "notify_email" = NULL, 1.203 + "notify_email_unconfirmed" = NULL, 1.204 + "notify_email_secret" = NULL, 1.205 + "notify_email_secret_expiry" = NULL, 1.206 + "notify_email_lock_expiry" = NULL, 1.207 + "notify_level" = NULL, 1.208 + "password_reset_secret" = NULL, 1.209 + "password_reset_secret_expiry" = NULL, 1.210 + "organizational_unit" = NULL, 1.211 + "internal_posts" = NULL, 1.212 + "realname" = NULL, 1.213 + "birthday" = NULL, 1.214 + "address" = NULL, 1.215 + "email" = NULL, 1.216 + "xmpp_address" = NULL, 1.217 + "website" = NULL, 1.218 + "phone" = NULL, 1.219 + "mobile_phone" = NULL, 1.220 + "profession" = NULL, 1.221 + "external_memberships" = NULL, 1.222 + "external_posts" = NULL, 1.223 + "formatting_engine" = NULL, 1.224 + "statement" = NULL; 1.225 + -- "text_search_data" is updated by triggers 1.226 + DELETE FROM "setting"; 1.227 + DELETE FROM "setting_map"; 1.228 + DELETE FROM "member_relation_setting"; 1.229 + DELETE FROM "member_image"; 1.230 + DELETE FROM "contact"; 1.231 + DELETE FROM "ignored_member"; 1.232 + DELETE FROM "session"; 1.233 + DELETE FROM "area_setting"; 1.234 + DELETE FROM "issue_setting"; 1.235 + DELETE FROM "ignored_initiative"; 1.236 + DELETE FROM "initiative_setting"; 1.237 + DELETE FROM "suggestion_setting"; 1.238 + DELETE FROM "non_voter"; 1.239 + DELETE FROM "direct_voter" USING "issue" 1.240 + WHERE "direct_voter"."issue_id" = "issue"."id" 1.241 + AND "issue"."closed" ISNULL; 1.242 + RETURN; 1.243 + END; 1.244 + $$; 1.245 + 1.246 +COMMIT;