liquid_feedback_core

view update/core-update.v1.3.0-v1.3.1.sql @ 103:bc8aa59b0945

Introduced "last_login_public" field, which is only updated after each day and does only contain date but not time for privacy reasons
(required changes in lf_update)
author jbe
date Sat Jan 22 20:09:18 2011 +0100 (2011-01-22)
parents 2daa8ce3d743
children 0d03c57ebae5
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 ALTER TABLE "member" ADD COLUMN "last_login_public" DATE;
8 ALTER TABLE "member" ADD COLUMN "locked" BOOLEAN NOT NULL DEFAULT FALSE;
10 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
11 COMMENT ON COLUMN "member"."last_login_public" IS 'Date of last login (time stripped for privacy reasons, updated only after day change)';
12 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
13 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.';
15 CREATE FUNCTION "publish_last_login"()
16 RETURNS VOID
17 LANGUAGE 'plpgsql' VOLATILE AS $$
18 BEGIN
19 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
20 UPDATE "member" SET "last_login_public" = "last_login"::date
21 WHERE "last_login"::date < 'today';
22 RETURN;
23 END;
24 $$;
26 COMMENT ON FUNCTION "publish_last_login"() IS 'Updates "last_login_public" field, which contains the date but not the time of the last login. For privacy reasons this function does not update "last_login_public", if the last login of a member has been today.';
28 CREATE OR REPLACE FUNCTION "create_interest_snapshot"
29 ( "issue_id_p" "issue"."id"%TYPE )
30 RETURNS VOID
31 LANGUAGE 'plpgsql' VOLATILE AS $$
32 DECLARE
33 "member_id_v" "member"."id"%TYPE;
34 BEGIN
35 DELETE FROM "direct_interest_snapshot"
36 WHERE "issue_id" = "issue_id_p"
37 AND "event" = 'periodic';
38 DELETE FROM "delegating_interest_snapshot"
39 WHERE "issue_id" = "issue_id_p"
40 AND "event" = 'periodic';
41 DELETE FROM "direct_supporter_snapshot"
42 WHERE "issue_id" = "issue_id_p"
43 AND "event" = 'periodic';
44 INSERT INTO "direct_interest_snapshot"
45 ("issue_id", "event", "member_id", "voting_requested")
46 SELECT
47 "issue_id_p" AS "issue_id",
48 'periodic' AS "event",
49 "member"."id" AS "member_id",
50 "interest"."voting_requested"
51 FROM "interest" JOIN "member"
52 ON "interest"."member_id" = "member"."id"
53 WHERE "interest"."issue_id" = "issue_id_p"
54 AND "member"."active";
55 FOR "member_id_v" IN
56 SELECT "member_id" FROM "direct_interest_snapshot"
57 WHERE "issue_id" = "issue_id_p"
58 AND "event" = 'periodic'
59 LOOP
60 UPDATE "direct_interest_snapshot" SET
61 "weight" = 1 +
62 "weight_of_added_delegations_for_interest_snapshot"(
63 "issue_id_p",
64 "member_id_v",
65 '{}'
66 )
67 WHERE "issue_id" = "issue_id_p"
68 AND "event" = 'periodic'
69 AND "member_id" = "member_id_v";
70 END LOOP;
71 INSERT INTO "direct_supporter_snapshot"
72 ( "issue_id", "initiative_id", "event", "member_id",
73 "informed", "satisfied" )
74 SELECT
75 "issue_id_p" AS "issue_id",
76 "initiative"."id" AS "initiative_id",
77 'periodic' AS "event",
78 "supporter"."member_id" AS "member_id",
79 "supporter"."draft_id" = "current_draft"."id" AS "informed",
80 NOT EXISTS (
81 SELECT NULL FROM "critical_opinion"
82 WHERE "initiative_id" = "initiative"."id"
83 AND "member_id" = "supporter"."member_id"
84 ) AS "satisfied"
85 FROM "initiative"
86 JOIN "supporter"
87 ON "supporter"."initiative_id" = "initiative"."id"
88 JOIN "current_draft"
89 ON "initiative"."id" = "current_draft"."initiative_id"
90 JOIN "direct_interest_snapshot"
91 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
92 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
93 AND "event" = 'periodic'
94 WHERE "initiative"."issue_id" = "issue_id_p";
95 RETURN;
96 END;
97 $$;
99 CREATE OR REPLACE FUNCTION "check_everything"()
100 RETURNS VOID
101 LANGUAGE 'plpgsql' VOLATILE AS $$
102 DECLARE
103 "issue_id_v" "issue"."id"%TYPE;
104 BEGIN
105 DELETE FROM "expired_session";
106 PERFORM "publish_last_login"();
107 PERFORM "calculate_member_counts"();
108 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
109 PERFORM "check_issue"("issue_id_v");
110 END LOOP;
111 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
112 PERFORM "calculate_ranks"("issue_id_v");
113 END LOOP;
114 RETURN;
115 END;
116 $$;
118 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.';
120 CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
121 RETURNS VOID
122 LANGUAGE 'plpgsql' VOLATILE AS $$
123 BEGIN
124 UPDATE "member" SET
125 "last_login" = NULL,
126 "last_login_public" = NULL,
127 "login" = NULL,
128 "password" = NULL,
129 "locked" = TRUE,
130 "active" = FALSE,
131 "notify_email" = NULL,
132 "notify_email_unconfirmed" = NULL,
133 "notify_email_secret" = NULL,
134 "notify_email_secret_expiry" = NULL,
135 "notify_email_lock_expiry" = NULL,
136 "password_reset_secret" = NULL,
137 "password_reset_secret_expiry" = NULL,
138 "organizational_unit" = NULL,
139 "internal_posts" = NULL,
140 "realname" = NULL,
141 "birthday" = NULL,
142 "address" = NULL,
143 "email" = NULL,
144 "xmpp_address" = NULL,
145 "website" = NULL,
146 "phone" = NULL,
147 "mobile_phone" = NULL,
148 "profession" = NULL,
149 "external_memberships" = NULL,
150 "external_posts" = NULL,
151 "statement" = NULL
152 WHERE "id" = "member_id_p";
153 -- "text_search_data" is updated by triggers
154 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
155 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
156 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
157 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
158 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
159 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
160 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
161 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
162 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
163 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
164 DELETE FROM "ignored_issue" WHERE "member_id" = "member_id_p";
165 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
166 DELETE FROM "direct_voter" USING "issue"
167 WHERE "direct_voter"."issue_id" = "issue"."id"
168 AND "issue"."closed" ISNULL
169 AND "member_id" = "member_id_p";
170 RETURN;
171 END;
172 $$;
174 COMMIT;

Impressum / About Us