jbe@602: CREATE OR REPLACE VIEW "liquid_feedback_version" AS jbe@602: SELECT * FROM (VALUES ('4.2.0-incomplete-update', 4, 2, -1)) jbe@602: AS "subquery"("string", "major", "minor", "revision"); jbe@602: jbe@602: ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'posting_created'; jbe@602: jbe@602: BEGIN; jbe@602: jbe@602: CREATE OR REPLACE VIEW "liquid_feedback_version" AS jbe@602: SELECT * FROM (VALUES ('4.2.0', 4, 2, 0)) jbe@602: AS "subquery"("string", "major", "minor", "revision"); jbe@602: jbe@602: DROP VIEW "newsletter_to_send"; jbe@602: DROP VIEW "scheduled_notification_to_send"; jbe@602: DROP VIEW "member_contingent_left"; jbe@602: DROP VIEW "member_contingent"; jbe@602: DROP VIEW "expired_snapshot"; jbe@602: DROP VIEW "current_draft"; jbe@602: DROP VIEW "opening_draft"; jbe@602: DROP VIEW "area_with_unaccepted_issues"; jbe@602: DROP VIEW "member_to_notify"; jbe@602: DROP VIEW "member_eligible_to_be_notified"; jbe@602: jbe@602: CREATE EXTENSION IF NOT EXISTS btree_gist; jbe@602: CREATE EXTENSION IF NOT EXISTS conflux; jbe@602: jbe@602: DROP FUNCTION "text_search_query" (TEXT); jbe@602: jbe@602: ALTER TABLE "system_setting" DROP COLUMN "snapshot_retention"; jbe@602: jbe@602: CREATE TABLE "file" ( jbe@602: "id" SERIAL8 PRIMARY KEY, jbe@602: UNIQUE ("content_type", "hash"), jbe@602: "content_type" TEXT NOT NULL, jbe@602: "hash" TEXT NOT NULL, jbe@602: "data" BYTEA NOT NULL, jbe@602: "preview_content_type" TEXT, jbe@602: "preview_data" BYTEA ); jbe@602: jbe@602: COMMENT ON TABLE "file" IS 'Table holding file contents for draft attachments'; jbe@602: jbe@602: COMMENT ON COLUMN "file"."content_type" IS 'Content type of "data"'; jbe@602: COMMENT ON COLUMN "file"."hash" IS 'Hash of "data" to avoid storing duplicates where content-type and data is identical'; jbe@602: COMMENT ON COLUMN "file"."data" IS 'Binary content'; jbe@602: COMMENT ON COLUMN "file"."preview_content_type" IS 'Content type of "preview_data"'; jbe@602: COMMENT ON COLUMN "file"."preview_data" IS 'Preview (e.g. preview image)'; jbe@602: jbe@602: ALTER TABLE "member" DROP COLUMN "text_search_data"; jbe@602: DROP TRIGGER "update_text_search_data" ON "member"; jbe@602: jbe@602: CREATE INDEX "member_useterms_member_id_contract_identifier" ON "member_useterms" ("member_id", "contract_identifier"); jbe@602: jbe@602: ALTER TABLE "member_profile" DROP COLUMN "text_search_data"; jbe@602: DROP TRIGGER "update_text_search_data" ON "member_profile"; jbe@602: jbe@602: ALTER TABLE "contact" ADD COLUMN "following" BOOLEAN NOT NULL DEFAULT TRUE; jbe@602: jbe@602: COMMENT ON COLUMN "contact"."following" IS 'TRUE = actions of contact are shown in personal timeline'; jbe@602: jbe@602: ALTER TABLE "unit" DROP COLUMN "text_search_data"; jbe@602: DROP TRIGGER "update_text_search_data" ON "unit"; jbe@602: jbe@602: ALTER TABLE "area" DROP COLUMN "text_search_data"; jbe@602: DROP TRIGGER "update_text_search_data" ON "area"; jbe@602: jbe@602: DROP INDEX "issue_accepted_idx"; jbe@602: DROP INDEX "issue_half_frozen_idx"; jbe@602: DROP INDEX "issue_fully_frozen_idx"; jbe@602: ALTER INDEX "issue_created_idx_open" RENAME TO "issue_open_created_idx"; jbe@602: DROP INDEX "issue_closed_idx_canceled"; jbe@602: ALTER INDEX "issue_latest_snapshot_id" RENAME TO "issue_latest_snapshot_id_idx"; jbe@602: ALTER INDEX "issue_admission_snapshot_id" RENAME TO "issue_admission_snapshot_id_idx"; jbe@602: ALTER INDEX "issue_half_freeze_snapshot_id" RENAME TO "issue_half_freeze_snapshot_id_idx"; jbe@602: ALTER INDEX "issue_full_freeze_snapshot_id" RENAME TO "issue_full_freeze_snapshot_id_idx"; jbe@602: jbe@602: ALTER TABLE "initiative" ADD COLUMN "content" TEXT; jbe@602: ALTER TABLE "initiative" DROP COLUMN "text_search_data"; jbe@602: ALTER TABLE "initiative" DROP COLUMN "draft_text_search_data"; jbe@602: DROP INDEX "initiative_revoked_idx"; jbe@602: DROP TRIGGER "update_text_search_data" ON "initiative"; jbe@602: jbe@602: COMMENT ON COLUMN "initiative"."content" IS 'Initiative text (automatically copied from most recent draft)'; jbe@602: jbe@602: ALTER TABLE "battle" DROP CONSTRAINT "initiative_ids_not_equal"; jbe@602: ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK ( jbe@602: "winning_initiative_id" != "losing_initiative_id" AND jbe@602: ("winning_initiative_id" NOTNULL OR "losing_initiative_id" NOTNULL) ); jbe@602: jbe@602: ALTER TABLE "draft" DROP COLUMN "text_search_data"; jbe@602: DROP TRIGGER "update_text_search_data" ON "draft"; jbe@602: jbe@602: CREATE TABLE "draft_attachment" ( jbe@602: "id" SERIAL8 PRIMARY KEY, jbe@602: "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: "file_id" INT8 REFERENCES "file" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, jbe@602: "title" TEXT, jbe@602: "description" TEXT ); jbe@602: jbe@602: COMMENT ON TABLE "draft_attachment" IS 'Binary attachments for a draft (images, PDF file, etc.); Implicitly ordered through ''id'' column'; jbe@602: jbe@602: ALTER TABLE "suggestion" DROP COLUMN "text_search_data"; jbe@602: DROP TRIGGER "update_text_search_data" ON "suggestion"; jbe@602: jbe@602: ALTER TABLE "direct_voter" DROP COLUMN "text_search_data"; jbe@602: DROP TRIGGER "update_text_search_data" ON "direct_voter"; jbe@602: jbe@602: CREATE TABLE "posting" ( jbe@602: UNIQUE ("author_id", "id"), -- index needed for foreign-key on table "posting_lexeme" jbe@602: "id" SERIAL8 PRIMARY KEY, jbe@602: "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, jbe@602: "created" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@602: "message" TEXT NOT NULL, jbe@602: "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: "area_id" INT4, jbe@602: FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: "initiative_id" INT4, jbe@602: "suggestion_id" INT8, jbe@602: -- NOTE: no referential integrity for suggestions because those are jbe@602: -- actually deleted jbe@602: -- FOREIGN KEY ("initiative_id", "suggestion_id") jbe@602: -- REFERENCES "suggestion" ("initiative_id", "id") jbe@602: -- ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: CONSTRAINT "area_requires_unit" CHECK ( jbe@602: "area_id" ISNULL OR "unit_id" NOTNULL ), jbe@602: CONSTRAINT "policy_set_when_issue_set" CHECK ( jbe@602: ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ), jbe@602: CONSTRAINT "issue_requires_area" CHECK ( jbe@602: "issue_id" ISNULL OR "area_id" NOTNULL ), jbe@602: CONSTRAINT "initiative_requires_issue" CHECK ( jbe@602: "initiative_id" ISNULL OR "issue_id" NOTNULL ), jbe@602: CONSTRAINT "suggestion_requires_initiative" CHECK ( jbe@602: "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) ); jbe@602: CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id"))); jbe@602: CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL; jbe@602: CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL; jbe@602: CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL; jbe@602: CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL; jbe@602: CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL; jbe@602: CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL; jbe@602: COMMENT ON TABLE "posting" IS 'Text postings of members; a text posting may optionally be associated to a unit, area, policy, issue, initiative, or suggestion'; jbe@602: jbe@602: CREATE TABLE "posting_lexeme" ( jbe@602: PRIMARY KEY ("posting_id", "lexeme"), jbe@602: FOREIGN KEY ("posting_id", "author_id") REFERENCES "posting" ("id", "author_id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@602: "posting_id" INT8, jbe@602: "lexeme" TEXT, jbe@602: "author_id" INT4 ); jbe@602: CREATE INDEX "posting_lexeme_idx" ON "posting_lexeme" USING gist ("lexeme", (pstamp("author_id", "posting_id"))); jbe@602: jbe@602: COMMENT ON TABLE "posting_lexeme" IS 'Helper table to allow searches for hashtags.'; jbe@602: jbe@602: ALTER TABLE "event" ADD COLUMN "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_issue_state_changed"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_suggestion_creation"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_suggestion_removal"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_value_less_member_event"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_member_active"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_member_name_updated"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_interest"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_initiator"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_support"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_support_updated"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_suggestion_rated"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_delegation"; jbe@602: ALTER TABLE "event" DROP CONSTRAINT "constr_for_contact"; jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_issue_state_changed" CHECK ( jbe@602: "event" != 'issue_state_changed' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" ISNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" ISNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK ( jbe@602: "event" NOT IN ( jbe@602: 'initiative_created_in_new_issue', jbe@602: 'initiative_created_in_existing_issue', jbe@602: 'initiative_revoked', jbe@602: 'new_draft_created' jbe@602: ) OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" NOTNULL AND jbe@602: "draft_id" NOTNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_suggestion_creation" CHECK ( jbe@602: "event" != 'suggestion_created' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" NOTNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" NOTNULL AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_suggestion_removal" CHECK ( jbe@602: "event" != 'suggestion_deleted' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" ISNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" NOTNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" NOTNULL AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_value_less_member_event" CHECK ( jbe@602: "event" NOT IN ( jbe@602: 'member_activated', jbe@602: 'member_deleted', jbe@602: 'member_profile_updated', jbe@602: 'member_image_updated' jbe@602: ) OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" ISNULL AND jbe@602: "area_id" ISNULL AND jbe@602: "policy_id" ISNULL AND jbe@602: "issue_id" ISNULL AND jbe@602: "state" ISNULL AND jbe@602: "initiative_id" ISNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_member_active" CHECK ( jbe@602: "event" != 'member_active' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" ISNULL AND jbe@602: "area_id" ISNULL AND jbe@602: "policy_id" ISNULL AND jbe@602: "issue_id" ISNULL AND jbe@602: "state" ISNULL AND jbe@602: "initiative_id" ISNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" NOTNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_member_name_updated" CHECK ( jbe@602: "event" != 'member_name_updated' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" ISNULL AND jbe@602: "area_id" ISNULL AND jbe@602: "policy_id" ISNULL AND jbe@602: "issue_id" ISNULL AND jbe@602: "state" ISNULL AND jbe@602: "initiative_id" ISNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" NOTNULL AND jbe@602: "old_text_value" NOTNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_interest" CHECK ( jbe@602: "event" != 'interest' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" ISNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" NOTNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_initiator" CHECK ( jbe@602: "event" != 'initiator' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" NOTNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" NOTNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_support" CHECK ( jbe@602: "event" != 'support' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" NOTNULL AND jbe@602: ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" NOTNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_support_updated" CHECK ( jbe@602: "event" != 'support_updated' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" NOTNULL AND jbe@602: "draft_id" NOTNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_suggestion_rated" CHECK ( jbe@602: "event" != 'suggestion_rated' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: "area_id" NOTNULL AND jbe@602: "policy_id" NOTNULL AND jbe@602: "issue_id" NOTNULL AND jbe@602: "state" NOTNULL AND jbe@602: "initiative_id" NOTNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" NOTNULL AND jbe@602: ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND jbe@602: "numeric_value" NOTNULL AND jbe@602: "numeric_value" IN (-2, -1, 0, 1, 2) AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_delegation" CHECK ( jbe@602: "event" != 'delegation' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND jbe@602: "scope" NOTNULL AND jbe@602: "unit_id" NOTNULL AND jbe@602: ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND jbe@602: "policy_id" ISNULL AND jbe@602: ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND jbe@602: ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND jbe@602: "initiative_id" ISNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" NOTNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_contact" CHECK ( jbe@602: "event" != 'contact' OR ( jbe@602: "posting_id" ISNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" NOTNULL AND jbe@602: "scope" ISNULL AND jbe@602: "unit_id" ISNULL AND jbe@602: "area_id" ISNULL AND jbe@602: "policy_id" ISNULL AND jbe@602: "issue_id" ISNULL AND jbe@602: "state" ISNULL AND jbe@602: "initiative_id" ISNULL AND jbe@602: "draft_id" ISNULL AND jbe@602: "suggestion_id" ISNULL AND jbe@602: "boolean_value" NOTNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: ALTER TABLE "event" ADD jbe@602: CONSTRAINT "constr_for_posting_created" CHECK ( jbe@602: "event" != 'posting_created' OR ( jbe@602: "posting_id" NOTNULL AND jbe@602: "member_id" NOTNULL AND jbe@602: "other_member_id" ISNULL AND jbe@602: "scope" ISNULL AND jbe@602: "state" ISNULL AND jbe@602: ("area_id" ISNULL OR "unit_id" NOTNULL) AND jbe@602: ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND jbe@602: ("issue_id" ISNULL OR "area_id" NOTNULL) AND jbe@602: ("state" NOTNULL) = ("issue_id" NOTNULL) AND jbe@602: ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND jbe@602: "draft_id" ISNULL AND jbe@602: ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND jbe@602: "boolean_value" ISNULL AND jbe@602: "numeric_value" ISNULL AND jbe@602: "text_value" ISNULL AND jbe@602: "old_text_value" ISNULL )); jbe@602: jbe@602: CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id"))); jbe@602: CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL; jbe@602: CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL; jbe@602: CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL; jbe@602: CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL; jbe@602: CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL; jbe@602: CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL; jbe@602: jbe@602: CREATE OR REPLACE FUNCTION "highlight" jbe@602: ( "body_p" TEXT, jbe@602: "query_text_p" TEXT ) jbe@602: RETURNS TEXT jbe@602: LANGUAGE 'plpgsql' IMMUTABLE AS $$ jbe@602: BEGIN jbe@602: RETURN ts_headline( jbe@602: replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'), jbe@602: "plainto_tsquery"("query_text_p"), jbe@602: 'StartSel=* StopSel=* HighlightAll=TRUE' ); jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("member") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."name", jbe@602: $1."identification" jbe@602: )) $$; jbe@602: CREATE INDEX "member_to_tsvector_idx" ON "member" USING gin jbe@602: (("to_tsvector"("member".*))); jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("member_profile") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."statement", jbe@602: $1."profile_text_data" jbe@602: )) $$; jbe@602: CREATE INDEX "member_profile_to_tsvector_idx" ON "member_profile" USING gin jbe@602: (("to_tsvector"("member_profile".*))); jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("unit") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."name", jbe@602: $1."description" jbe@602: )) $$; jbe@602: CREATE INDEX "unit_to_tsvector_idx" ON "unit" USING gin jbe@602: (("to_tsvector"("unit".*))); jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("area") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."name", jbe@602: $1."description" jbe@602: )) $$; jbe@602: CREATE INDEX "area_to_tsvector_idx" ON "area" USING gin jbe@602: (("to_tsvector"("area".*))); jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("initiative") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."name", jbe@602: $1."content" jbe@602: )) $$; jbe@602: CREATE INDEX "initiative_to_tsvector_idx" ON "initiative" USING gin jbe@602: (("to_tsvector"("initiative".*))); jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("draft") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."content" jbe@602: )) $$; jbe@602: CREATE INDEX "draft_to_tsvector_idx" ON "draft" USING gin jbe@602: (("to_tsvector"("draft".*))); jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("suggestion") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."name", jbe@602: $1."content" jbe@602: )) $$; jbe@602: CREATE INDEX "suggestion_to_tsvector_idx" ON "suggestion" USING gin jbe@602: (("to_tsvector"("suggestion".*))); jbe@602: jbe@602: CREATE FUNCTION "to_tsvector"("direct_voter") RETURNS TSVECTOR jbe@602: LANGUAGE SQL IMMUTABLE AS $$ SELECT to_tsvector(concat_ws(' ', jbe@602: $1."comment" jbe@602: )) $$; jbe@602: CREATE INDEX "direct_voter_to_tsvector_idx" ON "direct_voter" USING gin jbe@602: (("to_tsvector"("direct_voter".*))); jbe@602: jbe@602: CREATE FUNCTION "update_posting_lexeme_trigger"() jbe@602: RETURNS TRIGGER jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: DECLARE jbe@602: "lexeme_v" TEXT; jbe@602: BEGIN jbe@602: IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN jbe@602: DELETE FROM "posting_lexeme" WHERE "posting_id" = OLD."id"; jbe@602: END IF; jbe@602: IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN jbe@602: FOR "lexeme_v" IN jbe@602: SELECT regexp_matches[1] jbe@602: FROM regexp_matches(NEW."message", '#[^\s.,;:]+') jbe@602: LOOP jbe@602: INSERT INTO "posting_lexeme" ("posting_id", "author_id", "lexeme") jbe@602: VALUES ( jbe@602: NEW."id", jbe@602: NEW."author_id", jbe@602: "lexeme_v" ) jbe@602: ON CONFLICT ("posting_id", "lexeme") DO NOTHING; jbe@602: END LOOP; jbe@602: END IF; jbe@602: RETURN NULL; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE TRIGGER "update_posting_lexeme" jbe@602: AFTER INSERT OR UPDATE OR DELETE ON "posting" jbe@602: FOR EACH ROW EXECUTE PROCEDURE "update_posting_lexeme_trigger"(); jbe@602: jbe@602: COMMENT ON FUNCTION "update_posting_lexeme_trigger"() IS 'Implementation of trigger "update_posting_lexeme" on table "posting"'; jbe@602: COMMENT ON TRIGGER "update_posting_lexeme" ON "posting" IS 'Keeps table "posting_lexeme" up to date'; jbe@602: jbe@602: CREATE FUNCTION "write_event_posting_trigger"() jbe@602: RETURNS TRIGGER jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: BEGIN jbe@602: INSERT INTO "event" ( jbe@602: "event", "posting_id", "member_id", jbe@602: "unit_id", "area_id", "policy_id", jbe@602: "issue_id", "initiative_id", "suggestion_id" jbe@602: ) VALUES ( jbe@602: 'posting_created', NEW."id", NEW."author_id", jbe@602: NEW."unit_id", NEW."area_id", NEW."policy_id", jbe@602: NEW."issue_id", NEW."initiative_id", NEW."suggestion_id" jbe@602: ); jbe@602: RETURN NULL; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE TRIGGER "write_event_posting" jbe@602: AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE jbe@602: "write_event_posting_trigger"(); jbe@602: jbe@602: COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"'; jbe@602: COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting'; jbe@602: jbe@602: CREATE FUNCTION "file_requires_reference_trigger"() jbe@602: RETURNS TRIGGER jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: BEGIN jbe@602: IF NOT EXISTS ( jbe@602: SELECT NULL FROM "draft_attachment" WHERE "file_id" = NEW."id" jbe@602: ) THEN jbe@602: RAISE EXCEPTION 'Cannot create an unreferenced file.' USING jbe@602: ERRCODE = 'integrity_constraint_violation', jbe@602: HINT = 'Create file and its reference in another table within the same transaction.'; jbe@602: END IF; jbe@602: RETURN NULL; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE CONSTRAINT TRIGGER "file_requires_reference" jbe@602: AFTER INSERT OR UPDATE ON "file" DEFERRABLE INITIALLY DEFERRED jbe@602: FOR EACH ROW EXECUTE PROCEDURE jbe@602: "file_requires_reference_trigger"(); jbe@602: jbe@602: COMMENT ON FUNCTION "file_requires_reference_trigger"() IS 'Implementation of trigger "file_requires_reference" on table "file"'; jbe@602: COMMENT ON TRIGGER "file_requires_reference" ON "file" IS 'Ensure that files are always referenced'; jbe@602: jbe@602: CREATE FUNCTION "last_reference_deletes_file_trigger"() jbe@602: RETURNS TRIGGER jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: DECLARE jbe@602: "reference_lost" BOOLEAN; jbe@602: BEGIN jbe@602: IF TG_OP = 'DELETE' THEN jbe@602: "reference_lost" := TRUE; jbe@602: ELSE jbe@602: "reference_lost" := NEW."file_id" != OLD."file_id"; jbe@602: END IF; jbe@602: IF jbe@602: "reference_lost" AND NOT EXISTS ( jbe@602: SELECT NULL FROM "draft_attachment" WHERE "file_id" = OLD."file_id" jbe@602: ) jbe@602: THEN jbe@602: DELETE FROM "file" WHERE "id" = OLD."file_id"; jbe@602: END IF; jbe@602: RETURN NULL; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE CONSTRAINT TRIGGER "last_reference_deletes_file" jbe@602: AFTER UPDATE OR DELETE ON "draft_attachment" DEFERRABLE INITIALLY DEFERRED jbe@602: FOR EACH ROW EXECUTE PROCEDURE jbe@602: "last_reference_deletes_file_trigger"(); jbe@602: jbe@602: COMMENT ON FUNCTION "last_reference_deletes_file_trigger"() IS 'Implementation of trigger "last_reference_deletes_file" on table "draft_attachment"'; jbe@602: COMMENT ON TRIGGER "last_reference_deletes_file" ON "draft_attachment" IS 'Removing the last reference to a file deletes the file'; jbe@602: jbe@602: CREATE OR REPLACE FUNCTION "copy_current_draft_data" jbe@602: ("initiative_id_p" "initiative"."id"%TYPE ) jbe@602: RETURNS VOID jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: BEGIN jbe@602: PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p" jbe@602: FOR UPDATE; jbe@602: UPDATE "initiative" SET jbe@602: "location" = "draft"."location", jbe@602: "content" = "draft"."content" jbe@602: FROM "current_draft" AS "draft" jbe@602: WHERE "initiative"."id" = "initiative_id_p" jbe@602: AND "draft"."initiative_id" = "initiative_id_p"; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE VIEW "follower" AS jbe@602: SELECT jbe@602: "id" AS "follower_id", jbe@602: ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id") jbe@602: FROM "contact" jbe@602: WHERE "contact"."member_id" = "member"."id" AND "contact"."following" ) jbe@602: AS "following_ids" jbe@602: FROM "member"; jbe@602: jbe@602: COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs'; jbe@602: jbe@602: CREATE OR REPLACE FUNCTION "check_issue" jbe@602: ( "issue_id_p" "issue"."id"%TYPE, jbe@602: "persist" "check_issue_persistence" ) jbe@602: RETURNS "check_issue_persistence" jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: DECLARE jbe@602: "issue_row" "issue"%ROWTYPE; jbe@602: "last_calculated_v" "snapshot"."calculated"%TYPE; jbe@602: "policy_row" "policy"%ROWTYPE; jbe@602: "initiative_row" "initiative"%ROWTYPE; jbe@602: "state_v" "issue_state"; jbe@602: BEGIN jbe@602: PERFORM "require_transaction_isolation"(); jbe@602: IF "persist" ISNULL THEN jbe@602: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p" jbe@602: FOR UPDATE; jbe@602: SELECT "calculated" INTO "last_calculated_v" jbe@602: FROM "snapshot" JOIN "snapshot_issue" jbe@602: ON "snapshot"."id" = "snapshot_issue"."snapshot_id" jbe@602: WHERE "snapshot_issue"."issue_id" = "issue_id_p" jbe@602: ORDER BY "snapshot"."id" DESC; jbe@602: IF "issue_row"."closed" NOTNULL THEN jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: "persist"."state" := "issue_row"."state"; jbe@602: IF jbe@602: ( "issue_row"."state" = 'admission' AND "last_calculated_v" >= jbe@602: "issue_row"."created" + "issue_row"."max_admission_time" ) OR jbe@602: ( "issue_row"."state" = 'discussion' AND now() >= jbe@602: "issue_row"."accepted" + "issue_row"."discussion_time" ) OR jbe@602: ( "issue_row"."state" = 'verification' AND now() >= jbe@602: "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR jbe@602: ( "issue_row"."state" = 'voting' AND now() >= jbe@602: "issue_row"."fully_frozen" + "issue_row"."voting_time" ) jbe@602: THEN jbe@602: "persist"."phase_finished" := TRUE; jbe@602: ELSE jbe@602: "persist"."phase_finished" := FALSE; jbe@602: END IF; jbe@602: IF jbe@602: NOT EXISTS ( jbe@602: -- all initiatives are revoked jbe@602: SELECT NULL FROM "initiative" jbe@602: WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL jbe@602: ) AND ( jbe@602: -- and issue has not been accepted yet jbe@602: "persist"."state" = 'admission' OR jbe@602: -- or verification time has elapsed jbe@602: ( "persist"."state" = 'verification' AND jbe@602: "persist"."phase_finished" ) OR jbe@602: -- or no initiatives have been revoked lately jbe@602: NOT EXISTS ( jbe@602: SELECT NULL FROM "initiative" jbe@602: WHERE "issue_id" = "issue_id_p" jbe@602: AND now() < "revoked" + "issue_row"."verification_time" jbe@602: ) jbe@602: ) jbe@602: THEN jbe@602: "persist"."issue_revoked" := TRUE; jbe@602: ELSE jbe@602: "persist"."issue_revoked" := FALSE; jbe@602: END IF; jbe@602: IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN jbe@602: UPDATE "issue" SET "phase_finished" = now() jbe@602: WHERE "id" = "issue_row"."id"; jbe@602: RETURN "persist"; jbe@602: ELSIF jbe@602: "persist"."state" IN ('admission', 'discussion', 'verification') jbe@602: THEN jbe@602: RETURN "persist"; jbe@602: ELSE jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: END IF; jbe@602: IF jbe@602: "persist"."state" IN ('admission', 'discussion', 'verification') AND jbe@602: coalesce("persist"."snapshot_created", FALSE) = FALSE jbe@602: THEN jbe@602: IF "persist"."state" != 'admission' THEN jbe@602: PERFORM "take_snapshot"("issue_id_p"); jbe@602: PERFORM "finish_snapshot"("issue_id_p"); jbe@602: ELSE jbe@602: UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum" jbe@602: FROM "issue_quorum" jbe@602: WHERE "id" = "issue_id_p" jbe@602: AND "issue_quorum"."issue_id" = "issue_id_p"; jbe@602: END IF; jbe@602: "persist"."snapshot_created" = TRUE; jbe@602: IF "persist"."phase_finished" THEN jbe@602: IF "persist"."state" = 'admission' THEN jbe@602: UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id" jbe@602: WHERE "id" = "issue_id_p"; jbe@602: ELSIF "persist"."state" = 'discussion' THEN jbe@602: UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id" jbe@602: WHERE "id" = "issue_id_p"; jbe@602: ELSIF "persist"."state" = 'verification' THEN jbe@602: UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id" jbe@602: WHERE "id" = "issue_id_p"; jbe@602: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"; jbe@602: FOR "initiative_row" IN jbe@602: SELECT * FROM "initiative" jbe@602: WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL jbe@602: FOR UPDATE jbe@602: LOOP jbe@602: IF jbe@602: "initiative_row"."polling" OR jbe@602: "initiative_row"."satisfied_supporter_count" >= jbe@602: "issue_row"."initiative_quorum" jbe@602: THEN jbe@602: UPDATE "initiative" SET "admitted" = TRUE jbe@602: WHERE "id" = "initiative_row"."id"; jbe@602: ELSE jbe@602: UPDATE "initiative" SET "admitted" = FALSE jbe@602: WHERE "id" = "initiative_row"."id"; jbe@602: END IF; jbe@602: END LOOP; jbe@602: END IF; jbe@602: END IF; jbe@602: RETURN "persist"; jbe@602: END IF; jbe@602: IF jbe@602: "persist"."state" IN ('admission', 'discussion', 'verification') AND jbe@602: coalesce("persist"."harmonic_weights_set", FALSE) = FALSE jbe@602: THEN jbe@602: PERFORM "set_harmonic_initiative_weights"("issue_id_p"); jbe@602: "persist"."harmonic_weights_set" = TRUE; jbe@602: IF jbe@602: "persist"."phase_finished" OR jbe@602: "persist"."issue_revoked" OR jbe@602: "persist"."state" = 'admission' jbe@602: THEN jbe@602: RETURN "persist"; jbe@602: ELSE jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: END IF; jbe@602: IF "persist"."issue_revoked" THEN jbe@602: IF "persist"."state" = 'admission' THEN jbe@602: "state_v" := 'canceled_revoked_before_accepted'; jbe@602: ELSIF "persist"."state" = 'discussion' THEN jbe@602: "state_v" := 'canceled_after_revocation_during_discussion'; jbe@602: ELSIF "persist"."state" = 'verification' THEN jbe@602: "state_v" := 'canceled_after_revocation_during_verification'; jbe@602: END IF; jbe@602: UPDATE "issue" SET jbe@602: "state" = "state_v", jbe@602: "closed" = "phase_finished", jbe@602: "phase_finished" = NULL jbe@602: WHERE "id" = "issue_id_p"; jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: IF "persist"."state" = 'admission' THEN jbe@602: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p" jbe@602: FOR UPDATE; jbe@602: IF "issue_row"."phase_finished" NOTNULL THEN jbe@602: UPDATE "issue" SET jbe@602: "state" = 'canceled_issue_not_accepted', jbe@602: "closed" = "phase_finished", jbe@602: "phase_finished" = NULL jbe@602: WHERE "id" = "issue_id_p"; jbe@602: END IF; jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: IF "persist"."phase_finished" THEN jbe@602: IF "persist"."state" = 'discussion' THEN jbe@602: UPDATE "issue" SET jbe@602: "state" = 'verification', jbe@602: "half_frozen" = "phase_finished", jbe@602: "phase_finished" = NULL jbe@602: WHERE "id" = "issue_id_p"; jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: IF "persist"."state" = 'verification' THEN jbe@602: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p" jbe@602: FOR UPDATE; jbe@602: SELECT * INTO "policy_row" FROM "policy" jbe@602: WHERE "id" = "issue_row"."policy_id"; jbe@602: IF EXISTS ( jbe@602: SELECT NULL FROM "initiative" jbe@602: WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE jbe@602: ) THEN jbe@602: UPDATE "issue" SET jbe@602: "state" = 'voting', jbe@602: "fully_frozen" = "phase_finished", jbe@602: "phase_finished" = NULL jbe@602: WHERE "id" = "issue_id_p"; jbe@602: ELSE jbe@602: UPDATE "issue" SET jbe@602: "state" = 'canceled_no_initiative_admitted', jbe@602: "fully_frozen" = "phase_finished", jbe@602: "closed" = "phase_finished", jbe@602: "phase_finished" = NULL jbe@602: WHERE "id" = "issue_id_p"; jbe@602: -- NOTE: The following DELETE statements have effect only when jbe@602: -- issue state has been manipulated jbe@602: DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p"; jbe@602: DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p"; jbe@602: DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; jbe@602: END IF; jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: IF "persist"."state" = 'voting' THEN jbe@602: IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN jbe@602: PERFORM "close_voting"("issue_id_p"); jbe@602: "persist"."closed_voting" = TRUE; jbe@602: RETURN "persist"; jbe@602: END IF; jbe@602: PERFORM "calculate_ranks"("issue_id_p"); jbe@602: RETURN NULL; jbe@602: END IF; jbe@602: END IF; jbe@602: RAISE WARNING 'should not happen'; jbe@602: RETURN NULL; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE OR REPLACE FUNCTION "check_everything"() jbe@602: RETURNS VOID jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: DECLARE jbe@602: "area_id_v" "area"."id"%TYPE; jbe@602: "snapshot_id_v" "snapshot"."id"%TYPE; jbe@602: "issue_id_v" "issue"."id"%TYPE; jbe@602: "persist_v" "check_issue_persistence"; jbe@602: BEGIN jbe@602: RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes'; jbe@602: DELETE FROM "expired_session"; jbe@602: DELETE FROM "expired_token"; jbe@602: DELETE FROM "unused_snapshot"; jbe@602: PERFORM "check_activity"(); jbe@602: PERFORM "calculate_member_counts"(); jbe@602: FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP jbe@602: SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v"; jbe@602: PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue" jbe@602: WHERE "snapshot_id" = "snapshot_id_v"; jbe@602: LOOP jbe@602: EXIT WHEN "issue_admission"("area_id_v") = FALSE; jbe@602: END LOOP; jbe@602: END LOOP; jbe@602: FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP jbe@602: "persist_v" := NULL; jbe@602: LOOP jbe@602: "persist_v" := "check_issue"("issue_id_v", "persist_v"); jbe@602: EXIT WHEN "persist_v" ISNULL; jbe@602: END LOOP; jbe@602: END LOOP; jbe@602: DELETE FROM "unused_snapshot"; jbe@602: RETURN; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) jbe@602: RETURNS VOID jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: BEGIN jbe@602: UPDATE "member" SET jbe@602: "last_login" = NULL, jbe@602: "last_delegation_check" = NULL, jbe@602: "login" = NULL, jbe@602: "password" = NULL, jbe@602: "authority" = NULL, jbe@602: "authority_uid" = NULL, jbe@602: "authority_login" = NULL, jbe@602: "deleted" = coalesce("deleted", now()), jbe@602: "locked" = TRUE, jbe@602: "active" = FALSE, jbe@602: "notify_email" = NULL, jbe@602: "notify_email_unconfirmed" = NULL, jbe@602: "notify_email_secret" = NULL, jbe@602: "notify_email_secret_expiry" = NULL, jbe@602: "notify_email_lock_expiry" = NULL, jbe@602: "disable_notifications" = TRUE, jbe@602: "notification_counter" = DEFAULT, jbe@602: "notification_sample_size" = 0, jbe@602: "notification_dow" = NULL, jbe@602: "notification_hour" = NULL, jbe@602: "notification_sent" = NULL, jbe@602: "login_recovery_expiry" = NULL, jbe@602: "password_reset_secret" = NULL, jbe@602: "password_reset_secret_expiry" = NULL, jbe@602: "location" = NULL jbe@602: WHERE "id" = "member_id_p"; jbe@602: DELETE FROM "member_settings" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "member_profile" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "member_image" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "contact" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "session" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "member_application" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "token" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "subscription" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "delegation" WHERE "truster_id" = "member_id_p"; jbe@602: DELETE FROM "non_voter" WHERE "member_id" = "member_id_p"; jbe@602: DELETE FROM "direct_voter" USING "issue" jbe@602: WHERE "direct_voter"."issue_id" = "issue"."id" jbe@602: AND "issue"."closed" ISNULL jbe@602: AND "member_id" = "member_id_p"; jbe@602: DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p"; jbe@602: RETURN; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE OR REPLACE FUNCTION "delete_private_data"() jbe@602: RETURNS VOID jbe@602: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@602: BEGIN jbe@602: DELETE FROM "temporary_transaction_data"; jbe@602: DELETE FROM "temporary_suggestion_counts"; jbe@602: DELETE FROM "member" WHERE "activated" ISNULL; jbe@602: UPDATE "member" SET jbe@602: "invite_code" = NULL, jbe@602: "invite_code_expiry" = NULL, jbe@602: "admin_comment" = NULL, jbe@602: "last_login" = NULL, jbe@602: "last_delegation_check" = NULL, jbe@602: "login" = NULL, jbe@602: "password" = NULL, jbe@602: "authority" = NULL, jbe@602: "authority_uid" = NULL, jbe@602: "authority_login" = NULL, jbe@602: "lang" = NULL, jbe@602: "notify_email" = NULL, jbe@602: "notify_email_unconfirmed" = NULL, jbe@602: "notify_email_secret" = NULL, jbe@602: "notify_email_secret_expiry" = NULL, jbe@602: "notify_email_lock_expiry" = NULL, jbe@602: "disable_notifications" = TRUE, jbe@602: "notification_counter" = DEFAULT, jbe@602: "notification_sample_size" = 0, jbe@602: "notification_dow" = NULL, jbe@602: "notification_hour" = NULL, jbe@602: "notification_sent" = NULL, jbe@602: "login_recovery_expiry" = NULL, jbe@602: "password_reset_secret" = NULL, jbe@602: "password_reset_secret_expiry" = NULL, jbe@602: "location" = NULL; jbe@602: DELETE FROM "verification"; jbe@602: DELETE FROM "member_settings"; jbe@602: DELETE FROM "member_useterms"; jbe@602: DELETE FROM "member_profile"; jbe@602: DELETE FROM "rendered_member_statement"; jbe@602: DELETE FROM "member_image"; jbe@602: DELETE FROM "contact"; jbe@602: DELETE FROM "ignored_member"; jbe@602: DELETE FROM "session"; jbe@602: DELETE FROM "system_application"; jbe@602: DELETE FROM "system_application_redirect_uri"; jbe@602: DELETE FROM "dynamic_application_scope"; jbe@602: DELETE FROM "member_application"; jbe@602: DELETE FROM "token"; jbe@602: DELETE FROM "subscription"; jbe@602: DELETE FROM "ignored_area"; jbe@602: DELETE FROM "ignored_initiative"; jbe@602: DELETE FROM "non_voter"; jbe@602: DELETE FROM "direct_voter" USING "issue" jbe@602: WHERE "direct_voter"."issue_id" = "issue"."id" jbe@602: AND "issue"."closed" ISNULL; jbe@602: DELETE FROM "event_processed"; jbe@602: DELETE FROM "notification_initiative_sent"; jbe@602: DELETE FROM "newsletter"; jbe@602: RETURN; jbe@602: END; jbe@602: $$; jbe@602: jbe@602: CREATE VIEW "member_eligible_to_be_notified" AS jbe@602: SELECT * FROM "member" jbe@602: WHERE "activated" NOTNULL AND "locked" = FALSE; jbe@602: jbe@602: COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")'; jbe@602: jbe@602: CREATE VIEW "member_to_notify" AS jbe@602: SELECT * FROM "member_eligible_to_be_notified" jbe@602: WHERE "disable_notifications" = FALSE; jbe@602: jbe@602: COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)'; jbe@602: jbe@602: CREATE VIEW "area_with_unaccepted_issues" AS jbe@602: SELECT DISTINCT ON ("area"."id") "area".* jbe@602: FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id" jbe@602: WHERE "issue"."state" = 'admission'; jbe@602: jbe@602: COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)'; jbe@602: jbe@602: CREATE VIEW "opening_draft" AS jbe@602: SELECT DISTINCT ON ("initiative_id") * FROM "draft" jbe@602: ORDER BY "initiative_id", "id"; jbe@602: jbe@602: COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives'; jbe@602: jbe@602: CREATE VIEW "current_draft" AS jbe@602: SELECT DISTINCT ON ("initiative_id") * FROM "draft" jbe@602: ORDER BY "initiative_id", "id" DESC; jbe@602: jbe@602: COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative'; jbe@602: jbe@602: CREATE VIEW "member_contingent" AS jbe@602: SELECT jbe@602: "member"."id" AS "member_id", jbe@602: "contingent"."polling", jbe@602: "contingent"."time_frame", jbe@602: CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN jbe@602: ( jbe@602: SELECT count(1) FROM "draft" jbe@602: JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id" jbe@602: WHERE "draft"."author_id" = "member"."id" jbe@602: AND "initiative"."polling" = "contingent"."polling" jbe@602: AND "draft"."created" > now() - "contingent"."time_frame" jbe@602: ) + ( jbe@602: SELECT count(1) FROM "suggestion" jbe@602: JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id" jbe@602: WHERE "suggestion"."author_id" = "member"."id" jbe@602: AND "contingent"."polling" = FALSE jbe@602: AND "suggestion"."created" > now() - "contingent"."time_frame" jbe@602: ) jbe@602: ELSE NULL END AS "text_entry_count", jbe@602: "contingent"."text_entry_limit", jbe@602: CASE WHEN "contingent"."initiative_limit" NOTNULL THEN ( jbe@602: SELECT count(1) FROM "opening_draft" AS "draft" jbe@602: JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id" jbe@602: WHERE "draft"."author_id" = "member"."id" jbe@602: AND "initiative"."polling" = "contingent"."polling" jbe@602: AND "draft"."created" > now() - "contingent"."time_frame" jbe@602: ) ELSE NULL END AS "initiative_count", jbe@602: "contingent"."initiative_limit" jbe@602: FROM "member" CROSS JOIN "contingent"; jbe@602: jbe@602: 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@602: jbe@602: COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row'; jbe@602: COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row'; jbe@602: jbe@602: CREATE VIEW "member_contingent_left" AS jbe@602: SELECT jbe@602: "member_id", jbe@602: "polling", jbe@602: max("text_entry_limit" - "text_entry_count") AS "text_entries_left", jbe@602: max("initiative_limit" - "initiative_count") AS "initiatives_left" jbe@602: FROM "member_contingent" GROUP BY "member_id", "polling"; jbe@602: jbe@602: 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@602: jbe@602: CREATE VIEW "scheduled_notification_to_send" AS jbe@602: SELECT * FROM ( jbe@602: SELECT jbe@602: "id" AS "recipient_id", jbe@602: now() - CASE WHEN "notification_dow" ISNULL THEN jbe@602: ( "notification_sent"::DATE + CASE jbe@602: WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour" jbe@602: THEN 0 ELSE 1 END jbe@602: )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour" jbe@602: ELSE jbe@602: ( "notification_sent"::DATE + jbe@602: ( 7 + "notification_dow" - jbe@602: EXTRACT(DOW FROM jbe@602: ( "notification_sent"::DATE + CASE jbe@602: WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour" jbe@602: THEN 0 ELSE 1 END jbe@602: )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour" jbe@602: )::INTEGER jbe@602: ) % 7 + jbe@602: CASE jbe@602: WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour" jbe@602: THEN 0 ELSE 1 jbe@602: END jbe@602: )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour" jbe@602: END AS "pending" jbe@602: FROM ( jbe@602: SELECT jbe@602: "id", jbe@602: COALESCE("notification_sent", "activated") AS "notification_sent", jbe@602: "notification_dow", jbe@602: "notification_hour" jbe@602: FROM "member_to_notify" jbe@602: WHERE "notification_hour" NOTNULL jbe@602: ) AS "subquery1" jbe@602: ) AS "subquery2" jbe@602: WHERE "pending" > '0'::INTERVAL; jbe@602: jbe@602: COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending'; jbe@602: jbe@602: COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail'; jbe@602: COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending'; jbe@602: jbe@602: CREATE VIEW "newsletter_to_send" AS jbe@602: SELECT jbe@602: "member"."id" AS "recipient_id", jbe@602: "newsletter"."id" AS "newsletter_id", jbe@602: "newsletter"."published" jbe@602: FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member" jbe@602: LEFT JOIN "privilege" ON jbe@602: "privilege"."member_id" = "member"."id" AND jbe@602: "privilege"."unit_id" = "newsletter"."unit_id" AND jbe@602: "privilege"."voting_right" = TRUE jbe@602: LEFT JOIN "subscription" ON jbe@602: "subscription"."member_id" = "member"."id" AND jbe@602: "subscription"."unit_id" = "newsletter"."unit_id" jbe@602: WHERE "newsletter"."published" <= now() jbe@602: AND "newsletter"."sent" ISNULL jbe@602: AND ( jbe@602: "member"."disable_notifications" = FALSE OR jbe@602: "newsletter"."include_all_members" = TRUE ) jbe@602: AND ( jbe@602: "newsletter"."unit_id" ISNULL OR jbe@602: "privilege"."member_id" NOTNULL OR jbe@602: "subscription"."member_id" NOTNULL ); jbe@602: jbe@602: COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out'; jbe@602: jbe@602: COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)'; jbe@602: jbe@602: SELECT "copy_current_draft_data" ("id") FROM "initiative"; jbe@602: jbe@602: END;