liquid_feedback_core

view update/core-update.v3.1.0-v3.2.0.sql @ 479:8ded0e66a542

Repaired preliminary update script
author jbe
date Fri Apr 01 16:42:04 2016 +0200 (2016-04-01)
parents 2f79434d0226
children bae6d7c89f97
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"."harmonic_weight", -"better_initiative"."id") >
50 ("initiative"."harmonic_weight", -"better_initiative"."id")
51 ) AS "leading",
52 "initiative".*
53 FROM "member" CROSS JOIN "initiative"
54 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
55 JOIN "supporter" ON
56 "supporter"."member_id" = "member"."id" AND
57 "supporter"."initiative_id" = "initiative"."id"
58 WHERE "issue"."state" IN ('admission', 'discussion') ISNULL
59 AND (
60 EXISTS (
61 SELECT NULL FROM "draft"
62 WHERE "draft"."initiative_id" = "initiative"."id"
63 AND "draft"."id" > "supporter"."draft_id"
64 ) OR EXISTS (
65 SELECT NULL FROM "suggestion"
66 WHERE "suggestion"."initiative_id" = "initiative"."id"
67 AND COALESCE(
68 "suggestion"."id" > "member"."last_notified_suggestion_id",
69 TRUE
70 )
71 )
72 );
74 CREATE FUNCTION "featured_initiative"
75 ( "member_id_p" "member"."id"%TYPE,
76 "area_id_p" "area"."id"%TYPE )
77 RETURNS SETOF "initiative"
78 LANGUAGE 'plpgsql' STABLE AS $$
79 DECLARE
80 "sample_size_v" INT4;
81 "member_id_v" "member"."id"%TYPE;
82 "seed_v" TEXT;
83 "result_row" "initiative"%ROWTYPE;
84 "match_v" BOOLEAN;
85 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
86 BEGIN
87 SELECT INTO "sample_size_v" "sample_size" FROM "member" WHERE "id" = "member_id_p";
88 "initiative_id_ary" := '{}';
89 LOOP
90 "match_v" := FALSE;
91 FOR "member_id_v", "seed_v" IN
92 SELECT * FROM (
93 SELECT DISTINCT
94 "supporter"."member_id",
95 md5("member_id" || '-' || "member"."notification_counter" || '-' || "area_id_p") AS "seed"
96 FROM "supporter"
97 JOIN "member" ON "member"."id" = "supporter"."member_id"
98 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
99 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
100 WHERE "supporter"."member_id" != "member_id_p"
101 AND "issue"."area_id" = "area_id_p"
102 AND "issue"."state" IN ('admission', 'discussion', 'verification')
103 ) AS "subquery"
104 ORDER BY "seed"
105 LOOP
106 SELECT "initiative".* INTO "result_row"
107 FROM "initiative"
108 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
109 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
110 LEFT JOIN "supporter" AS "self_support" ON
111 "self_support"."initiative_id" = "initiative"."id" AND
112 "self_support"."member_id" = "member_id_p"
113 WHERE "supporter"."member_id" = "member_id_v"
114 AND "issue"."area_id" = "area_id_p"
115 AND "issue"."state" IN ('admission', 'discussion', 'verification')
116 AND "self_support"."member_id" ISNULL
117 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
118 ORDER BY md5("seed_v" || '-' || "initiative"."id")
119 LIMIT 1;
120 IF FOUND THEN
121 "match_v" := TRUE;
122 "initiative_id_ary" := "initiative_id_ary" || "result_row"."id";
123 RETURN NEXT "result_row";
124 IF array_length("initiative_id_ary", 1) >= "sample_size_v" THEN
125 RETURN;
126 END IF;
127 END IF;
128 END LOOP;
129 EXIT WHEN NOT "match_v";
130 END LOOP;
131 RETURN;
132 END;
133 $$;
135 CREATE VIEW "updated_or_featured_initiative" AS
136 SELECT * FROM "updated_initiative"
137 UNION ALL
138 SELECT
139 "member"."id" AS "seen_by_member_id",
140 FALSE AS "supported",
141 NULL::BOOLEAN AS "new_draft",
142 NULL::INTEGER AS "new_suggestion_count",
143 TRUE AS "featured",
144 NOT EXISTS (
145 SELECT NULL FROM "initiative" AS "better_initiative"
146 WHERE
147 ("better_initiative"."harmonic_weight", -"better_initiative"."id") >
148 ("initiative"."harmonic_weight", -"better_initiative"."id")
149 ) AS "leading",
150 "initiative".*
151 FROM "member" CROSS JOIN "area"
152 CROSS JOIN LATERAL
153 "featured_initiative"("member"."id", "area"."id") AS "initiative";
155 CREATE VIEW "leading_complement_initiative" AS
156 SELECT * FROM (
157 SELECT DISTINCT ON ("seen_by_member_id", "initiative"."issue_id")
158 "updated_or_featured_initiative"."seen_by_member_id",
159 FALSE AS "supported",
160 NULL::BOOLEAN AS "new_draft",
161 NULL::INTEGER AS "new_suggestion_count",
162 FALSE AS "featured",
163 TRUE AS "leading",
164 "initiative".*
165 FROM "updated_or_featured_initiative"
166 JOIN "initiative"
167 ON "updated_or_featured_initiative"."issue_id" = "initiative"."issue_id"
168 ORDER BY
169 "seen_by_member_id",
170 "initiative"."issue_id",
171 "initiative"."harmonic_weight" DESC,
172 "initiative"."id"
173 ) AS "subquery"
174 WHERE NOT EXISTS (
175 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
176 WHERE "other"."seen_by_member_id" = "subquery"."seen_by_member_id"
177 AND "other"."id" = "subquery"."id"
178 );
180 CREATE VIEW "initiative_for_notification" AS
181 SELECT * FROM "updated_or_featured_initiative"
182 UNION ALL
183 SELECT * FROM "leading_complement_initiative";
185 COMMIT;

Impressum / About Us