liquid_feedback_core

view update/core-update.v4.0.0-v4.0.1.sql @ 582:225a0c047691

Bugfix in function "write_event_initiative_revoked_trigger" (wrong use of SELECT, needs to be PERFORM)
author jbe
date Tue Sep 04 14:30:41 2018 +0200 (2018-09-04)
parents 1cb6710fc429
children f5095a9696eb
line source
1 BEGIN;
3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
4 SELECT * FROM (VALUES ('4.0.1-dev', 4, 0, -1))
5 AS "subquery"("string", "major", "minor", "revision");
7 ALTER TABLE "member" ADD COLUMN "role" BOOLEAN NOT NULL DEFAULT FALSE;
9 CREATE TABLE "agent" (
10 PRIMARY KEY ("controlled_id", "controller_id"),
11 "controlled_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
12 "controller_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
13 "accepted" BOOLEAN,
14 CONSTRAINT "controlled_id_and_controller_id_differ" CHECK (
15 "controlled_id" != "controller_id" ) );
16 CREATE INDEX "agent_controller_id_idx" ON "agent" ("controller_id");
18 COMMENT ON TABLE "agent" IS 'Privileges for role accounts';
20 COMMENT ON COLUMN "agent"."accepted" IS 'If "accepted" is NULL, then the member was invited to be an agent, but has not reacted yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.';
22 ALTER TABLE "session" ADD COLUMN "real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
24 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in, or role account in use';
25 COMMENT ON COLUMN "session"."real_member_id" IS 'Reference to member, who is really logged in (real person rather than role account)';
27 CREATE TABLE "role_verification" (
28 "id" SERIAL8 PRIMARY KEY,
29 "requested" TIMESTAMPTZ,
30 "request_origin" JSONB,
31 "request_data" JSONB,
32 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
33 "requesting_real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
34 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
35 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
36 "verified" TIMESTAMPTZ,
37 "verification_data" JSONB,
38 "denied" TIMESTAMPTZ,
39 "comment" TEXT,
40 CONSTRAINT "verified_and_denied_conflict" CHECK (
41 "verified" ISNULL OR "denied" ISNULL ) );
42 CREATE INDEX "role_verification_requested_idx" ON "role_verification" ("requested");
43 CREATE INDEX "role_verification_open_request_idx" ON "role_verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
44 CREATE INDEX "role_verification_requesting_member_id_idx" ON "role_verification" ("requesting_member_id");
45 CREATE INDEX "role_verification_verified_member_id_idx" ON "role_verification" ("verified_member_id");
46 CREATE INDEX "role_verification_verified_idx" ON "role_verification" ("verified");
47 CREATE INDEX "role_verification_denied_idx" ON "role_verification" ("denied");
49 COMMENT ON TABLE "role_verification" IS 'Request to verify a role account (see table "verification" for documentation of columns not documented for this table)';
51 COMMENT ON COLUMN "role_verification"."requesting_member_id" IS 'Member role account to verify';
52 COMMENT ON COLUMN "role_verification"."requesting_real_member_id" IS 'Member account of real person who requested verification';
54 ALTER TABLE "ignored_area" DROP CONSTRAINT "ignored_area_member_id_fkey";
55 ALTER TABLE "ignored_area" ADD FOREIGN KEY ("member_id") REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
57 CREATE OR REPLACE VIEW "expired_token" AS
58 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
59 "token_type" = 'authorization' AND "used" AND EXISTS (
60 SELECT NULL FROM "token" AS "other"
61 WHERE "other"."authorization_token_id" = "token"."id" ) );
63 ALTER TABLE "system_application" RENAME COLUMN "discovery_baseurl" TO "base_url";
64 ALTER TABLE "system_application" ADD COLUMN "manifest_url" TEXT;
66 COMMENT ON COLUMN "system_application"."base_url" IS 'Base URL for users';
67 COMMENT ON COLUMN "system_application"."manifest_url" IS 'URL referring to a manifest that can be used for application (type/version) discovery';
69 CREATE OR REPLACE FUNCTION "write_event_initiative_revoked_trigger"()
70 RETURNS TRIGGER
71 LANGUAGE 'plpgsql' VOLATILE AS $$
72 DECLARE
73 "issue_row" "issue"%ROWTYPE;
74 "area_row" "area"%ROWTYPE;
75 "draft_id_v" "draft"."id"%TYPE;
76 BEGIN
77 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
78 -- NOTE: lock for primary key update to avoid new drafts
79 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
80 SELECT * INTO "issue_row" FROM "issue"
81 WHERE "id" = NEW."issue_id" FOR SHARE;
82 SELECT * INTO "area_row" FROM "area"
83 WHERE "id" = "issue_row"."area_id" FOR SHARE;
84 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
85 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
86 SELECT "id" INTO "draft_id_v" FROM "current_draft"
87 WHERE "initiative_id" = NEW."id";
88 INSERT INTO "event" (
89 "event", "member_id",
90 "unit_id", "area_id", "policy_id", "issue_id", "state",
91 "initiative_id", "draft_id"
92 ) VALUES (
93 'initiative_revoked', NEW."revoked_by_member_id",
94 "area_row"."unit_id", "issue_row"."area_id",
95 "issue_row"."policy_id",
96 NEW."issue_id", "issue_row"."state",
97 NEW."id", "draft_id_v"
98 );
99 END IF;
100 RETURN NULL;
101 END;
102 $$;
104 COMMIT;

Impressum / About Us