liquid_feedback_core

view update/core-update.v3.1.0-v3.2.0.sql @ 482:75130c1d90da

Bugfix in function "featured_initiative"
author jbe
date Fri Apr 01 17:13:46 2016 +0200 (2016-04-01)
parents 698559ebe9cd
children 39f37c2a0c85
line source
1 BEGIN;
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
4 SELECT * FROM (VALUES ('3.2.0', 3, 2, 0))
5 AS "subquery"("string", "major", "minor", "revision");
7 ALTER TABLE "member" ADD COLUMN "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE;
8 ALTER TABLE "member" ADD COLUMN "notification_counter" INT4 NOT NULL DEFAULT 0;
9 ALTER TABLE "member" ADD COLUMN "sample_size" INT4 NOT NULL DEFAULT 3;
10 ALTER TABLE "member" ADD COLUMN "last_notified_suggestion_id" INT8;
12 UPDATE "member" SET "disable_notifications" = TRUE WHERE "notify_level" = 'none';
14 CREATE TABLE "subscription_time" (
15 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
16 "day_of_week" INT2 CONSTRAINT "day_of_week_range" CHECK ("day_of_week" BETWEEN 0 AND 6),
17 "time_of_day" TIME NOT NULL );
18 CREATE UNIQUE INDEX "subscription_time_all_days_of_week_time_of_day_idx" ON "subscription_time" ("time_of_day", "member_id") WHERE ("day_of_week" ISNULL);
19 CREATE UNIQUE INDEX "subscription_time_day_of_week_time_of_day_idx" ON "subscription_time" ("day_of_week", "time_of_day", "member_id");
21 CREATE TABLE "subscription" (
22 PRIMARY KEY ("member_id", "unit_id"),
23 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
24 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
25 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
27 DROP VIEW "selected_event_seen_by_member";
29 CREATE VIEW "updated_initiative" AS
30 SELECT
31 "member"."id" AS "seen_by_member_id",
32 TRUE AS "supported",
33 EXISTS (
34 SELECT NULL FROM "draft"
35 WHERE "draft"."initiative_id" = "initiative"."id"
36 AND "draft"."id" > "supporter"."draft_id"
37 ) AS "new_draft",
38 ( SELECT count(1) FROM "suggestion"
39 WHERE "suggestion"."initiative_id" = "initiative"."id"
40 AND COALESCE(
41 "suggestion"."id" > "member"."last_notified_suggestion_id",
42 TRUE
43 )
44 ) AS "new_suggestion_count",
45 FALSE AS "featured",
46 NOT EXISTS (
47 SELECT NULL FROM "initiative" AS "better_initiative"
48 WHERE
49 "better_initiative"."issue_id" = "initiative"."issue_id" AND
50 ("better_initiative"."harmonic_weight", -"better_initiative"."id") >
51 ("initiative"."harmonic_weight", -"better_initiative"."id")
52 ) AS "leading",
53 "initiative".*
54 FROM "member" CROSS JOIN "initiative"
55 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
56 JOIN "supporter" ON
57 "supporter"."member_id" = "member"."id" AND
58 "supporter"."initiative_id" = "initiative"."id"
59 WHERE "issue"."state" IN ('admission', 'discussion')
60 AND (
61 EXISTS (
62 SELECT NULL FROM "draft"
63 WHERE "draft"."initiative_id" = "initiative"."id"
64 AND "draft"."id" > "supporter"."draft_id"
65 ) OR EXISTS (
66 SELECT NULL FROM "suggestion"
67 WHERE "suggestion"."initiative_id" = "initiative"."id"
68 AND COALESCE(
69 "suggestion"."id" > "member"."last_notified_suggestion_id",
70 TRUE
71 )
72 )
73 );
75 CREATE FUNCTION "featured_initiative"
76 ( "member_id_p" "member"."id"%TYPE,
77 "area_id_p" "area"."id"%TYPE )
78 RETURNS SETOF "initiative"
79 LANGUAGE 'plpgsql' STABLE AS $$
80 DECLARE
81 "member_row" "member"%ROWTYPE;
82 "member_id_v" "member"."id"%TYPE;
83 "seed_v" TEXT;
84 "result_row" "initiative"%ROWTYPE;
85 "match_v" BOOLEAN;
86 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
87 BEGIN
88 SELECT INTO "member_row" * FROM "member" WHERE "id" = "member_id_p";
89 "initiative_id_ary" := '{}';
90 LOOP
91 "match_v" := FALSE;
92 FOR "member_id_v", "seed_v" IN
93 SELECT * FROM (
94 SELECT DISTINCT
95 "supporter"."member_id",
96 md5("member_id_p" || '-' || "member_row"."notification_counter" || '-' || "area_id_p" || '-' || "supporter"."member_id") AS "seed"
97 FROM "supporter"
98 JOIN "member" ON "member"."id" = "supporter"."member_id"
99 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
100 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
101 WHERE "supporter"."member_id" != "member_id_p"
102 AND "issue"."area_id" = "area_id_p"
103 AND "issue"."state" IN ('admission', 'discussion', 'verification')
104 ) AS "subquery"
105 ORDER BY "seed"
106 LOOP
107 SELECT "initiative".* INTO "result_row"
108 FROM "initiative"
109 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
110 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
111 LEFT JOIN "supporter" AS "self_support" ON
112 "self_support"."initiative_id" = "initiative"."id" AND
113 "self_support"."member_id" = "member_id_p"
114 WHERE "supporter"."member_id" = "member_id_v"
115 AND "issue"."area_id" = "area_id_p"
116 AND "issue"."state" IN ('admission', 'discussion', 'verification')
117 AND "self_support"."member_id" ISNULL
118 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
119 ORDER BY md5("seed_v" || '-' || "initiative"."id")
120 LIMIT 1;
121 IF FOUND THEN
122 "match_v" := TRUE;
123 "initiative_id_ary" := "initiative_id_ary" || "result_row"."id";
124 RETURN NEXT "result_row";
125 IF array_length("initiative_id_ary", 1) >= "member_row""member_row"."sample_size" THEN
126 RETURN;
127 END IF;
128 END IF;
129 END LOOP;
130 EXIT WHEN NOT "match_v";
131 END LOOP;
132 RETURN;
133 END;
134 $$;
136 CREATE VIEW "updated_or_featured_initiative" AS
137 SELECT * FROM "updated_initiative"
138 UNION ALL
139 SELECT
140 "member"."id" AS "seen_by_member_id",
141 FALSE AS "supported",
142 NULL::BOOLEAN AS "new_draft",
143 NULL::INTEGER AS "new_suggestion_count",
144 TRUE AS "featured",
145 NOT EXISTS (
146 SELECT NULL FROM "initiative" AS "better_initiative"
147 WHERE
148 "better_initiative"."issue_id" = "initiative"."issue_id" AND
149 ("better_initiative"."harmonic_weight", -"better_initiative"."id") >
150 ("initiative"."harmonic_weight", -"better_initiative"."id")
151 ) AS "leading",
152 "initiative".*
153 FROM "member" CROSS JOIN "area"
154 CROSS JOIN LATERAL
155 "featured_initiative"("member"."id", "area"."id") AS "initiative";
157 CREATE VIEW "leading_complement_initiative" AS
158 SELECT * FROM (
159 SELECT DISTINCT ON ("seen_by_member_id", "initiative"."issue_id")
160 "updated_or_featured_initiative"."seen_by_member_id",
161 FALSE AS "supported",
162 NULL::BOOLEAN AS "new_draft",
163 NULL::INTEGER AS "new_suggestion_count",
164 FALSE AS "featured",
165 TRUE AS "leading",
166 "initiative".*
167 FROM "updated_or_featured_initiative"
168 JOIN "initiative"
169 ON "updated_or_featured_initiative"."issue_id" = "initiative"."issue_id"
170 ORDER BY
171 "seen_by_member_id",
172 "initiative"."issue_id",
173 "initiative"."harmonic_weight" DESC,
174 "initiative"."id"
175 ) AS "subquery"
176 WHERE NOT EXISTS (
177 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
178 WHERE "other"."seen_by_member_id" = "subquery"."seen_by_member_id"
179 AND "other"."id" = "subquery"."id"
180 );
182 CREATE VIEW "initiative_for_notification" AS
183 SELECT * FROM "updated_or_featured_initiative"
184 UNION ALL
185 SELECT * FROM "leading_complement_initiative";
187 COMMIT;

Impressum / About Us