liquid_feedback_core

annotate update/core-update.v3.1.0-v3.2.0.sql @ 485:e431f1b73c35

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

Impressum / About Us