| rev |
line source |
|
jbe@315
|
1 BEGIN;
|
|
jbe@315
|
2
|
|
jbe@315
|
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
|
|
jbe@315
|
4 SELECT * FROM (VALUES ('2.1.1', 2, 1, 1))
|
|
jbe@315
|
5 AS "subquery"("string", "major", "minor", "revision");
|
|
jbe@315
|
6
|
|
jbe@315
|
7 ALTER TABLE "initiative" ADD COLUMN "harmonic_weight" NUMERIC(12, 3);
|
|
jbe@315
|
8 COMMENT ON COLUMN "initiative"."harmonic_weight" IS 'Indicates the relevancy of the initiative, calculated from the potential supporters weighted with the harmonic series to avoid a large number of clones affecting other initiative''s sorting positions too much';
|
|
jbe@315
|
9
|
|
jbe@315
|
10 ALTER TABLE "suggestion" ADD COLUMN "harmonic_weight" NUMERIC(12, 3);
|
|
jbe@315
|
11 COMMENT ON COLUMN "suggestion"."harmonic_weight" IS 'Indicates the relevancy of the suggestion, calculated from the supporters (positive "degree") of the suggestion weighted with the harmonic series to avoid a large number of clones affecting other suggestion''s sortings position too much';
|
|
jbe@315
|
12
|
|
jbe@315
|
13 CREATE VIEW "remaining_harmonic_supporter_weight" AS
|
|
jbe@315
|
14 SELECT
|
|
jbe@315
|
15 "direct_interest_snapshot"."issue_id",
|
|
jbe@315
|
16 "direct_interest_snapshot"."event",
|
|
jbe@315
|
17 "direct_interest_snapshot"."member_id",
|
|
jbe@315
|
18 "direct_interest_snapshot"."weight" AS "weight_num",
|
|
jbe@315
|
19 count("initiative"."id") AS "weight_den"
|
|
jbe@315
|
20 FROM "issue"
|
|
jbe@315
|
21 JOIN "direct_interest_snapshot"
|
|
jbe@315
|
22 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
|
|
jbe@315
|
23 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
|
|
jbe@315
|
24 JOIN "direct_supporter_snapshot"
|
|
jbe@315
|
25 ON "direct_interest_snapshot"."issue_id" = "direct_supporter_snapshot"."issue_id"
|
|
jbe@315
|
26 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
|
|
jbe@315
|
27 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
|
|
jbe@315
|
28 JOIN "initiative"
|
|
jbe@315
|
29 ON "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
|
|
jbe@315
|
30 AND "initiative"."harmonic_weight" ISNULL
|
|
jbe@315
|
31 GROUP BY
|
|
jbe@315
|
32 "direct_interest_snapshot"."issue_id",
|
|
jbe@315
|
33 "direct_interest_snapshot"."event",
|
|
jbe@315
|
34 "direct_interest_snapshot"."member_id",
|
|
jbe@315
|
35 "direct_interest_snapshot"."weight";
|
|
jbe@315
|
36
|
|
jbe@315
|
37 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
|
|
jbe@315
|
38
|
|
jbe@315
|
39 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
|
|
jbe@315
|
40 SELECT
|
|
jbe@315
|
41 "initiative"."issue_id",
|
|
jbe@315
|
42 "initiative"."id" AS "initiative_id",
|
|
jbe@315
|
43 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
|
|
jbe@315
|
44 "remaining_harmonic_supporter_weight"."weight_den"
|
|
jbe@315
|
45 FROM "remaining_harmonic_supporter_weight"
|
|
jbe@315
|
46 JOIN "direct_supporter_snapshot"
|
|
jbe@315
|
47 ON "remaining_harmonic_supporter_weight"."issue_id" = "direct_supporter_snapshot"."issue_id"
|
|
jbe@315
|
48 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
|
|
jbe@315
|
49 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
|
|
jbe@315
|
50 JOIN "initiative"
|
|
jbe@315
|
51 ON "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
|
|
jbe@315
|
52 AND "initiative"."harmonic_weight" ISNULL
|
|
jbe@315
|
53 GROUP BY
|
|
jbe@315
|
54 "initiative"."issue_id",
|
|
jbe@315
|
55 "initiative"."id",
|
|
jbe@315
|
56 "remaining_harmonic_supporter_weight"."weight_den";
|
|
jbe@315
|
57
|
|
jbe@315
|
58 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
|
|
jbe@315
|
59
|
|
jbe@315
|
60 CREATE FUNCTION "set_harmonic_initiative_weights"
|
|
jbe@315
|
61 ( "issue_id_p" "issue"."id"%TYPE )
|
|
jbe@315
|
62 RETURNS VOID
|
|
jbe@315
|
63 LANGUAGE 'plpgsql' VOLATILE AS $$
|
|
jbe@315
|
64 DECLARE
|
|
jbe@315
|
65 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
|
|
jbe@315
|
66 "i" INT4;
|
|
jbe@315
|
67 "count_v" INT4;
|
|
jbe@315
|
68 "summand_v" FLOAT;
|
|
jbe@315
|
69 "id_ary" INT4[];
|
|
jbe@315
|
70 "weight_ary" FLOAT[];
|
|
jbe@315
|
71 "min_weight_v" FLOAT;
|
|
jbe@315
|
72 BEGIN
|
|
jbe@315
|
73 UPDATE "initiative" SET "harmonic_weight" = NULL
|
|
jbe@315
|
74 WHERE "issue_id" = "issue_id_p";
|
|
jbe@315
|
75 LOOP
|
|
jbe@315
|
76 "min_weight_v" := NULL;
|
|
jbe@315
|
77 "i" := 0;
|
|
jbe@315
|
78 "count_v" := 0;
|
|
jbe@315
|
79 FOR "weight_row" IN
|
|
jbe@315
|
80 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
|
|
jbe@315
|
81 WHERE "issue_id" = "issue_id_p"
|
|
jbe@315
|
82 ORDER BY "initiative_id" DESC, "weight_den" DESC
|
|
jbe@315
|
83 -- NOTE: latest initiatives treated worse
|
|
jbe@315
|
84 LOOP
|
|
jbe@315
|
85 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
|
|
jbe@315
|
86 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
|
|
jbe@315
|
87 "i" := "i" + 1;
|
|
jbe@315
|
88 "count_v" := "i";
|
|
jbe@315
|
89 "id_ary"["i"] := "weight_row"."initiative_id";
|
|
jbe@315
|
90 "weight_ary"["i"] := "summand_v";
|
|
jbe@315
|
91 ELSE
|
|
jbe@315
|
92 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
|
|
jbe@315
|
93 END IF;
|
|
jbe@315
|
94 END LOOP;
|
|
jbe@315
|
95 EXIT WHEN "count_v" = 0;
|
|
jbe@315
|
96 "i" := 1;
|
|
jbe@315
|
97 LOOP
|
|
jbe@315
|
98 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
|
|
jbe@315
|
99 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
|
|
jbe@315
|
100 "min_weight_v" := "weight_ary"["i"];
|
|
jbe@315
|
101 END IF;
|
|
jbe@315
|
102 "i" := "i" + 1;
|
|
jbe@315
|
103 EXIT WHEN "i" > "count_v";
|
|
jbe@315
|
104 END LOOP;
|
|
jbe@315
|
105 "i" := 1;
|
|
jbe@315
|
106 LOOP
|
|
jbe@315
|
107 IF "weight_ary"["i"] = "min_weight_v" THEN
|
|
jbe@315
|
108 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
|
|
jbe@315
|
109 WHERE "id" = "id_ary"["i"];
|
|
jbe@315
|
110 EXIT;
|
|
jbe@315
|
111 END IF;
|
|
jbe@315
|
112 "i" := "i" + 1;
|
|
jbe@315
|
113 END LOOP;
|
|
jbe@315
|
114 END LOOP;
|
|
jbe@316
|
115 UPDATE "initiative" SET "harmonic_weight" = 0
|
|
jbe@316
|
116 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
|
|
jbe@315
|
117 END;
|
|
jbe@315
|
118 $$;
|
|
jbe@315
|
119
|
|
jbe@315
|
120 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
|
|
jbe@315
|
121 ( "issue"."id"%TYPE )
|
|
jbe@315
|
122 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
|
|
jbe@315
|
123
|
|
jbe@315
|
124 CREATE VIEW "remaining_harmonic_opinion_weight" AS
|
|
jbe@315
|
125 SELECT
|
|
jbe@315
|
126 "initiative"."issue_id",
|
|
jbe@315
|
127 "opinion"."initiative_id",
|
|
jbe@315
|
128 "direct_interest_snapshot"."member_id",
|
|
jbe@315
|
129 "direct_interest_snapshot"."weight" AS "weight_num",
|
|
jbe@315
|
130 count("opinion"."suggestion_id") AS "weight_den"
|
|
jbe@315
|
131 FROM "issue"
|
|
jbe@315
|
132 JOIN "direct_interest_snapshot"
|
|
jbe@315
|
133 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
|
|
jbe@315
|
134 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
|
|
jbe@315
|
135 JOIN "initiative"
|
|
jbe@315
|
136 ON "direct_interest_snapshot"."issue_id" = "initiative"."issue_id"
|
|
jbe@315
|
137 JOIN "opinion"
|
|
jbe@315
|
138 ON "direct_interest_snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
139 AND "initiative"."id" = "opinion"."initiative_id"
|
|
jbe@317
|
140 AND (
|
|
jbe@317
|
141 ("opinion"."degree" > 0 AND "opinion"."fulfilled" = FALSE) OR
|
|
jbe@317
|
142 ("opinion"."degree" < 0 AND "opinion"."fulfilled" = TRUE)
|
|
jbe@317
|
143 )
|
|
jbe@318
|
144 JOIN "suggestion"
|
|
jbe@318
|
145 ON "opinion"."suggestion_id" = "suggestion"."id"
|
|
jbe@318
|
146 AND "suggestion"."harmonic_weight" ISNULL
|
|
jbe@315
|
147 GROUP BY
|
|
jbe@315
|
148 "initiative"."issue_id",
|
|
jbe@315
|
149 "opinion"."initiative_id",
|
|
jbe@315
|
150 "direct_interest_snapshot"."member_id",
|
|
jbe@315
|
151 "direct_interest_snapshot"."weight";
|
|
jbe@315
|
152
|
|
jbe@315
|
153 COMMENT ON VIEW "remaining_harmonic_opinion_weight" IS 'Helper view for function "set_harmonic_suggestion_weights"';
|
|
jbe@315
|
154
|
|
jbe@315
|
155 CREATE VIEW "remaining_harmonic_suggestion_weight_summands" AS
|
|
jbe@315
|
156 SELECT
|
|
jbe@315
|
157 "suggestion"."initiative_id",
|
|
jbe@315
|
158 "opinion"."suggestion_id",
|
|
jbe@315
|
159 sum("remaining_harmonic_opinion_weight"."weight_num") AS "weight_num",
|
|
jbe@315
|
160 "remaining_harmonic_opinion_weight"."weight_den"
|
|
jbe@315
|
161 FROM "remaining_harmonic_opinion_weight"
|
|
jbe@315
|
162 JOIN "opinion"
|
|
jbe@315
|
163 ON "remaining_harmonic_opinion_weight"."initiative_id" = "opinion"."initiative_id"
|
|
jbe@315
|
164 AND "remaining_harmonic_opinion_weight"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
165 JOIN "suggestion"
|
|
jbe@315
|
166 ON "opinion"."suggestion_id" = "suggestion"."id"
|
|
jbe@315
|
167 AND "suggestion"."harmonic_weight" ISNULL
|
|
jbe@315
|
168 GROUP BY
|
|
jbe@315
|
169 "suggestion"."initiative_id",
|
|
jbe@315
|
170 "opinion"."suggestion_id",
|
|
jbe@315
|
171 "remaining_harmonic_opinion_weight"."weight_den";
|
|
jbe@315
|
172
|
|
jbe@315
|
173 COMMENT ON VIEW "remaining_harmonic_suggestion_weight_summands" IS 'Helper view for function "set_harmonic_suggestion_weights"';
|
|
jbe@315
|
174
|
|
jbe@315
|
175 CREATE FUNCTION "set_harmonic_suggestion_weights"
|
|
jbe@315
|
176 ( "initiative_id_p" "initiative"."id"%TYPE )
|
|
jbe@315
|
177 RETURNS VOID
|
|
jbe@315
|
178 LANGUAGE 'plpgsql' VOLATILE AS $$
|
|
jbe@315
|
179 DECLARE
|
|
jbe@315
|
180 "weight_row" "remaining_harmonic_suggestion_weight_summands"%ROWTYPE;
|
|
jbe@315
|
181 "i" INT4;
|
|
jbe@315
|
182 "count_v" INT4;
|
|
jbe@315
|
183 "summand_v" FLOAT;
|
|
jbe@315
|
184 "id_ary" INT4[];
|
|
jbe@315
|
185 "weight_ary" FLOAT[];
|
|
jbe@315
|
186 "min_weight_v" FLOAT;
|
|
jbe@315
|
187 BEGIN
|
|
jbe@315
|
188 UPDATE "suggestion" SET "harmonic_weight" = NULL
|
|
jbe@315
|
189 WHERE "initiative_id" = "initiative_id_p";
|
|
jbe@315
|
190 LOOP
|
|
jbe@315
|
191 "min_weight_v" := NULL;
|
|
jbe@315
|
192 "i" := 0;
|
|
jbe@315
|
193 "count_v" := 0;
|
|
jbe@315
|
194 FOR "weight_row" IN
|
|
jbe@315
|
195 SELECT * FROM "remaining_harmonic_suggestion_weight_summands"
|
|
jbe@315
|
196 WHERE "initiative_id" = "initiative_id_p"
|
|
jbe@315
|
197 ORDER BY "suggestion_id" DESC, "weight_den" DESC
|
|
jbe@315
|
198 -- NOTE: latest suggestions treated worse
|
|
jbe@315
|
199 LOOP
|
|
jbe@315
|
200 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
|
|
jbe@315
|
201 IF "i" = 0 OR "weight_row"."suggestion_id" != "id_ary"["i"] THEN
|
|
jbe@315
|
202 "i" := "i" + 1;
|
|
jbe@315
|
203 "count_v" := "i";
|
|
jbe@315
|
204 "id_ary"["i"] := "weight_row"."suggestion_id";
|
|
jbe@315
|
205 "weight_ary"["i"] := "summand_v";
|
|
jbe@315
|
206 ELSE
|
|
jbe@315
|
207 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
|
|
jbe@315
|
208 END IF;
|
|
jbe@315
|
209 END LOOP;
|
|
jbe@315
|
210 EXIT WHEN "count_v" = 0;
|
|
jbe@315
|
211 "i" := 1;
|
|
jbe@315
|
212 LOOP
|
|
jbe@315
|
213 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
|
|
jbe@315
|
214 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
|
|
jbe@315
|
215 "min_weight_v" := "weight_ary"["i"];
|
|
jbe@315
|
216 END IF;
|
|
jbe@315
|
217 "i" := "i" + 1;
|
|
jbe@315
|
218 EXIT WHEN "i" > "count_v";
|
|
jbe@315
|
219 END LOOP;
|
|
jbe@315
|
220 "i" := 1;
|
|
jbe@315
|
221 LOOP
|
|
jbe@315
|
222 IF "weight_ary"["i"] = "min_weight_v" THEN
|
|
jbe@315
|
223 UPDATE "suggestion" SET "harmonic_weight" = "min_weight_v"
|
|
jbe@315
|
224 WHERE "id" = "id_ary"["i"];
|
|
jbe@315
|
225 EXIT;
|
|
jbe@315
|
226 END IF;
|
|
jbe@315
|
227 "i" := "i" + 1;
|
|
jbe@315
|
228 END LOOP;
|
|
jbe@315
|
229 END LOOP;
|
|
jbe@316
|
230 UPDATE "suggestion" SET "harmonic_weight" = 0
|
|
jbe@316
|
231 WHERE "initiative_id" = "initiative_id_p" AND "harmonic_weight" ISNULL;
|
|
jbe@315
|
232 END;
|
|
jbe@315
|
233 $$;
|
|
jbe@315
|
234
|
|
jbe@315
|
235 COMMENT ON FUNCTION "set_harmonic_suggestion_weights"
|
|
jbe@315
|
236 ( "issue"."id"%TYPE )
|
|
jbe@315
|
237 IS 'Calculates and sets "harmonic_weight" of suggestions in a given initiative';
|
|
jbe@315
|
238
|
|
jbe@315
|
239 CREATE OR REPLACE FUNCTION "create_snapshot"
|
|
jbe@315
|
240 ( "issue_id_p" "issue"."id"%TYPE )
|
|
jbe@315
|
241 RETURNS VOID
|
|
jbe@315
|
242 LANGUAGE 'plpgsql' VOLATILE AS $$
|
|
jbe@315
|
243 DECLARE
|
|
jbe@315
|
244 "initiative_id_v" "initiative"."id"%TYPE;
|
|
jbe@315
|
245 "suggestion_id_v" "suggestion"."id"%TYPE;
|
|
jbe@315
|
246 BEGIN
|
|
jbe@315
|
247 PERFORM "lock_issue"("issue_id_p");
|
|
jbe@315
|
248 PERFORM "create_population_snapshot"("issue_id_p");
|
|
jbe@315
|
249 PERFORM "create_interest_snapshot"("issue_id_p");
|
|
jbe@315
|
250 UPDATE "issue" SET
|
|
jbe@315
|
251 "snapshot" = now(),
|
|
jbe@315
|
252 "latest_snapshot_event" = 'periodic',
|
|
jbe@315
|
253 "population" = (
|
|
jbe@315
|
254 SELECT coalesce(sum("weight"), 0)
|
|
jbe@315
|
255 FROM "direct_population_snapshot"
|
|
jbe@315
|
256 WHERE "issue_id" = "issue_id_p"
|
|
jbe@315
|
257 AND "event" = 'periodic'
|
|
jbe@315
|
258 )
|
|
jbe@315
|
259 WHERE "id" = "issue_id_p";
|
|
jbe@315
|
260 FOR "initiative_id_v" IN
|
|
jbe@315
|
261 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
|
|
jbe@315
|
262 LOOP
|
|
jbe@315
|
263 UPDATE "initiative" SET
|
|
jbe@315
|
264 "supporter_count" = (
|
|
jbe@315
|
265 SELECT coalesce(sum("di"."weight"), 0)
|
|
jbe@315
|
266 FROM "direct_interest_snapshot" AS "di"
|
|
jbe@315
|
267 JOIN "direct_supporter_snapshot" AS "ds"
|
|
jbe@315
|
268 ON "di"."member_id" = "ds"."member_id"
|
|
jbe@315
|
269 WHERE "di"."issue_id" = "issue_id_p"
|
|
jbe@315
|
270 AND "di"."event" = 'periodic'
|
|
jbe@315
|
271 AND "ds"."initiative_id" = "initiative_id_v"
|
|
jbe@315
|
272 AND "ds"."event" = 'periodic'
|
|
jbe@315
|
273 ),
|
|
jbe@315
|
274 "informed_supporter_count" = (
|
|
jbe@315
|
275 SELECT coalesce(sum("di"."weight"), 0)
|
|
jbe@315
|
276 FROM "direct_interest_snapshot" AS "di"
|
|
jbe@315
|
277 JOIN "direct_supporter_snapshot" AS "ds"
|
|
jbe@315
|
278 ON "di"."member_id" = "ds"."member_id"
|
|
jbe@315
|
279 WHERE "di"."issue_id" = "issue_id_p"
|
|
jbe@315
|
280 AND "di"."event" = 'periodic'
|
|
jbe@315
|
281 AND "ds"."initiative_id" = "initiative_id_v"
|
|
jbe@315
|
282 AND "ds"."event" = 'periodic'
|
|
jbe@315
|
283 AND "ds"."informed"
|
|
jbe@315
|
284 ),
|
|
jbe@315
|
285 "satisfied_supporter_count" = (
|
|
jbe@315
|
286 SELECT coalesce(sum("di"."weight"), 0)
|
|
jbe@315
|
287 FROM "direct_interest_snapshot" AS "di"
|
|
jbe@315
|
288 JOIN "direct_supporter_snapshot" AS "ds"
|
|
jbe@315
|
289 ON "di"."member_id" = "ds"."member_id"
|
|
jbe@315
|
290 WHERE "di"."issue_id" = "issue_id_p"
|
|
jbe@315
|
291 AND "di"."event" = 'periodic'
|
|
jbe@315
|
292 AND "ds"."initiative_id" = "initiative_id_v"
|
|
jbe@315
|
293 AND "ds"."event" = 'periodic'
|
|
jbe@315
|
294 AND "ds"."satisfied"
|
|
jbe@315
|
295 ),
|
|
jbe@315
|
296 "satisfied_informed_supporter_count" = (
|
|
jbe@315
|
297 SELECT coalesce(sum("di"."weight"), 0)
|
|
jbe@315
|
298 FROM "direct_interest_snapshot" AS "di"
|
|
jbe@315
|
299 JOIN "direct_supporter_snapshot" AS "ds"
|
|
jbe@315
|
300 ON "di"."member_id" = "ds"."member_id"
|
|
jbe@315
|
301 WHERE "di"."issue_id" = "issue_id_p"
|
|
jbe@315
|
302 AND "di"."event" = 'periodic'
|
|
jbe@315
|
303 AND "ds"."initiative_id" = "initiative_id_v"
|
|
jbe@315
|
304 AND "ds"."event" = 'periodic'
|
|
jbe@315
|
305 AND "ds"."informed"
|
|
jbe@315
|
306 AND "ds"."satisfied"
|
|
jbe@315
|
307 )
|
|
jbe@315
|
308 WHERE "id" = "initiative_id_v";
|
|
jbe@315
|
309 FOR "suggestion_id_v" IN
|
|
jbe@315
|
310 SELECT "id" FROM "suggestion"
|
|
jbe@315
|
311 WHERE "initiative_id" = "initiative_id_v"
|
|
jbe@315
|
312 LOOP
|
|
jbe@315
|
313 UPDATE "suggestion" SET
|
|
jbe@315
|
314 "minus2_unfulfilled_count" = (
|
|
jbe@315
|
315 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
316 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
317 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
318 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
319 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
320 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
321 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
322 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
323 AND "opinion"."degree" = -2
|
|
jbe@315
|
324 AND "opinion"."fulfilled" = FALSE
|
|
jbe@315
|
325 ),
|
|
jbe@315
|
326 "minus2_fulfilled_count" = (
|
|
jbe@315
|
327 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
328 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
329 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
330 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
331 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
332 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
333 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
334 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
335 AND "opinion"."degree" = -2
|
|
jbe@315
|
336 AND "opinion"."fulfilled" = TRUE
|
|
jbe@315
|
337 ),
|
|
jbe@315
|
338 "minus1_unfulfilled_count" = (
|
|
jbe@315
|
339 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
340 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
341 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
342 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
343 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
344 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
345 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
346 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
347 AND "opinion"."degree" = -1
|
|
jbe@315
|
348 AND "opinion"."fulfilled" = FALSE
|
|
jbe@315
|
349 ),
|
|
jbe@315
|
350 "minus1_fulfilled_count" = (
|
|
jbe@315
|
351 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
352 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
353 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
354 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
355 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
356 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
357 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
358 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
359 AND "opinion"."degree" = -1
|
|
jbe@315
|
360 AND "opinion"."fulfilled" = TRUE
|
|
jbe@315
|
361 ),
|
|
jbe@315
|
362 "plus1_unfulfilled_count" = (
|
|
jbe@315
|
363 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
364 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
365 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
366 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
367 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
368 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
369 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
370 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
371 AND "opinion"."degree" = 1
|
|
jbe@315
|
372 AND "opinion"."fulfilled" = FALSE
|
|
jbe@315
|
373 ),
|
|
jbe@315
|
374 "plus1_fulfilled_count" = (
|
|
jbe@315
|
375 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
376 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
377 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
378 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
379 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
380 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
381 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
382 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
383 AND "opinion"."degree" = 1
|
|
jbe@315
|
384 AND "opinion"."fulfilled" = TRUE
|
|
jbe@315
|
385 ),
|
|
jbe@315
|
386 "plus2_unfulfilled_count" = (
|
|
jbe@315
|
387 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
388 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
389 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
390 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
391 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
392 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
393 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
394 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
395 AND "opinion"."degree" = 2
|
|
jbe@315
|
396 AND "opinion"."fulfilled" = FALSE
|
|
jbe@315
|
397 ),
|
|
jbe@315
|
398 "plus2_fulfilled_count" = (
|
|
jbe@315
|
399 SELECT coalesce(sum("snapshot"."weight"), 0)
|
|
jbe@315
|
400 FROM "issue" CROSS JOIN "opinion"
|
|
jbe@315
|
401 JOIN "direct_interest_snapshot" AS "snapshot"
|
|
jbe@315
|
402 ON "snapshot"."issue_id" = "issue"."id"
|
|
jbe@315
|
403 AND "snapshot"."event" = "issue"."latest_snapshot_event"
|
|
jbe@315
|
404 AND "snapshot"."member_id" = "opinion"."member_id"
|
|
jbe@315
|
405 WHERE "issue"."id" = "issue_id_p"
|
|
jbe@315
|
406 AND "opinion"."suggestion_id" = "suggestion_id_v"
|
|
jbe@315
|
407 AND "opinion"."degree" = 2
|
|
jbe@315
|
408 AND "opinion"."fulfilled" = TRUE
|
|
jbe@315
|
409 )
|
|
jbe@315
|
410 WHERE "suggestion"."id" = "suggestion_id_v";
|
|
jbe@315
|
411 END LOOP;
|
|
jbe@315
|
412 PERFORM "set_harmonic_suggestion_weights"("initiative_id_v");
|
|
jbe@315
|
413 END LOOP;
|
|
jbe@315
|
414 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
|
|
jbe@315
|
415 RETURN;
|
|
jbe@315
|
416 END;
|
|
jbe@315
|
417 $$;
|
|
jbe@315
|
418
|
|
jbe@315
|
419 SELECT "set_harmonic_initiative_weights"("id") FROM "issue";
|
|
jbe@315
|
420 SELECT "set_harmonic_suggestion_weights"("id") FROM "initiative";
|
|
jbe@315
|
421
|
|
jbe@315
|
422 COMMIT;
|