liquid_feedback_core

view update/core-update.v1.3.0-v1.3.1.sql @ 106:4d121276bf04

Race condition fixed in "check_last_login"()
author jbe
date Sat Feb 05 16:18:07 2011 +0100 (2011-02-05)
parents 0d03c57ebae5
children 53ae1d37e5de
line source
1 BEGIN;
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
4 SELECT * FROM (VALUES ('1.3.1', 1, 3, 1))
5 AS "subquery"("string", "major", "minor", "revision");
7 CREATE TABLE "system_setting" (
8 "member_ttl" INTERVAL );
9 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
11 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
12 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
13 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not login anymore.';
15 ALTER TABLE "member" ADD COLUMN "last_login_public" DATE;
16 ALTER TABLE "member" ADD COLUMN "locked" BOOLEAN NOT NULL DEFAULT FALSE;
18 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
19 COMMENT ON COLUMN "member"."last_login_public" IS 'Date of last login (time stripped for privacy reasons, updated only after day change)';
20 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
21 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. When the user does not log in for an extended period of time, this flag may be set to FALSE. If the user is not locked, he/she may reset the active flag by logging in.';
23 CREATE FUNCTION "check_last_login"()
24 RETURNS VOID
25 LANGUAGE 'plpgsql' VOLATILE AS $$
26 DECLARE
27 "system_setting_row" "system_setting"%ROWTYPE;
28 BEGIN
29 SELECT * INTO "system_setting_row" FROM "system_setting";
30 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
31 UPDATE "member" SET "last_login_public" = "last_login"::date
32 WHERE "last_login"::date < 'today';
33 IF "system_setting_row"."member_ttl" NOTNULL THEN
34 UPDATE "member" SET "active" = FALSE
35 WHERE "active" = TRUE
36 AND "last_login_public" <
37 (now() - "system_setting_row"."member_ttl")::date;
38 END IF;
39 RETURN;
40 END;
41 $$;
43 COMMENT ON FUNCTION "check_last_login"() IS 'Updates "last_login_public" field, which contains the date but not the time of the last login, and deactivates members who do not login for the time specified in "system_setting"."member_ttl". For privacy reasons this function does not update "last_login_public", if the last login of a member has been today.';
45 CREATE OR REPLACE FUNCTION "create_interest_snapshot"
46 ( "issue_id_p" "issue"."id"%TYPE )
47 RETURNS VOID
48 LANGUAGE 'plpgsql' VOLATILE AS $$
49 DECLARE
50 "member_id_v" "member"."id"%TYPE;
51 BEGIN
52 DELETE FROM "direct_interest_snapshot"
53 WHERE "issue_id" = "issue_id_p"
54 AND "event" = 'periodic';
55 DELETE FROM "delegating_interest_snapshot"
56 WHERE "issue_id" = "issue_id_p"
57 AND "event" = 'periodic';
58 DELETE FROM "direct_supporter_snapshot"
59 WHERE "issue_id" = "issue_id_p"
60 AND "event" = 'periodic';
61 INSERT INTO "direct_interest_snapshot"
62 ("issue_id", "event", "member_id", "voting_requested")
63 SELECT
64 "issue_id_p" AS "issue_id",
65 'periodic' AS "event",
66 "member"."id" AS "member_id",
67 "interest"."voting_requested"
68 FROM "interest" JOIN "member"
69 ON "interest"."member_id" = "member"."id"
70 WHERE "interest"."issue_id" = "issue_id_p"
71 AND "member"."active";
72 FOR "member_id_v" IN
73 SELECT "member_id" FROM "direct_interest_snapshot"
74 WHERE "issue_id" = "issue_id_p"
75 AND "event" = 'periodic'
76 LOOP
77 UPDATE "direct_interest_snapshot" SET
78 "weight" = 1 +
79 "weight_of_added_delegations_for_interest_snapshot"(
80 "issue_id_p",
81 "member_id_v",
82 '{}'
83 )
84 WHERE "issue_id" = "issue_id_p"
85 AND "event" = 'periodic'
86 AND "member_id" = "member_id_v";
87 END LOOP;
88 INSERT INTO "direct_supporter_snapshot"
89 ( "issue_id", "initiative_id", "event", "member_id",
90 "informed", "satisfied" )
91 SELECT
92 "issue_id_p" AS "issue_id",
93 "initiative"."id" AS "initiative_id",
94 'periodic' AS "event",
95 "supporter"."member_id" AS "member_id",
96 "supporter"."draft_id" = "current_draft"."id" AS "informed",
97 NOT EXISTS (
98 SELECT NULL FROM "critical_opinion"
99 WHERE "initiative_id" = "initiative"."id"
100 AND "member_id" = "supporter"."member_id"
101 ) AS "satisfied"
102 FROM "initiative"
103 JOIN "supporter"
104 ON "supporter"."initiative_id" = "initiative"."id"
105 JOIN "current_draft"
106 ON "initiative"."id" = "current_draft"."initiative_id"
107 JOIN "direct_interest_snapshot"
108 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
109 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
110 AND "event" = 'periodic'
111 WHERE "initiative"."issue_id" = "issue_id_p";
112 RETURN;
113 END;
114 $$;
116 CREATE OR REPLACE FUNCTION "check_everything"()
117 RETURNS VOID
118 LANGUAGE 'plpgsql' VOLATILE AS $$
119 DECLARE
120 "issue_id_v" "issue"."id"%TYPE;
121 BEGIN
122 DELETE FROM "expired_session";
123 PERFORM "check_last_login"();
124 PERFORM "calculate_member_counts"();
125 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
126 PERFORM "check_issue"("issue_id_v");
127 END LOOP;
128 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
129 PERFORM "calculate_ranks"("issue_id_v");
130 END LOOP;
131 RETURN;
132 END;
133 $$;
135 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue, and if possible, automatically calculates ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result. In productive environments you should call the lf_update program instead.';
137 CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
138 RETURNS VOID
139 LANGUAGE 'plpgsql' VOLATILE AS $$
140 BEGIN
141 UPDATE "member" SET
142 "last_login" = NULL,
143 "last_login_public" = NULL,
144 "login" = NULL,
145 "password" = NULL,
146 "locked" = TRUE,
147 "active" = FALSE,
148 "notify_email" = NULL,
149 "notify_email_unconfirmed" = NULL,
150 "notify_email_secret" = NULL,
151 "notify_email_secret_expiry" = NULL,
152 "notify_email_lock_expiry" = NULL,
153 "password_reset_secret" = NULL,
154 "password_reset_secret_expiry" = NULL,
155 "organizational_unit" = NULL,
156 "internal_posts" = NULL,
157 "realname" = NULL,
158 "birthday" = NULL,
159 "address" = NULL,
160 "email" = NULL,
161 "xmpp_address" = NULL,
162 "website" = NULL,
163 "phone" = NULL,
164 "mobile_phone" = NULL,
165 "profession" = NULL,
166 "external_memberships" = NULL,
167 "external_posts" = NULL,
168 "statement" = NULL
169 WHERE "id" = "member_id_p";
170 -- "text_search_data" is updated by triggers
171 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
172 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
173 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
174 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
175 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
176 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
177 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
178 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
179 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
180 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
181 DELETE FROM "ignored_issue" WHERE "member_id" = "member_id_p";
182 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
183 DELETE FROM "direct_voter" USING "issue"
184 WHERE "direct_voter"."issue_id" = "issue"."id"
185 AND "issue"."closed" ISNULL
186 AND "member_id" = "member_id_p";
187 RETURN;
188 END;
189 $$;
191 COMMIT;

Impressum / About Us