jbe@0: jbe@92: -- Execute the following command manually for PostgreSQL prior version 9.0: jbe@92: -- CREATE LANGUAGE plpgsql; jbe@0: jbe@0: -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index jbe@0: jbe@0: BEGIN; jbe@0: jbe@5: CREATE VIEW "liquid_feedback_version" AS jbe@460: SELECT * FROM (VALUES ('3.2.0', 3, 2, 0)) jbe@5: AS "subquery"("string", "major", "minor", "revision"); jbe@5: jbe@0: jbe@0: jbe@7: ---------------------- jbe@7: -- Full text search -- jbe@7: ---------------------- jbe@7: jbe@7: jbe@7: CREATE FUNCTION "text_search_query"("query_text_p" TEXT) jbe@7: RETURNS TSQUERY jbe@7: LANGUAGE 'plpgsql' IMMUTABLE AS $$ jbe@7: BEGIN jbe@7: RETURN plainto_tsquery('pg_catalog.simple', "query_text_p"); jbe@7: END; jbe@7: $$; jbe@7: jbe@7: COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"('''')'; jbe@7: jbe@7: jbe@7: CREATE FUNCTION "highlight" jbe@7: ( "body_p" TEXT, jbe@7: "query_text_p" TEXT ) jbe@7: RETURNS TEXT jbe@7: LANGUAGE 'plpgsql' IMMUTABLE AS $$ jbe@7: BEGIN jbe@7: RETURN ts_headline( jbe@7: 'pg_catalog.simple', jbe@8: replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'), jbe@7: "text_search_query"("query_text_p"), jbe@7: 'StartSel=* StopSel=* HighlightAll=TRUE' ); jbe@7: END; jbe@7: $$; jbe@7: jbe@7: COMMENT ON FUNCTION "highlight" jbe@7: ( "body_p" TEXT, jbe@7: "query_text_p" TEXT ) jbe@7: IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.'; jbe@7: jbe@7: jbe@7: jbe@0: ------------------------- jbe@0: -- Tables and indicies -- jbe@0: ------------------------- jbe@0: jbe@8: jbe@385: CREATE TABLE "temporary_transaction_data" ( jbe@385: PRIMARY KEY ("txid", "key"), jbe@385: "txid" INT8 DEFAULT txid_current(), jbe@383: "key" TEXT, jbe@383: "value" TEXT NOT NULL ); jbe@383: jbe@385: COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed'; jbe@385: jbe@385: COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table'; jbe@383: jbe@383: jbe@104: CREATE TABLE "system_setting" ( jbe@104: "member_ttl" INTERVAL ); jbe@104: CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1)); jbe@104: jbe@104: COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.'; jbe@104: COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.'; jbe@104: jbe@184: COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.'; jbe@104: jbe@104: jbe@111: CREATE TABLE "contingent" ( jbe@293: PRIMARY KEY ("polling", "time_frame"), jbe@293: "polling" BOOLEAN, jbe@293: "time_frame" INTERVAL, jbe@111: "text_entry_limit" INT4, jbe@111: "initiative_limit" INT4 ); jbe@111: jbe@111: COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.'; jbe@111: 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@111: COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame'; jbe@111: COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame'; jbe@111: jbe@111: jbe@113: CREATE TYPE "notify_level" AS ENUM jbe@113: ('none', 'voting', 'verification', 'discussion', 'all'); jbe@113: jbe@113: COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything'; jbe@113: jbe@113: jbe@0: CREATE TABLE "member" ( jbe@0: "id" SERIAL4 PRIMARY KEY, jbe@13: "created" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@181: "invite_code" TEXT UNIQUE, jbe@232: "invite_code_expiry" TIMESTAMPTZ, jbe@182: "admin_comment" TEXT, jbe@181: "activated" TIMESTAMPTZ, jbe@184: "last_activity" DATE, jbe@42: "last_login" TIMESTAMPTZ, jbe@387: "last_delegation_check" TIMESTAMPTZ, jbe@45: "login" TEXT UNIQUE, jbe@0: "password" TEXT, jbe@440: "authority" TEXT, jbe@440: "authority_uid" TEXT, jbe@440: "authority_login" TEXT, jbe@99: "locked" BOOLEAN NOT NULL DEFAULT FALSE, jbe@181: "active" BOOLEAN NOT NULL DEFAULT FALSE, jbe@0: "admin" BOOLEAN NOT NULL DEFAULT FALSE, jbe@221: "lang" TEXT, jbe@7: "notify_email" TEXT, jbe@11: "notify_email_unconfirmed" TEXT, jbe@11: "notify_email_secret" TEXT UNIQUE, jbe@11: "notify_email_secret_expiry" TIMESTAMPTZ, jbe@55: "notify_email_lock_expiry" TIMESTAMPTZ, jbe@486: "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE, jbe@486: "notification_counter" INT4 NOT NULL DEFAULT 1, jbe@486: "notification_sample_size" INT4 NOT NULL DEFAULT 3, jbe@486: "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6), jbe@486: "notification_hour" INT4 CHECK ("notification_hour" BETWEEN 0 AND 23), jbe@387: "login_recovery_expiry" TIMESTAMPTZ, jbe@11: "password_reset_secret" TEXT UNIQUE, jbe@11: "password_reset_secret_expiry" TIMESTAMPTZ, jbe@225: "name" TEXT UNIQUE, jbe@7: "identification" TEXT UNIQUE, jbe@214: "authentication" TEXT, jbe@7: "organizational_unit" TEXT, jbe@7: "internal_posts" TEXT, jbe@7: "realname" TEXT, jbe@7: "birthday" DATE, jbe@7: "address" TEXT, jbe@7: "email" TEXT, jbe@7: "xmpp_address" TEXT, jbe@7: "website" TEXT, jbe@7: "phone" TEXT, jbe@7: "mobile_phone" TEXT, jbe@7: "profession" TEXT, jbe@7: "external_memberships" TEXT, jbe@7: "external_posts" TEXT, jbe@159: "formatting_engine" TEXT, jbe@7: "statement" TEXT, jbe@181: "text_search_data" TSVECTOR, jbe@184: CONSTRAINT "active_requires_activated_and_last_activity" jbe@225: CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)), jbe@440: CONSTRAINT "authority_requires_uid_and_vice_versa" jbe@447: CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)), jbe@440: CONSTRAINT "authority_uid_unique_per_authority" jbe@440: UNIQUE ("authority", "authority_uid"), jbe@440: CONSTRAINT "authority_login_requires_authority" jbe@440: CHECK ("authority" NOTNULL OR "authority_login" ISNULL), jbe@225: CONSTRAINT "name_not_null_if_activated" jbe@225: CHECK ("activated" ISNULL OR "name" NOTNULL) ); jbe@440: CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login"); jbe@0: CREATE INDEX "member_active_idx" ON "member" ("active"); jbe@8: CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data"); jbe@7: CREATE TRIGGER "update_text_search_data" jbe@7: BEFORE INSERT OR UPDATE ON "member" jbe@7: FOR EACH ROW EXECUTE PROCEDURE jbe@7: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', jbe@7: "name", "identification", "organizational_unit", "internal_posts", jbe@7: "realname", "external_memberships", "external_posts", "statement" ); jbe@0: jbe@0: COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization'; jbe@0: jbe@181: COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code'; jbe@181: COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time'; jbe@232: COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"'; jbe@182: COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes'; jbe@207: COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members'; jbe@184: COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members'; jbe@103: COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login'; jbe@387: COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)'; jbe@10: COMMENT ON COLUMN "member"."login" IS 'Login name'; jbe@10: COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)'; jbe@440: COMMENT ON COLUMN "member"."authority" IS 'NULL if LiquidFeedback Core is authoritative for the member account; otherwise a string that indicates the source/authority of the external account (e.g. ''LDAP'' for an LDAP account)'; jbe@440: COMMENT ON COLUMN "member"."authority_uid" IS 'Unique identifier (unique per "authority") that allows to identify an external account (e.g. even if the login name changes)'; jbe@440: COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)'; jbe@99: COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.'; jbe@184: COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".'; jbe@10: COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas'; jbe@221: COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member'; jbe@10: COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to'; jbe@10: COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification'; jbe@10: COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"'; jbe@10: COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"'; jbe@55: COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)'; jbe@460: COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications'; jbe@387: COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed'; jbe@387: COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery'; jbe@387: COMMENT ON COLUMN "member"."password_reset_secret_expiry" IS 'Date/time until the password recovery secret is valid, and date/time after which another password recovery attempt is allowed'; jbe@225: COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet'; jbe@10: COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member'; jbe@214: COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated'; jbe@10: COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to'; jbe@10: COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization'; jbe@10: COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"'; jbe@10: COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications'; jbe@10: COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in'; jbe@10: COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization'; jbe@159: COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"'; jbe@207: COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile'; jbe@7: jbe@7: jbe@13: CREATE TABLE "member_history" ( jbe@13: "id" SERIAL8 PRIMARY KEY, jbe@13: "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@13: "until" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@42: "active" BOOLEAN NOT NULL, jbe@13: "name" TEXT NOT NULL ); jbe@45: CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id"); jbe@13: jbe@57: COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members'; jbe@13: jbe@13: COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)'; jbe@57: COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid'; jbe@13: jbe@13: jbe@159: CREATE TABLE "rendered_member_statement" ( jbe@159: PRIMARY KEY ("member_id", "format"), jbe@461: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@159: "format" TEXT, jbe@159: "content" TEXT NOT NULL ); jbe@159: jbe@159: COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)'; jbe@9: jbe@9: jbe@9: CREATE TABLE "setting" ( jbe@9: PRIMARY KEY ("member_id", "key"), jbe@9: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@9: "key" TEXT NOT NULL, jbe@9: "value" TEXT NOT NULL ); jbe@9: CREATE INDEX "setting_key_idx" ON "setting" ("key"); jbe@9: jbe@38: COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string'; jbe@9: jbe@9: COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix'; jbe@9: jbe@9: jbe@16: CREATE TABLE "setting_map" ( jbe@16: PRIMARY KEY ("member_id", "key", "subkey"), jbe@16: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@16: "key" TEXT NOT NULL, jbe@16: "subkey" TEXT NOT NULL, jbe@16: "value" TEXT NOT NULL ); jbe@16: CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key"); jbe@16: jbe@23: COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs'; jbe@16: jbe@16: COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix'; jbe@16: COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry'; jbe@16: COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry'; jbe@16: jbe@16: jbe@23: CREATE TABLE "member_relation_setting" ( jbe@23: PRIMARY KEY ("member_id", "key", "other_member_id"), jbe@23: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "key" TEXT NOT NULL, jbe@23: "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "value" TEXT NOT NULL ); jbe@23: jbe@38: COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string'; jbe@23: jbe@23: jbe@7: CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar'); jbe@7: jbe@7: COMMENT ON TYPE "member_image_type" IS 'Types of images for a member'; jbe@7: jbe@7: jbe@7: CREATE TABLE "member_image" ( jbe@7: PRIMARY KEY ("member_id", "image_type", "scaled"), jbe@7: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@7: "image_type" "member_image_type", jbe@7: "scaled" BOOLEAN, jbe@7: "content_type" TEXT, jbe@7: "data" BYTEA NOT NULL ); jbe@7: jbe@7: COMMENT ON TABLE "member_image" IS 'Images of members'; jbe@7: jbe@7: COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image'; jbe@0: jbe@0: jbe@4: CREATE TABLE "member_count" ( jbe@341: "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@5: "total_count" INT4 NOT NULL ); jbe@4: jbe@5: COMMENT ON TABLE "member_count" IS 'Contains one row which contains the total count of active(!) members and a timestamp indicating when the total member count and area member counts were calculated'; jbe@4: jbe@5: COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated'; jbe@5: COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members'; jbe@4: jbe@4: jbe@0: CREATE TABLE "contact" ( jbe@0: PRIMARY KEY ("member_id", "other_member_id"), jbe@0: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@11: "public" BOOLEAN NOT NULL DEFAULT FALSE, jbe@11: CONSTRAINT "cant_save_yourself_as_contact" jbe@11: CHECK ("member_id" != "other_member_id") ); jbe@113: CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id"); jbe@0: jbe@0: COMMENT ON TABLE "contact" IS 'Contact lists'; jbe@0: jbe@0: COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list'; jbe@0: COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list'; jbe@0: COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically'; jbe@0: jbe@0: jbe@113: CREATE TABLE "ignored_member" ( jbe@113: PRIMARY KEY ("member_id", "other_member_id"), jbe@113: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@113: "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@113: CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id"); jbe@113: jbe@113: COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members'; jbe@113: jbe@113: COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone'; jbe@113: COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored'; jbe@113: jbe@113: jbe@220: CREATE TABLE "session" ( jbe@220: "ident" TEXT PRIMARY KEY, jbe@220: "additional_secret" TEXT, jbe@220: "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours', jbe@461: "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL, jbe@440: "authority" TEXT, jbe@440: "authority_uid" TEXT, jbe@440: "authority_login" TEXT, jbe@387: "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE, jbe@220: "lang" TEXT ); jbe@220: CREATE INDEX "session_expiry_idx" ON "session" ("expiry"); jbe@220: jbe@220: COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer'; jbe@220: jbe@220: COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)'; jbe@220: COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks'; jbe@220: COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in'; jbe@440: COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation'; jbe@440: COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation'; jbe@440: COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation'; jbe@387: COMMENT ON COLUMN "session"."needs_delegation_check" IS 'Set to TRUE, if member must perform a delegation check to proceed with login; see column "last_delegation_check" in "member" table'; jbe@220: COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language'; jbe@220: jbe@220: jbe@424: CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple'); jbe@424: jbe@424: COMMENT ON TYPE "defeat_strength" IS 'How pairwise defeats are measured for the Schulze method: ''simple'' = only the number of winning votes, ''tuple'' = primarily the number of winning votes, secondarily the number of losing votes'; jbe@424: jbe@424: jbe@424: CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2'); jbe@424: jbe@424: COMMENT ON TYPE "tie_breaking" IS 'Tie-breaker for the Schulze method: ''simple'' = only initiative ids are used, ''variant1'' = use initiative ids in variant 1 for tie breaking of the links (TBRL) and sequentially forbid shared links, ''variant2'' = use initiative ids in variant 2 for tie breaking of the links (TBRL) and sequentially forbid shared links'; jbe@424: jbe@424: jbe@0: CREATE TABLE "policy" ( jbe@0: "id" SERIAL4 PRIMARY KEY, jbe@9: "index" INT4 NOT NULL, jbe@0: "active" BOOLEAN NOT NULL DEFAULT TRUE, jbe@0: "name" TEXT NOT NULL UNIQUE, jbe@0: "description" TEXT NOT NULL DEFAULT '', jbe@261: "polling" BOOLEAN NOT NULL DEFAULT FALSE, jbe@447: "min_admission_time" INTERVAL, jbe@447: "max_admission_time" INTERVAL, jbe@261: "discussion_time" INTERVAL, jbe@261: "verification_time" INTERVAL, jbe@261: "voting_time" INTERVAL, jbe@292: "issue_quorum_num" INT4, jbe@292: "issue_quorum_den" INT4, jbe@0: "initiative_quorum_num" INT4 NOT NULL, jbe@10: "initiative_quorum_den" INT4 NOT NULL, jbe@424: "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple', jbe@424: "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1', jbe@167: "direct_majority_num" INT4 NOT NULL DEFAULT 1, jbe@167: "direct_majority_den" INT4 NOT NULL DEFAULT 2, jbe@167: "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE, jbe@167: "direct_majority_positive" INT4 NOT NULL DEFAULT 0, jbe@167: "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0, jbe@167: "indirect_majority_num" INT4 NOT NULL DEFAULT 1, jbe@167: "indirect_majority_den" INT4 NOT NULL DEFAULT 2, jbe@167: "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE, jbe@167: "indirect_majority_positive" INT4 NOT NULL DEFAULT 0, jbe@167: "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0, jbe@429: "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE, jbe@260: "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE, jbe@260: CONSTRAINT "timing" CHECK ( jbe@261: ( "polling" = FALSE AND jbe@447: "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND jbe@454: "min_admission_time" <= "max_admission_time" AND jbe@447: "discussion_time" NOTNULL AND jbe@447: "verification_time" NOTNULL AND jbe@447: "voting_time" NOTNULL ) OR jbe@261: ( "polling" = TRUE AND jbe@447: "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND jbe@447: "discussion_time" NOTNULL AND jbe@447: "verification_time" NOTNULL AND jbe@447: "voting_time" NOTNULL ) OR jbe@447: ( "polling" = TRUE AND jbe@447: "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND jbe@447: "discussion_time" ISNULL AND jbe@447: "verification_time" ISNULL AND jbe@447: "voting_time" ISNULL ) ), jbe@292: CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK ( jbe@447: "polling" = ("issue_quorum_num" ISNULL) AND jbe@447: "polling" = ("issue_quorum_den" ISNULL) ), jbe@429: CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK ( jbe@429: "defeat_strength" = 'tuple'::"defeat_strength" OR jbe@429: "no_reverse_beat_path" = FALSE ) ); jbe@0: CREATE INDEX "policy_active_idx" ON "policy" ("active"); jbe@0: jbe@0: COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)'; jbe@0: jbe@9: COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings'; jbe@0: COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues'; jbe@447: 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; "min_admission_time" and "max_admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues'; jbe@447: COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open'; jbe@447: COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"'; jbe@207: COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"'; jbe@207: COMMENT ON COLUMN "policy"."verification_time" IS 'Duration of issue state ''verification''; Regular time until an issue is "fully_frozen" (e.g. entering issue state ''voting'') after being "half_frozen"'; jbe@207: COMMENT ON COLUMN "policy"."voting_time" IS 'Duration of issue state ''voting''; Time after an issue is "fully_frozen" but not "closed" (duration of issue state ''voting'')'; jbe@207: COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion'''; jbe@207: COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion'''; jbe@10: COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting'; jbe@10: COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting'; jbe@428: COMMENT ON COLUMN "policy"."defeat_strength" IS 'How pairwise defeats are measured for the Schulze method; see type "defeat_strength"; ''tuple'' is the recommended setting'; jbe@428: COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended'; jbe@167: COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner'; jbe@167: COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner'; jbe@167: COMMENT ON COLUMN "policy"."direct_majority_strict" IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.'; jbe@167: COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner'; jbe@167: COMMENT ON COLUMN "policy"."direct_majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner'; jbe@167: COMMENT ON COLUMN "policy"."indirect_majority_num" IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner'; jbe@167: COMMENT ON COLUMN "policy"."indirect_majority_den" IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner'; jbe@167: COMMENT ON COLUMN "policy"."indirect_majority_strict" IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.'; jbe@167: COMMENT ON COLUMN "policy"."indirect_majority_positive" IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner'; jbe@167: COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner'; jbe@429: COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.'; jbe@429: COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").'; jbe@0: jbe@0: jbe@97: CREATE TABLE "unit" ( jbe@97: "id" SERIAL4 PRIMARY KEY, jbe@97: "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@97: "active" BOOLEAN NOT NULL DEFAULT TRUE, jbe@97: "name" TEXT NOT NULL, jbe@97: "description" TEXT NOT NULL DEFAULT '', jbe@444: "external_reference" TEXT, jbe@97: "member_count" INT4, jbe@97: "text_search_data" TSVECTOR ); jbe@97: CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL; jbe@97: CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id"); jbe@97: CREATE INDEX "unit_active_idx" ON "unit" ("active"); jbe@97: CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data"); jbe@97: CREATE TRIGGER "update_text_search_data" jbe@97: BEFORE INSERT OR UPDATE ON "unit" jbe@97: FOR EACH ROW EXECUTE PROCEDURE jbe@97: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', jbe@97: "name", "description" ); jbe@97: jbe@97: COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.'; jbe@97: jbe@444: COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed'; jbe@444: COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit'; jbe@444: COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference'; jbe@444: COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"'; jbe@97: jbe@97: jbe@465: CREATE TABLE "subscription" ( jbe@465: PRIMARY KEY ("member_id", "unit_id"), jbe@465: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@465: "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@465: CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id"); jbe@465: jbe@465: COMMENT ON TABLE "subscription" IS 'An entry in this table denotes that the member wishes to receive notifications regardless of his/her privileges in the given unit'; jbe@465: jbe@465: jbe@203: CREATE TABLE "unit_setting" ( jbe@203: PRIMARY KEY ("member_id", "key", "unit_id"), jbe@203: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@203: "key" TEXT NOT NULL, jbe@203: "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@203: "value" TEXT NOT NULL ); jbe@203: jbe@203: COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings'; jbe@203: jbe@203: jbe@0: CREATE TABLE "area" ( jbe@0: "id" SERIAL4 PRIMARY KEY, jbe@97: "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "active" BOOLEAN NOT NULL DEFAULT TRUE, jbe@0: "name" TEXT NOT NULL, jbe@4: "description" TEXT NOT NULL DEFAULT '', jbe@444: "external_reference" TEXT, jbe@5: "direct_member_count" INT4, jbe@5: "member_weight" INT4, jbe@7: "text_search_data" TSVECTOR ); jbe@97: CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id"); jbe@0: CREATE INDEX "area_active_idx" ON "area" ("active"); jbe@8: CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data"); jbe@7: CREATE TRIGGER "update_text_search_data" jbe@7: BEFORE INSERT OR UPDATE ON "area" jbe@7: FOR EACH ROW EXECUTE PROCEDURE jbe@7: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', jbe@7: "name", "description" ); jbe@0: jbe@0: COMMENT ON TABLE "area" IS 'Subject areas'; jbe@0: jbe@5: COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area'; jbe@444: COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference'; jbe@5: COMMENT ON COLUMN "area"."direct_member_count" IS 'Number of active members of that area (ignoring their weight), as calculated from view "area_member_count"'; jbe@5: COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations'; jbe@0: jbe@0: jbe@465: CREATE TABLE "ignored_area" ( jbe@465: PRIMARY KEY ("member_id", "area_id"), jbe@465: "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@465: "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@465: CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id"); jbe@465: jbe@465: COMMENT ON TABLE "ignored_area" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given subject area unless he/she declared interested in a particular issue'; jbe@465: jbe@465: jbe@23: CREATE TABLE "area_setting" ( jbe@23: PRIMARY KEY ("member_id", "key", "area_id"), jbe@23: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "key" TEXT NOT NULL, jbe@23: "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "value" TEXT NOT NULL ); jbe@23: jbe@23: COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings'; jbe@23: jbe@23: jbe@9: CREATE TABLE "allowed_policy" ( jbe@9: PRIMARY KEY ("area_id", "policy_id"), jbe@9: "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@9: "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@9: "default_policy" BOOLEAN NOT NULL DEFAULT FALSE ); jbe@9: CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy"; jbe@9: jbe@9: COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area'; jbe@9: jbe@9: COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.'; jbe@9: jbe@9: jbe@21: CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze'); jbe@21: jbe@21: COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period'; jbe@8: jbe@8: jbe@112: CREATE TYPE "issue_state" AS ENUM ( jbe@112: 'admission', 'discussion', 'verification', 'voting', jbe@389: 'canceled_by_admin', jbe@113: 'canceled_revoked_before_accepted', jbe@113: 'canceled_issue_not_accepted', jbe@113: 'canceled_after_revocation_during_discussion', jbe@113: 'canceled_after_revocation_during_verification', jbe@113: 'canceled_no_initiative_admitted', jbe@112: 'finished_without_winner', 'finished_with_winner'); jbe@111: jbe@111: COMMENT ON TYPE "issue_state" IS 'State of issues'; jbe@111: jbe@111: jbe@0: CREATE TABLE "issue" ( jbe@0: "id" SERIAL4 PRIMARY KEY, jbe@0: "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, jbe@389: "admin_notice" TEXT, jbe@444: "external_reference" TEXT, jbe@111: "state" "issue_state" NOT NULL DEFAULT 'admission', jbe@328: "phase_finished" TIMESTAMPTZ, jbe@0: "created" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@0: "accepted" TIMESTAMPTZ, jbe@3: "half_frozen" TIMESTAMPTZ, jbe@3: "fully_frozen" TIMESTAMPTZ, jbe@0: "closed" TIMESTAMPTZ, jbe@59: "cleaned" TIMESTAMPTZ, jbe@447: "min_admission_time" INTERVAL, jbe@447: "max_admission_time" INTERVAL, jbe@22: "discussion_time" INTERVAL NOT NULL, jbe@22: "verification_time" INTERVAL NOT NULL, jbe@22: "voting_time" INTERVAL NOT NULL, jbe@0: "snapshot" TIMESTAMPTZ, jbe@8: "latest_snapshot_event" "snapshot_event", jbe@0: "population" INT4, jbe@4: "voter_count" INT4, jbe@170: "status_quo_schulze_rank" INT4, jbe@291: CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK ( jbe@447: ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND jbe@452: ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ), jbe@340: CONSTRAINT "valid_state" CHECK ( jbe@340: ( jbe@340: ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR jbe@340: ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR jbe@340: ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR jbe@340: ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL) jbe@340: ) AND ( jbe@340: ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR jbe@340: ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR jbe@340: ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR jbe@340: ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR jbe@389: ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR jbe@340: ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR jbe@340: ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR jbe@340: ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR jbe@340: ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR jbe@340: ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR jbe@340: ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR jbe@340: ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") jbe@111: )), jbe@328: CONSTRAINT "phase_finished_only_when_not_closed" CHECK ( jbe@328: "phase_finished" ISNULL OR "closed" ISNULL ), jbe@3: CONSTRAINT "state_change_order" CHECK ( jbe@10: "created" <= "accepted" AND jbe@10: "accepted" <= "half_frozen" AND jbe@10: "half_frozen" <= "fully_frozen" AND jbe@3: "fully_frozen" <= "closed" ), jbe@61: CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK ( jbe@61: "cleaned" ISNULL OR "closed" NOTNULL ), jbe@10: CONSTRAINT "last_snapshot_on_full_freeze" jbe@10: CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet jbe@10: CONSTRAINT "freeze_requires_snapshot" jbe@10: CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL), jbe@10: CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event" jbe@447: CHECK (("snapshot" NOTNULL) = ("latest_snapshot_event" NOTNULL)) ); jbe@0: CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id"); jbe@0: CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id"); jbe@16: CREATE INDEX "issue_created_idx" ON "issue" ("created"); jbe@16: CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted"); jbe@16: CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen"); jbe@16: CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen"); jbe@16: CREATE INDEX "issue_closed_idx" ON "issue" ("closed"); jbe@0: CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL; jbe@16: CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL; jbe@0: jbe@0: COMMENT ON TABLE "issue" IS 'Groups of initiatives'; jbe@0: jbe@389: COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections'; jbe@444: COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference'; jbe@328: COMMENT ON COLUMN "issue"."phase_finished" IS 'Set to a value NOTNULL, if the current phase has finished, but calculations are pending; No changes in this issue shall be made by the frontend or API when this value is set'; jbe@170: COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"'; jbe@170: COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.'; jbe@170: COMMENT ON COLUMN "issue"."fully_frozen" IS 'Point in time, when "verification_time" has elapsed and voting has started; Frontends must ensure that for fully_frozen issues additionally to the restrictions for half_frozen issues a) initiatives are not created, b) no interest is created or removed, c) no supporters are added or removed, d) no opinions are created, changed or deleted.'; jbe@447: COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "max_admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.'; jbe@170: COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted'; jbe@447: COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue'; jbe@447: COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue'; jbe@170: COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue'; jbe@170: COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue'; jbe@170: COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue'; jbe@170: COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated'; jbe@170: COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables'; jbe@170: COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"'; jbe@170: COMMENT ON COLUMN "issue"."voter_count" IS 'Total number of direct and delegating voters; This value is related to the final voting, while "population" is related to snapshots before the final voting'; jbe@170: COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function'; jbe@0: jbe@0: jbe@410: CREATE TABLE "issue_order_in_admission_state" ( jbe@400: "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@410: "order_in_area" INT4, jbe@410: "order_in_unit" INT4 ); jbe@410: jbe@410: COMMENT ON TABLE "issue_order_in_admission_state" IS 'Ordering information for issues that are not stored in the "issue" table to avoid locking of multiple issues at once; Filled/updated by "lf_update_issue_order"'; jbe@410: jbe@410: COMMENT ON COLUMN "issue_order_in_admission_state"."id" IS 'References "issue" ("id") but has no referential integrity trigger associated, due to performance/locking issues'; jbe@410: COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_area" IS 'Order of issues in admission state within a single area; NULL values sort last'; jbe@410: COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_unit" IS 'Order of issues in admission state within all areas of a unit; NULL values sort last'; jbe@0: jbe@0: jbe@23: CREATE TABLE "issue_setting" ( jbe@23: PRIMARY KEY ("member_id", "key", "issue_id"), jbe@23: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "key" TEXT NOT NULL, jbe@23: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "value" TEXT NOT NULL ); jbe@23: jbe@23: COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings'; jbe@23: jbe@23: jbe@0: CREATE TABLE "initiative" ( jbe@0: UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote" jbe@0: "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "id" SERIAL4 PRIMARY KEY, jbe@0: "name" TEXT NOT NULL, jbe@261: "polling" BOOLEAN NOT NULL DEFAULT FALSE, jbe@0: "created" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@0: "revoked" TIMESTAMPTZ, jbe@112: "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, jbe@14: "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@444: "external_reference" TEXT, jbe@0: "admitted" BOOLEAN, jbe@0: "supporter_count" INT4, jbe@0: "informed_supporter_count" INT4, jbe@0: "satisfied_supporter_count" INT4, jbe@0: "satisfied_informed_supporter_count" INT4, jbe@313: "harmonic_weight" NUMERIC(12, 3), jbe@352: "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE, jbe@414: "first_preference_votes" INT4, jbe@0: "positive_votes" INT4, jbe@0: "negative_votes" INT4, jbe@167: "direct_majority" BOOLEAN, jbe@167: "indirect_majority" BOOLEAN, jbe@170: "schulze_rank" INT4, jbe@167: "better_than_status_quo" BOOLEAN, jbe@167: "worse_than_status_quo" BOOLEAN, jbe@429: "reverse_beat_path" BOOLEAN, jbe@154: "multistage_majority" BOOLEAN, jbe@154: "eligible" BOOLEAN, jbe@126: "winner" BOOLEAN, jbe@0: "rank" INT4, jbe@7: "text_search_data" TSVECTOR, jbe@112: CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null" jbe@447: CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)), jbe@14: CONSTRAINT "non_revoked_initiatives_cant_suggest_other" jbe@14: CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL), jbe@0: CONSTRAINT "revoked_initiatives_cant_be_admitted" jbe@0: CHECK ("revoked" ISNULL OR "admitted" ISNULL), jbe@128: CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK ( jbe@128: ( "admitted" NOTNULL AND "admitted" = TRUE ) OR jbe@414: ( "first_preference_votes" ISNULL AND jbe@414: "positive_votes" ISNULL AND "negative_votes" ISNULL AND jbe@167: "direct_majority" ISNULL AND "indirect_majority" ISNULL AND jbe@173: "schulze_rank" ISNULL AND jbe@167: "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND jbe@429: "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND jbe@173: "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ), jbe@173: CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")), jbe@175: CONSTRAINT "minimum_requirement_to_be_eligible" CHECK ( jbe@175: "eligible" = FALSE OR jbe@175: ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ), jbe@175: CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE), jbe@175: CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1), jbe@176: CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE), jbe@173: CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") ); jbe@16: CREATE INDEX "initiative_created_idx" ON "initiative" ("created"); jbe@16: CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked"); jbe@8: CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data"); jbe@7: CREATE TRIGGER "update_text_search_data" jbe@7: BEFORE INSERT OR UPDATE ON "initiative" jbe@7: FOR EACH ROW EXECUTE PROCEDURE jbe@450: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name"); jbe@0: jbe@10: COMMENT ON TABLE "initiative" IS 'Group of members publishing drafts for resolutions to be passed; Frontends must ensure that initiatives of half_frozen issues are not revoked, and that initiatives of fully_frozen or closed issues are neither revoked nor created.'; jbe@0: jbe@289: COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")'; jbe@210: COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative'; jbe@210: COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative'; jbe@444: COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference'; jbe@210: COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue'; jbe@0: COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; jbe@0: COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; jbe@0: COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; jbe@0: COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; jbe@320: 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; shall be used as secondary sorting key after "admitted" as primary sorting key'; jbe@352: COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time'; jbe@414: COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice'; jbe@414: COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo'; jbe@414: COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo'; jbe@210: COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"'; jbe@210: COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths'; jbe@411: COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking'; jbe@411: COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo'; jbe@411: COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (DEPRECATED, since schulze-ranking is unique per issue; use "better_than_status_quo"=FALSE)'; jbe@429: COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties) from this initiative to the status quo; set to NULL if "policy"."defeat_strength" is set to ''simple'''; jbe@210: COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X'; jbe@429: COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative has a "direct_majority" and an "indirect_majority", is "better_than_status_quo" and depending on selected policy the initiative has no "reverse_beat_path" or "multistage_majority"'; jbe@411: COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"'; jbe@210: COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives'; jbe@0: jbe@0: jbe@61: CREATE TABLE "battle" ( jbe@126: "issue_id" INT4 NOT NULL, jbe@61: "winning_initiative_id" INT4, jbe@61: FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@61: "losing_initiative_id" INT4, jbe@61: FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@126: "count" INT4 NOT NULL, jbe@126: CONSTRAINT "initiative_ids_not_equal" CHECK ( jbe@126: "winning_initiative_id" != "losing_initiative_id" OR jbe@126: ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR jbe@126: ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) ); jbe@126: CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id"); jbe@126: CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL; jbe@126: CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL; jbe@126: jbe@126: COMMENT ON TABLE "battle" IS 'Number of members preferring one initiative to another; Filled by "battle_view" when closing an issue; NULL as initiative_id denotes virtual "status-quo" initiative'; jbe@61: jbe@61: jbe@113: CREATE TABLE "ignored_initiative" ( jbe@465: PRIMARY KEY ("member_id", "initiative_id"), jbe@465: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@465: "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@465: CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id"); jbe@113: jbe@113: COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives'; jbe@113: jbe@113: jbe@23: CREATE TABLE "initiative_setting" ( jbe@23: PRIMARY KEY ("member_id", "key", "initiative_id"), jbe@23: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "key" TEXT NOT NULL, jbe@23: "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "value" TEXT NOT NULL ); jbe@23: jbe@23: COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings'; jbe@23: jbe@23: jbe@0: CREATE TABLE "draft" ( jbe@0: UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter" jbe@0: "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "id" SERIAL8 PRIMARY KEY, jbe@0: "created" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@0: "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, jbe@9: "formatting_engine" TEXT, jbe@7: "content" TEXT NOT NULL, jbe@444: "external_reference" TEXT, jbe@7: "text_search_data" TSVECTOR ); jbe@16: CREATE INDEX "draft_created_idx" ON "draft" ("created"); jbe@9: CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created"); jbe@8: CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data"); jbe@7: CREATE TRIGGER "update_text_search_data" jbe@7: BEFORE INSERT OR UPDATE ON "draft" jbe@7: FOR EACH ROW EXECUTE PROCEDURE jbe@7: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content"); jbe@0: jbe@10: COMMENT ON TABLE "draft" IS 'Drafts of initiatives to solve issues; Frontends must ensure that new drafts for initiatives of half_frozen, fully_frozen or closed issues can''t be created.'; jbe@0: jbe@444: COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used'; jbe@444: COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"'; jbe@444: COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference'; jbe@9: jbe@0: jbe@63: CREATE TABLE "rendered_draft" ( jbe@63: PRIMARY KEY ("draft_id", "format"), jbe@63: "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@63: "format" TEXT, jbe@63: "content" TEXT NOT NULL ); jbe@63: jbe@63: COMMENT ON TABLE "rendered_draft" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)'; jbe@63: jbe@63: jbe@0: CREATE TABLE "suggestion" ( jbe@0: UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion" jbe@0: "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "id" SERIAL8 PRIMARY KEY, jbe@160: "draft_id" INT8 NOT NULL, jbe@160: FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE, jbe@0: "created" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@0: "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, jbe@0: "name" TEXT NOT NULL, jbe@159: "formatting_engine" TEXT, jbe@159: "content" TEXT NOT NULL DEFAULT '', jbe@444: "external_reference" TEXT, jbe@7: "text_search_data" TSVECTOR, jbe@0: "minus2_unfulfilled_count" INT4, jbe@0: "minus2_fulfilled_count" INT4, jbe@0: "minus1_unfulfilled_count" INT4, jbe@0: "minus1_fulfilled_count" INT4, jbe@0: "plus1_unfulfilled_count" INT4, jbe@0: "plus1_fulfilled_count" INT4, jbe@0: "plus2_unfulfilled_count" INT4, jbe@352: "plus2_fulfilled_count" INT4, jbe@352: "proportional_order" INT4 ); jbe@16: CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created"); jbe@9: CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created"); jbe@8: CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data"); jbe@7: CREATE TRIGGER "update_text_search_data" jbe@7: BEFORE INSERT OR UPDATE ON "suggestion" jbe@7: FOR EACH ROW EXECUTE PROCEDURE jbe@7: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', jbe@159: "name", "content"); jbe@0: jbe@10: COMMENT ON TABLE "suggestion" IS 'Suggestions to initiators, to change the current draft; must not be deleted explicitly, as they vanish automatically if the last opinion is deleted'; jbe@0: jbe@160: COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")'; jbe@444: COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference'; jbe@0: COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@0: COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@0: COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@0: COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@0: COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@0: COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@0: COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@0: COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; jbe@378: COMMENT ON COLUMN "suggestion"."proportional_order" IS 'To be used for sorting suggestions within an initiative; NULL values sort last; updated by "lf_update_suggestion_order"'; jbe@0: jbe@0: jbe@159: CREATE TABLE "rendered_suggestion" ( jbe@159: PRIMARY KEY ("suggestion_id", "format"), jbe@159: "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@159: "format" TEXT, jbe@159: "content" TEXT NOT NULL ); jbe@159: jbe@159: COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)'; jbe@159: jbe@159: jbe@23: CREATE TABLE "suggestion_setting" ( jbe@23: PRIMARY KEY ("member_id", "key", "suggestion_id"), jbe@23: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "key" TEXT NOT NULL, jbe@23: "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@23: "value" TEXT NOT NULL ); jbe@23: jbe@23: COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings'; jbe@23: jbe@23: jbe@97: CREATE TABLE "privilege" ( jbe@97: PRIMARY KEY ("unit_id", "member_id"), jbe@97: "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@97: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@97: "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE, jbe@97: "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE, jbe@97: "area_manager" BOOLEAN NOT NULL DEFAULT FALSE, jbe@261: "member_manager" BOOLEAN NOT NULL DEFAULT FALSE, jbe@261: "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE, jbe@261: "voting_right" BOOLEAN NOT NULL DEFAULT TRUE, jbe@261: "polling_right" BOOLEAN NOT NULL DEFAULT FALSE ); jbe@97: jbe@97: COMMENT ON TABLE "privilege" IS 'Members rights related to each unit'; jbe@97: jbe@289: COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members'; jbe@289: COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units'; jbe@289: COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters'; jbe@289: COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"'; jbe@289: COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative'; jbe@289: 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@97: jbe@97: jbe@0: CREATE TABLE "membership" ( jbe@0: PRIMARY KEY ("area_id", "member_id"), jbe@0: "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@169: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@0: CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id"); jbe@0: jbe@0: COMMENT ON TABLE "membership" IS 'Interest of members in topic areas'; jbe@0: jbe@0: jbe@0: CREATE TABLE "interest" ( jbe@0: PRIMARY KEY ("issue_id", "member_id"), jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@148: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@0: CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id"); jbe@0: jbe@10: COMMENT ON TABLE "interest" IS 'Interest of members in a particular issue; Frontends must ensure that interest for fully_frozen or closed issues is not added or removed.'; jbe@0: jbe@0: jbe@0: CREATE TABLE "initiator" ( jbe@0: PRIMARY KEY ("initiative_id", "member_id"), jbe@0: "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@14: "accepted" BOOLEAN ); jbe@0: CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id"); jbe@0: jbe@10: COMMENT ON TABLE "initiator" IS 'Members who are allowed to post new drafts; Frontends must ensure that initiators are not added or removed from half_frozen, fully_frozen or closed initiatives.'; jbe@0: jbe@14: COMMENT ON COLUMN "initiator"."accepted" IS 'If "accepted" is NULL, then the member was invited to be a co-initiator, but has not answered yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.'; jbe@0: jbe@0: jbe@0: CREATE TABLE "supporter" ( jbe@0: "issue_id" INT4 NOT NULL, jbe@0: PRIMARY KEY ("initiative_id", "member_id"), jbe@0: "initiative_id" INT4, jbe@0: "member_id" INT4, jbe@0: "draft_id" INT8 NOT NULL, jbe@10: FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@160: FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE ); jbe@0: CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id"); jbe@0: jbe@10: COMMENT ON TABLE "supporter" IS 'Members who support an initiative (conditionally); Frontends must ensure that supporters are not added or removed from fully_frozen or closed initiatives.'; jbe@0: jbe@207: COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary'; jbe@160: COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")'; jbe@84: jbe@0: jbe@0: CREATE TABLE "opinion" ( jbe@0: "initiative_id" INT4 NOT NULL, jbe@0: PRIMARY KEY ("suggestion_id", "member_id"), jbe@0: "suggestion_id" INT8, jbe@0: "member_id" INT4, jbe@0: "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0), jbe@0: "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE, jbe@42: FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@10: CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id"); jbe@0: jbe@10: COMMENT ON TABLE "opinion" IS 'Opinion on suggestions (criticism related to initiatives); Frontends must ensure that opinions are not created modified or deleted when related to fully_frozen or closed issues.'; jbe@0: jbe@0: COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support'; jbe@0: jbe@0: jbe@97: CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue'); jbe@97: jbe@97: COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)'; jbe@10: jbe@10: jbe@0: CREATE TABLE "delegation" ( jbe@0: "id" SERIAL8 PRIMARY KEY, jbe@0: "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@86: "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@10: "scope" "delegation_scope" NOT NULL, jbe@97: "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"), jbe@97: CONSTRAINT "no_unit_delegation_to_null" jbe@97: CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'), jbe@10: CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK ( jbe@97: ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR jbe@97: ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR jbe@97: ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ), jbe@97: UNIQUE ("unit_id", "truster_id"), jbe@74: UNIQUE ("area_id", "truster_id"), jbe@74: UNIQUE ("issue_id", "truster_id") ); jbe@0: CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id"); jbe@0: CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id"); jbe@0: jbe@0: COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members'; jbe@0: jbe@97: COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL'; jbe@0: COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL'; jbe@0: COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL'; jbe@0: jbe@0: jbe@0: CREATE TABLE "direct_population_snapshot" ( jbe@0: PRIMARY KEY ("issue_id", "event", "member_id"), jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "event" "snapshot_event", jbe@45: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, jbe@54: "weight" INT4 ); jbe@0: CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id"); jbe@0: jbe@389: COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@148: COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; jbe@148: COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"'; jbe@0: jbe@0: jbe@0: CREATE TABLE "delegating_population_snapshot" ( jbe@0: PRIMARY KEY ("issue_id", "event", "member_id"), jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "event" "snapshot_event", jbe@45: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, jbe@8: "weight" INT4, jbe@10: "scope" "delegation_scope" NOT NULL, jbe@0: "delegate_member_ids" INT4[] NOT NULL ); jbe@0: CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id"); jbe@0: jbe@389: COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table; for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@0: COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; jbe@0: COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member'; jbe@8: COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight'; jbe@0: COMMENT ON COLUMN "delegating_population_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_population_snapshot"'; jbe@0: jbe@0: jbe@0: CREATE TABLE "direct_interest_snapshot" ( jbe@0: PRIMARY KEY ("issue_id", "event", "member_id"), jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "event" "snapshot_event", jbe@45: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, jbe@144: "weight" INT4 ); jbe@0: CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id"); jbe@0: jbe@389: COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@0: COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; jbe@0: COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"'; jbe@0: jbe@0: jbe@0: CREATE TABLE "delegating_interest_snapshot" ( jbe@0: PRIMARY KEY ("issue_id", "event", "member_id"), jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@0: "event" "snapshot_event", jbe@45: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, jbe@8: "weight" INT4, jbe@10: "scope" "delegation_scope" NOT NULL, jbe@0: "delegate_member_ids" INT4[] NOT NULL ); jbe@0: CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id"); jbe@0: jbe@389: COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table; for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@0: COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; jbe@0: COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member'; jbe@8: COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight'; jbe@0: COMMENT ON COLUMN "delegating_interest_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_interest_snapshot"'; jbe@0: jbe@0: jbe@0: CREATE TABLE "direct_supporter_snapshot" ( jbe@0: "issue_id" INT4 NOT NULL, jbe@0: PRIMARY KEY ("initiative_id", "event", "member_id"), jbe@0: "initiative_id" INT4, jbe@0: "event" "snapshot_event", jbe@45: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, jbe@204: "draft_id" INT8 NOT NULL, jbe@0: "informed" BOOLEAN NOT NULL, jbe@0: "satisfied" BOOLEAN NOT NULL, jbe@0: FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@204: FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE, jbe@0: FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@0: CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id"); jbe@0: jbe@389: COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot"); for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@207: COMMENT ON COLUMN "direct_supporter_snapshot"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary'; jbe@0: COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; jbe@0: COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative'; jbe@0: COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s'; jbe@0: jbe@0: jbe@113: CREATE TABLE "non_voter" ( jbe@113: PRIMARY KEY ("issue_id", "member_id"), jbe@113: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@113: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); jbe@113: CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id"); jbe@113: jbe@113: COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue'; jbe@113: jbe@113: jbe@0: CREATE TABLE "direct_voter" ( jbe@0: PRIMARY KEY ("issue_id", "member_id"), jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@45: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, jbe@285: "weight" INT4, jbe@285: "comment_changed" TIMESTAMPTZ, jbe@285: "formatting_engine" TEXT, jbe@285: "comment" TEXT, jbe@285: "text_search_data" TSVECTOR ); jbe@0: CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id"); jbe@285: CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data"); jbe@285: CREATE TRIGGER "update_text_search_data" jbe@285: BEFORE INSERT OR UPDATE ON "direct_voter" jbe@285: FOR EACH ROW EXECUTE PROCEDURE jbe@285: tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment"); jbe@0: jbe@389: COMMENT ON TABLE "direct_voter" IS 'Members having directly voted for/against initiatives of an issue; frontends must ensure that no voters are added or removed to/from this table when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@285: COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table'; jbe@285: 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@285: 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@285: 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@285: jbe@285: jbe@285: CREATE TABLE "rendered_voter_comment" ( jbe@285: PRIMARY KEY ("issue_id", "member_id", "format"), jbe@285: FOREIGN KEY ("issue_id", "member_id") jbe@285: REFERENCES "direct_voter" ("issue_id", "member_id") jbe@285: ON DELETE CASCADE ON UPDATE CASCADE, jbe@285: "issue_id" INT4, jbe@285: "member_id" INT4, jbe@285: "format" TEXT, jbe@285: "content" TEXT NOT NULL ); jbe@285: jbe@285: 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@0: jbe@0: jbe@0: CREATE TABLE "delegating_voter" ( jbe@0: PRIMARY KEY ("issue_id", "member_id"), jbe@0: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@45: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, jbe@8: "weight" INT4, jbe@10: "scope" "delegation_scope" NOT NULL, jbe@0: "delegate_member_ids" INT4[] NOT NULL ); jbe@52: CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id"); jbe@0: jbe@389: COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table; for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@0: COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member'; jbe@8: COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight'; jbe@0: COMMENT ON COLUMN "delegating_voter"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_voter"'; jbe@0: jbe@0: jbe@0: CREATE TABLE "vote" ( jbe@0: "issue_id" INT4 NOT NULL, jbe@0: PRIMARY KEY ("initiative_id", "member_id"), jbe@0: "initiative_id" INT4, jbe@0: "member_id" INT4, jbe@414: "grade" INT4 NOT NULL, jbe@414: "first_preference" BOOLEAN, jbe@0: FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@414: FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@414: CONSTRAINT "first_preference_flag_only_set_on_positive_grades" jbe@414: CHECK ("grade" > 0 OR "first_preference" ISNULL) ); jbe@0: CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id"); jbe@0: jbe@389: COMMENT ON TABLE "vote" IS 'Manual and delegated votes without abstentions; frontends must ensure that no votes are added modified or removed when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table'; jbe@0: jbe@414: COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary'; jbe@414: COMMENT ON COLUMN "vote"."grade" IS 'Values smaller than zero mean reject, values greater than zero mean acceptance, zero or missing row means abstention. Preferences are expressed by different positive or negative numbers.'; jbe@414: COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.'; jbe@0: jbe@0: jbe@112: CREATE TYPE "event_type" AS ENUM ( jbe@112: 'issue_state_changed', jbe@112: 'initiative_created_in_new_issue', jbe@112: 'initiative_created_in_existing_issue', jbe@112: 'initiative_revoked', jbe@112: 'new_draft_created', jbe@112: 'suggestion_created'); jbe@112: jbe@112: COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"'; jbe@112: jbe@112: jbe@112: CREATE TABLE "event" ( jbe@112: "id" SERIAL8 PRIMARY KEY, jbe@112: "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(), jbe@112: "event" "event_type" NOT NULL, jbe@112: "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, jbe@112: "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@328: "state" "issue_state", jbe@112: "initiative_id" INT4, jbe@112: "draft_id" INT8, jbe@112: "suggestion_id" INT8, jbe@112: FOREIGN KEY ("issue_id", "initiative_id") jbe@112: REFERENCES "initiative" ("issue_id", "id") jbe@112: ON DELETE CASCADE ON UPDATE CASCADE, jbe@112: FOREIGN KEY ("initiative_id", "draft_id") jbe@112: REFERENCES "draft" ("initiative_id", "id") jbe@112: ON DELETE CASCADE ON UPDATE CASCADE, jbe@112: FOREIGN KEY ("initiative_id", "suggestion_id") jbe@112: REFERENCES "suggestion" ("initiative_id", "id") jbe@112: ON DELETE CASCADE ON UPDATE CASCADE, jbe@451: CONSTRAINT "null_constr_for_issue_state_changed" CHECK ( jbe@112: "event" != 'issue_state_changed' OR ( jbe@112: "member_id" ISNULL AND jbe@112: "issue_id" NOTNULL AND jbe@113: "state" NOTNULL AND jbe@112: "initiative_id" ISNULL AND jbe@112: "draft_id" ISNULL AND jbe@112: "suggestion_id" ISNULL )), jbe@451: CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft" CHECK ( jbe@112: "event" NOT IN ( jbe@112: 'initiative_created_in_new_issue', jbe@112: 'initiative_created_in_existing_issue', jbe@112: 'initiative_revoked', jbe@112: 'new_draft_created' jbe@112: ) OR ( jbe@112: "member_id" NOTNULL AND jbe@112: "issue_id" NOTNULL AND jbe@113: "state" NOTNULL AND jbe@112: "initiative_id" NOTNULL AND jbe@112: "draft_id" NOTNULL AND jbe@112: "suggestion_id" ISNULL )), jbe@451: CONSTRAINT "null_constr_for_suggestion_creation" CHECK ( jbe@112: "event" != 'suggestion_created' OR ( jbe@112: "member_id" NOTNULL AND jbe@112: "issue_id" NOTNULL AND jbe@113: "state" NOTNULL AND jbe@112: "initiative_id" NOTNULL AND jbe@112: "draft_id" ISNULL AND jbe@112: "suggestion_id" NOTNULL )) ); jbe@223: CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence"); jbe@112: jbe@112: COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers'; jbe@112: jbe@114: COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred'; jbe@114: COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")'; jbe@114: COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable'; jbe@114: COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state'; jbe@114: jbe@112: jbe@222: CREATE TABLE "notification_sent" ( jbe@222: "event_id" INT8 NOT NULL ); jbe@222: CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1)); jbe@222: jbe@222: COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out'; jbe@222: COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.'; jbe@222: jbe@222: jbe@486: CREATE TABLE "initiative_notification_sent" ( jbe@486: PRIMARY KEY ("member_id", "initiative_id"), jbe@486: "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@486: "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, jbe@486: "last_draft_id" INT8 NOT NULL, jbe@486: "last_suggestion_id" INT8 NOT NULL ); jbe@486: CREATE INDEX "initiative_notification_sent_initiative_idx" ON "initiative_notification_sent" ("initiative_id"); jbe@486: jbe@486: jbe@112: jbe@112: ---------------------------------------------- jbe@112: -- Writing of history entries and event log -- jbe@112: ---------------------------------------------- jbe@13: jbe@181: jbe@13: CREATE FUNCTION "write_member_history_trigger"() jbe@13: RETURNS TRIGGER jbe@13: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@13: BEGIN jbe@42: IF jbe@230: ( NEW."active" != OLD."active" OR jbe@230: NEW."name" != OLD."name" ) AND jbe@230: OLD."activated" NOTNULL jbe@42: THEN jbe@42: INSERT INTO "member_history" jbe@57: ("member_id", "active", "name") jbe@57: VALUES (NEW."id", OLD."active", OLD."name"); jbe@13: END IF; jbe@13: RETURN NULL; jbe@13: END; jbe@13: $$; jbe@13: jbe@13: CREATE TRIGGER "write_member_history" jbe@13: AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE jbe@13: "write_member_history_trigger"(); jbe@13: jbe@13: COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"'; jbe@57: COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table'; jbe@13: jbe@13: jbe@112: CREATE FUNCTION "write_event_issue_state_changed_trigger"() jbe@112: RETURNS TRIGGER jbe@112: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@112: BEGIN jbe@328: IF NEW."state" != OLD."state" THEN jbe@112: INSERT INTO "event" ("event", "issue_id", "state") jbe@112: VALUES ('issue_state_changed', NEW."id", NEW."state"); jbe@112: END IF; jbe@112: RETURN NULL; jbe@112: END; jbe@112: $$; jbe@112: jbe@112: CREATE TRIGGER "write_event_issue_state_changed" jbe@112: AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE jbe@112: "write_event_issue_state_changed_trigger"(); jbe@112: jbe@112: COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"'; jbe@112: COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change'; jbe@112: jbe@112: jbe@112: CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"() jbe@112: RETURNS TRIGGER jbe@112: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@112: DECLARE jbe@112: "initiative_row" "initiative"%ROWTYPE; jbe@113: "issue_row" "issue"%ROWTYPE; jbe@112: "event_v" "event_type"; jbe@112: BEGIN jbe@112: SELECT * INTO "initiative_row" FROM "initiative" jbe@112: WHERE "id" = NEW."initiative_id"; jbe@113: SELECT * INTO "issue_row" FROM "issue" jbe@113: WHERE "id" = "initiative_row"."issue_id"; jbe@112: IF EXISTS ( jbe@112: SELECT NULL FROM "draft" jbe@112: WHERE "initiative_id" = NEW."initiative_id" jbe@112: AND "id" != NEW."id" jbe@112: ) THEN jbe@112: "event_v" := 'new_draft_created'; jbe@112: ELSE jbe@112: IF EXISTS ( jbe@112: SELECT NULL FROM "initiative" jbe@112: WHERE "issue_id" = "initiative_row"."issue_id" jbe@112: AND "id" != "initiative_row"."id" jbe@112: ) THEN jbe@112: "event_v" := 'initiative_created_in_existing_issue'; jbe@112: ELSE jbe@112: "event_v" := 'initiative_created_in_new_issue'; jbe@112: END IF; jbe@112: END IF; jbe@112: INSERT INTO "event" ( jbe@112: "event", "member_id", jbe@113: "issue_id", "state", "initiative_id", "draft_id" jbe@112: ) VALUES ( jbe@112: "event_v", jbe@112: NEW."author_id", jbe@112: "initiative_row"."issue_id", jbe@113: "issue_row"."state", jbe@112: "initiative_row"."id", jbe@112: NEW."id" ); jbe@112: RETURN NULL; jbe@112: END; jbe@112: $$; jbe@112: jbe@112: CREATE TRIGGER "write_event_initiative_or_draft_created" jbe@112: AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE jbe@112: "write_event_initiative_or_draft_created_trigger"(); jbe@112: jbe@112: COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"'; jbe@112: COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation'; jbe@112: jbe@112: jbe@112: CREATE FUNCTION "write_event_initiative_revoked_trigger"() jbe@112: RETURNS TRIGGER jbe@112: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@113: DECLARE jbe@231: "issue_row" "issue"%ROWTYPE; jbe@231: "draft_id_v" "draft"."id"%TYPE; jbe@112: BEGIN jbe@112: IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN jbe@231: SELECT * INTO "issue_row" FROM "issue" jbe@231: WHERE "id" = NEW."issue_id"; jbe@231: SELECT "id" INTO "draft_id_v" FROM "current_draft" jbe@231: WHERE "initiative_id" = NEW."id"; jbe@112: INSERT INTO "event" ( jbe@231: "event", "member_id", "issue_id", "state", "initiative_id", "draft_id" jbe@112: ) VALUES ( jbe@112: 'initiative_revoked', jbe@112: NEW."revoked_by_member_id", jbe@112: NEW."issue_id", jbe@113: "issue_row"."state", jbe@231: NEW."id", jbe@231: "draft_id_v"); jbe@112: END IF; jbe@112: RETURN NULL; jbe@112: END; jbe@112: $$; jbe@112: jbe@112: CREATE TRIGGER "write_event_initiative_revoked" jbe@112: AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE jbe@112: "write_event_initiative_revoked_trigger"(); jbe@112: jbe@112: COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"'; jbe@112: COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked'; jbe@112: jbe@112: jbe@112: CREATE FUNCTION "write_event_suggestion_created_trigger"() jbe@112: RETURNS TRIGGER jbe@112: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@112: DECLARE jbe@112: "initiative_row" "initiative"%ROWTYPE; jbe@113: "issue_row" "issue"%ROWTYPE; jbe@112: BEGIN jbe@112: SELECT * INTO "initiative_row" FROM "initiative" jbe@112: WHERE "id" = NEW."initiative_id"; jbe@113: SELECT * INTO "issue_row" FROM "issue" jbe@113: WHERE "id" = "initiative_row"."issue_id"; jbe@112: INSERT INTO "event" ( jbe@112: "event", "member_id", jbe@113: "issue_id", "state", "initiative_id", "suggestion_id" jbe@112: ) VALUES ( jbe@112: 'suggestion_created', jbe@112: NEW."author_id", jbe@112: "initiative_row"."issue_id", jbe@113: "issue_row"."state", jbe@112: "initiative_row"."id", jbe@112: NEW."id" ); jbe@112: RETURN NULL; jbe@112: END; jbe@112: $$; jbe@112: jbe@112: CREATE TRIGGER "write_event_suggestion_created" jbe@112: AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE jbe@112: "write_event_suggestion_created_trigger"(); jbe@112: jbe@112: COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"'; jbe@112: COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation'; jbe@112: jbe@112: jbe@13: jbe@0: ---------------------------- jbe@0: -- Additional constraints -- jbe@0: ---------------------------- jbe@0: jbe@0: jbe@0: CREATE FUNCTION "issue_requires_first_initiative_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: BEGIN jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id" jbe@0: ) THEN jbe@463: RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING jbe@463: ERRCODE = 'integrity_constraint_violation', jbe@463: HINT = 'Create issue, initiative, and draft within the same transaction.'; jbe@0: END IF; jbe@0: RETURN NULL; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative" jbe@0: AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED jbe@0: FOR EACH ROW EXECUTE PROCEDURE jbe@0: "issue_requires_first_initiative_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"'; jbe@0: COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "last_initiative_deletes_issue_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "reference_lost" BOOLEAN; jbe@0: BEGIN jbe@0: IF TG_OP = 'DELETE' THEN jbe@0: "reference_lost" := TRUE; jbe@0: ELSE jbe@0: "reference_lost" := NEW."issue_id" != OLD."issue_id"; jbe@0: END IF; jbe@0: IF jbe@0: "reference_lost" AND NOT EXISTS ( jbe@0: SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id" jbe@0: ) jbe@0: THEN jbe@0: DELETE FROM "issue" WHERE "id" = OLD."issue_id"; jbe@0: END IF; jbe@0: RETURN NULL; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue" jbe@0: AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED jbe@0: FOR EACH ROW EXECUTE PROCEDURE jbe@0: "last_initiative_deletes_issue_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"'; jbe@0: COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "initiative_requires_first_draft_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: BEGIN jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id" jbe@0: ) THEN jbe@463: RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING jbe@463: ERRCODE = 'integrity_constraint_violation', jbe@463: HINT = 'Create issue, initiative and draft within the same transaction.'; jbe@0: END IF; jbe@0: RETURN NULL; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft" jbe@0: AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED jbe@0: FOR EACH ROW EXECUTE PROCEDURE jbe@0: "initiative_requires_first_draft_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"'; jbe@0: COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "last_draft_deletes_initiative_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "reference_lost" BOOLEAN; jbe@0: BEGIN jbe@0: IF TG_OP = 'DELETE' THEN jbe@0: "reference_lost" := TRUE; jbe@0: ELSE jbe@0: "reference_lost" := NEW."initiative_id" != OLD."initiative_id"; jbe@0: END IF; jbe@0: IF jbe@0: "reference_lost" AND NOT EXISTS ( jbe@0: SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id" jbe@0: ) jbe@0: THEN jbe@0: DELETE FROM "initiative" WHERE "id" = OLD."initiative_id"; jbe@0: END IF; jbe@0: RETURN NULL; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative" jbe@0: AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED jbe@0: FOR EACH ROW EXECUTE PROCEDURE jbe@0: "last_draft_deletes_initiative_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"'; jbe@0: COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "suggestion_requires_first_opinion_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: BEGIN jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id" jbe@0: ) THEN jbe@463: RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING jbe@463: ERRCODE = 'integrity_constraint_violation', jbe@463: HINT = 'Create suggestion and opinion within the same transaction.'; jbe@0: END IF; jbe@0: RETURN NULL; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion" jbe@0: AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED jbe@0: FOR EACH ROW EXECUTE PROCEDURE jbe@0: "suggestion_requires_first_opinion_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"'; jbe@0: COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "reference_lost" BOOLEAN; jbe@0: BEGIN jbe@0: IF TG_OP = 'DELETE' THEN jbe@0: "reference_lost" := TRUE; jbe@0: ELSE jbe@0: "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id"; jbe@0: END IF; jbe@0: IF jbe@0: "reference_lost" AND NOT EXISTS ( jbe@0: SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id" jbe@0: ) jbe@0: THEN jbe@0: DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id"; jbe@0: END IF; jbe@0: RETURN NULL; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion" jbe@0: AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED jbe@0: FOR EACH ROW EXECUTE PROCEDURE jbe@0: "last_opinion_deletes_suggestion_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"'; jbe@0: COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion'; jbe@0: jbe@0: jbe@284: CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"() jbe@284: RETURNS TRIGGER jbe@284: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@284: BEGIN jbe@284: DELETE FROM "direct_voter" jbe@284: WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id"; jbe@284: RETURN NULL; jbe@284: END; jbe@284: $$; jbe@284: jbe@284: CREATE TRIGGER "non_voter_deletes_direct_voter" jbe@284: AFTER INSERT OR UPDATE ON "non_voter" jbe@284: FOR EACH ROW EXECUTE PROCEDURE jbe@284: "non_voter_deletes_direct_voter_trigger"(); jbe@284: jbe@284: COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"'; jbe@284: 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@284: jbe@284: jbe@284: CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"() jbe@284: RETURNS TRIGGER jbe@284: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@284: BEGIN jbe@284: DELETE FROM "non_voter" jbe@284: WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id"; jbe@284: RETURN NULL; jbe@284: END; jbe@284: $$; jbe@284: jbe@284: CREATE TRIGGER "direct_voter_deletes_non_voter" jbe@284: AFTER INSERT OR UPDATE ON "direct_voter" jbe@284: FOR EACH ROW EXECUTE PROCEDURE jbe@284: "direct_voter_deletes_non_voter_trigger"(); jbe@284: jbe@284: COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"'; jbe@284: 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@284: jbe@284: jbe@285: CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() jbe@285: RETURNS TRIGGER jbe@285: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@285: BEGIN jbe@285: IF NEW."comment" ISNULL THEN jbe@285: NEW."comment_changed" := NULL; jbe@285: NEW."formatting_engine" := NULL; jbe@285: END IF; jbe@285: RETURN NEW; jbe@285: END; jbe@285: $$; jbe@285: jbe@285: CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" jbe@285: BEFORE INSERT OR UPDATE ON "direct_voter" jbe@285: FOR EACH ROW EXECUTE PROCEDURE jbe@285: "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"(); jbe@285: jbe@285: 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@285: 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@285: jbe@0: jbe@20: --------------------------------------------------------------- jbe@333: -- Ensure that votes are not modified when issues are closed -- jbe@20: --------------------------------------------------------------- jbe@20: jbe@20: -- NOTE: Frontends should ensure this anyway, but in case of programming jbe@20: -- errors the following triggers ensure data integrity. jbe@20: jbe@20: jbe@20: CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"() jbe@20: RETURNS TRIGGER jbe@20: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@20: DECLARE jbe@336: "issue_id_v" "issue"."id"%TYPE; jbe@336: "issue_row" "issue"%ROWTYPE; jbe@20: BEGIN jbe@383: IF EXISTS ( jbe@385: SELECT NULL FROM "temporary_transaction_data" jbe@385: WHERE "txid" = txid_current() jbe@383: AND "key" = 'override_protection_triggers' jbe@383: AND "value" = TRUE::TEXT jbe@383: ) THEN jbe@383: RETURN NULL; jbe@383: END IF; jbe@32: IF TG_OP = 'DELETE' THEN jbe@32: "issue_id_v" := OLD."issue_id"; jbe@32: ELSE jbe@32: "issue_id_v" := NEW."issue_id"; jbe@32: END IF; jbe@20: SELECT INTO "issue_row" * FROM "issue" jbe@32: WHERE "id" = "issue_id_v" FOR SHARE; jbe@383: IF ( jbe@383: "issue_row"."closed" NOTNULL OR ( jbe@383: "issue_row"."state" = 'voting' AND jbe@383: "issue_row"."phase_finished" NOTNULL jbe@383: ) jbe@383: ) THEN jbe@332: IF jbe@332: TG_RELID = 'direct_voter'::regclass AND jbe@332: TG_OP = 'UPDATE' jbe@332: THEN jbe@332: IF jbe@332: OLD."issue_id" = NEW."issue_id" AND jbe@332: OLD."member_id" = NEW."member_id" AND jbe@332: OLD."weight" = NEW."weight" jbe@332: THEN jbe@332: RETURN NULL; -- allows changing of voter comment jbe@332: END IF; jbe@332: END IF; jbe@463: RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING jbe@463: ERRCODE = 'integrity_constraint_violation'; jbe@20: END IF; jbe@20: RETURN NULL; jbe@20: END; jbe@20: $$; jbe@20: jbe@20: CREATE TRIGGER "forbid_changes_on_closed_issue" jbe@20: AFTER INSERT OR UPDATE OR DELETE ON "direct_voter" jbe@20: FOR EACH ROW EXECUTE PROCEDURE jbe@20: "forbid_changes_on_closed_issue_trigger"(); jbe@20: jbe@20: CREATE TRIGGER "forbid_changes_on_closed_issue" jbe@20: AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter" jbe@20: FOR EACH ROW EXECUTE PROCEDURE jbe@20: "forbid_changes_on_closed_issue_trigger"(); jbe@20: jbe@20: CREATE TRIGGER "forbid_changes_on_closed_issue" jbe@20: AFTER INSERT OR UPDATE OR DELETE ON "vote" jbe@20: FOR EACH ROW EXECUTE PROCEDURE jbe@20: "forbid_changes_on_closed_issue_trigger"(); jbe@20: jbe@20: COMMENT ON FUNCTION "forbid_changes_on_closed_issue_trigger"() IS 'Implementation of triggers "forbid_changes_on_closed_issue" on tables "direct_voter", "delegating_voter" and "vote"'; jbe@20: COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "direct_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors'; jbe@20: COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "delegating_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors'; jbe@20: COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "vote" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors'; jbe@20: jbe@20: jbe@20: jbe@0: -------------------------------------------------------------------- jbe@0: -- Auto-retrieval of fields only needed for referential integrity -- jbe@0: -------------------------------------------------------------------- jbe@0: jbe@20: jbe@0: CREATE FUNCTION "autofill_issue_id_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: BEGIN jbe@0: IF NEW."issue_id" ISNULL THEN jbe@0: SELECT "issue_id" INTO NEW."issue_id" jbe@0: FROM "initiative" WHERE "id" = NEW."initiative_id"; jbe@0: END IF; jbe@0: RETURN NEW; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter" jbe@0: FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"(); jbe@0: jbe@0: CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote" jbe@0: FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"'; jbe@0: COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL'; jbe@0: COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "autofill_initiative_id_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: BEGIN jbe@0: IF NEW."initiative_id" ISNULL THEN jbe@0: SELECT "initiative_id" INTO NEW."initiative_id" jbe@0: FROM "suggestion" WHERE "id" = NEW."suggestion_id"; jbe@0: END IF; jbe@0: RETURN NEW; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion" jbe@0: FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"'; jbe@0: COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL'; jbe@0: jbe@0: jbe@0: jbe@4: ----------------------------------------------------- jbe@4: -- Automatic calculation of certain default values -- jbe@4: ----------------------------------------------------- jbe@0: jbe@22: jbe@22: CREATE FUNCTION "copy_timings_trigger"() jbe@22: RETURNS TRIGGER jbe@22: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@22: DECLARE jbe@22: "policy_row" "policy"%ROWTYPE; jbe@22: BEGIN jbe@22: SELECT * INTO "policy_row" FROM "policy" jbe@22: WHERE "id" = NEW."policy_id"; jbe@447: IF NEW."min_admission_time" ISNULL THEN jbe@447: NEW."min_admission_time" := "policy_row"."min_admission_time"; jbe@447: END IF; jbe@447: IF NEW."max_admission_time" ISNULL THEN jbe@447: NEW."max_admission_time" := "policy_row"."max_admission_time"; jbe@22: END IF; jbe@22: IF NEW."discussion_time" ISNULL THEN jbe@22: NEW."discussion_time" := "policy_row"."discussion_time"; jbe@22: END IF; jbe@22: IF NEW."verification_time" ISNULL THEN jbe@22: NEW."verification_time" := "policy_row"."verification_time"; jbe@22: END IF; jbe@22: IF NEW."voting_time" ISNULL THEN jbe@22: NEW."voting_time" := "policy_row"."voting_time"; jbe@22: END IF; jbe@22: RETURN NEW; jbe@22: END; jbe@22: $$; jbe@22: jbe@22: CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue" jbe@22: FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"(); jbe@22: jbe@22: COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"'; jbe@22: COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.'; jbe@22: jbe@22: jbe@160: CREATE FUNCTION "default_for_draft_id_trigger"() jbe@2: RETURNS TRIGGER jbe@2: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@2: BEGIN jbe@2: IF NEW."draft_id" ISNULL THEN jbe@2: SELECT "id" INTO NEW."draft_id" FROM "current_draft" jbe@2: WHERE "initiative_id" = NEW."initiative_id"; jbe@2: END IF; jbe@2: RETURN NEW; jbe@2: END; jbe@2: $$; jbe@2: jbe@160: CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion" jbe@160: FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"(); jbe@2: CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter" jbe@160: FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"(); jbe@160: jbe@160: COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"'; jbe@160: COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default'; jbe@160: COMMENT ON TRIGGER "default_for_draft_id" ON "supporter" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default'; jbe@2: jbe@2: jbe@0: jbe@0: ---------------------------------------- jbe@0: -- Automatic creation of dependencies -- jbe@0: ---------------------------------------- jbe@0: jbe@22: jbe@0: CREATE FUNCTION "autocreate_interest_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: BEGIN jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "initiative" JOIN "interest" jbe@0: ON "initiative"."issue_id" = "interest"."issue_id" jbe@0: WHERE "initiative"."id" = NEW."initiative_id" jbe@0: AND "interest"."member_id" = NEW."member_id" jbe@0: ) THEN jbe@0: BEGIN jbe@0: INSERT INTO "interest" ("issue_id", "member_id") jbe@0: SELECT "issue_id", NEW."member_id" jbe@0: FROM "initiative" WHERE "id" = NEW."initiative_id"; jbe@0: EXCEPTION WHEN unique_violation THEN END; jbe@0: END IF; jbe@0: RETURN NEW; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter" jbe@0: FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"'; jbe@0: COMMENT ON TRIGGER "autocreate_interest" ON "supporter" IS 'Supporting an initiative implies interest in the issue, thus automatically creates an entry in the "interest" table'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "autocreate_supporter_trigger"() jbe@0: RETURNS TRIGGER jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: BEGIN jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "suggestion" JOIN "supporter" jbe@0: ON "suggestion"."initiative_id" = "supporter"."initiative_id" jbe@0: WHERE "suggestion"."id" = NEW."suggestion_id" jbe@0: AND "supporter"."member_id" = NEW."member_id" jbe@0: ) THEN jbe@0: BEGIN jbe@0: INSERT INTO "supporter" ("initiative_id", "member_id") jbe@0: SELECT "initiative_id", NEW."member_id" jbe@0: FROM "suggestion" WHERE "id" = NEW."suggestion_id"; jbe@0: EXCEPTION WHEN unique_violation THEN END; jbe@0: END IF; jbe@0: RETURN NEW; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion" jbe@0: FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"(); jbe@0: jbe@0: COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"'; jbe@0: COMMENT ON TRIGGER "autocreate_supporter" ON "opinion" IS 'Opinions can only be added for supported initiatives. This trigger automatrically creates an entry in the "supporter" table, if not existent yet.'; jbe@0: jbe@0: jbe@0: jbe@0: ------------------------------------------ jbe@0: -- Views and helper functions for views -- jbe@0: ------------------------------------------ jbe@0: jbe@5: jbe@97: CREATE VIEW "unit_delegation" AS jbe@97: SELECT jbe@97: "unit"."id" AS "unit_id", jbe@97: "delegation"."id", jbe@97: "delegation"."truster_id", jbe@97: "delegation"."trustee_id", jbe@97: "delegation"."scope" jbe@97: FROM "unit" jbe@97: JOIN "delegation" jbe@97: ON "delegation"."unit_id" = "unit"."id" jbe@97: JOIN "member" jbe@97: ON "delegation"."truster_id" = "member"."id" jbe@97: JOIN "privilege" jbe@97: ON "delegation"."unit_id" = "privilege"."unit_id" jbe@97: AND "delegation"."truster_id" = "privilege"."member_id" jbe@97: WHERE "member"."active" AND "privilege"."voting_right"; jbe@97: jbe@97: COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right'; jbe@5: jbe@5: jbe@5: CREATE VIEW "area_delegation" AS jbe@70: SELECT DISTINCT ON ("area"."id", "delegation"."truster_id") jbe@70: "area"."id" AS "area_id", jbe@70: "delegation"."id", jbe@70: "delegation"."truster_id", jbe@70: "delegation"."trustee_id", jbe@70: "delegation"."scope" jbe@97: FROM "area" jbe@97: JOIN "delegation" jbe@97: ON "delegation"."unit_id" = "area"."unit_id" jbe@97: OR "delegation"."area_id" = "area"."id" jbe@97: JOIN "member" jbe@97: ON "delegation"."truster_id" = "member"."id" jbe@97: JOIN "privilege" jbe@97: ON "area"."unit_id" = "privilege"."unit_id" jbe@97: AND "delegation"."truster_id" = "privilege"."member_id" jbe@97: WHERE "member"."active" AND "privilege"."voting_right" jbe@70: ORDER BY jbe@70: "area"."id", jbe@70: "delegation"."truster_id", jbe@70: "delegation"."scope" DESC; jbe@70: jbe@97: COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right'; jbe@5: jbe@5: jbe@5: CREATE VIEW "issue_delegation" AS jbe@70: SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id") jbe@70: "issue"."id" AS "issue_id", jbe@70: "delegation"."id", jbe@70: "delegation"."truster_id", jbe@70: "delegation"."trustee_id", jbe@70: "delegation"."scope" jbe@97: FROM "issue" jbe@97: JOIN "area" jbe@97: ON "area"."id" = "issue"."area_id" jbe@97: JOIN "delegation" jbe@97: ON "delegation"."unit_id" = "area"."unit_id" jbe@97: OR "delegation"."area_id" = "area"."id" jbe@97: OR "delegation"."issue_id" = "issue"."id" jbe@97: JOIN "member" jbe@97: ON "delegation"."truster_id" = "member"."id" jbe@97: JOIN "privilege" jbe@97: ON "area"."unit_id" = "privilege"."unit_id" jbe@97: AND "delegation"."truster_id" = "privilege"."member_id" jbe@97: WHERE "member"."active" AND "privilege"."voting_right" jbe@70: ORDER BY jbe@70: "issue"."id", jbe@70: "delegation"."truster_id", jbe@70: "delegation"."scope" DESC; jbe@70: jbe@97: COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right'; jbe@5: jbe@5: jbe@5: CREATE FUNCTION "membership_weight_with_skipping" jbe@5: ( "area_id_p" "area"."id"%TYPE, jbe@5: "member_id_p" "member"."id"%TYPE, jbe@5: "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[] jbe@5: RETURNS INT4 jbe@5: LANGUAGE 'plpgsql' STABLE AS $$ jbe@5: DECLARE jbe@5: "sum_v" INT4; jbe@5: "delegation_row" "area_delegation"%ROWTYPE; jbe@5: BEGIN jbe@5: "sum_v" := 1; jbe@5: FOR "delegation_row" IN jbe@5: SELECT "area_delegation".* jbe@5: FROM "area_delegation" LEFT JOIN "membership" jbe@5: ON "membership"."area_id" = "area_id_p" jbe@5: AND "membership"."member_id" = "area_delegation"."truster_id" jbe@5: WHERE "area_delegation"."area_id" = "area_id_p" jbe@5: AND "area_delegation"."trustee_id" = "member_id_p" jbe@5: AND "membership"."member_id" ISNULL jbe@5: LOOP jbe@5: IF NOT jbe@5: "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"] jbe@5: THEN jbe@5: "sum_v" := "sum_v" + "membership_weight_with_skipping"( jbe@5: "area_id_p", jbe@5: "delegation_row"."truster_id", jbe@5: "skip_member_ids_p" || "delegation_row"."truster_id" jbe@5: ); jbe@5: END IF; jbe@5: END LOOP; jbe@5: RETURN "sum_v"; jbe@5: END; jbe@5: $$; jbe@5: jbe@8: COMMENT ON FUNCTION "membership_weight_with_skipping" jbe@8: ( "area"."id"%TYPE, jbe@8: "member"."id"%TYPE, jbe@8: INT4[] ) jbe@8: IS 'Helper function for "membership_weight" function'; jbe@8: jbe@8: jbe@5: CREATE FUNCTION "membership_weight" jbe@5: ( "area_id_p" "area"."id"%TYPE, jbe@5: "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[] jbe@5: RETURNS INT4 jbe@5: LANGUAGE 'plpgsql' STABLE AS $$ jbe@5: BEGIN jbe@5: RETURN "membership_weight_with_skipping"( jbe@5: "area_id_p", jbe@5: "member_id_p", jbe@5: ARRAY["member_id_p"] jbe@5: ); jbe@5: END; jbe@5: $$; jbe@5: jbe@8: COMMENT ON FUNCTION "membership_weight" jbe@8: ( "area"."id"%TYPE, jbe@8: "member"."id"%TYPE ) jbe@8: IS 'Calculates the potential voting weight of a member in a given area'; jbe@8: jbe@5: jbe@4: CREATE VIEW "member_count_view" AS jbe@5: SELECT count(1) AS "total_count" FROM "member" WHERE "active"; jbe@4: jbe@4: COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table'; jbe@4: jbe@4: jbe@97: CREATE VIEW "unit_member_count" AS jbe@97: SELECT jbe@97: "unit"."id" AS "unit_id", jbe@248: count("member"."id") AS "member_count" jbe@97: FROM "unit" jbe@97: LEFT JOIN "privilege" jbe@97: ON "privilege"."unit_id" = "unit"."id" jbe@97: AND "privilege"."voting_right" jbe@97: LEFT JOIN "member" jbe@97: ON "member"."id" = "privilege"."member_id" jbe@97: AND "member"."active" jbe@97: GROUP BY "unit"."id"; jbe@97: jbe@97: COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table'; jbe@97: jbe@97: jbe@4: CREATE VIEW "area_member_count" AS jbe@5: SELECT jbe@5: "area"."id" AS "area_id", jbe@5: count("member"."id") AS "direct_member_count", jbe@5: coalesce( jbe@5: sum( jbe@5: CASE WHEN "member"."id" NOTNULL THEN jbe@5: "membership_weight"("area"."id", "member"."id") jbe@5: ELSE 0 END jbe@5: ) jbe@169: ) AS "member_weight" jbe@4: FROM "area" jbe@4: LEFT JOIN "membership" jbe@4: ON "area"."id" = "membership"."area_id" jbe@97: LEFT JOIN "privilege" jbe@97: ON "privilege"."unit_id" = "area"."unit_id" jbe@97: AND "privilege"."member_id" = "membership"."member_id" jbe@97: AND "privilege"."voting_right" jbe@4: LEFT JOIN "member" jbe@97: ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here! jbe@4: AND "member"."active" jbe@4: GROUP BY "area"."id"; jbe@4: jbe@169: COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"'; jbe@4: jbe@4: jbe@9: CREATE VIEW "opening_draft" AS jbe@9: SELECT "draft".* FROM ( jbe@9: SELECT jbe@9: "initiative"."id" AS "initiative_id", jbe@9: min("draft"."id") AS "draft_id" jbe@9: FROM "initiative" JOIN "draft" jbe@9: ON "initiative"."id" = "draft"."initiative_id" jbe@9: GROUP BY "initiative"."id" jbe@9: ) AS "subquery" jbe@9: JOIN "draft" ON "subquery"."draft_id" = "draft"."id"; jbe@9: jbe@9: COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives'; jbe@9: jbe@9: jbe@0: CREATE VIEW "current_draft" AS jbe@0: SELECT "draft".* FROM ( jbe@0: SELECT jbe@0: "initiative"."id" AS "initiative_id", jbe@0: max("draft"."id") AS "draft_id" jbe@0: FROM "initiative" JOIN "draft" jbe@0: ON "initiative"."id" = "draft"."initiative_id" jbe@0: GROUP BY "initiative"."id" jbe@0: ) AS "subquery" jbe@0: JOIN "draft" ON "subquery"."draft_id" = "draft"."id"; jbe@0: jbe@0: COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative'; jbe@0: jbe@0: jbe@0: CREATE VIEW "critical_opinion" AS jbe@0: SELECT * FROM "opinion" jbe@0: WHERE ("degree" = 2 AND "fulfilled" = FALSE) jbe@0: OR ("degree" = -2 AND "fulfilled" = TRUE); jbe@0: jbe@0: COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction'; jbe@0: jbe@0: jbe@392: CREATE VIEW "issue_supporter_in_admission_state" AS jbe@466: SELECT DISTINCT -- TODO: DISTINCT needed? jbe@410: "area"."unit_id", jbe@392: "issue"."area_id", jbe@392: "issue"."id" AS "issue_id", jbe@392: "supporter"."member_id", jbe@392: "direct_interest_snapshot"."weight" jbe@392: FROM "issue" jbe@410: JOIN "area" ON "area"."id" = "issue"."area_id" jbe@392: JOIN "supporter" ON "supporter"."issue_id" = "issue"."id" jbe@392: JOIN "direct_interest_snapshot" jbe@392: ON "direct_interest_snapshot"."issue_id" = "issue"."id" jbe@392: AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event" jbe@392: AND "direct_interest_snapshot"."member_id" = "supporter"."member_id" jbe@392: WHERE "issue"."state" = 'admission'::"issue_state"; jbe@392: jbe@392: COMMENT ON VIEW "issue_supporter_in_admission_state" IS 'Helper view for "lf_update_issue_order" to allow a (proportional) ordering of issues within an area'; jbe@392: jbe@392: jbe@352: CREATE VIEW "initiative_suggestion_order_calculation" AS jbe@352: SELECT jbe@352: "initiative"."id" AS "initiative_id", jbe@352: ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final" jbe@352: FROM "initiative" JOIN "issue" jbe@352: ON "initiative"."issue_id" = "issue"."id" jbe@352: WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL) jbe@352: OR ("initiative"."final_suggestion_order_calculated" = FALSE); jbe@352: jbe@352: COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated'; jbe@352: jbe@360: COMMENT ON COLUMN "initiative_suggestion_order_calculation"."final" IS 'Set to TRUE, if the issue is fully frozen or closed, and the calculation has to be done only once for one last time'; jbe@352: jbe@352: jbe@352: CREATE VIEW "individual_suggestion_ranking" AS jbe@352: SELECT jbe@352: "opinion"."initiative_id", jbe@352: "opinion"."member_id", jbe@352: "direct_interest_snapshot"."weight", jbe@352: CASE WHEN jbe@352: ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR jbe@352: ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE) jbe@352: THEN 1 ELSE jbe@352: CASE WHEN jbe@352: ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR jbe@352: ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE) jbe@352: THEN 2 ELSE jbe@352: CASE WHEN jbe@352: ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR jbe@352: ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE) jbe@352: THEN 3 ELSE 4 END jbe@352: END jbe@352: END AS "preference", jbe@352: "opinion"."suggestion_id" jbe@352: FROM "opinion" jbe@352: JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id" jbe@352: JOIN "issue" ON "issue"."id" = "initiative"."issue_id" jbe@352: JOIN "direct_interest_snapshot" jbe@352: ON "direct_interest_snapshot"."issue_id" = "issue"."id" jbe@352: AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event" jbe@352: AND "direct_interest_snapshot"."member_id" = "opinion"."member_id"; jbe@352: jbe@352: COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative'; jbe@352: jbe@352: jbe@126: CREATE VIEW "battle_participant" AS jbe@126: SELECT "initiative"."id", "initiative"."issue_id" jbe@126: FROM "issue" JOIN "initiative" jbe@126: ON "issue"."id" = "initiative"."issue_id" jbe@126: WHERE "initiative"."admitted" jbe@126: UNION ALL jbe@126: SELECT NULL, "id" AS "issue_id" jbe@126: FROM "issue"; jbe@126: jbe@126: COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference'; jbe@126: jbe@126: jbe@61: CREATE VIEW "battle_view" AS jbe@0: SELECT jbe@0: "issue"."id" AS "issue_id", jbe@10: "winning_initiative"."id" AS "winning_initiative_id", jbe@10: "losing_initiative"."id" AS "losing_initiative_id", jbe@0: sum( jbe@0: CASE WHEN jbe@0: coalesce("better_vote"."grade", 0) > jbe@0: coalesce("worse_vote"."grade", 0) jbe@0: THEN "direct_voter"."weight" ELSE 0 END jbe@0: ) AS "count" jbe@0: FROM "issue" jbe@0: LEFT JOIN "direct_voter" jbe@0: ON "issue"."id" = "direct_voter"."issue_id" jbe@126: JOIN "battle_participant" AS "winning_initiative" jbe@10: ON "issue"."id" = "winning_initiative"."issue_id" jbe@126: JOIN "battle_participant" AS "losing_initiative" jbe@10: ON "issue"."id" = "losing_initiative"."issue_id" jbe@0: LEFT JOIN "vote" AS "better_vote" jbe@10: ON "direct_voter"."member_id" = "better_vote"."member_id" jbe@10: AND "winning_initiative"."id" = "better_vote"."initiative_id" jbe@0: LEFT JOIN "vote" AS "worse_vote" jbe@10: ON "direct_voter"."member_id" = "worse_vote"."member_id" jbe@10: AND "losing_initiative"."id" = "worse_vote"."initiative_id" jbe@328: WHERE "issue"."state" = 'voting' jbe@328: AND "issue"."phase_finished" NOTNULL jbe@126: AND ( jbe@126: "winning_initiative"."id" != "losing_initiative"."id" OR jbe@126: ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR jbe@126: ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) ) jbe@0: GROUP BY jbe@0: "issue"."id", jbe@10: "winning_initiative"."id", jbe@10: "losing_initiative"."id"; jbe@0: jbe@126: COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative (or status-quo) to another initiative (or status-quo); Used to fill "battle" table'; jbe@1: jbe@1: jbe@235: CREATE VIEW "expired_session" AS jbe@235: SELECT * FROM "session" WHERE now() > "expiry"; jbe@235: jbe@235: CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD jbe@235: DELETE FROM "session" WHERE "ident" = OLD."ident"; jbe@235: jbe@235: COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible'; jbe@235: COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"'; jbe@235: jbe@235: jbe@0: CREATE VIEW "open_issue" AS jbe@0: SELECT * FROM "issue" WHERE "closed" ISNULL; jbe@0: jbe@0: COMMENT ON VIEW "open_issue" IS 'All open issues'; jbe@0: jbe@0: jbe@9: CREATE VIEW "member_contingent" AS jbe@9: SELECT jbe@9: "member"."id" AS "member_id", jbe@293: "contingent"."polling", jbe@9: "contingent"."time_frame", jbe@9: CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN jbe@9: ( jbe@9: SELECT count(1) FROM "draft" jbe@293: JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id" jbe@9: WHERE "draft"."author_id" = "member"."id" jbe@293: AND "initiative"."polling" = "contingent"."polling" jbe@9: AND "draft"."created" > now() - "contingent"."time_frame" jbe@9: ) + ( jbe@9: SELECT count(1) FROM "suggestion" jbe@293: JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id" jbe@9: WHERE "suggestion"."author_id" = "member"."id" jbe@293: AND "contingent"."polling" = FALSE jbe@9: AND "suggestion"."created" > now() - "contingent"."time_frame" jbe@9: ) jbe@9: ELSE NULL END AS "text_entry_count", jbe@9: "contingent"."text_entry_limit", jbe@9: 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@9: ) ELSE NULL END AS "initiative_count", jbe@9: "contingent"."initiative_limit" jbe@9: FROM "member" CROSS JOIN "contingent"; jbe@9: jbe@9: 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@9: jbe@9: COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row'; jbe@9: COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row'; jbe@9: jbe@9: jbe@9: CREATE VIEW "member_contingent_left" AS jbe@9: SELECT jbe@9: "member_id", jbe@293: "polling", jbe@9: max("text_entry_limit" - "text_entry_count") AS "text_entries_left", jbe@9: max("initiative_limit" - "initiative_count") AS "initiatives_left" jbe@293: FROM "member_contingent" GROUP BY "member_id", "polling"; jbe@9: jbe@9: 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@9: jbe@9: jbe@113: CREATE VIEW "event_seen_by_member" AS jbe@113: SELECT jbe@113: "member"."id" AS "seen_by_member_id", jbe@113: CASE WHEN "event"."state" IN ( jbe@113: 'voting', jbe@113: 'finished_without_winner', jbe@113: 'finished_with_winner' jbe@113: ) THEN jbe@113: 'voting'::"notify_level" jbe@113: ELSE jbe@113: CASE WHEN "event"."state" IN ( jbe@113: 'verification', jbe@113: 'canceled_after_revocation_during_verification', jbe@113: 'canceled_no_initiative_admitted' jbe@113: ) THEN jbe@113: 'verification'::"notify_level" jbe@113: ELSE jbe@113: CASE WHEN "event"."state" IN ( jbe@113: 'discussion', jbe@113: 'canceled_after_revocation_during_discussion' jbe@113: ) THEN jbe@113: 'discussion'::"notify_level" jbe@113: ELSE jbe@113: 'all'::"notify_level" jbe@113: END jbe@113: END jbe@113: END AS "notify_level", jbe@113: "event".* jbe@113: FROM "member" CROSS JOIN "event" jbe@113: LEFT JOIN "issue" jbe@113: ON "event"."issue_id" = "issue"."id" jbe@113: LEFT JOIN "membership" jbe@113: ON "member"."id" = "membership"."member_id" jbe@113: AND "issue"."area_id" = "membership"."area_id" jbe@113: LEFT JOIN "interest" jbe@113: ON "member"."id" = "interest"."member_id" jbe@113: AND "event"."issue_id" = "interest"."issue_id" jbe@113: LEFT JOIN "ignored_member" jbe@113: ON "member"."id" = "ignored_member"."member_id" jbe@113: AND "event"."member_id" = "ignored_member"."other_member_id" jbe@113: LEFT JOIN "ignored_initiative" jbe@113: ON "member"."id" = "ignored_initiative"."member_id" jbe@113: AND "event"."initiative_id" = "ignored_initiative"."initiative_id" jbe@113: WHERE ( jbe@113: "interest"."member_id" NOTNULL OR jbe@113: ( "membership"."member_id" NOTNULL AND jbe@113: "event"."event" IN ( jbe@113: 'issue_state_changed', jbe@113: 'initiative_created_in_new_issue', jbe@113: 'initiative_created_in_existing_issue', jbe@113: 'initiative_revoked' ) ) ) jbe@113: AND "ignored_member"."member_id" ISNULL jbe@113: AND "ignored_initiative"."member_id" ISNULL; jbe@113: jbe@222: COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support, but ignoring members "notify_level"'; jbe@222: jbe@222: jbe@473: CREATE VIEW "updated_initiative" AS jbe@473: SELECT jbe@486: "supporter"."member_id" AS "seen_by_member_id", jbe@477: TRUE AS "supported", jbe@477: EXISTS ( jbe@477: SELECT NULL FROM "draft" jbe@477: WHERE "draft"."initiative_id" = "initiative"."id" jbe@477: AND "draft"."id" > "supporter"."draft_id" jbe@477: ) AS "new_draft", jbe@477: ( SELECT count(1) FROM "suggestion" jbe@488: LEFT JOIN "opinion" ON jbe@488: "opinion"."member_id" = "supporter"."member_id" AND jbe@488: "opinion"."suggestion_id" = "suggestion"."id" jbe@477: WHERE "suggestion"."initiative_id" = "initiative"."id" jbe@488: AND "opinion"."member_id" ISNULL jbe@477: AND COALESCE( jbe@486: "suggestion"."id" > "sent"."last_suggestion_id", jbe@477: TRUE jbe@477: ) jbe@477: ) AS "new_suggestion_count", jbe@477: FALSE AS "featured", jbe@477: NOT EXISTS ( jbe@477: SELECT NULL FROM "initiative" AS "better_initiative" jbe@477: WHERE jbe@484: "better_initiative"."issue_id" = "initiative"."issue_id" jbe@484: AND jbe@484: ( COALESCE("better_initiative"."harmonic_weight", -1), jbe@484: -"better_initiative"."id" ) > jbe@484: ( COALESCE("initiative"."harmonic_weight", -1), jbe@485: -"initiative"."id" ) jbe@477: ) AS "leading", jbe@473: "initiative".* jbe@486: FROM "supporter" JOIN "initiative" jbe@486: ON "supporter"."initiative_id" = "initiative"."id" jbe@486: LEFT JOIN "initiative_notification_sent" AS "sent" jbe@486: ON "sent"."member_id" = "supporter"."member_id" jbe@486: AND "sent"."initiative_id" = "initiative"."id" jbe@473: JOIN "issue" ON "issue"."id" = "initiative"."issue_id" jbe@480: WHERE "issue"."state" IN ('admission', 'discussion') jbe@473: AND ( jbe@473: EXISTS ( jbe@473: SELECT NULL FROM "draft" jbe@473: WHERE "draft"."initiative_id" = "initiative"."id" jbe@473: AND "draft"."id" > "supporter"."draft_id" jbe@473: ) OR EXISTS ( jbe@473: SELECT NULL FROM "suggestion" jbe@487: LEFT JOIN "opinion" ON jbe@487: "opinion"."member_id" = "supporter"."member_id" AND jbe@487: "opinion"."suggestion_id" = "suggestion"."id" jbe@473: WHERE "suggestion"."initiative_id" = "initiative"."id" jbe@487: AND "opinion"."member_id" ISNULL jbe@473: AND COALESCE( jbe@486: "suggestion"."id" > "sent"."last_suggestion_id", jbe@473: TRUE jbe@473: ) jbe@473: ) jbe@473: ); jbe@473: jbe@474: CREATE FUNCTION "featured_initiative" jbe@474: ( "member_id_p" "member"."id"%TYPE, jbe@474: "area_id_p" "area"."id"%TYPE ) jbe@474: RETURNS SETOF "initiative" jbe@474: LANGUAGE 'plpgsql' STABLE AS $$ jbe@474: DECLARE jbe@482: "member_row" "member"%ROWTYPE; jbe@474: "member_id_v" "member"."id"%TYPE; jbe@474: "seed_v" TEXT; jbe@474: "result_row" "initiative"%ROWTYPE; jbe@474: "match_v" BOOLEAN; jbe@474: "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[] jbe@474: BEGIN jbe@482: SELECT INTO "member_row" * FROM "member" WHERE "id" = "member_id_p"; jbe@474: "initiative_id_ary" := '{}'; jbe@474: LOOP jbe@474: "match_v" := FALSE; jbe@474: FOR "member_id_v", "seed_v" IN jbe@474: SELECT * FROM ( jbe@474: SELECT DISTINCT jbe@474: "supporter"."member_id", jbe@482: md5("member_id_p" || '-' || "member_row"."notification_counter" || '-' || "area_id_p" || '-' || "supporter"."member_id") AS "seed" jbe@474: FROM "supporter" jbe@474: JOIN "member" ON "member"."id" = "supporter"."member_id" jbe@474: JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id" jbe@474: JOIN "issue" ON "issue"."id" = "initiative"."issue_id" jbe@474: WHERE "supporter"."member_id" != "member_id_p" jbe@474: AND "issue"."area_id" = "area_id_p" jbe@474: AND "issue"."state" IN ('admission', 'discussion', 'verification') jbe@474: ) AS "subquery" jbe@474: ORDER BY "seed" jbe@474: LOOP jbe@476: SELECT "initiative".* INTO "result_row" jbe@476: FROM "initiative" jbe@474: JOIN "issue" ON "issue"."id" = "initiative"."issue_id" jbe@474: JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id" jbe@474: LEFT JOIN "supporter" AS "self_support" ON jbe@474: "self_support"."initiative_id" = "initiative"."id" AND jbe@474: "self_support"."member_id" = "member_id_p" jbe@474: WHERE "supporter"."member_id" = "member_id_v" jbe@474: AND "issue"."area_id" = "area_id_p" jbe@474: AND "issue"."state" IN ('admission', 'discussion', 'verification') jbe@474: AND "self_support"."member_id" ISNULL jbe@476: AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"] jbe@474: ORDER BY md5("seed_v" || '-' || "initiative"."id") jbe@476: LIMIT 1; jbe@476: IF FOUND THEN jbe@476: "match_v" := TRUE; jbe@476: "initiative_id_ary" := "initiative_id_ary" || "result_row"."id"; jbe@476: RETURN NEXT "result_row"; jbe@486: IF array_length("initiative_id_ary", 1) >= "member_row"."notification_sample_size" THEN jbe@476: RETURN; jbe@474: END IF; jbe@476: END IF; jbe@474: END LOOP; jbe@474: EXIT WHEN NOT "match_v"; jbe@474: END LOOP; jbe@474: RETURN; jbe@474: END; jbe@474: $$; jbe@474: jbe@474: CREATE VIEW "updated_or_featured_initiative" AS jbe@474: SELECT * FROM "updated_initiative" jbe@474: UNION ALL jbe@474: SELECT jbe@474: "member"."id" AS "seen_by_member_id", jbe@477: FALSE AS "supported", jbe@489: EXISTS ( jbe@489: SELECT NULL FROM "draft" jbe@489: WHERE "draft"."initiative_id" = "initiative"."id" jbe@489: AND COALESCE( jbe@489: "draft"."id" > "sent"."last_draft_id", jbe@489: TRUE jbe@489: ) jbe@489: ) AS "new_draft", jbe@489: ( SELECT count(1) FROM "suggestion" jbe@489: WHERE "suggestion"."initiative_id" = "initiative"."id" jbe@489: AND COALESCE( jbe@489: "suggestion"."id" > "sent"."last_suggestion_id", jbe@489: TRUE jbe@489: ) jbe@489: ) AS "new_suggestion_count", jbe@477: TRUE AS "featured", jbe@477: NOT EXISTS ( jbe@477: SELECT NULL FROM "initiative" AS "better_initiative" jbe@477: WHERE jbe@484: "better_initiative"."issue_id" = "initiative"."issue_id" jbe@484: AND jbe@484: ( COALESCE("better_initiative"."harmonic_weight", -1), jbe@484: -"better_initiative"."id" ) > jbe@484: ( COALESCE("initiative"."harmonic_weight", -1), jbe@485: -"initiative"."id" ) jbe@477: ) AS "leading", jbe@477: "initiative".* jbe@474: FROM "member" CROSS JOIN "area" jbe@477: CROSS JOIN LATERAL jbe@489: "featured_initiative"("member"."id", "area"."id") AS "initiative" jbe@489: LEFT JOIN "initiative_notification_sent" AS "sent" jbe@489: ON "sent"."member_id" = "member"."id" jbe@489: AND "sent"."initiative_id" = "initiative"."id"; jbe@474: jbe@474: CREATE VIEW "leading_complement_initiative" AS jbe@477: SELECT * FROM ( jbe@477: SELECT DISTINCT ON ("seen_by_member_id", "initiative"."issue_id") jbe@489: "uf_initiative"."seen_by_member_id", jbe@489: "supporter"."member_id" NOTNULL AS "supported", jbe@489: CASE WHEN "supporter"."member_id" NOTNULL THEN FALSE ELSE jbe@489: EXISTS ( jbe@489: SELECT NULL FROM "draft" jbe@489: WHERE "draft"."initiative_id" = "initiative"."id" jbe@489: AND COALESCE( jbe@489: "draft"."id" > "sent"."last_draft_id", jbe@489: TRUE jbe@489: ) jbe@489: ) jbe@489: END AS "new_draft", jbe@489: CASE WHEN "supporter"."member_id" NOTNULL THEN 0 ELSE jbe@489: ( SELECT count(1) FROM "suggestion" jbe@489: WHERE "suggestion"."initiative_id" = "initiative"."id" jbe@489: AND COALESCE( jbe@489: "suggestion"."id" > "sent"."last_suggestion_id", jbe@489: TRUE jbe@489: ) jbe@489: ) jbe@489: END AS "new_suggestion_count", jbe@477: FALSE AS "featured", jbe@477: TRUE AS "leading", jbe@477: "initiative".* jbe@489: FROM "updated_or_featured_initiative" AS "uf_initiative" jbe@489: JOIN "initiative" ON jbe@489: "uf_initiative"."issue_id" = "initiative"."issue_id" jbe@489: LEFT JOIN "supporter" ON jbe@489: "supporter"."member_id" = "uf_initiative"."seen_by_member_id" AND jbe@489: "supporter"."initiative_id" = "initiative"."id" jbe@489: LEFT JOIN "initiative_notification_sent" AS "sent" jbe@489: ON "sent"."member_id" = "uf_initiative"."seen_by_member_id" jbe@489: AND "sent"."initiative_id" = "initiative"."id" jbe@477: ORDER BY jbe@477: "seen_by_member_id", jbe@477: "initiative"."issue_id", jbe@477: "initiative"."harmonic_weight" DESC, jbe@477: "initiative"."id" jbe@477: ) AS "subquery" jbe@477: WHERE NOT EXISTS ( jbe@477: SELECT NULL FROM "updated_or_featured_initiative" AS "other" jbe@477: WHERE "other"."seen_by_member_id" = "subquery"."seen_by_member_id" jbe@477: AND "other"."id" = "subquery"."id" jbe@477: ); jbe@474: jbe@490: CREATE VIEW "unfiltered_initiative_for_notification" AS jbe@474: SELECT * FROM "updated_or_featured_initiative" jbe@477: UNION ALL jbe@474: SELECT * FROM "leading_complement_initiative"; jbe@474: jbe@490: CREATE VIEW "initiative_for_notification" AS jbe@490: SELECT "initiative1".* jbe@490: FROM "unfiltered_initiative_for_notification" "initiative1" jbe@490: JOIN "issue" AS "issue1" ON "initiative1"."issue_id" = "issue1"."id" jbe@490: WHERE EXISTS ( jbe@490: SELECT NULL jbe@490: FROM "unfiltered_initiative_for_notification" "initiative2" jbe@490: JOIN "issue" AS "issue2" ON "initiative2"."issue_id" = "issue2"."id" jbe@490: WHERE "initiative1"."seen_by_member_id" = "initiative2"."seen_by_member_id" jbe@490: AND "issue1"."area_id" = "issue2"."area_id" jbe@490: AND ( "initiative2"."new_draft" OR "initiative2"."new_suggestion_count" > 0 ) jbe@490: ); jbe@490: jbe@473: jbe@0: jbe@242: ------------------------------------------------------ jbe@242: -- Row set returning function for delegation chains -- jbe@242: ------------------------------------------------------ jbe@5: jbe@5: jbe@5: CREATE TYPE "delegation_chain_loop_tag" AS ENUM jbe@5: ('first', 'intermediate', 'last', 'repetition'); jbe@5: jbe@5: COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type'; jbe@5: jbe@5: jbe@5: CREATE TYPE "delegation_chain_row" AS ( jbe@5: "index" INT4, jbe@5: "member_id" INT4, jbe@97: "member_valid" BOOLEAN, jbe@5: "participation" BOOLEAN, jbe@5: "overridden" BOOLEAN, jbe@5: "scope_in" "delegation_scope", jbe@5: "scope_out" "delegation_scope", jbe@86: "disabled_out" BOOLEAN, jbe@5: "loop" "delegation_chain_loop_tag" ); jbe@5: jbe@243: COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function'; jbe@5: jbe@5: COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up'; jbe@5: COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest, for areas: membership, for global delegation chains: always null'; jbe@5: COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true'; jbe@5: COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation'; jbe@5: COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation'; jbe@86: COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL'; jbe@5: COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type'; jbe@5: jbe@5: jbe@242: CREATE FUNCTION "delegation_chain_for_closed_issue" jbe@242: ( "member_id_p" "member"."id"%TYPE, jbe@242: "issue_id_p" "issue"."id"%TYPE ) jbe@242: RETURNS SETOF "delegation_chain_row" jbe@242: LANGUAGE 'plpgsql' STABLE AS $$ jbe@242: DECLARE jbe@242: "output_row" "delegation_chain_row"; jbe@242: "direct_voter_row" "direct_voter"%ROWTYPE; jbe@242: "delegating_voter_row" "delegating_voter"%ROWTYPE; jbe@242: BEGIN jbe@242: "output_row"."index" := 0; jbe@242: "output_row"."member_id" := "member_id_p"; jbe@242: "output_row"."member_valid" := TRUE; jbe@242: "output_row"."participation" := FALSE; jbe@242: "output_row"."overridden" := FALSE; jbe@242: "output_row"."disabled_out" := FALSE; jbe@242: LOOP jbe@242: SELECT INTO "direct_voter_row" * FROM "direct_voter" jbe@242: WHERE "issue_id" = "issue_id_p" jbe@242: AND "member_id" = "output_row"."member_id"; jbe@242: IF "direct_voter_row"."member_id" NOTNULL THEN jbe@242: "output_row"."participation" := TRUE; jbe@242: "output_row"."scope_out" := NULL; jbe@242: "output_row"."disabled_out" := NULL; jbe@242: RETURN NEXT "output_row"; jbe@242: RETURN; jbe@242: END IF; jbe@242: SELECT INTO "delegating_voter_row" * FROM "delegating_voter" jbe@242: WHERE "issue_id" = "issue_id_p" jbe@242: AND "member_id" = "output_row"."member_id"; jbe@242: IF "delegating_voter_row"."member_id" ISNULL THEN jbe@242: RETURN; jbe@242: END IF; jbe@242: "output_row"."scope_out" := "delegating_voter_row"."scope"; jbe@242: RETURN NEXT "output_row"; jbe@242: "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1]; jbe@242: "output_row"."scope_in" := "output_row"."scope_out"; jbe@242: END LOOP; jbe@242: END; jbe@242: $$; jbe@242: jbe@242: COMMENT ON FUNCTION "delegation_chain_for_closed_issue" jbe@242: ( "member"."id"%TYPE, jbe@242: "member"."id"%TYPE ) jbe@242: IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting'; jbe@242: jbe@242: jbe@5: CREATE FUNCTION "delegation_chain" jbe@5: ( "member_id_p" "member"."id"%TYPE, jbe@97: "unit_id_p" "unit"."id"%TYPE, jbe@5: "area_id_p" "area"."id"%TYPE, jbe@5: "issue_id_p" "issue"."id"%TYPE, jbe@255: "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL, jbe@255: "simulate_default_p" BOOLEAN DEFAULT FALSE ) jbe@5: RETURNS SETOF "delegation_chain_row" jbe@5: LANGUAGE 'plpgsql' STABLE AS $$ jbe@5: DECLARE jbe@97: "scope_v" "delegation_scope"; jbe@97: "unit_id_v" "unit"."id"%TYPE; jbe@97: "area_id_v" "area"."id"%TYPE; jbe@241: "issue_row" "issue"%ROWTYPE; jbe@5: "visited_member_ids" INT4[]; -- "member"."id"%TYPE[] jbe@5: "loop_member_id_v" "member"."id"%TYPE; jbe@5: "output_row" "delegation_chain_row"; jbe@5: "output_rows" "delegation_chain_row"[]; jbe@255: "simulate_v" BOOLEAN; jbe@255: "simulate_here_v" BOOLEAN; jbe@5: "delegation_row" "delegation"%ROWTYPE; jbe@5: "row_count" INT4; jbe@5: "i" INT4; jbe@5: "loop_v" BOOLEAN; jbe@5: BEGIN jbe@255: IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN jbe@255: RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true'; jbe@255: END IF; jbe@255: IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN jbe@255: "simulate_v" := TRUE; jbe@255: ELSE jbe@255: "simulate_v" := FALSE; jbe@255: END IF; jbe@97: IF jbe@97: "unit_id_p" NOTNULL AND jbe@97: "area_id_p" ISNULL AND jbe@97: "issue_id_p" ISNULL jbe@97: THEN jbe@97: "scope_v" := 'unit'; jbe@97: "unit_id_v" := "unit_id_p"; jbe@97: ELSIF jbe@97: "unit_id_p" ISNULL AND jbe@97: "area_id_p" NOTNULL AND jbe@97: "issue_id_p" ISNULL jbe@97: THEN jbe@97: "scope_v" := 'area'; jbe@97: "area_id_v" := "area_id_p"; jbe@97: SELECT "unit_id" INTO "unit_id_v" jbe@97: FROM "area" WHERE "id" = "area_id_v"; jbe@97: ELSIF jbe@97: "unit_id_p" ISNULL AND jbe@97: "area_id_p" ISNULL AND jbe@97: "issue_id_p" NOTNULL jbe@97: THEN jbe@242: SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p"; jbe@242: IF "issue_row"."id" ISNULL THEN jbe@242: RETURN; jbe@242: END IF; jbe@242: IF "issue_row"."closed" NOTNULL THEN jbe@255: IF "simulate_v" THEN jbe@242: RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.'; jbe@242: END IF; jbe@242: FOR "output_row" IN jbe@242: SELECT * FROM jbe@242: "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p") jbe@242: LOOP jbe@242: RETURN NEXT "output_row"; jbe@242: END LOOP; jbe@242: RETURN; jbe@242: END IF; jbe@97: "scope_v" := 'issue'; jbe@97: SELECT "area_id" INTO "area_id_v" jbe@97: FROM "issue" WHERE "id" = "issue_id_p"; jbe@97: SELECT "unit_id" INTO "unit_id_v" jbe@97: FROM "area" WHERE "id" = "area_id_v"; jbe@97: ELSE jbe@97: RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.'; jbe@97: END IF; jbe@5: "visited_member_ids" := '{}'; jbe@5: "loop_member_id_v" := NULL; jbe@5: "output_rows" := '{}'; jbe@5: "output_row"."index" := 0; jbe@5: "output_row"."member_id" := "member_id_p"; jbe@97: "output_row"."member_valid" := TRUE; jbe@5: "output_row"."participation" := FALSE; jbe@5: "output_row"."overridden" := FALSE; jbe@86: "output_row"."disabled_out" := FALSE; jbe@5: "output_row"."scope_out" := NULL; jbe@5: LOOP jbe@5: IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN jbe@5: "loop_member_id_v" := "output_row"."member_id"; jbe@5: ELSE jbe@5: "visited_member_ids" := jbe@5: "visited_member_ids" || "output_row"."member_id"; jbe@5: END IF; jbe@241: IF "output_row"."participation" ISNULL THEN jbe@241: "output_row"."overridden" := NULL; jbe@241: ELSIF "output_row"."participation" THEN jbe@5: "output_row"."overridden" := TRUE; jbe@5: END IF; jbe@5: "output_row"."scope_in" := "output_row"."scope_out"; jbe@255: "output_row"."member_valid" := EXISTS ( jbe@97: SELECT NULL FROM "member" JOIN "privilege" jbe@97: ON "privilege"."member_id" = "member"."id" jbe@97: AND "privilege"."unit_id" = "unit_id_v" jbe@97: WHERE "id" = "output_row"."member_id" jbe@97: AND "member"."active" AND "privilege"."voting_right" jbe@255: ); jbe@255: "simulate_here_v" := ( jbe@255: "simulate_v" AND jbe@255: "output_row"."member_id" = "member_id_p" jbe@255: ); jbe@255: "delegation_row" := ROW(NULL); jbe@255: IF "output_row"."member_valid" OR "simulate_here_v" THEN jbe@97: IF "scope_v" = 'unit' THEN jbe@255: IF NOT "simulate_here_v" THEN jbe@255: SELECT * INTO "delegation_row" FROM "delegation" jbe@255: WHERE "truster_id" = "output_row"."member_id" jbe@255: AND "unit_id" = "unit_id_v"; jbe@255: END IF; jbe@97: ELSIF "scope_v" = 'area' THEN jbe@5: "output_row"."participation" := EXISTS ( jbe@5: SELECT NULL FROM "membership" jbe@5: WHERE "area_id" = "area_id_p" jbe@5: AND "member_id" = "output_row"."member_id" jbe@5: ); jbe@255: IF "simulate_here_v" THEN jbe@255: IF "simulate_trustee_id_p" ISNULL THEN jbe@255: SELECT * INTO "delegation_row" FROM "delegation" jbe@255: WHERE "truster_id" = "output_row"."member_id" jbe@255: AND "unit_id" = "unit_id_v"; jbe@255: END IF; jbe@255: ELSE jbe@255: SELECT * INTO "delegation_row" FROM "delegation" jbe@255: WHERE "truster_id" = "output_row"."member_id" jbe@255: AND ( jbe@255: "unit_id" = "unit_id_v" OR jbe@255: "area_id" = "area_id_v" jbe@255: ) jbe@255: ORDER BY "scope" DESC; jbe@255: END IF; jbe@97: ELSIF "scope_v" = 'issue' THEN jbe@241: IF "issue_row"."fully_frozen" ISNULL THEN jbe@241: "output_row"."participation" := EXISTS ( jbe@241: SELECT NULL FROM "interest" jbe@241: WHERE "issue_id" = "issue_id_p" jbe@241: AND "member_id" = "output_row"."member_id" jbe@241: ); jbe@241: ELSE jbe@241: IF "output_row"."member_id" = "member_id_p" THEN jbe@241: "output_row"."participation" := EXISTS ( jbe@241: SELECT NULL FROM "direct_voter" jbe@241: WHERE "issue_id" = "issue_id_p" jbe@241: AND "member_id" = "output_row"."member_id" jbe@241: ); jbe@241: ELSE jbe@241: "output_row"."participation" := NULL; jbe@241: END IF; jbe@241: END IF; jbe@255: IF "simulate_here_v" THEN jbe@255: IF "simulate_trustee_id_p" ISNULL THEN jbe@255: SELECT * INTO "delegation_row" FROM "delegation" jbe@255: WHERE "truster_id" = "output_row"."member_id" jbe@255: AND ( jbe@255: "unit_id" = "unit_id_v" OR jbe@255: "area_id" = "area_id_v" jbe@255: ) jbe@255: ORDER BY "scope" DESC; jbe@255: END IF; jbe@255: ELSE jbe@255: SELECT * INTO "delegation_row" FROM "delegation" jbe@255: WHERE "truster_id" = "output_row"."member_id" jbe@255: AND ( jbe@255: "unit_id" = "unit_id_v" OR jbe@255: "area_id" = "area_id_v" OR jbe@255: "issue_id" = "issue_id_p" jbe@255: ) jbe@255: ORDER BY "scope" DESC; jbe@255: END IF; jbe@5: END IF; jbe@5: ELSE jbe@5: "output_row"."participation" := FALSE; jbe@5: END IF; jbe@255: IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN jbe@97: "output_row"."scope_out" := "scope_v"; jbe@5: "output_rows" := "output_rows" || "output_row"; jbe@5: "output_row"."member_id" := "simulate_trustee_id_p"; jbe@5: ELSIF "delegation_row"."trustee_id" NOTNULL THEN jbe@10: "output_row"."scope_out" := "delegation_row"."scope"; jbe@5: "output_rows" := "output_rows" || "output_row"; jbe@5: "output_row"."member_id" := "delegation_row"."trustee_id"; jbe@86: ELSIF "delegation_row"."scope" NOTNULL THEN jbe@86: "output_row"."scope_out" := "delegation_row"."scope"; jbe@86: "output_row"."disabled_out" := TRUE; jbe@86: "output_rows" := "output_rows" || "output_row"; jbe@86: EXIT; jbe@5: ELSE jbe@5: "output_row"."scope_out" := NULL; jbe@5: "output_rows" := "output_rows" || "output_row"; jbe@5: EXIT; jbe@5: END IF; jbe@5: EXIT WHEN "loop_member_id_v" NOTNULL; jbe@5: "output_row"."index" := "output_row"."index" + 1; jbe@5: END LOOP; jbe@5: "row_count" := array_upper("output_rows", 1); jbe@5: "i" := 1; jbe@5: "loop_v" := FALSE; jbe@5: LOOP jbe@5: "output_row" := "output_rows"["i"]; jbe@98: EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results! jbe@5: IF "loop_v" THEN jbe@5: IF "i" + 1 = "row_count" THEN jbe@5: "output_row"."loop" := 'last'; jbe@5: ELSIF "i" = "row_count" THEN jbe@5: "output_row"."loop" := 'repetition'; jbe@5: ELSE jbe@5: "output_row"."loop" := 'intermediate'; jbe@5: END IF; jbe@5: ELSIF "output_row"."member_id" = "loop_member_id_v" THEN jbe@5: "output_row"."loop" := 'first'; jbe@5: "loop_v" := TRUE; jbe@5: END IF; jbe@97: IF "scope_v" = 'unit' THEN jbe@5: "output_row"."participation" := NULL; jbe@5: END IF; jbe@5: RETURN NEXT "output_row"; jbe@5: "i" := "i" + 1; jbe@5: END LOOP; jbe@5: RETURN; jbe@5: END; jbe@5: $$; jbe@5: jbe@5: COMMENT ON FUNCTION "delegation_chain" jbe@5: ( "member"."id"%TYPE, jbe@97: "unit"."id"%TYPE, jbe@5: "area"."id"%TYPE, jbe@5: "issue"."id"%TYPE, jbe@255: "member"."id"%TYPE, jbe@255: BOOLEAN ) jbe@242: IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information'; jbe@242: jbe@242: jbe@242: jbe@242: --------------------------------------------------------- jbe@242: -- Single row returning function for delegation chains -- jbe@242: --------------------------------------------------------- jbe@242: jbe@242: jbe@242: CREATE TYPE "delegation_info_loop_type" AS ENUM jbe@242: ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis'); jbe@240: jbe@243: COMMENT ON TYPE "delegation_info_loop_type" IS 'Type of "delegation_loop" in "delegation_info_type"; ''own'' means loop to self, ''first'' means loop to first trustee, ''first_ellipsis'' means loop to ellipsis after first trustee, ''other'' means loop to other trustee, ''other_ellipsis'' means loop to ellipsis after other trustee'''; jbe@243: jbe@243: jbe@240: CREATE TYPE "delegation_info_type" AS ( jbe@242: "own_participation" BOOLEAN, jbe@242: "own_delegation_scope" "delegation_scope", jbe@242: "first_trustee_id" INT4, jbe@240: "first_trustee_participation" BOOLEAN, jbe@242: "first_trustee_ellipsis" BOOLEAN, jbe@242: "other_trustee_id" INT4, jbe@240: "other_trustee_participation" BOOLEAN, jbe@242: "other_trustee_ellipsis" BOOLEAN, jbe@253: "delegation_loop" "delegation_info_loop_type", jbe@253: "participating_member_id" INT4 ); jbe@240: jbe@243: COMMENT ON TYPE "delegation_info_type" IS 'Type of result returned by "delegation_info" function; For meaning of "participation" check comment on "delegation_chain_row" type'; jbe@243: jbe@243: COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."other_trustee_participation" IS 'Another trustee is participating (redundant field: if "other_trustee_id" is set, then "other_trustee_participation" is always TRUE, else "other_trustee_participation" is NULL)'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"'; jbe@243: COMMENT ON COLUMN "delegation_info_type"."delegation_loop" IS 'Non-NULL value, if delegation chain contains a circle; See comment on "delegation_info_loop_type" for details'; jbe@253: COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain'; jbe@243: jbe@243: jbe@240: CREATE FUNCTION "delegation_info" jbe@242: ( "member_id_p" "member"."id"%TYPE, jbe@242: "unit_id_p" "unit"."id"%TYPE, jbe@242: "area_id_p" "area"."id"%TYPE, jbe@242: "issue_id_p" "issue"."id"%TYPE, jbe@255: "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL, jbe@255: "simulate_default_p" BOOLEAN DEFAULT FALSE ) jbe@240: RETURNS "delegation_info_type" jbe@240: LANGUAGE 'plpgsql' STABLE AS $$ jbe@240: DECLARE jbe@242: "current_row" "delegation_chain_row"; jbe@242: "result" "delegation_info_type"; jbe@240: BEGIN jbe@242: "result"."own_participation" := FALSE; jbe@242: FOR "current_row" IN jbe@242: SELECT * FROM "delegation_chain"( jbe@242: "member_id_p", jbe@242: "unit_id_p", "area_id_p", "issue_id_p", jbe@255: "simulate_trustee_id_p", "simulate_default_p") jbe@242: LOOP jbe@253: IF jbe@253: "result"."participating_member_id" ISNULL AND jbe@253: "current_row"."participation" jbe@253: THEN jbe@253: "result"."participating_member_id" := "current_row"."member_id"; jbe@253: END IF; jbe@242: IF "current_row"."member_id" = "member_id_p" THEN jbe@242: "result"."own_participation" := "current_row"."participation"; jbe@242: "result"."own_delegation_scope" := "current_row"."scope_out"; jbe@242: IF "current_row"."loop" = 'first' THEN jbe@242: "result"."delegation_loop" := 'own'; jbe@242: END IF; jbe@242: ELSIF jbe@242: "current_row"."member_valid" AND jbe@242: ( "current_row"."loop" ISNULL OR jbe@242: "current_row"."loop" != 'repetition' ) jbe@242: THEN jbe@242: IF "result"."first_trustee_id" ISNULL THEN jbe@242: "result"."first_trustee_id" := "current_row"."member_id"; jbe@242: "result"."first_trustee_participation" := "current_row"."participation"; jbe@242: "result"."first_trustee_ellipsis" := FALSE; jbe@242: IF "current_row"."loop" = 'first' THEN jbe@242: "result"."delegation_loop" := 'first'; jbe@242: END IF; jbe@242: ELSIF "result"."other_trustee_id" ISNULL THEN jbe@247: IF "current_row"."participation" AND NOT "current_row"."overridden" THEN jbe@242: "result"."other_trustee_id" := "current_row"."member_id"; jbe@242: "result"."other_trustee_participation" := TRUE; jbe@242: "result"."other_trustee_ellipsis" := FALSE; jbe@242: IF "current_row"."loop" = 'first' THEN jbe@242: "result"."delegation_loop" := 'other'; jbe@240: END IF; jbe@240: ELSE jbe@242: "result"."first_trustee_ellipsis" := TRUE; jbe@242: IF "current_row"."loop" = 'first' THEN jbe@242: "result"."delegation_loop" := 'first_ellipsis'; jbe@242: END IF; jbe@242: END IF; jbe@242: ELSE jbe@242: "result"."other_trustee_ellipsis" := TRUE; jbe@242: IF "current_row"."loop" = 'first' THEN jbe@242: "result"."delegation_loop" := 'other_ellipsis'; jbe@240: END IF; jbe@240: END IF; jbe@240: END IF; jbe@242: END LOOP; jbe@240: RETURN "result"; jbe@240: END; jbe@240: $$; jbe@240: jbe@243: COMMENT ON FUNCTION "delegation_info" jbe@243: ( "member"."id"%TYPE, jbe@243: "unit"."id"%TYPE, jbe@243: "area"."id"%TYPE, jbe@243: "issue"."id"%TYPE, jbe@255: "member"."id"%TYPE, jbe@255: BOOLEAN ) jbe@243: IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information'; jbe@243: jbe@240: jbe@240: jbe@333: --------------------------- jbe@333: -- Transaction isolation -- jbe@333: --------------------------- jbe@333: jbe@344: jbe@333: CREATE FUNCTION "require_transaction_isolation"() jbe@333: RETURNS VOID jbe@333: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@333: BEGIN jbe@333: IF jbe@333: current_setting('transaction_isolation') NOT IN jbe@333: ('repeatable read', 'serializable') jbe@333: THEN jbe@463: RAISE EXCEPTION 'Insufficient transaction isolation level' USING jbe@463: HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.'; jbe@333: END IF; jbe@333: RETURN; jbe@333: END; jbe@333: $$; jbe@333: jbe@344: COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot'; jbe@344: jbe@333: jbe@333: CREATE FUNCTION "dont_require_transaction_isolation"() jbe@333: RETURNS VOID jbe@333: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@333: BEGIN jbe@333: IF jbe@333: current_setting('transaction_isolation') IN jbe@333: ('repeatable read', 'serializable') jbe@333: THEN jbe@333: RAISE WARNING 'Unneccessary transaction isolation level: %', jbe@333: current_setting('transaction_isolation'); jbe@333: END IF; jbe@333: RETURN; jbe@333: END; jbe@333: $$; jbe@333: jbe@344: COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED'; jbe@344: jbe@333: jbe@333: jbe@491: ------------------------- jbe@491: -- Notification system -- jbe@491: ------------------------- jbe@491: jbe@491: CREATE FUNCTION "get_initiatives_for_notification" jbe@491: ( "member_id_p" "member"."id"%TYPE ) jbe@491: RETURNS SETOF "initiative_for_notification" jbe@491: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@491: DECLARE jbe@491: "result_row" "initiative_for_notification"%ROWTYPE; jbe@491: "last_draft_id_v" "draft"."id"%TYPE; jbe@491: "last_suggestion_id_v" "suggestion"."id"%TYPE; jbe@491: BEGIN jbe@491: PERFORM "require_transaction_isolation"(); jbe@491: PERFORM NULL FROM "member" WHERE "id" = "member_id_p" FOR UPDATE; jbe@491: FOR "result_row" IN jbe@491: SELECT * FROM "initiative_for_notification" jbe@491: WHERE "seen_by_member_id" = "member_id_p" jbe@491: LOOP jbe@491: SELECT "id" INTO "last_draft_id_v" FROM "draft" jbe@491: WHERE "draft"."initiative_id" = "result_row"."id" jbe@491: ORDER BY "id" DESC LIMIT 1; jbe@491: SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion" jbe@491: WHERE "suggestion"."initiative_id" = "result_row"."id" jbe@491: ORDER BY "id" DESC LIMIT 1; jbe@491: INSERT INTO "initiative_notification_sent" jbe@491: ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id") jbe@491: VALUES ( jbe@491: "member_id_p", jbe@491: "result_row"."id", jbe@493: "last_draft_id_v", jbe@493: "last_suggestion_id_v" ) jbe@491: ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET jbe@491: "last_draft_id" = CASE jbe@494: WHEN "initiative_notification_sent"."last_draft_id" > "last_draft_id_v" jbe@494: THEN "initiative_notification_sent"."last_draft_id" jbe@491: ELSE "last_draft_id_v" jbe@491: END, jbe@491: "last_suggestion_id" = CASE jbe@494: WHEN "initiative_notification_sent"."last_suggestion_id" > "last_suggestion_id_v" jbe@494: THEN "initiative_notification_sent"."last_suggestion_id" jbe@491: ELSE "last_suggestion_id_v" jbe@491: END; jbe@491: RETURN NEXT "result_row"; jbe@491: END LOOP; jbe@491: DELETE FROM "initiative_notification_sent" jbe@491: USING "initiative", "issue" jbe@491: WHERE "initiative_notification_sent"."member_id" = "member_id_p" jbe@491: AND "initiative"."id" = "initiative_notification_sent"."initiative_id" jbe@491: AND "issue"."id" = "initiative"."issue_id" jbe@491: AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL ); jbe@491: UPDATE "member" SET "notification_counter" = "notification_counter" + 1 jbe@491: WHERE "id" = "member_id_p"; jbe@491: RETURN; jbe@491: END; jbe@491: $$; jbe@491: jbe@491: jbe@491: jbe@103: ------------------------------------------------------------------------ jbe@103: -- Regular tasks, except calculcation of snapshots and voting results -- jbe@103: ------------------------------------------------------------------------ jbe@103: jbe@333: jbe@184: CREATE FUNCTION "check_activity"() jbe@103: RETURNS VOID jbe@103: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@104: DECLARE jbe@104: "system_setting_row" "system_setting"%ROWTYPE; jbe@103: BEGIN jbe@333: PERFORM "dont_require_transaction_isolation"(); jbe@104: SELECT * INTO "system_setting_row" FROM "system_setting"; jbe@104: IF "system_setting_row"."member_ttl" NOTNULL THEN jbe@104: UPDATE "member" SET "active" = FALSE jbe@104: WHERE "active" = TRUE jbe@184: AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE; jbe@104: END IF; jbe@103: RETURN; jbe@103: END; jbe@103: $$; jbe@103: jbe@184: COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".'; jbe@103: jbe@4: jbe@4: CREATE FUNCTION "calculate_member_counts"() jbe@4: RETURNS VOID jbe@4: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@4: BEGIN jbe@333: PERFORM "require_transaction_isolation"(); jbe@4: DELETE FROM "member_count"; jbe@5: INSERT INTO "member_count" ("total_count") jbe@5: SELECT "total_count" FROM "member_count_view"; jbe@97: UPDATE "unit" SET "member_count" = "view"."member_count" jbe@97: FROM "unit_member_count" AS "view" jbe@97: WHERE "view"."unit_id" = "unit"."id"; jbe@5: UPDATE "area" SET jbe@5: "direct_member_count" = "view"."direct_member_count", jbe@169: "member_weight" = "view"."member_weight" jbe@5: FROM "area_member_count" AS "view" jbe@5: WHERE "view"."area_id" = "area"."id"; jbe@4: RETURN; jbe@4: END; jbe@4: $$; jbe@4: jbe@4: COMMENT ON FUNCTION "calculate_member_counts"() IS 'Updates "member_count" table and "member_count" column of table "area" by materializing data from views "member_count_view" and "area_member_count"'; jbe@4: jbe@4: jbe@4: jbe@327: ------------------------------------ jbe@327: -- Calculation of harmonic weight -- jbe@327: ------------------------------------ jbe@310: jbe@312: jbe@310: CREATE VIEW "remaining_harmonic_supporter_weight" AS jbe@310: SELECT jbe@310: "direct_interest_snapshot"."issue_id", jbe@310: "direct_interest_snapshot"."event", jbe@310: "direct_interest_snapshot"."member_id", jbe@310: "direct_interest_snapshot"."weight" AS "weight_num", jbe@310: count("initiative"."id") AS "weight_den" jbe@312: FROM "issue" jbe@312: JOIN "direct_interest_snapshot" jbe@312: ON "issue"."id" = "direct_interest_snapshot"."issue_id" jbe@312: AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event" jbe@327: JOIN "initiative" jbe@327: ON "issue"."id" = "initiative"."issue_id" jbe@327: AND "initiative"."harmonic_weight" ISNULL jbe@310: JOIN "direct_supporter_snapshot" jbe@327: ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id" jbe@310: AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event" jbe@310: AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id" jbe@321: AND ( jbe@321: "direct_supporter_snapshot"."satisfied" = TRUE OR jbe@321: coalesce("initiative"."admitted", FALSE) = FALSE jbe@321: ) jbe@310: GROUP BY jbe@310: "direct_interest_snapshot"."issue_id", jbe@310: "direct_interest_snapshot"."event", jbe@310: "direct_interest_snapshot"."member_id", jbe@310: "direct_interest_snapshot"."weight"; jbe@310: jbe@310: COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"'; jbe@310: jbe@310: jbe@310: CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS jbe@310: SELECT jbe@310: "initiative"."issue_id", jbe@310: "initiative"."id" AS "initiative_id", jbe@320: "initiative"."admitted", jbe@310: sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num", jbe@310: "remaining_harmonic_supporter_weight"."weight_den" jbe@310: FROM "remaining_harmonic_supporter_weight" jbe@327: JOIN "initiative" jbe@327: ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id" jbe@327: AND "initiative"."harmonic_weight" ISNULL jbe@310: JOIN "direct_supporter_snapshot" jbe@327: ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id" jbe@310: AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event" jbe@310: AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id" jbe@321: AND ( jbe@321: "direct_supporter_snapshot"."satisfied" = TRUE OR jbe@321: coalesce("initiative"."admitted", FALSE) = FALSE jbe@321: ) jbe@310: GROUP BY jbe@310: "initiative"."issue_id", jbe@310: "initiative"."id", jbe@320: "initiative"."admitted", jbe@310: "remaining_harmonic_supporter_weight"."weight_den"; jbe@310: jbe@310: COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"'; jbe@310: jbe@310: jbe@349: CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS jbe@349: SELECT jbe@349: "issue_id", jbe@349: "id" AS "initiative_id", jbe@349: "admitted", jbe@349: 0 AS "weight_num", jbe@349: 1 AS "weight_den" jbe@349: FROM "initiative" jbe@349: WHERE "harmonic_weight" ISNULL; jbe@349: jbe@349: COMMENT ON VIEW "remaining_harmonic_initiative_weight_dummies" IS 'Helper view for function "set_harmonic_initiative_weights" providing dummy weights of zero value, which are needed for corner cases where there are no supporters for an initiative at all'; jbe@349: jbe@349: jbe@310: CREATE FUNCTION "set_harmonic_initiative_weights" jbe@310: ( "issue_id_p" "issue"."id"%TYPE ) jbe@310: RETURNS VOID jbe@310: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@310: DECLARE jbe@310: "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE; jbe@310: "i" INT4; jbe@310: "count_v" INT4; jbe@310: "summand_v" FLOAT; jbe@310: "id_ary" INT4[]; jbe@310: "weight_ary" FLOAT[]; jbe@310: "min_weight_v" FLOAT; jbe@310: BEGIN jbe@333: PERFORM "require_transaction_isolation"(); jbe@312: UPDATE "initiative" SET "harmonic_weight" = NULL jbe@312: WHERE "issue_id" = "issue_id_p"; jbe@310: LOOP jbe@310: "min_weight_v" := NULL; jbe@310: "i" := 0; jbe@310: "count_v" := 0; jbe@310: FOR "weight_row" IN jbe@310: SELECT * FROM "remaining_harmonic_initiative_weight_summands" jbe@310: WHERE "issue_id" = "issue_id_p" jbe@320: AND ( jbe@320: coalesce("admitted", FALSE) = FALSE OR NOT EXISTS ( jbe@320: SELECT NULL FROM "initiative" jbe@320: WHERE "issue_id" = "issue_id_p" jbe@320: AND "harmonic_weight" ISNULL jbe@320: AND coalesce("admitted", FALSE) = FALSE jbe@320: ) jbe@320: ) jbe@349: UNION ALL -- needed for corner cases jbe@349: SELECT * FROM "remaining_harmonic_initiative_weight_dummies" jbe@349: WHERE "issue_id" = "issue_id_p" jbe@349: AND ( jbe@349: coalesce("admitted", FALSE) = FALSE OR NOT EXISTS ( jbe@349: SELECT NULL FROM "initiative" jbe@349: WHERE "issue_id" = "issue_id_p" jbe@349: AND "harmonic_weight" ISNULL jbe@349: AND coalesce("admitted", FALSE) = FALSE jbe@349: ) jbe@349: ) jbe@310: ORDER BY "initiative_id" DESC, "weight_den" DESC jbe@320: -- NOTE: non-admitted initiatives placed first (at last positions), jbe@320: -- latest initiatives treated worse in case of tie jbe@310: LOOP jbe@310: "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT; jbe@310: IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN jbe@310: "i" := "i" + 1; jbe@310: "count_v" := "i"; jbe@310: "id_ary"["i"] := "weight_row"."initiative_id"; jbe@310: "weight_ary"["i"] := "summand_v"; jbe@310: ELSE jbe@310: "weight_ary"["i"] := "weight_ary"["i"] + "summand_v"; jbe@310: END IF; jbe@310: END LOOP; jbe@310: EXIT WHEN "count_v" = 0; jbe@310: "i" := 1; jbe@310: LOOP jbe@313: "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3); jbe@310: IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN jbe@310: "min_weight_v" := "weight_ary"["i"]; jbe@310: END IF; jbe@310: "i" := "i" + 1; jbe@310: EXIT WHEN "i" > "count_v"; jbe@310: END LOOP; jbe@310: "i" := 1; jbe@310: LOOP jbe@310: IF "weight_ary"["i"] = "min_weight_v" THEN jbe@310: UPDATE "initiative" SET "harmonic_weight" = "min_weight_v" jbe@310: WHERE "id" = "id_ary"["i"]; jbe@310: EXIT; jbe@310: END IF; jbe@310: "i" := "i" + 1; jbe@310: END LOOP; jbe@310: END LOOP; jbe@316: UPDATE "initiative" SET "harmonic_weight" = 0 jbe@316: WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL; jbe@310: END; jbe@310: $$; jbe@310: jbe@310: COMMENT ON FUNCTION "set_harmonic_initiative_weights" jbe@310: ( "issue"."id"%TYPE ) jbe@310: IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue'; jbe@310: jbe@310: jbe@312: jbe@0: ------------------------------ jbe@0: -- Calculation of snapshots -- jbe@0: ------------------------------ jbe@0: jbe@312: jbe@0: CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot" jbe@0: ( "issue_id_p" "issue"."id"%TYPE, jbe@0: "member_id_p" "member"."id"%TYPE, jbe@0: "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE ) jbe@0: RETURNS "direct_population_snapshot"."weight"%TYPE jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "issue_delegation_row" "issue_delegation"%ROWTYPE; jbe@0: "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE; jbe@0: "weight_v" INT4; jbe@8: "sub_weight_v" INT4; jbe@0: BEGIN jbe@336: PERFORM "require_transaction_isolation"(); jbe@0: "weight_v" := 0; jbe@0: FOR "issue_delegation_row" IN jbe@0: SELECT * FROM "issue_delegation" jbe@0: WHERE "trustee_id" = "member_id_p" jbe@0: AND "issue_id" = "issue_id_p" jbe@0: LOOP jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "direct_population_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: AND "member_id" = "issue_delegation_row"."truster_id" jbe@0: ) AND NOT EXISTS ( jbe@0: SELECT NULL FROM "delegating_population_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: AND "member_id" = "issue_delegation_row"."truster_id" jbe@0: ) THEN jbe@0: "delegate_member_ids_v" := jbe@0: "member_id_p" || "delegate_member_ids_p"; jbe@10: INSERT INTO "delegating_population_snapshot" ( jbe@10: "issue_id", jbe@10: "event", jbe@10: "member_id", jbe@10: "scope", jbe@10: "delegate_member_ids" jbe@10: ) VALUES ( jbe@0: "issue_id_p", jbe@0: 'periodic', jbe@0: "issue_delegation_row"."truster_id", jbe@10: "issue_delegation_row"."scope", jbe@0: "delegate_member_ids_v" jbe@0: ); jbe@8: "sub_weight_v" := 1 + jbe@0: "weight_of_added_delegations_for_population_snapshot"( jbe@0: "issue_id_p", jbe@0: "issue_delegation_row"."truster_id", jbe@0: "delegate_member_ids_v" jbe@0: ); jbe@8: UPDATE "delegating_population_snapshot" jbe@8: SET "weight" = "sub_weight_v" jbe@8: WHERE "issue_id" = "issue_id_p" jbe@8: AND "event" = 'periodic' jbe@8: AND "member_id" = "issue_delegation_row"."truster_id"; jbe@8: "weight_v" := "weight_v" + "sub_weight_v"; jbe@0: END IF; jbe@0: END LOOP; jbe@0: RETURN "weight_v"; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot" jbe@0: ( "issue"."id"%TYPE, jbe@0: "member"."id"%TYPE, jbe@0: "delegating_population_snapshot"."delegate_member_ids"%TYPE ) jbe@0: IS 'Helper function for "create_population_snapshot" function'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "create_population_snapshot" jbe@0: ( "issue_id_p" "issue"."id"%TYPE ) jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "member_id_v" "member"."id"%TYPE; jbe@0: BEGIN jbe@336: PERFORM "require_transaction_isolation"(); jbe@0: DELETE FROM "direct_population_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic'; jbe@0: DELETE FROM "delegating_population_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic'; jbe@0: INSERT INTO "direct_population_snapshot" jbe@54: ("issue_id", "event", "member_id") jbe@54: SELECT jbe@54: "issue_id_p" AS "issue_id", jbe@54: 'periodic'::"snapshot_event" AS "event", jbe@54: "member"."id" AS "member_id" jbe@54: FROM "issue" jbe@54: JOIN "area" ON "issue"."area_id" = "area"."id" jbe@54: JOIN "membership" ON "area"."id" = "membership"."area_id" jbe@54: JOIN "member" ON "membership"."member_id" = "member"."id" jbe@97: JOIN "privilege" jbe@97: ON "privilege"."unit_id" = "area"."unit_id" jbe@97: AND "privilege"."member_id" = "member"."id" jbe@54: WHERE "issue"."id" = "issue_id_p" jbe@97: AND "member"."active" AND "privilege"."voting_right" jbe@54: UNION jbe@54: SELECT jbe@54: "issue_id_p" AS "issue_id", jbe@54: 'periodic'::"snapshot_event" AS "event", jbe@54: "member"."id" AS "member_id" jbe@97: FROM "issue" jbe@97: JOIN "area" ON "issue"."area_id" = "area"."id" jbe@97: JOIN "interest" ON "issue"."id" = "interest"."issue_id" jbe@97: JOIN "member" ON "interest"."member_id" = "member"."id" jbe@97: JOIN "privilege" jbe@97: ON "privilege"."unit_id" = "area"."unit_id" jbe@97: AND "privilege"."member_id" = "member"."id" jbe@97: WHERE "issue"."id" = "issue_id_p" jbe@97: AND "member"."active" AND "privilege"."voting_right"; jbe@0: FOR "member_id_v" IN jbe@0: SELECT "member_id" FROM "direct_population_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: LOOP jbe@0: UPDATE "direct_population_snapshot" SET jbe@0: "weight" = 1 + jbe@0: "weight_of_added_delegations_for_population_snapshot"( jbe@0: "issue_id_p", jbe@0: "member_id_v", jbe@0: '{}' jbe@0: ) jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: AND "member_id" = "member_id_v"; jbe@0: END LOOP; jbe@0: RETURN; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "create_population_snapshot" jbe@67: ( "issue"."id"%TYPE ) jbe@0: IS 'This function creates a new ''periodic'' population snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot" jbe@0: ( "issue_id_p" "issue"."id"%TYPE, jbe@0: "member_id_p" "member"."id"%TYPE, jbe@0: "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE ) jbe@0: RETURNS "direct_interest_snapshot"."weight"%TYPE jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "issue_delegation_row" "issue_delegation"%ROWTYPE; jbe@0: "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE; jbe@0: "weight_v" INT4; jbe@8: "sub_weight_v" INT4; jbe@0: BEGIN jbe@336: PERFORM "require_transaction_isolation"(); jbe@0: "weight_v" := 0; jbe@0: FOR "issue_delegation_row" IN jbe@0: SELECT * FROM "issue_delegation" jbe@0: WHERE "trustee_id" = "member_id_p" jbe@0: AND "issue_id" = "issue_id_p" jbe@0: LOOP jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "direct_interest_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: AND "member_id" = "issue_delegation_row"."truster_id" jbe@0: ) AND NOT EXISTS ( jbe@0: SELECT NULL FROM "delegating_interest_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: AND "member_id" = "issue_delegation_row"."truster_id" jbe@0: ) THEN jbe@0: "delegate_member_ids_v" := jbe@0: "member_id_p" || "delegate_member_ids_p"; jbe@10: INSERT INTO "delegating_interest_snapshot" ( jbe@10: "issue_id", jbe@10: "event", jbe@10: "member_id", jbe@10: "scope", jbe@10: "delegate_member_ids" jbe@10: ) VALUES ( jbe@0: "issue_id_p", jbe@0: 'periodic', jbe@0: "issue_delegation_row"."truster_id", jbe@10: "issue_delegation_row"."scope", jbe@0: "delegate_member_ids_v" jbe@0: ); jbe@8: "sub_weight_v" := 1 + jbe@0: "weight_of_added_delegations_for_interest_snapshot"( jbe@0: "issue_id_p", jbe@0: "issue_delegation_row"."truster_id", jbe@0: "delegate_member_ids_v" jbe@0: ); jbe@8: UPDATE "delegating_interest_snapshot" jbe@8: SET "weight" = "sub_weight_v" jbe@8: WHERE "issue_id" = "issue_id_p" jbe@8: AND "event" = 'periodic' jbe@8: AND "member_id" = "issue_delegation_row"."truster_id"; jbe@8: "weight_v" := "weight_v" + "sub_weight_v"; jbe@0: END IF; jbe@0: END LOOP; jbe@0: RETURN "weight_v"; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot" jbe@0: ( "issue"."id"%TYPE, jbe@0: "member"."id"%TYPE, jbe@0: "delegating_interest_snapshot"."delegate_member_ids"%TYPE ) jbe@0: IS 'Helper function for "create_interest_snapshot" function'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "create_interest_snapshot" jbe@0: ( "issue_id_p" "issue"."id"%TYPE ) jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "member_id_v" "member"."id"%TYPE; jbe@0: BEGIN jbe@336: PERFORM "require_transaction_isolation"(); jbe@0: DELETE FROM "direct_interest_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic'; jbe@0: DELETE FROM "delegating_interest_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic'; jbe@0: DELETE FROM "direct_supporter_snapshot" jbe@325: USING "initiative" -- NOTE: due to missing index on issue_id jbe@325: WHERE "initiative"."issue_id" = "issue_id_p" jbe@325: AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id" jbe@325: AND "direct_supporter_snapshot"."event" = 'periodic'; jbe@0: INSERT INTO "direct_interest_snapshot" jbe@144: ("issue_id", "event", "member_id") jbe@0: SELECT jbe@0: "issue_id_p" AS "issue_id", jbe@0: 'periodic' AS "event", jbe@144: "member"."id" AS "member_id" jbe@97: FROM "issue" jbe@97: JOIN "area" ON "issue"."area_id" = "area"."id" jbe@97: JOIN "interest" ON "issue"."id" = "interest"."issue_id" jbe@97: JOIN "member" ON "interest"."member_id" = "member"."id" jbe@97: JOIN "privilege" jbe@97: ON "privilege"."unit_id" = "area"."unit_id" jbe@97: AND "privilege"."member_id" = "member"."id" jbe@97: WHERE "issue"."id" = "issue_id_p" jbe@97: AND "member"."active" AND "privilege"."voting_right"; jbe@0: FOR "member_id_v" IN jbe@0: SELECT "member_id" FROM "direct_interest_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: LOOP jbe@0: UPDATE "direct_interest_snapshot" SET jbe@0: "weight" = 1 + jbe@0: "weight_of_added_delegations_for_interest_snapshot"( jbe@0: "issue_id_p", jbe@0: "member_id_v", jbe@0: '{}' jbe@0: ) jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: AND "member_id" = "member_id_v"; jbe@0: END LOOP; jbe@0: INSERT INTO "direct_supporter_snapshot" jbe@0: ( "issue_id", "initiative_id", "event", "member_id", jbe@204: "draft_id", "informed", "satisfied" ) jbe@0: SELECT jbe@96: "issue_id_p" AS "issue_id", jbe@96: "initiative"."id" AS "initiative_id", jbe@96: 'periodic' AS "event", jbe@96: "supporter"."member_id" AS "member_id", jbe@204: "supporter"."draft_id" AS "draft_id", jbe@0: "supporter"."draft_id" = "current_draft"."id" AS "informed", jbe@0: NOT EXISTS ( jbe@0: SELECT NULL FROM "critical_opinion" jbe@0: WHERE "initiative_id" = "initiative"."id" jbe@96: AND "member_id" = "supporter"."member_id" jbe@0: ) AS "satisfied" jbe@96: FROM "initiative" jbe@96: JOIN "supporter" jbe@0: ON "supporter"."initiative_id" = "initiative"."id" jbe@0: JOIN "current_draft" jbe@0: ON "initiative"."id" = "current_draft"."initiative_id" jbe@0: JOIN "direct_interest_snapshot" jbe@96: ON "supporter"."member_id" = "direct_interest_snapshot"."member_id" jbe@0: AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id" jbe@3: AND "event" = 'periodic' jbe@96: WHERE "initiative"."issue_id" = "issue_id_p"; jbe@0: RETURN; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "create_interest_snapshot" jbe@0: ( "issue"."id"%TYPE ) jbe@0: IS 'This function creates a new ''periodic'' interest/supporter snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "create_snapshot" jbe@0: ( "issue_id_p" "issue"."id"%TYPE ) jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "initiative_id_v" "initiative"."id"%TYPE; jbe@0: "suggestion_id_v" "suggestion"."id"%TYPE; jbe@0: BEGIN jbe@333: PERFORM "require_transaction_isolation"(); jbe@0: PERFORM "create_population_snapshot"("issue_id_p"); jbe@0: PERFORM "create_interest_snapshot"("issue_id_p"); jbe@0: UPDATE "issue" SET jbe@331: "snapshot" = coalesce("phase_finished", now()), jbe@8: "latest_snapshot_event" = 'periodic', jbe@0: "population" = ( jbe@0: SELECT coalesce(sum("weight"), 0) jbe@0: FROM "direct_population_snapshot" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: AND "event" = 'periodic' jbe@0: ) jbe@0: WHERE "id" = "issue_id_p"; jbe@0: FOR "initiative_id_v" IN jbe@0: SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p" jbe@0: LOOP jbe@0: UPDATE "initiative" SET jbe@0: "supporter_count" = ( jbe@0: SELECT coalesce(sum("di"."weight"), 0) jbe@0: FROM "direct_interest_snapshot" AS "di" jbe@0: JOIN "direct_supporter_snapshot" AS "ds" jbe@0: ON "di"."member_id" = "ds"."member_id" jbe@0: WHERE "di"."issue_id" = "issue_id_p" jbe@0: AND "di"."event" = 'periodic' jbe@0: AND "ds"."initiative_id" = "initiative_id_v" jbe@0: AND "ds"."event" = 'periodic' jbe@0: ), jbe@0: "informed_supporter_count" = ( jbe@0: SELECT coalesce(sum("di"."weight"), 0) jbe@0: FROM "direct_interest_snapshot" AS "di" jbe@0: JOIN "direct_supporter_snapshot" AS "ds" jbe@0: ON "di"."member_id" = "ds"."member_id" jbe@0: WHERE "di"."issue_id" = "issue_id_p" jbe@0: AND "di"."event" = 'periodic' jbe@0: AND "ds"."initiative_id" = "initiative_id_v" jbe@0: AND "ds"."event" = 'periodic' jbe@0: AND "ds"."informed" jbe@0: ), jbe@0: "satisfied_supporter_count" = ( jbe@0: SELECT coalesce(sum("di"."weight"), 0) jbe@0: FROM "direct_interest_snapshot" AS "di" jbe@0: JOIN "direct_supporter_snapshot" AS "ds" jbe@0: ON "di"."member_id" = "ds"."member_id" jbe@0: WHERE "di"."issue_id" = "issue_id_p" jbe@0: AND "di"."event" = 'periodic' jbe@0: AND "ds"."initiative_id" = "initiative_id_v" jbe@0: AND "ds"."event" = 'periodic' jbe@0: AND "ds"."satisfied" jbe@0: ), jbe@0: "satisfied_informed_supporter_count" = ( jbe@0: SELECT coalesce(sum("di"."weight"), 0) jbe@0: FROM "direct_interest_snapshot" AS "di" jbe@0: JOIN "direct_supporter_snapshot" AS "ds" jbe@0: ON "di"."member_id" = "ds"."member_id" jbe@0: WHERE "di"."issue_id" = "issue_id_p" jbe@0: AND "di"."event" = 'periodic' jbe@0: AND "ds"."initiative_id" = "initiative_id_v" jbe@0: AND "ds"."event" = 'periodic' jbe@0: AND "ds"."informed" jbe@0: AND "ds"."satisfied" jbe@0: ) jbe@0: WHERE "id" = "initiative_id_v"; jbe@0: FOR "suggestion_id_v" IN jbe@0: SELECT "id" FROM "suggestion" jbe@0: WHERE "initiative_id" = "initiative_id_v" jbe@0: LOOP jbe@0: UPDATE "suggestion" SET jbe@0: "minus2_unfulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = -2 jbe@0: AND "opinion"."fulfilled" = FALSE jbe@0: ), jbe@0: "minus2_fulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = -2 jbe@0: AND "opinion"."fulfilled" = TRUE jbe@0: ), jbe@0: "minus1_unfulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = -1 jbe@0: AND "opinion"."fulfilled" = FALSE jbe@0: ), jbe@0: "minus1_fulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = -1 jbe@0: AND "opinion"."fulfilled" = TRUE jbe@0: ), jbe@0: "plus1_unfulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = 1 jbe@0: AND "opinion"."fulfilled" = FALSE jbe@0: ), jbe@0: "plus1_fulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = 1 jbe@0: AND "opinion"."fulfilled" = TRUE jbe@0: ), jbe@0: "plus2_unfulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = 2 jbe@0: AND "opinion"."fulfilled" = FALSE jbe@0: ), jbe@0: "plus2_fulfilled_count" = ( jbe@0: SELECT coalesce(sum("snapshot"."weight"), 0) jbe@36: FROM "issue" CROSS JOIN "opinion" jbe@36: JOIN "direct_interest_snapshot" AS "snapshot" jbe@36: ON "snapshot"."issue_id" = "issue"."id" jbe@36: AND "snapshot"."event" = "issue"."latest_snapshot_event" jbe@36: AND "snapshot"."member_id" = "opinion"."member_id" jbe@36: WHERE "issue"."id" = "issue_id_p" jbe@36: AND "opinion"."suggestion_id" = "suggestion_id_v" jbe@0: AND "opinion"."degree" = 2 jbe@0: AND "opinion"."fulfilled" = TRUE jbe@0: ) jbe@0: WHERE "suggestion"."id" = "suggestion_id_v"; jbe@0: END LOOP; jbe@0: END LOOP; jbe@0: RETURN; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "create_snapshot" jbe@0: ( "issue"."id"%TYPE ) jbe@0: IS 'This function creates a complete new ''periodic'' snapshot of population, interest and support for the given issue. All involved tables are locked, and after completion precalculated values in the source tables are updated.'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "set_snapshot_event" jbe@0: ( "issue_id_p" "issue"."id"%TYPE, jbe@0: "event_p" "snapshot_event" ) jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@21: DECLARE jbe@21: "event_v" "issue"."latest_snapshot_event"%TYPE; jbe@0: BEGIN jbe@333: PERFORM "require_transaction_isolation"(); jbe@21: SELECT "latest_snapshot_event" INTO "event_v" FROM "issue" jbe@21: WHERE "id" = "issue_id_p" FOR UPDATE; jbe@8: UPDATE "issue" SET "latest_snapshot_event" = "event_p" jbe@8: WHERE "id" = "issue_id_p"; jbe@3: UPDATE "direct_population_snapshot" SET "event" = "event_p" jbe@21: WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; jbe@3: UPDATE "delegating_population_snapshot" SET "event" = "event_p" jbe@21: WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; jbe@3: UPDATE "direct_interest_snapshot" SET "event" = "event_p" jbe@21: WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; jbe@3: UPDATE "delegating_interest_snapshot" SET "event" = "event_p" jbe@21: WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; jbe@3: UPDATE "direct_supporter_snapshot" SET "event" = "event_p" jbe@325: FROM "initiative" -- NOTE: due to missing index on issue_id jbe@325: WHERE "initiative"."issue_id" = "issue_id_p" jbe@325: AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id" jbe@325: AND "direct_supporter_snapshot"."event" = "event_v"; jbe@0: RETURN; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "set_snapshot_event" jbe@0: ( "issue"."id"%TYPE, jbe@0: "snapshot_event" ) jbe@0: IS 'Change "event" attribute of the previous ''periodic'' snapshot'; jbe@0: jbe@0: jbe@0: jbe@0: ----------------------- jbe@0: -- Counting of votes -- jbe@0: ----------------------- jbe@0: jbe@0: jbe@5: CREATE FUNCTION "weight_of_added_vote_delegations" jbe@0: ( "issue_id_p" "issue"."id"%TYPE, jbe@0: "member_id_p" "member"."id"%TYPE, jbe@0: "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE ) jbe@0: RETURNS "direct_voter"."weight"%TYPE jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "issue_delegation_row" "issue_delegation"%ROWTYPE; jbe@0: "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE; jbe@0: "weight_v" INT4; jbe@8: "sub_weight_v" INT4; jbe@0: BEGIN jbe@336: PERFORM "require_transaction_isolation"(); jbe@0: "weight_v" := 0; jbe@0: FOR "issue_delegation_row" IN jbe@0: SELECT * FROM "issue_delegation" jbe@0: WHERE "trustee_id" = "member_id_p" jbe@0: AND "issue_id" = "issue_id_p" jbe@0: LOOP jbe@0: IF NOT EXISTS ( jbe@0: SELECT NULL FROM "direct_voter" jbe@0: WHERE "member_id" = "issue_delegation_row"."truster_id" jbe@0: AND "issue_id" = "issue_id_p" jbe@0: ) AND NOT EXISTS ( jbe@0: SELECT NULL FROM "delegating_voter" jbe@0: WHERE "member_id" = "issue_delegation_row"."truster_id" jbe@0: AND "issue_id" = "issue_id_p" jbe@0: ) THEN jbe@0: "delegate_member_ids_v" := jbe@0: "member_id_p" || "delegate_member_ids_p"; jbe@10: INSERT INTO "delegating_voter" ( jbe@10: "issue_id", jbe@10: "member_id", jbe@10: "scope", jbe@10: "delegate_member_ids" jbe@10: ) VALUES ( jbe@5: "issue_id_p", jbe@5: "issue_delegation_row"."truster_id", jbe@10: "issue_delegation_row"."scope", jbe@5: "delegate_member_ids_v" jbe@5: ); jbe@8: "sub_weight_v" := 1 + jbe@8: "weight_of_added_vote_delegations"( jbe@8: "issue_id_p", jbe@8: "issue_delegation_row"."truster_id", jbe@8: "delegate_member_ids_v" jbe@8: ); jbe@8: UPDATE "delegating_voter" jbe@8: SET "weight" = "sub_weight_v" jbe@8: WHERE "issue_id" = "issue_id_p" jbe@8: AND "member_id" = "issue_delegation_row"."truster_id"; jbe@8: "weight_v" := "weight_v" + "sub_weight_v"; jbe@0: END IF; jbe@0: END LOOP; jbe@0: RETURN "weight_v"; jbe@0: END; jbe@0: $$; jbe@0: jbe@5: COMMENT ON FUNCTION "weight_of_added_vote_delegations" jbe@0: ( "issue"."id"%TYPE, jbe@0: "member"."id"%TYPE, jbe@0: "delegating_voter"."delegate_member_ids"%TYPE ) jbe@0: IS 'Helper function for "add_vote_delegations" function'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "add_vote_delegations" jbe@0: ( "issue_id_p" "issue"."id"%TYPE ) jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "member_id_v" "member"."id"%TYPE; jbe@0: BEGIN jbe@336: PERFORM "require_transaction_isolation"(); jbe@0: FOR "member_id_v" IN jbe@0: SELECT "member_id" FROM "direct_voter" jbe@0: WHERE "issue_id" = "issue_id_p" jbe@0: LOOP jbe@0: UPDATE "direct_voter" SET jbe@5: "weight" = "weight" + "weight_of_added_vote_delegations"( jbe@0: "issue_id_p", jbe@0: "member_id_v", jbe@0: '{}' jbe@0: ) jbe@0: WHERE "member_id" = "member_id_v" jbe@0: AND "issue_id" = "issue_id_p"; jbe@0: END LOOP; jbe@0: RETURN; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "add_vote_delegations" jbe@0: ( "issue_id_p" "issue"."id"%TYPE ) jbe@0: IS 'Helper function for "close_voting" function'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE) jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@97: "area_id_v" "area"."id"%TYPE; jbe@97: "unit_id_v" "unit"."id"%TYPE; jbe@0: "member_id_v" "member"."id"%TYPE; jbe@0: BEGIN jbe@333: PERFORM "require_transaction_isolation"(); jbe@129: SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p"; jbe@129: SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v"; jbe@383: -- override protection triggers: jbe@385: INSERT INTO "temporary_transaction_data" ("key", "value") jbe@385: VALUES ('override_protection_triggers', TRUE::TEXT); 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@169: -- delete delegating votes (in cases of manual reset of issue state): jbe@0: DELETE FROM "delegating_voter" jbe@0: WHERE "issue_id" = "issue_id_p"; jbe@169: -- delete votes from non-privileged voters: jbe@97: DELETE FROM "direct_voter" jbe@97: USING ( jbe@97: SELECT jbe@97: "direct_voter"."member_id" jbe@97: FROM "direct_voter" jbe@97: JOIN "member" ON "direct_voter"."member_id" = "member"."id" jbe@97: LEFT JOIN "privilege" jbe@97: ON "privilege"."unit_id" = "unit_id_v" jbe@97: AND "privilege"."member_id" = "direct_voter"."member_id" jbe@97: WHERE "direct_voter"."issue_id" = "issue_id_p" AND ( jbe@97: "member"."active" = FALSE OR jbe@97: "privilege"."voting_right" ISNULL OR jbe@97: "privilege"."voting_right" = FALSE jbe@97: ) jbe@97: ) AS "subquery" jbe@97: WHERE "direct_voter"."issue_id" = "issue_id_p" jbe@97: AND "direct_voter"."member_id" = "subquery"."member_id"; jbe@169: -- consider delegations: jbe@0: UPDATE "direct_voter" SET "weight" = 1 jbe@0: WHERE "issue_id" = "issue_id_p"; jbe@0: PERFORM "add_vote_delegations"("issue_id_p"); jbe@414: -- mark first preferences: jbe@414: UPDATE "vote" SET "first_preference" = "subquery"."first_preference" jbe@414: FROM ( jbe@414: SELECT jbe@414: "vote"."initiative_id", jbe@414: "vote"."member_id", jbe@414: CASE WHEN "vote"."grade" > 0 THEN jbe@414: CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END jbe@414: ELSE NULL jbe@414: END AS "first_preference" jbe@415: FROM "vote" jbe@415: JOIN "initiative" -- NOTE: due to missing index on issue_id jbe@415: ON "vote"."issue_id" = "initiative"."issue_id" jbe@415: JOIN "vote" AS "agg" jbe@415: ON "initiative"."id" = "agg"."initiative_id" jbe@415: AND "vote"."member_id" = "agg"."member_id" jbe@433: GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade" jbe@414: ) AS "subquery" jbe@414: WHERE "vote"."issue_id" = "issue_id_p" jbe@414: AND "vote"."initiative_id" = "subquery"."initiative_id" jbe@414: AND "vote"."member_id" = "subquery"."member_id"; jbe@385: -- finish overriding protection triggers (avoids garbage): jbe@385: DELETE FROM "temporary_transaction_data" jbe@385: WHERE "key" = 'override_protection_triggers'; jbe@137: -- materialize battle_view: jbe@61: -- NOTE: "closed" column of issue must be set at this point jbe@61: DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; jbe@61: INSERT INTO "battle" ( jbe@61: "issue_id", jbe@61: "winning_initiative_id", "losing_initiative_id", jbe@61: "count" jbe@61: ) SELECT jbe@61: "issue_id", jbe@61: "winning_initiative_id", "losing_initiative_id", jbe@61: "count" jbe@61: FROM "battle_view" WHERE "issue_id" = "issue_id_p"; jbe@331: -- set voter count: jbe@331: UPDATE "issue" SET jbe@331: "voter_count" = ( jbe@331: SELECT coalesce(sum("weight"), 0) jbe@331: FROM "direct_voter" WHERE "issue_id" = "issue_id_p" jbe@331: ) jbe@331: WHERE "id" = "issue_id_p"; jbe@437: -- copy "positive_votes" and "negative_votes" from "battle" table: jbe@437: -- NOTE: "first_preference_votes" is set to a default of 0 at this step jbe@437: UPDATE "initiative" SET jbe@437: "first_preference_votes" = 0, jbe@437: "positive_votes" = "battle_win"."count", jbe@437: "negative_votes" = "battle_lose"."count" jbe@437: FROM "battle" AS "battle_win", "battle" AS "battle_lose" jbe@437: WHERE jbe@437: "battle_win"."issue_id" = "issue_id_p" AND jbe@437: "battle_win"."winning_initiative_id" = "initiative"."id" AND jbe@437: "battle_win"."losing_initiative_id" ISNULL AND jbe@437: "battle_lose"."issue_id" = "issue_id_p" AND jbe@437: "battle_lose"."losing_initiative_id" = "initiative"."id" AND jbe@437: "battle_lose"."winning_initiative_id" ISNULL; jbe@414: -- calculate "first_preference_votes": jbe@437: -- NOTE: will only set values not equal to zero jbe@437: UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum" jbe@414: FROM ( jbe@414: SELECT "vote"."initiative_id", sum("direct_voter"."weight") jbe@414: FROM "vote" JOIN "direct_voter" jbe@414: ON "vote"."issue_id" = "direct_voter"."issue_id" jbe@414: AND "vote"."member_id" = "direct_voter"."member_id" jbe@414: WHERE "vote"."first_preference" jbe@414: GROUP BY "vote"."initiative_id" jbe@414: ) AS "subquery" jbe@414: WHERE "initiative"."issue_id" = "issue_id_p" jbe@414: AND "initiative"."admitted" jbe@414: AND "initiative"."id" = "subquery"."initiative_id"; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "close_voting" jbe@0: ( "issue"."id"%TYPE ) jbe@0: IS 'Closes the voting on an issue, and calculates positive and negative votes for each initiative; The ranking is not calculated yet, to keep the (locking) transaction short.'; jbe@0: jbe@0: jbe@30: CREATE FUNCTION "defeat_strength" jbe@424: ( "positive_votes_p" INT4, jbe@424: "negative_votes_p" INT4, jbe@424: "defeat_strength_p" "defeat_strength" ) jbe@30: RETURNS INT8 jbe@30: LANGUAGE 'plpgsql' IMMUTABLE AS $$ jbe@30: BEGIN jbe@424: IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN jbe@424: IF "positive_votes_p" > "negative_votes_p" THEN jbe@424: RETURN "positive_votes_p"; jbe@424: ELSE jbe@424: RETURN 0; jbe@424: END IF; jbe@30: ELSE jbe@424: IF "positive_votes_p" > "negative_votes_p" THEN jbe@424: RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8; jbe@424: ELSIF "positive_votes_p" = "negative_votes_p" THEN jbe@424: RETURN 0; jbe@424: ELSE jbe@424: RETURN -1; jbe@424: END IF; jbe@30: END IF; jbe@30: END; jbe@30: $$; jbe@30: jbe@425: COMMENT ON FUNCTION "defeat_strength"(INT4, INT4, "defeat_strength") IS 'Calculates defeat strength (INT8!) according to the "defeat_strength" option (see comment on type "defeat_strength")'; jbe@30: jbe@30: jbe@423: CREATE FUNCTION "secondary_link_strength" jbe@426: ( "initiative1_ord_p" INT4, jbe@426: "initiative2_ord_p" INT4, jbe@424: "tie_breaking_p" "tie_breaking" ) jbe@423: RETURNS INT8 jbe@423: LANGUAGE 'plpgsql' IMMUTABLE AS $$ jbe@423: BEGIN jbe@426: IF "initiative1_ord_p" = "initiative2_ord_p" THEN jbe@423: RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)'; jbe@423: END IF; jbe@423: RETURN ( jbe@426: CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN jbe@426: 0 jbe@424: ELSE jbe@426: CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN jbe@426: 1::INT8 << 62 jbe@426: ELSE 0 END jbe@426: + jbe@426: CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN jbe@426: ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8 jbe@426: ELSE jbe@426: "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31) jbe@426: END jbe@424: END jbe@423: ); jbe@423: END; jbe@423: $$; jbe@423: jbe@424: COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)'; jbe@423: jbe@423: jbe@426: CREATE TYPE "link_strength" AS ( jbe@426: "primary" INT8, jbe@426: "secondary" INT8 ); jbe@426: jbe@428: COMMENT ON TYPE "link_strength" IS 'Type to store the defeat strength of a link between two candidates plus a secondary criterion to create unique link strengths between the candidates (needed for tie-breaking ''variant1'' and ''variant2'')'; jbe@427: jbe@427: jbe@427: CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][]) jbe@427: RETURNS "link_strength"[][] jbe@427: LANGUAGE 'plpgsql' IMMUTABLE AS $$ jbe@427: DECLARE jbe@427: "dimension_v" INT4; jbe@427: "matrix_p" "link_strength"[][]; jbe@427: "i" INT4; jbe@427: "j" INT4; jbe@427: "k" INT4; jbe@427: BEGIN jbe@427: "dimension_v" := array_upper("matrix_d", 1); jbe@427: "matrix_p" := "matrix_d"; jbe@427: "i" := 1; jbe@427: LOOP jbe@427: "j" := 1; jbe@427: LOOP jbe@427: IF "i" != "j" THEN jbe@427: "k" := 1; jbe@427: LOOP jbe@427: IF "i" != "k" AND "j" != "k" THEN jbe@427: IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN jbe@427: IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN jbe@427: "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"]; jbe@427: END IF; jbe@427: ELSE jbe@427: IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN jbe@427: "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"]; jbe@427: END IF; jbe@427: END IF; jbe@427: END IF; jbe@427: EXIT WHEN "k" = "dimension_v"; jbe@427: "k" := "k" + 1; jbe@427: END LOOP; jbe@427: END IF; jbe@427: EXIT WHEN "j" = "dimension_v"; jbe@427: "j" := "j" + 1; jbe@427: END LOOP; jbe@427: EXIT WHEN "i" = "dimension_v"; jbe@427: "i" := "i" + 1; jbe@427: END LOOP; jbe@427: RETURN "matrix_p"; jbe@427: END; jbe@427: $$; jbe@427: jbe@428: COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix'; jbe@426: jbe@426: jbe@0: CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE) jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@427: "issue_row" "issue"%ROWTYPE; jbe@427: "policy_row" "policy"%ROWTYPE; jbe@427: "dimension_v" INT4; jbe@427: "matrix_a" INT4[][]; -- absolute votes jbe@427: "matrix_d" "link_strength"[][]; -- defeat strength (direct) jbe@427: "matrix_p" "link_strength"[][]; -- defeat strength (best path) jbe@427: "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking) jbe@427: "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking) jbe@427: "matrix_b" BOOLEAN[][]; -- final order (who beats who) jbe@427: "i" INT4; jbe@427: "j" INT4; jbe@427: "m" INT4; jbe@427: "n" INT4; jbe@427: "battle_row" "battle"%ROWTYPE; jbe@427: "rank_ary" INT4[]; jbe@427: "rank_v" INT4; jbe@427: "initiative_id_v" "initiative"."id"%TYPE; jbe@0: BEGIN jbe@333: PERFORM "require_transaction_isolation"(); jbe@155: SELECT * INTO "issue_row" jbe@331: FROM "issue" WHERE "id" = "issue_id_p"; jbe@155: SELECT * INTO "policy_row" jbe@155: FROM "policy" WHERE "id" = "issue_row"."policy_id"; jbe@126: SELECT count(1) INTO "dimension_v" jbe@126: FROM "battle_participant" WHERE "issue_id" = "issue_id_p"; jbe@428: -- create "matrix_a" with absolute number of votes in pairwise jbe@170: -- comparison: jbe@427: "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]); jbe@170: "i" := 1; jbe@170: "j" := 2; jbe@170: FOR "battle_row" IN jbe@170: SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p" jbe@170: ORDER BY jbe@411: "winning_initiative_id" NULLS FIRST, jbe@411: "losing_initiative_id" NULLS FIRST jbe@170: LOOP jbe@427: "matrix_a"["i"]["j"] := "battle_row"."count"; jbe@170: IF "j" = "dimension_v" THEN jbe@170: "i" := "i" + 1; jbe@170: "j" := 1; jbe@170: ELSE jbe@170: "j" := "j" + 1; jbe@170: IF "j" = "i" THEN jbe@170: "j" := "j" + 1; jbe@170: END IF; jbe@170: END IF; jbe@170: END LOOP; jbe@170: IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN jbe@170: RAISE EXCEPTION 'Wrong battle count (should not happen)'; jbe@170: END IF; jbe@428: -- store direct defeat strengths in "matrix_d" using "defeat_strength" jbe@427: -- and "secondary_link_strength" functions: jbe@427: "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]); jbe@170: "i" := 1; jbe@170: LOOP jbe@170: "j" := 1; jbe@0: LOOP jbe@170: IF "i" != "j" THEN jbe@427: "matrix_d"["i"]["j"] := ( jbe@426: "defeat_strength"( jbe@427: "matrix_a"["i"]["j"], jbe@427: "matrix_a"["j"]["i"], jbe@426: "policy_row"."defeat_strength" jbe@426: ), jbe@426: "secondary_link_strength"( jbe@426: "i", jbe@426: "j", jbe@426: "policy_row"."tie_breaking" jbe@426: ) jbe@426: )::"link_strength"; jbe@0: END IF; jbe@170: EXIT WHEN "j" = "dimension_v"; jbe@170: "j" := "j" + 1; jbe@0: END LOOP; jbe@170: EXIT WHEN "i" = "dimension_v"; jbe@170: "i" := "i" + 1; jbe@170: END LOOP; jbe@428: -- find best paths: jbe@427: "matrix_p" := "find_best_paths"("matrix_d"); jbe@428: -- create partial order: jbe@427: "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]); jbe@170: "i" := 1; jbe@170: LOOP jbe@427: "j" := "i" + 1; jbe@170: LOOP jbe@170: IF "i" != "j" THEN jbe@427: IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN jbe@427: "matrix_b"["i"]["j"] := TRUE; jbe@427: "matrix_b"["j"]["i"] := FALSE; jbe@427: ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN jbe@427: "matrix_b"["i"]["j"] := FALSE; jbe@427: "matrix_b"["j"]["i"] := TRUE; jbe@427: END IF; jbe@170: END IF; jbe@170: EXIT WHEN "j" = "dimension_v"; jbe@170: "j" := "j" + 1; jbe@170: END LOOP; jbe@427: EXIT WHEN "i" = "dimension_v" - 1; jbe@170: "i" := "i" + 1; jbe@170: END LOOP; jbe@428: -- tie-breaking by forbidding shared weakest links in beat-paths jbe@428: -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking jbe@428: -- is performed later by initiative id): jbe@427: IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN jbe@427: "m" := 1; jbe@427: LOOP jbe@427: "n" := "m" + 1; jbe@427: LOOP jbe@428: -- only process those candidates m and n, which are tied: jbe@427: IF "matrix_b"["m"]["n"] ISNULL THEN jbe@428: -- start with beat-paths prior tie-breaking: jbe@427: "matrix_t" := "matrix_p"; jbe@428: -- start with all links allowed: jbe@427: "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]); jbe@427: LOOP jbe@428: -- determine (and forbid) that link that is the weakest link jbe@428: -- in both the best path from candidate m to candidate n and jbe@428: -- from candidate n to candidate m: jbe@427: "i" := 1; jbe@427: <> jbe@427: LOOP jbe@427: "j" := 1; jbe@427: LOOP jbe@427: IF "i" != "j" THEN jbe@427: IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN jbe@427: "matrix_f"["i"]["j"] := TRUE; jbe@427: -- exit for performance reasons, jbe@428: -- as exactly one link will be found: jbe@427: EXIT forbid_one_link; jbe@427: END IF; jbe@427: END IF; jbe@427: EXIT WHEN "j" = "dimension_v"; jbe@427: "j" := "j" + 1; jbe@427: END LOOP; jbe@427: IF "i" = "dimension_v" THEN jbe@428: RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)'; jbe@427: END IF; jbe@427: "i" := "i" + 1; jbe@427: END LOOP; jbe@428: -- calculate best beat-paths while ignoring forbidden links: jbe@427: "i" := 1; jbe@427: LOOP jbe@427: "j" := 1; jbe@427: LOOP jbe@427: IF "i" != "j" THEN jbe@427: "matrix_t"["i"]["j"] := CASE jbe@427: WHEN "matrix_f"["i"]["j"] jbe@431: THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value jbe@427: ELSE "matrix_d"["i"]["j"] END; jbe@427: END IF; jbe@427: EXIT WHEN "j" = "dimension_v"; jbe@427: "j" := "j" + 1; jbe@427: END LOOP; jbe@427: EXIT WHEN "i" = "dimension_v"; jbe@427: "i" := "i" + 1; jbe@427: END LOOP; jbe@427: "matrix_t" := "find_best_paths"("matrix_t"); jbe@428: -- extend partial order, if tie-breaking was successful: jbe@427: IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN jbe@427: "matrix_b"["m"]["n"] := TRUE; jbe@427: "matrix_b"["n"]["m"] := FALSE; jbe@427: EXIT; jbe@427: ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN jbe@427: "matrix_b"["m"]["n"] := FALSE; jbe@427: "matrix_b"["n"]["m"] := TRUE; jbe@427: EXIT; jbe@427: END IF; jbe@427: END LOOP; jbe@427: END IF; jbe@427: EXIT WHEN "n" = "dimension_v"; jbe@427: "n" := "n" + 1; jbe@427: END LOOP; jbe@427: EXIT WHEN "m" = "dimension_v" - 1; jbe@427: "m" := "m" + 1; jbe@427: END LOOP; jbe@427: END IF; jbe@428: -- store a unique ranking in "rank_ary": jbe@170: "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]); jbe@170: "rank_v" := 1; jbe@170: LOOP jbe@0: "i" := 1; jbe@428: <> jbe@0: LOOP jbe@170: IF "rank_ary"["i"] ISNULL THEN jbe@170: "j" := 1; jbe@170: LOOP jbe@170: IF jbe@170: "i" != "j" AND jbe@170: "rank_ary"["j"] ISNULL AND jbe@427: ( "matrix_b"["j"]["i"] OR jbe@411: -- tie-breaking by "id" jbe@427: ( "matrix_b"["j"]["i"] ISNULL AND jbe@411: "j" < "i" ) ) jbe@170: THEN jbe@170: -- someone else is better jbe@170: EXIT; jbe@170: END IF; jbe@428: IF "j" = "dimension_v" THEN jbe@170: -- noone is better jbe@411: "rank_ary"["i"] := "rank_v"; jbe@428: EXIT assign_next_rank; jbe@170: END IF; jbe@428: "j" := "j" + 1; jbe@170: END LOOP; jbe@170: END IF; jbe@0: "i" := "i" + 1; jbe@411: IF "i" > "dimension_v" THEN jbe@411: RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)'; jbe@411: END IF; jbe@0: END LOOP; jbe@411: EXIT WHEN "rank_v" = "dimension_v"; jbe@170: "rank_v" := "rank_v" + 1; jbe@170: END LOOP; jbe@170: -- write preliminary results: jbe@411: "i" := 2; -- omit status quo with "i" = 1 jbe@170: FOR "initiative_id_v" IN jbe@170: SELECT "id" FROM "initiative" jbe@170: WHERE "issue_id" = "issue_id_p" AND "admitted" jbe@170: ORDER BY "id" jbe@170: LOOP jbe@170: UPDATE "initiative" SET jbe@170: "direct_majority" = jbe@170: CASE WHEN "policy_row"."direct_majority_strict" THEN jbe@170: "positive_votes" * "policy_row"."direct_majority_den" > jbe@170: "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes") jbe@170: ELSE jbe@170: "positive_votes" * "policy_row"."direct_majority_den" >= jbe@170: "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes") jbe@170: END jbe@170: AND "positive_votes" >= "policy_row"."direct_majority_positive" jbe@170: AND "issue_row"."voter_count"-"negative_votes" >= jbe@170: "policy_row"."direct_majority_non_negative", jbe@170: "indirect_majority" = jbe@170: CASE WHEN "policy_row"."indirect_majority_strict" THEN jbe@170: "positive_votes" * "policy_row"."indirect_majority_den" > jbe@170: "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes") jbe@170: ELSE jbe@170: "positive_votes" * "policy_row"."indirect_majority_den" >= jbe@170: "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes") jbe@170: END jbe@170: AND "positive_votes" >= "policy_row"."indirect_majority_positive" jbe@170: AND "issue_row"."voter_count"-"negative_votes" >= jbe@170: "policy_row"."indirect_majority_non_negative", jbe@171: "schulze_rank" = "rank_ary"["i"], jbe@411: "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1], jbe@411: "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1], jbe@411: "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1], jbe@429: "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength" jbe@429: THEN NULL jbe@429: ELSE "matrix_p"[1]["i"]."primary" >= 0 END, jbe@216: "eligible" = FALSE, jbe@250: "winner" = FALSE, jbe@250: "rank" = NULL -- NOTE: in cases of manual reset of issue state jbe@170: WHERE "id" = "initiative_id_v"; jbe@170: "i" := "i" + 1; jbe@170: END LOOP; jbe@411: IF "i" != "dimension_v" + 1 THEN jbe@170: RAISE EXCEPTION 'Wrong winner count (should not happen)'; jbe@0: END IF; jbe@170: -- take indirect majorities into account: jbe@170: LOOP jbe@170: UPDATE "initiative" SET "indirect_majority" = TRUE jbe@139: FROM ( jbe@170: SELECT "new_initiative"."id" AS "initiative_id" jbe@170: FROM "initiative" "old_initiative" jbe@170: JOIN "initiative" "new_initiative" jbe@170: ON "new_initiative"."issue_id" = "issue_id_p" jbe@170: AND "new_initiative"."indirect_majority" = FALSE jbe@139: JOIN "battle" "battle_win" jbe@139: ON "battle_win"."issue_id" = "issue_id_p" jbe@170: AND "battle_win"."winning_initiative_id" = "new_initiative"."id" jbe@170: AND "battle_win"."losing_initiative_id" = "old_initiative"."id" jbe@139: JOIN "battle" "battle_lose" jbe@139: ON "battle_lose"."issue_id" = "issue_id_p" jbe@170: AND "battle_lose"."losing_initiative_id" = "new_initiative"."id" jbe@170: AND "battle_lose"."winning_initiative_id" = "old_initiative"."id" jbe@170: WHERE "old_initiative"."issue_id" = "issue_id_p" jbe@170: AND "old_initiative"."indirect_majority" = TRUE jbe@170: AND CASE WHEN "policy_row"."indirect_majority_strict" THEN jbe@170: "battle_win"."count" * "policy_row"."indirect_majority_den" > jbe@170: "policy_row"."indirect_majority_num" * jbe@170: ("battle_win"."count"+"battle_lose"."count") jbe@170: ELSE jbe@170: "battle_win"."count" * "policy_row"."indirect_majority_den" >= jbe@170: "policy_row"."indirect_majority_num" * jbe@170: ("battle_win"."count"+"battle_lose"."count") jbe@170: END jbe@170: AND "battle_win"."count" >= "policy_row"."indirect_majority_positive" jbe@170: AND "issue_row"."voter_count"-"battle_lose"."count" >= jbe@170: "policy_row"."indirect_majority_non_negative" jbe@139: ) AS "subquery" jbe@139: WHERE "id" = "subquery"."initiative_id"; jbe@170: EXIT WHEN NOT FOUND; jbe@170: END LOOP; jbe@170: -- set "multistage_majority" for remaining matching initiatives: jbe@216: UPDATE "initiative" SET "multistage_majority" = TRUE jbe@170: FROM ( jbe@170: SELECT "losing_initiative"."id" AS "initiative_id" jbe@170: FROM "initiative" "losing_initiative" jbe@170: JOIN "initiative" "winning_initiative" jbe@170: ON "winning_initiative"."issue_id" = "issue_id_p" jbe@170: AND "winning_initiative"."admitted" jbe@170: JOIN "battle" "battle_win" jbe@170: ON "battle_win"."issue_id" = "issue_id_p" jbe@170: AND "battle_win"."winning_initiative_id" = "winning_initiative"."id" jbe@170: AND "battle_win"."losing_initiative_id" = "losing_initiative"."id" jbe@170: JOIN "battle" "battle_lose" jbe@170: ON "battle_lose"."issue_id" = "issue_id_p" jbe@170: AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id" jbe@170: AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id" jbe@170: WHERE "losing_initiative"."issue_id" = "issue_id_p" jbe@170: AND "losing_initiative"."admitted" jbe@170: AND "winning_initiative"."schulze_rank" < jbe@170: "losing_initiative"."schulze_rank" jbe@170: AND "battle_win"."count" > "battle_lose"."count" jbe@170: AND ( jbe@170: "battle_win"."count" > "winning_initiative"."positive_votes" OR jbe@170: "battle_lose"."count" < "losing_initiative"."negative_votes" ) jbe@170: ) AS "subquery" jbe@170: WHERE "id" = "subquery"."initiative_id"; jbe@170: -- mark eligible initiatives: jbe@170: UPDATE "initiative" SET "eligible" = TRUE jbe@171: WHERE "issue_id" = "issue_id_p" jbe@171: AND "initiative"."direct_majority" jbe@171: AND "initiative"."indirect_majority" jbe@171: AND "initiative"."better_than_status_quo" jbe@171: AND ( jbe@171: "policy_row"."no_multistage_majority" = FALSE OR jbe@429: "initiative"."multistage_majority" = FALSE ) jbe@429: AND ( jbe@429: "policy_row"."no_reverse_beat_path" = FALSE OR jbe@429: coalesce("initiative"."reverse_beat_path", FALSE) = FALSE ); jbe@170: -- mark final winner: jbe@170: UPDATE "initiative" SET "winner" = TRUE jbe@170: FROM ( jbe@170: SELECT "id" AS "initiative_id" jbe@170: FROM "initiative" jbe@170: WHERE "issue_id" = "issue_id_p" AND "eligible" jbe@217: ORDER BY jbe@217: "schulze_rank", jbe@217: "id" jbe@170: LIMIT 1 jbe@170: ) AS "subquery" jbe@170: WHERE "id" = "subquery"."initiative_id"; jbe@173: -- write (final) ranks: jbe@173: "rank_v" := 1; jbe@173: FOR "initiative_id_v" IN jbe@173: SELECT "id" jbe@173: FROM "initiative" jbe@173: WHERE "issue_id" = "issue_id_p" AND "admitted" jbe@174: ORDER BY jbe@174: "winner" DESC, jbe@217: "eligible" DESC, jbe@174: "schulze_rank", jbe@174: "id" jbe@173: LOOP jbe@173: UPDATE "initiative" SET "rank" = "rank_v" jbe@173: WHERE "id" = "initiative_id_v"; jbe@173: "rank_v" := "rank_v" + 1; jbe@173: END LOOP; jbe@170: -- set schulze rank of status quo and mark issue as finished: jbe@111: UPDATE "issue" SET jbe@411: "status_quo_schulze_rank" = "rank_ary"[1], jbe@111: "state" = jbe@139: CASE WHEN EXISTS ( jbe@139: SELECT NULL FROM "initiative" jbe@139: WHERE "issue_id" = "issue_id_p" AND "winner" jbe@139: ) THEN jbe@139: 'finished_with_winner'::"issue_state" jbe@139: ELSE jbe@121: 'finished_without_winner'::"issue_state" jbe@111: END, jbe@331: "closed" = "phase_finished", jbe@331: "phase_finished" = NULL jbe@0: WHERE "id" = "issue_id_p"; jbe@0: RETURN; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "calculate_ranks" jbe@0: ( "issue"."id"%TYPE ) jbe@0: IS 'Determine ranking (Votes have to be counted first)'; jbe@0: jbe@0: jbe@0: jbe@0: ----------------------------- jbe@0: -- Automatic state changes -- jbe@0: ----------------------------- jbe@0: jbe@0: jbe@331: CREATE TYPE "check_issue_persistence" AS ( jbe@331: "state" "issue_state", jbe@331: "phase_finished" BOOLEAN, jbe@331: "issue_revoked" BOOLEAN, jbe@331: "snapshot_created" BOOLEAN, jbe@331: "harmonic_weights_set" BOOLEAN, jbe@331: "closed_voting" BOOLEAN ); jbe@331: jbe@336: COMMENT ON TYPE "check_issue_persistence" IS 'Type of data returned by "check_issue" function, to be passed to subsequent calls of the same function'; jbe@336: jbe@336: jbe@0: CREATE FUNCTION "check_issue" jbe@331: ( "issue_id_p" "issue"."id"%TYPE, jbe@331: "persist" "check_issue_persistence" ) jbe@331: RETURNS "check_issue_persistence" jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@336: "issue_row" "issue"%ROWTYPE; jbe@336: "policy_row" "policy"%ROWTYPE; jbe@336: "initiative_row" "initiative"%ROWTYPE; jbe@336: "state_v" "issue_state"; jbe@0: BEGIN jbe@333: PERFORM "require_transaction_isolation"(); jbe@331: IF "persist" ISNULL THEN jbe@331: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p" jbe@331: FOR UPDATE; jbe@331: IF "issue_row"."closed" NOTNULL THEN jbe@331: RETURN NULL; jbe@0: END IF; jbe@331: "persist"."state" := "issue_row"."state"; jbe@331: IF jbe@331: ( "issue_row"."state" = 'admission' AND now() >= jbe@447: "issue_row"."created" + "issue_row"."max_admission_time" ) OR jbe@331: ( "issue_row"."state" = 'discussion' AND now() >= jbe@331: "issue_row"."accepted" + "issue_row"."discussion_time" ) OR jbe@331: ( "issue_row"."state" = 'verification' AND now() >= jbe@331: "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR jbe@331: ( "issue_row"."state" = 'voting' AND now() >= jbe@331: "issue_row"."fully_frozen" + "issue_row"."voting_time" ) jbe@331: THEN jbe@331: "persist"."phase_finished" := TRUE; jbe@331: ELSE jbe@331: "persist"."phase_finished" := FALSE; jbe@0: END IF; jbe@0: IF jbe@24: NOT EXISTS ( jbe@24: -- all initiatives are revoked jbe@24: SELECT NULL FROM "initiative" jbe@24: WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL jbe@24: ) AND ( jbe@111: -- and issue has not been accepted yet jbe@331: "persist"."state" = 'admission' OR jbe@331: -- or verification time has elapsed jbe@331: ( "persist"."state" = 'verification' AND jbe@331: "persist"."phase_finished" ) OR jbe@331: -- or no initiatives have been revoked lately jbe@24: NOT EXISTS ( jbe@24: SELECT NULL FROM "initiative" jbe@24: WHERE "issue_id" = "issue_id_p" jbe@24: AND now() < "revoked" + "issue_row"."verification_time" jbe@24: ) jbe@24: ) jbe@24: THEN jbe@331: "persist"."issue_revoked" := TRUE; jbe@331: ELSE jbe@331: "persist"."issue_revoked" := FALSE; jbe@24: END IF; jbe@331: IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN jbe@331: UPDATE "issue" SET "phase_finished" = now() jbe@331: WHERE "id" = "issue_row"."id"; jbe@331: RETURN "persist"; jbe@331: ELSIF jbe@331: "persist"."state" IN ('admission', 'discussion', 'verification') jbe@3: THEN jbe@331: RETURN "persist"; jbe@331: ELSE jbe@331: RETURN NULL; jbe@322: END IF; jbe@0: END IF; jbe@331: IF jbe@331: "persist"."state" IN ('admission', 'discussion', 'verification') AND jbe@331: coalesce("persist"."snapshot_created", FALSE) = FALSE jbe@331: THEN jbe@331: PERFORM "create_snapshot"("issue_id_p"); jbe@331: "persist"."snapshot_created" = TRUE; jbe@331: IF "persist"."phase_finished" THEN jbe@331: IF "persist"."state" = 'admission' THEN jbe@331: PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission'); jbe@331: ELSIF "persist"."state" = 'discussion' THEN jbe@331: PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze'); jbe@331: ELSIF "persist"."state" = 'verification' THEN jbe@331: PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze'); jbe@336: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"; jbe@336: SELECT * INTO "policy_row" FROM "policy" jbe@336: WHERE "id" = "issue_row"."policy_id"; jbe@336: FOR "initiative_row" IN jbe@336: SELECT * FROM "initiative" jbe@336: WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL jbe@336: FOR UPDATE jbe@336: LOOP jbe@336: IF jbe@336: "initiative_row"."polling" OR ( jbe@336: "initiative_row"."satisfied_supporter_count" > 0 AND jbe@336: "initiative_row"."satisfied_supporter_count" * jbe@336: "policy_row"."initiative_quorum_den" >= jbe@336: "issue_row"."population" * "policy_row"."initiative_quorum_num" jbe@336: ) jbe@336: THEN jbe@336: UPDATE "initiative" SET "admitted" = TRUE jbe@336: WHERE "id" = "initiative_row"."id"; jbe@336: ELSE jbe@336: UPDATE "initiative" SET "admitted" = FALSE jbe@336: WHERE "id" = "initiative_row"."id"; jbe@336: END IF; jbe@336: END LOOP; jbe@331: END IF; jbe@331: END IF; jbe@331: RETURN "persist"; jbe@331: END IF; jbe@331: IF jbe@331: "persist"."state" IN ('admission', 'discussion', 'verification') AND jbe@331: coalesce("persist"."harmonic_weights_set", FALSE) = FALSE jbe@331: THEN jbe@331: PERFORM "set_harmonic_initiative_weights"("issue_id_p"); jbe@331: "persist"."harmonic_weights_set" = TRUE; jbe@332: IF jbe@332: "persist"."phase_finished" OR jbe@332: "persist"."issue_revoked" OR jbe@332: "persist"."state" = 'admission' jbe@332: THEN jbe@331: RETURN "persist"; jbe@331: ELSE jbe@331: RETURN NULL; jbe@331: END IF; jbe@331: END IF; jbe@331: IF "persist"."issue_revoked" THEN jbe@331: IF "persist"."state" = 'admission' THEN jbe@331: "state_v" := 'canceled_revoked_before_accepted'; jbe@331: ELSIF "persist"."state" = 'discussion' THEN jbe@331: "state_v" := 'canceled_after_revocation_during_discussion'; jbe@331: ELSIF "persist"."state" = 'verification' THEN jbe@331: "state_v" := 'canceled_after_revocation_during_verification'; jbe@331: END IF; jbe@331: UPDATE "issue" SET jbe@331: "state" = "state_v", jbe@331: "closed" = "phase_finished", jbe@331: "phase_finished" = NULL jbe@332: WHERE "id" = "issue_id_p"; jbe@331: RETURN NULL; jbe@331: END IF; jbe@331: IF "persist"."state" = 'admission' THEN jbe@336: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p" jbe@336: FOR UPDATE; jbe@336: SELECT * INTO "policy_row" jbe@336: FROM "policy" WHERE "id" = "issue_row"."policy_id"; jbe@447: IF jbe@447: ( now() >= jbe@447: "issue_row"."created" + "issue_row"."min_admission_time" ) AND jbe@447: EXISTS ( jbe@447: SELECT NULL FROM "initiative" jbe@447: WHERE "issue_id" = "issue_id_p" jbe@447: AND "supporter_count" > 0 jbe@447: AND "supporter_count" * "policy_row"."issue_quorum_den" jbe@447: >= "issue_row"."population" * "policy_row"."issue_quorum_num" jbe@447: ) jbe@447: THEN jbe@336: UPDATE "issue" SET jbe@336: "state" = 'discussion', jbe@336: "accepted" = coalesce("phase_finished", now()), jbe@336: "phase_finished" = NULL jbe@336: WHERE "id" = "issue_id_p"; jbe@336: ELSIF "issue_row"."phase_finished" NOTNULL THEN jbe@336: UPDATE "issue" SET jbe@336: "state" = 'canceled_issue_not_accepted', jbe@336: "closed" = "phase_finished", jbe@336: "phase_finished" = NULL jbe@336: WHERE "id" = "issue_id_p"; jbe@336: END IF; jbe@331: RETURN NULL; jbe@331: END IF; jbe@332: IF "persist"."phase_finished" THEN jbe@443: IF "persist"."state" = 'discussion' THEN jbe@332: UPDATE "issue" SET jbe@332: "state" = 'verification', jbe@332: "half_frozen" = "phase_finished", jbe@332: "phase_finished" = NULL jbe@332: WHERE "id" = "issue_id_p"; jbe@332: RETURN NULL; jbe@332: END IF; jbe@332: IF "persist"."state" = 'verification' THEN jbe@336: SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p" jbe@336: FOR UPDATE; jbe@336: SELECT * INTO "policy_row" FROM "policy" jbe@336: WHERE "id" = "issue_row"."policy_id"; jbe@336: IF EXISTS ( jbe@336: SELECT NULL FROM "initiative" jbe@336: WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE jbe@336: ) THEN jbe@336: UPDATE "issue" SET jbe@343: "state" = 'voting', jbe@343: "fully_frozen" = "phase_finished", jbe@336: "phase_finished" = NULL jbe@336: WHERE "id" = "issue_id_p"; jbe@336: ELSE jbe@336: UPDATE "issue" SET jbe@343: "state" = 'canceled_no_initiative_admitted', jbe@343: "fully_frozen" = "phase_finished", jbe@343: "closed" = "phase_finished", jbe@343: "phase_finished" = NULL jbe@336: WHERE "id" = "issue_id_p"; jbe@336: -- NOTE: The following DELETE statements have effect only when jbe@336: -- issue state has been manipulated jbe@336: DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p"; jbe@336: DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p"; jbe@336: DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; jbe@336: END IF; jbe@332: RETURN NULL; jbe@332: END IF; jbe@332: IF "persist"."state" = 'voting' THEN jbe@332: IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN jbe@332: PERFORM "close_voting"("issue_id_p"); jbe@332: "persist"."closed_voting" = TRUE; jbe@332: RETURN "persist"; jbe@332: END IF; jbe@332: PERFORM "calculate_ranks"("issue_id_p"); jbe@332: RETURN NULL; jbe@332: END IF; jbe@331: END IF; jbe@331: RAISE WARNING 'should not happen'; jbe@331: RETURN NULL; jbe@0: END; jbe@0: $$; jbe@0: jbe@0: COMMENT ON FUNCTION "check_issue" jbe@331: ( "issue"."id"%TYPE, jbe@331: "check_issue_persistence" ) jbe@336: IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required, and perform the status change when necessary; Function must be called multiple times with the previous result as second parameter, until the result is NULL (see source code of function "check_everything")'; jbe@0: jbe@0: jbe@0: CREATE FUNCTION "check_everything"() jbe@0: RETURNS VOID jbe@0: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@0: DECLARE jbe@0: "issue_id_v" "issue"."id"%TYPE; jbe@331: "persist_v" "check_issue_persistence"; jbe@0: BEGIN jbe@333: RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes'; jbe@235: DELETE FROM "expired_session"; jbe@184: PERFORM "check_activity"(); jbe@4: PERFORM "calculate_member_counts"(); jbe@4: FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP jbe@331: "persist_v" := NULL; jbe@331: LOOP jbe@331: "persist_v" := "check_issue"("issue_id_v", "persist_v"); jbe@331: EXIT WHEN "persist_v" ISNULL; jbe@331: END LOOP; jbe@0: END LOOP; jbe@0: RETURN; jbe@0: END; jbe@0: $$; jbe@0: jbe@336: COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue. Use this function only for development and debugging purposes, as you may run into locking and/or serialization problems in productive environments.'; jbe@0: jbe@0: jbe@0: jbe@59: ---------------------- jbe@59: -- Deletion of data -- jbe@59: ---------------------- jbe@59: jbe@59: jbe@59: CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE) jbe@59: RETURNS VOID jbe@59: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@59: BEGIN jbe@385: IF EXISTS ( jbe@385: SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL jbe@385: ) THEN jbe@385: -- override protection triggers: jbe@385: INSERT INTO "temporary_transaction_data" ("key", "value") jbe@385: VALUES ('override_protection_triggers', TRUE::TEXT); jbe@385: -- clean data: jbe@59: DELETE FROM "delegating_voter" jbe@59: WHERE "issue_id" = "issue_id_p"; jbe@59: DELETE FROM "direct_voter" jbe@59: WHERE "issue_id" = "issue_id_p"; jbe@59: DELETE FROM "delegating_interest_snapshot" jbe@59: WHERE "issue_id" = "issue_id_p"; jbe@59: DELETE FROM "direct_interest_snapshot" jbe@59: WHERE "issue_id" = "issue_id_p"; jbe@59: DELETE FROM "delegating_population_snapshot" jbe@59: WHERE "issue_id" = "issue_id_p"; jbe@59: DELETE FROM "direct_population_snapshot" jbe@59: WHERE "issue_id" = "issue_id_p"; jbe@113: DELETE FROM "non_voter" jbe@94: WHERE "issue_id" = "issue_id_p"; jbe@59: DELETE FROM "delegation" jbe@59: WHERE "issue_id" = "issue_id_p"; jbe@59: DELETE FROM "supporter" jbe@329: USING "initiative" -- NOTE: due to missing index on issue_id jbe@325: WHERE "initiative"."issue_id" = "issue_id_p" jbe@325: AND "supporter"."initiative_id" = "initiative_id"; jbe@385: -- mark issue as cleaned: jbe@385: UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p"; jbe@385: -- finish overriding protection triggers (avoids garbage): jbe@385: DELETE FROM "temporary_transaction_data" jbe@385: WHERE "key" = 'override_protection_triggers'; jbe@59: END IF; jbe@59: RETURN; jbe@59: END; jbe@59: $$; jbe@59: jbe@59: COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue'; jbe@8: jbe@8: jbe@54: CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) jbe@8: RETURNS VOID jbe@8: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@8: BEGIN jbe@9: UPDATE "member" SET jbe@57: "last_login" = NULL, jbe@387: "last_delegation_check" = NULL, jbe@45: "login" = NULL, jbe@11: "password" = NULL, jbe@441: "authority" = NULL, jbe@441: "authority_uid" = NULL, jbe@441: "authority_login" = NULL, jbe@101: "locked" = TRUE, jbe@54: "active" = FALSE, jbe@11: "notify_email" = NULL, jbe@11: "notify_email_unconfirmed" = NULL, jbe@11: "notify_email_secret" = NULL, jbe@11: "notify_email_secret_expiry" = NULL, jbe@57: "notify_email_lock_expiry" = NULL, jbe@387: "login_recovery_expiry" = NULL, jbe@11: "password_reset_secret" = NULL, jbe@11: "password_reset_secret_expiry" = NULL, jbe@11: "organizational_unit" = NULL, jbe@11: "internal_posts" = NULL, jbe@11: "realname" = NULL, jbe@11: "birthday" = NULL, jbe@11: "address" = NULL, jbe@11: "email" = NULL, jbe@11: "xmpp_address" = NULL, jbe@11: "website" = NULL, jbe@11: "phone" = NULL, jbe@11: "mobile_phone" = NULL, jbe@11: "profession" = NULL, jbe@11: "external_memberships" = NULL, jbe@11: "external_posts" = NULL, jbe@45: "statement" = NULL jbe@45: WHERE "id" = "member_id_p"; jbe@11: -- "text_search_data" is updated by triggers jbe@45: DELETE FROM "setting" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "setting_map" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "member_image" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "contact" WHERE "member_id" = "member_id_p"; jbe@113: DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p"; jbe@235: DELETE FROM "session" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "area_setting" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p"; jbe@113: DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p"; jbe@45: DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p"; jbe@54: DELETE FROM "membership" WHERE "member_id" = "member_id_p"; jbe@54: DELETE FROM "delegation" WHERE "truster_id" = "member_id_p"; jbe@113: DELETE FROM "non_voter" WHERE "member_id" = "member_id_p"; jbe@57: DELETE FROM "direct_voter" USING "issue" jbe@57: WHERE "direct_voter"."issue_id" = "issue"."id" jbe@57: AND "issue"."closed" ISNULL jbe@57: AND "member_id" = "member_id_p"; jbe@45: RETURN; jbe@45: END; jbe@45: $$; jbe@45: jbe@57: COMMENT ON FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) IS 'Deactivate member and clear certain settings and data of this member (data protection)'; jbe@45: jbe@45: jbe@45: CREATE FUNCTION "delete_private_data"() jbe@45: RETURNS VOID jbe@45: LANGUAGE 'plpgsql' VOLATILE AS $$ jbe@45: BEGIN jbe@385: DELETE FROM "temporary_transaction_data"; jbe@226: DELETE FROM "member" WHERE "activated" ISNULL; jbe@50: UPDATE "member" SET jbe@206: "invite_code" = NULL, jbe@232: "invite_code_expiry" = NULL, jbe@228: "admin_comment" = NULL, jbe@57: "last_login" = NULL, jbe@387: "last_delegation_check" = NULL, jbe@50: "login" = NULL, jbe@50: "password" = NULL, jbe@441: "authority" = NULL, jbe@441: "authority_uid" = NULL, jbe@441: "authority_login" = NULL, jbe@238: "lang" = NULL, jbe@50: "notify_email" = NULL, jbe@50: "notify_email_unconfirmed" = NULL, jbe@50: "notify_email_secret" = NULL, jbe@50: "notify_email_secret_expiry" = NULL, jbe@57: "notify_email_lock_expiry" = NULL, jbe@238: "notify_level" = NULL, jbe@387: "login_recovery_expiry" = NULL, jbe@50: "password_reset_secret" = NULL, jbe@50: "password_reset_secret_expiry" = NULL, jbe@50: "organizational_unit" = NULL, jbe@50: "internal_posts" = NULL, jbe@50: "realname" = NULL, jbe@50: "birthday" = NULL, jbe@50: "address" = NULL, jbe@50: "email" = NULL, jbe@50: "xmpp_address" = NULL, jbe@50: "website" = NULL, jbe@50: "phone" = NULL, jbe@50: "mobile_phone" = NULL, jbe@50: "profession" = NULL, jbe@50: "external_memberships" = NULL, jbe@50: "external_posts" = NULL, jbe@238: "formatting_engine" = NULL, jbe@50: "statement" = NULL; jbe@50: -- "text_search_data" is updated by triggers jbe@50: DELETE FROM "setting"; jbe@50: DELETE FROM "setting_map"; jbe@50: DELETE FROM "member_relation_setting"; jbe@50: DELETE FROM "member_image"; jbe@50: DELETE FROM "contact"; jbe@113: DELETE FROM "ignored_member"; jbe@235: DELETE FROM "session"; jbe@50: DELETE FROM "area_setting"; jbe@50: DELETE FROM "issue_setting"; jbe@113: DELETE FROM "ignored_initiative"; jbe@50: DELETE FROM "initiative_setting"; jbe@50: DELETE FROM "suggestion_setting"; jbe@113: DELETE FROM "non_voter"; jbe@8: DELETE FROM "direct_voter" USING "issue" jbe@8: WHERE "direct_voter"."issue_id" = "issue"."id" jbe@8: AND "issue"."closed" ISNULL; jbe@8: RETURN; jbe@8: END; jbe@8: $$; jbe@8: jbe@273: 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@8: jbe@8: jbe@8: jbe@0: COMMIT;