jbe@262: BEGIN; jbe@262: jbe@287: jbe@287: -- update version number jbe@287: jbe@262: CREATE OR REPLACE VIEW "liquid_feedback_version" AS jbe@262: SELECT * FROM (VALUES ('2.1.0', 2, 1, 0)) jbe@262: AS "subquery"("string", "major", "minor", "revision"); jbe@262: jbe@287: jbe@287: -- old API tables are now deprecated jbe@287: jbe@286: COMMENT ON TYPE "application_access_level" IS 'DEPRECATED, WILL BE REMOVED! Access privileges for applications using the API'; jbe@286: COMMENT ON TABLE "member_application" IS 'DEPRECATED, WILL BE REMOVED! Registered application being allowed to use the API'; jbe@286: jbe@287: jbe@287: -- new polling mode and changed privileges jbe@287: jbe@262: ALTER TABLE "policy" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE; jbe@262: ALTER TABLE "policy" ALTER COLUMN "admission_time" DROP NOT NULL; jbe@262: ALTER TABLE "policy" ALTER COLUMN "discussion_time" DROP NOT NULL; jbe@262: ALTER TABLE "policy" ALTER COLUMN "verification_time" DROP NOT NULL; jbe@262: ALTER TABLE "policy" ALTER COLUMN "voting_time" DROP NOT NULL; jbe@292: ALTER TABLE "policy" ALTER COLUMN "issue_quorum_num" DROP NOT NULL; jbe@292: ALTER TABLE "policy" ALTER COLUMN "issue_quorum_den" DROP NOT NULL; jbe@262: ALTER TABLE "policy" ADD CONSTRAINT "timing" CHECK ( jbe@262: ( "polling" = FALSE AND jbe@262: "admission_time" NOTNULL AND "discussion_time" NOTNULL AND jbe@262: "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR jbe@262: ( "polling" = TRUE AND jbe@263: "admission_time" ISNULL AND "discussion_time" NOTNULL AND jbe@262: "verification_time" NOTNULL AND "voting_time" NOTNULL ) OR jbe@262: ( "polling" = TRUE AND jbe@262: "admission_time" ISNULL AND "discussion_time" ISNULL AND jbe@262: "verification_time" ISNULL AND "voting_time" ISNULL ) ); jbe@292: ALTER TABLE "policy" ADD CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK ( jbe@292: "polling" = "issue_quorum_num" ISNULL AND jbe@292: "polling" = "issue_quorum_den" ISNULL ); jbe@289: COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues'; jbe@262: jbe@291: ALTER TABLE "issue" ALTER COLUMN "admission_time" DROP NOT NULL; jbe@291: ALTER TABLE "issue" ADD CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK ( jbe@291: "admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created") ); jbe@291: jbe@262: ALTER TABLE "initiative" ADD COLUMN "polling" BOOLEAN NOT NULL DEFAULT FALSE; jbe@289: COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")'; jbe@262: jbe@262: ALTER TABLE "privilege" RENAME COLUMN "voting_right_manager" TO "member_manager"; jbe@262: ALTER TABLE "privilege" ADD COLUMN "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE; jbe@262: ALTER TABLE "privilege" ADD COLUMN "polling_right" BOOLEAN NOT NULL DEFAULT FALSE; jbe@262: UPDATE "privilege" SET "initiative_right" = "voting_right"; jbe@262: COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members'; jbe@262: COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"'; jbe@262: COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative'; jbe@262: COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote'; jbe@289: COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues'; jbe@262: jbe@293: DROP VIEW "member_contingent_left"; jbe@293: DROP VIEW "member_contingent"; jbe@293: ALTER TABLE "contingent" DROP CONSTRAINT "contingent_pkey"; jbe@293: ALTER TABLE "contingent" ALTER COLUMN "time_frame" DROP NOT NULL; jbe@294: ALTER TABLE "contingent" ADD COLUMN "polling" BOOLEAN DEFAULT FALSE; jbe@293: ALTER TABLE "contingent" ADD PRIMARY KEY ("polling", "time_frame"); jbe@294: ALTER TABLE "contingent" ALTER COLUMN "polling" DROP DEFAULT; jbe@293: COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set'; jbe@293: jbe@293: CREATE VIEW "member_contingent" AS jbe@293: SELECT jbe@293: "member"."id" AS "member_id", jbe@293: "contingent"."polling", jbe@293: "contingent"."time_frame", jbe@293: CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN jbe@293: ( jbe@293: SELECT count(1) FROM "draft" jbe@293: JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id" jbe@293: WHERE "draft"."author_id" = "member"."id" jbe@293: AND "initiative"."polling" = "contingent"."polling" jbe@293: AND "draft"."created" > now() - "contingent"."time_frame" jbe@293: ) + ( jbe@293: SELECT count(1) FROM "suggestion" jbe@293: JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id" jbe@293: WHERE "suggestion"."author_id" = "member"."id" jbe@293: AND "contingent"."polling" = FALSE jbe@293: AND "suggestion"."created" > now() - "contingent"."time_frame" jbe@293: ) jbe@293: ELSE NULL END AS "text_entry_count", jbe@293: "contingent"."text_entry_limit", jbe@293: CASE WHEN "contingent"."initiative_limit" NOTNULL THEN ( jbe@293: SELECT count(1) FROM "opening_draft" AS "draft" jbe@293: JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id" jbe@293: WHERE "draft"."author_id" = "member"."id" jbe@293: AND "initiative"."polling" = "contingent"."polling" jbe@293: AND "draft"."created" > now() - "contingent"."time_frame" jbe@293: ) ELSE NULL END AS "initiative_count", jbe@293: "contingent"."initiative_limit" jbe@293: FROM "member" CROSS JOIN "contingent"; jbe@293: jbe@293: COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.'; jbe@293: jbe@293: COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row'; jbe@293: COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row'; jbe@293: jbe@293: CREATE VIEW "member_contingent_left" AS jbe@293: SELECT jbe@293: "member_id", jbe@293: "polling", jbe@293: max("text_entry_limit" - "text_entry_count") AS "text_entries_left", jbe@293: max("initiative_limit" - "initiative_count") AS "initiatives_left" jbe@293: FROM "member_contingent" GROUP BY "member_id", "polling"; jbe@293: jbe@293: COMMENT ON VIEW "member_contingent_left" IS 'Amount of text entries or initiatives which can be posted now instantly by a member. This view should be used by a frontend to determine, if the contingent for posting is exhausted.'; jbe@293: jbe@262: CREATE OR REPLACE FUNCTION "freeze_after_snapshot" jbe@262: ( "issue_id_p" "issue"."id"%TYPE ) jbe@262: RETURNS VOID jbe@262: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@262: DECLARE jbe@262: "issue_row" "issue"%ROWTYPE; jbe@262: "policy_row" "policy"%ROWTYPE; jbe@262: "initiative_row" "initiative"%ROWTYPE; jbe@262: BEGIN jbe@262: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"; jbe@262: SELECT * INTO "policy_row" jbe@262: FROM "policy" WHERE "id" = "issue_row"."policy_id"; jbe@262: PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze'); jbe@262: FOR "initiative_row" IN jbe@262: SELECT * FROM "initiative" jbe@262: WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL jbe@262: LOOP jbe@262: IF jbe@262: "initiative_row"."polling" OR ( jbe@262: "initiative_row"."satisfied_supporter_count" > 0 AND jbe@262: "initiative_row"."satisfied_supporter_count" * jbe@262: "policy_row"."initiative_quorum_den" >= jbe@262: "issue_row"."population" * "policy_row"."initiative_quorum_num" jbe@262: ) jbe@262: THEN jbe@262: UPDATE "initiative" SET "admitted" = TRUE jbe@262: WHERE "id" = "initiative_row"."id"; jbe@262: ELSE jbe@262: UPDATE "initiative" SET "admitted" = FALSE jbe@262: WHERE "id" = "initiative_row"."id"; jbe@262: END IF; jbe@262: END LOOP; jbe@262: IF EXISTS ( jbe@262: SELECT NULL FROM "initiative" jbe@262: WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE jbe@262: ) THEN jbe@262: UPDATE "issue" SET jbe@262: "state" = 'voting', jbe@262: "accepted" = coalesce("accepted", now()), jbe@262: "half_frozen" = coalesce("half_frozen", now()), jbe@262: "fully_frozen" = now() jbe@262: WHERE "id" = "issue_id_p"; jbe@262: ELSE jbe@262: UPDATE "issue" SET jbe@262: "state" = 'canceled_no_initiative_admitted', jbe@262: "accepted" = coalesce("accepted", now()), jbe@262: "half_frozen" = coalesce("half_frozen", now()), jbe@262: "fully_frozen" = now(), jbe@262: "closed" = now(), jbe@262: "ranks_available" = TRUE jbe@262: WHERE "id" = "issue_id_p"; jbe@262: -- NOTE: The following DELETE statements have effect only when jbe@262: -- issue state has been manipulated jbe@262: DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p"; jbe@262: DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p"; jbe@262: DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; jbe@262: END IF; jbe@262: RETURN; jbe@262: END; jbe@262: $$; jbe@262: jbe@287: jbe@287: -- issue comments removed, voting comments integrated in "direct_voter" table jbe@287: jbe@287: ALTER TABLE "direct_voter" ADD COLUMN "comment_changed" TIMESTAMPTZ; jbe@287: ALTER TABLE "direct_voter" ADD COLUMN "formatting_engine" TEXT; jbe@287: ALTER TABLE "direct_voter" ADD COLUMN "comment" TEXT; jbe@287: ALTER TABLE "direct_voter" ADD COLUMN "text_search_data" TSVECTOR; jbe@287: CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data"); jbe@287: CREATE TRIGGER "update_text_search_data" jbe@287: BEFORE INSERT OR UPDATE ON "direct_voter" jbe@287: FOR EACH ROW EXECUTE PROCEDURE jbe@287: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment"); jbe@287: jbe@287: COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL'; jbe@287: COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL'; jbe@287: COMMENT ON COLUMN "direct_voter"."comment" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.'; jbe@287: jbe@287: CREATE TABLE "rendered_voter_comment" ( jbe@287: PRIMARY KEY ("issue_id", "member_id", "format"), jbe@287: FOREIGN KEY ("issue_id", "member_id") jbe@287: REFERENCES "direct_voter" ("issue_id", "member_id") jbe@287: ON DELETE CASCADE ON UPDATE CASCADE, jbe@287: "issue_id" INT4, jbe@287: "member_id" INT4, jbe@287: "format" TEXT, jbe@287: "content" TEXT NOT NULL ); jbe@287: jbe@287: COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)'; jbe@287: jbe@287: DROP TABLE "rendered_issue_comment"; jbe@287: DROP TABLE "issue_comment"; jbe@287: DROP TABLE "rendered_voting_comment"; jbe@287: DROP TABLE "voting_comment"; jbe@287: jbe@287: CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() jbe@287: RETURNS TRIGGER jbe@287: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@287: BEGIN jbe@287: IF NEW."comment" ISNULL THEN jbe@287: NEW."comment_changed" := NULL; jbe@287: NEW."formatting_engine" := NULL; jbe@287: END IF; jbe@287: RETURN NEW; jbe@287: END; jbe@287: $$; jbe@287: jbe@287: CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" jbe@287: BEFORE INSERT OR UPDATE ON "direct_voter" jbe@287: FOR EACH ROW EXECUTE PROCEDURE jbe@287: "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"(); jbe@287: jbe@287: COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"'; jbe@287: COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.'; jbe@287: jbe@290: CREATE OR REPLACE FUNCTION "forbid_changes_on_closed_issue_trigger"() jbe@290: RETURNS TRIGGER jbe@290: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@290: DECLARE jbe@290: "issue_id_v" "issue"."id"%TYPE; jbe@290: "issue_row" "issue"%ROWTYPE; jbe@290: BEGIN jbe@290: IF TG_RELID = 'direct_voter'::regclass AND TG_OP = 'UPDATE' THEN jbe@290: IF jbe@290: OLD."issue_id" = NEW."issue_id" AND jbe@290: OLD."member_id" = NEW."member_id" AND jbe@290: OLD."weight" = NEW."weight" jbe@290: THEN jbe@290: RETURN NULL; -- allows changing of voter comment jbe@290: END IF; jbe@290: END IF; jbe@290: IF TG_OP = 'DELETE' THEN jbe@290: "issue_id_v" := OLD."issue_id"; jbe@290: ELSE jbe@290: "issue_id_v" := NEW."issue_id"; jbe@290: END IF; jbe@290: SELECT INTO "issue_row" * FROM "issue" jbe@290: WHERE "id" = "issue_id_v" FOR SHARE; jbe@290: IF "issue_row"."closed" NOTNULL THEN jbe@290: RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.'; jbe@290: END IF; jbe@290: RETURN NULL; jbe@290: END; jbe@290: $$; jbe@290: jbe@285: CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE) jbe@285: RETURNS VOID jbe@285: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@285: DECLARE jbe@285: "area_id_v" "area"."id"%TYPE; jbe@285: "unit_id_v" "unit"."id"%TYPE; jbe@285: "member_id_v" "member"."id"%TYPE; jbe@285: BEGIN jbe@285: PERFORM "lock_issue"("issue_id_p"); jbe@285: SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p"; jbe@285: SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v"; jbe@285: -- delete timestamp of voting comment: jbe@285: UPDATE "direct_voter" SET "comment_changed" = NULL jbe@285: WHERE "issue_id" = "issue_id_p"; jbe@285: -- delete delegating votes (in cases of manual reset of issue state): jbe@285: DELETE FROM "delegating_voter" jbe@285: WHERE "issue_id" = "issue_id_p"; jbe@285: -- delete votes from non-privileged voters: jbe@285: DELETE FROM "direct_voter" jbe@285: USING ( jbe@285: SELECT jbe@285: "direct_voter"."member_id" jbe@285: FROM "direct_voter" jbe@285: JOIN "member" ON "direct_voter"."member_id" = "member"."id" jbe@285: LEFT JOIN "privilege" jbe@285: ON "privilege"."unit_id" = "unit_id_v" jbe@285: AND "privilege"."member_id" = "direct_voter"."member_id" jbe@285: WHERE "direct_voter"."issue_id" = "issue_id_p" AND ( jbe@285: "member"."active" = FALSE OR jbe@285: "privilege"."voting_right" ISNULL OR jbe@285: "privilege"."voting_right" = FALSE jbe@285: ) jbe@285: ) AS "subquery" jbe@285: WHERE "direct_voter"."issue_id" = "issue_id_p" jbe@285: AND "direct_voter"."member_id" = "subquery"."member_id"; jbe@285: -- consider delegations: jbe@285: UPDATE "direct_voter" SET "weight" = 1 jbe@285: WHERE "issue_id" = "issue_id_p"; jbe@285: PERFORM "add_vote_delegations"("issue_id_p"); jbe@285: -- set voter count and mark issue as being calculated: jbe@285: UPDATE "issue" SET jbe@285: "state" = 'calculation', jbe@285: "closed" = now(), jbe@285: "voter_count" = ( jbe@285: SELECT coalesce(sum("weight"), 0) jbe@285: FROM "direct_voter" WHERE "issue_id" = "issue_id_p" jbe@285: ) jbe@285: WHERE "id" = "issue_id_p"; jbe@285: -- materialize battle_view: jbe@285: -- NOTE: "closed" column of issue must be set at this point jbe@285: DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; jbe@285: INSERT INTO "battle" ( jbe@285: "issue_id", jbe@285: "winning_initiative_id", "losing_initiative_id", jbe@285: "count" jbe@285: ) SELECT jbe@285: "issue_id", jbe@285: "winning_initiative_id", "losing_initiative_id", jbe@285: "count" jbe@285: FROM "battle_view" WHERE "issue_id" = "issue_id_p"; jbe@285: -- copy "positive_votes" and "negative_votes" from "battle" table: jbe@285: UPDATE "initiative" SET jbe@285: "positive_votes" = "battle_win"."count", jbe@285: "negative_votes" = "battle_lose"."count" jbe@285: FROM "battle" AS "battle_win", "battle" AS "battle_lose" jbe@285: WHERE jbe@285: "battle_win"."issue_id" = "issue_id_p" AND jbe@285: "battle_win"."winning_initiative_id" = "initiative"."id" AND jbe@285: "battle_win"."losing_initiative_id" ISNULL AND jbe@285: "battle_lose"."issue_id" = "issue_id_p" AND jbe@285: "battle_lose"."losing_initiative_id" = "initiative"."id" AND jbe@285: "battle_lose"."winning_initiative_id" ISNULL; jbe@285: END; jbe@285: $$; jbe@285: jbe@288: CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE) jbe@288: RETURNS VOID jbe@288: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@288: DECLARE jbe@288: "issue_row" "issue"%ROWTYPE; jbe@288: BEGIN jbe@288: SELECT * INTO "issue_row" jbe@288: FROM "issue" WHERE "id" = "issue_id_p" jbe@288: FOR UPDATE; jbe@288: IF "issue_row"."cleaned" ISNULL THEN jbe@288: UPDATE "issue" SET jbe@288: "state" = 'voting', jbe@288: "closed" = NULL, jbe@288: "ranks_available" = FALSE jbe@288: WHERE "id" = "issue_id_p"; jbe@288: DELETE FROM "delegating_voter" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "direct_voter" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "delegating_interest_snapshot" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "direct_interest_snapshot" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "delegating_population_snapshot" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "direct_population_snapshot" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "non_voter" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "delegation" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: DELETE FROM "supporter" jbe@288: WHERE "issue_id" = "issue_id_p"; jbe@288: UPDATE "issue" SET jbe@288: "state" = "issue_row"."state", jbe@288: "closed" = "issue_row"."closed", jbe@288: "ranks_available" = "issue_row"."ranks_available", jbe@288: "cleaned" = now() jbe@288: WHERE "id" = "issue_id_p"; jbe@288: END IF; jbe@288: RETURN; jbe@288: END; jbe@288: $$; jbe@288: jbe@287: jbe@287: -- "non_voter" deletes "direct_voter" and vice versa jbe@287: jbe@287: CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"() jbe@287: RETURNS TRIGGER jbe@287: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@287: BEGIN jbe@287: DELETE FROM "direct_voter" jbe@287: WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id"; jbe@287: RETURN NULL; jbe@287: END; jbe@287: $$; jbe@287: jbe@287: CREATE TRIGGER "non_voter_deletes_direct_voter" jbe@287: AFTER INSERT OR UPDATE ON "non_voter" jbe@287: FOR EACH ROW EXECUTE PROCEDURE jbe@287: "non_voter_deletes_direct_voter_trigger"(); jbe@287: jbe@287: COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"'; jbe@287: COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")'; jbe@287: jbe@287: CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"() jbe@287: RETURNS TRIGGER jbe@287: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@287: BEGIN jbe@287: DELETE FROM "non_voter" jbe@287: WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id"; jbe@287: RETURN NULL; jbe@287: END; jbe@287: $$; jbe@287: jbe@287: CREATE TRIGGER "direct_voter_deletes_non_voter" jbe@287: AFTER INSERT OR UPDATE ON "direct_voter" jbe@287: FOR EACH ROW EXECUTE PROCEDURE jbe@287: "direct_voter_deletes_non_voter_trigger"(); jbe@287: jbe@287: COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"'; jbe@287: COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")'; jbe@287: jbe@287: jbe@297: -- different locking levels and different locking order to avoid deadlocks jbe@297: jbe@297: CREATE OR REPLACE FUNCTION "lock_issue" jbe@297: ( "issue_id_p" "issue"."id"%TYPE ) jbe@297: RETURNS VOID jbe@297: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@297: BEGIN jbe@297: -- The following locking order is used: jbe@297: -- 1st) row-level lock on the issue jbe@297: -- 2nd) table-level locks in order of occurrence in the core.sql file jbe@297: PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE; jbe@297: -- NOTE: The row-level exclusive lock in combination with the jbe@297: -- share_row_lock_issue(_via_initiative)_trigger functions (which jbe@297: -- acquire a row-level share lock on the issue) ensure that no data jbe@297: -- is changed, which could affect calculation of snapshots or jbe@297: -- counting of votes. Table "delegation" must be table-level-locked, jbe@297: -- as it also contains issue- and global-scope delegations. jbe@301: PERFORM NULL FROM "member" WHERE "active" FOR SHARE; jbe@299: -- NOTE: As we later cause implicit row-level share locks on many jbe@301: -- active members, we lock them before locking any other table jbe@301: -- to avoid deadlocks jbe@301: LOCK TABLE "member" IN SHARE MODE; jbe@297: LOCK TABLE "privilege" IN SHARE MODE; jbe@297: LOCK TABLE "membership" IN SHARE MODE; jbe@297: LOCK TABLE "policy" IN SHARE MODE; jbe@297: LOCK TABLE "delegation" IN SHARE MODE; jbe@297: LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE; jbe@297: LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE; jbe@297: LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE; jbe@297: LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE; jbe@297: LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE; jbe@297: RETURN; jbe@297: END; jbe@297: $$; jbe@297: jbe@297: jbe@287: -- new comment on function "delete_private_data"() jbe@287: jbe@283: COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.'; jbe@283: jbe@287: jbe@262: COMMIT;