liquid_feedback_core

annotate core.sql @ 588:6f427a8f8061

Added "posting" table and follower concept for members (column "following" in table "contact")
author jbe
date Wed Dec 05 00:35:30 2018 +0100 (2018-12-05)
parents 31d7cb4991ef
children aa23fa17604d
rev   line source
jbe@0 1
jbe@0 2 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
jbe@0 3
jbe@0 4 BEGIN;
jbe@0 5
jbe@588 6 CREATE EXTENSION IF NOT EXISTS btree_gist;
jbe@588 7 CREATE EXTENSION IF NOT EXISTS latlon;
jbe@588 8 CREATE EXTENSION IF NOT EXISTS conflux;
jbe@529 9
jbe@5 10 CREATE VIEW "liquid_feedback_version" AS
jbe@584 11 SELECT * FROM (VALUES ('4.1.0', 4, 1, 0))
jbe@5 12 AS "subquery"("string", "major", "minor", "revision");
jbe@5 13
jbe@0 14
jbe@0 15
jbe@7 16 ----------------------
jbe@7 17 -- Full text search --
jbe@7 18 ----------------------
jbe@7 19
jbe@7 20
jbe@7 21 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
jbe@7 22 RETURNS TSQUERY
jbe@7 23 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 24 BEGIN
jbe@7 25 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
jbe@7 26 END;
jbe@7 27 $$;
jbe@7 28
jbe@7 29 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
jbe@7 30
jbe@7 31
jbe@7 32 CREATE FUNCTION "highlight"
jbe@7 33 ( "body_p" TEXT,
jbe@7 34 "query_text_p" TEXT )
jbe@7 35 RETURNS TEXT
jbe@7 36 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 37 BEGIN
jbe@7 38 RETURN ts_headline(
jbe@7 39 'pg_catalog.simple',
jbe@8 40 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
jbe@7 41 "text_search_query"("query_text_p"),
jbe@7 42 'StartSel=* StopSel=* HighlightAll=TRUE' );
jbe@7 43 END;
jbe@7 44 $$;
jbe@7 45
jbe@7 46 COMMENT ON FUNCTION "highlight"
jbe@7 47 ( "body_p" TEXT,
jbe@7 48 "query_text_p" TEXT )
jbe@7 49 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 50
jbe@7 51
jbe@7 52
jbe@0 53 -------------------------
jbe@0 54 -- Tables and indicies --
jbe@0 55 -------------------------
jbe@0 56
jbe@8 57
jbe@385 58 CREATE TABLE "temporary_transaction_data" (
jbe@385 59 PRIMARY KEY ("txid", "key"),
jbe@385 60 "txid" INT8 DEFAULT txid_current(),
jbe@383 61 "key" TEXT,
jbe@383 62 "value" TEXT NOT NULL );
jbe@383 63
jbe@385 64 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
jbe@385 65
jbe@385 66 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 67
jbe@383 68
jbe@104 69 CREATE TABLE "system_setting" (
jbe@532 70 "member_ttl" INTERVAL,
jbe@532 71 "snapshot_retention" INTERVAL );
jbe@104 72 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
jbe@104 73
jbe@104 74 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
jbe@104 75 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
jbe@104 76
jbe@541 77 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@532 78 COMMENT ON COLUMN "system_setting"."snapshot_retention" IS 'Unreferenced snapshots are retained for the given period of time after creation; set to NULL for infinite retention.';
jbe@104 79
jbe@104 80
jbe@111 81 CREATE TABLE "contingent" (
jbe@293 82 PRIMARY KEY ("polling", "time_frame"),
jbe@293 83 "polling" BOOLEAN,
jbe@293 84 "time_frame" INTERVAL,
jbe@111 85 "text_entry_limit" INT4,
jbe@111 86 "initiative_limit" INT4 );
jbe@111 87
jbe@111 88 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 89
jbe@293 90 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
jbe@111 91 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 92 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
jbe@111 93
jbe@111 94
jbe@0 95 CREATE TABLE "member" (
jbe@0 96 "id" SERIAL4 PRIMARY KEY,
jbe@13 97 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@552 98 "deleted" TIMESTAMPTZ,
jbe@181 99 "invite_code" TEXT UNIQUE,
jbe@232 100 "invite_code_expiry" TIMESTAMPTZ,
jbe@182 101 "admin_comment" TEXT,
jbe@181 102 "activated" TIMESTAMPTZ,
jbe@184 103 "last_activity" DATE,
jbe@42 104 "last_login" TIMESTAMPTZ,
jbe@387 105 "last_delegation_check" TIMESTAMPTZ,
jbe@45 106 "login" TEXT UNIQUE,
jbe@0 107 "password" TEXT,
jbe@440 108 "authority" TEXT,
jbe@440 109 "authority_uid" TEXT,
jbe@440 110 "authority_login" TEXT,
jbe@99 111 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@181 112 "active" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 113 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@221 114 "lang" TEXT,
jbe@7 115 "notify_email" TEXT,
jbe@11 116 "notify_email_unconfirmed" TEXT,
jbe@11 117 "notify_email_secret" TEXT UNIQUE,
jbe@11 118 "notify_email_secret_expiry" TIMESTAMPTZ,
jbe@55 119 "notify_email_lock_expiry" TIMESTAMPTZ,
jbe@583 120 "unsubscribe_secret" TEXT,
jbe@486 121 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@486 122 "notification_counter" INT4 NOT NULL DEFAULT 1,
jbe@486 123 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
jbe@486 124 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
jbe@515 125 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
jbe@504 126 "notification_sent" TIMESTAMP,
jbe@387 127 "login_recovery_expiry" TIMESTAMPTZ,
jbe@11 128 "password_reset_secret" TEXT UNIQUE,
jbe@11 129 "password_reset_secret_expiry" TIMESTAMPTZ,
jbe@225 130 "name" TEXT UNIQUE,
jbe@7 131 "identification" TEXT UNIQUE,
jbe@214 132 "authentication" TEXT,
jbe@578 133 "role" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@532 134 "location" JSONB,
jbe@181 135 "text_search_data" TSVECTOR,
jbe@552 136 CONSTRAINT "deleted_requires_locked"
jbe@552 137 CHECK ("deleted" ISNULL OR "locked" = TRUE),
jbe@184 138 CONSTRAINT "active_requires_activated_and_last_activity"
jbe@225 139 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
jbe@440 140 CONSTRAINT "authority_requires_uid_and_vice_versa"
jbe@447 141 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
jbe@440 142 CONSTRAINT "authority_uid_unique_per_authority"
jbe@440 143 UNIQUE ("authority", "authority_uid"),
jbe@440 144 CONSTRAINT "authority_login_requires_authority"
jbe@440 145 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
jbe@505 146 CONSTRAINT "notification_dow_requires_notification_hour"
jbe@505 147 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
jbe@225 148 CONSTRAINT "name_not_null_if_activated"
jbe@529 149 CHECK ("activated" ISNULL OR "name" NOTNULL) );
jbe@440 150 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
jbe@0 151 CREATE INDEX "member_active_idx" ON "member" ("active");
jbe@532 152 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
jbe@8 153 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
jbe@7 154 CREATE TRIGGER "update_text_search_data"
jbe@7 155 BEFORE INSERT OR UPDATE ON "member"
jbe@7 156 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 157 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@532 158 "name", "identification");
jbe@0 159
jbe@0 160 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
jbe@0 161
jbe@181 162 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
jbe@181 163 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
jbe@232 164 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
jbe@182 165 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
jbe@207 166 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 167 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
jbe@103 168 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
jbe@387 169 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
jbe@10 170 COMMENT ON COLUMN "member"."login" IS 'Login name';
jbe@10 171 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
jbe@440 172 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 173 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 174 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
jbe@552 175 COMMENT ON COLUMN "member"."deleted" IS 'Timestamp of deletion (set by "delete_member" function)';
jbe@99 176 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
jbe@184 177 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 178 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
jbe@221 179 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
jbe@10 180 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
jbe@10 181 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 182 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
jbe@10 183 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
jbe@55 184 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
jbe@583 185 COMMENT ON COLUMN "member"."unsubscribe_secret" IS 'Secret string to be used for a List-Unsubscribe mail header';
jbe@508 186 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
jbe@508 187 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
jbe@508 188 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
jbe@508 189 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
jbe@508 190 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
jbe@508 191 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
jbe@387 192 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
jbe@387 193 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
jbe@387 194 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 195 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
jbe@10 196 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
jbe@214 197 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
jbe@532 198 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
jbe@532 199
jbe@532 200
jbe@532 201 CREATE TABLE "member_history" ( -- TODO: redundancy with new "event" table
jbe@13 202 "id" SERIAL8 PRIMARY KEY,
jbe@13 203 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@13 204 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@42 205 "active" BOOLEAN NOT NULL,
jbe@13 206 "name" TEXT NOT NULL );
jbe@45 207 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
jbe@13 208
jbe@57 209 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
jbe@13 210
jbe@13 211 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
jbe@57 212 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
jbe@13 213
jbe@13 214
jbe@578 215 CREATE TABLE "agent" (
jbe@578 216 PRIMARY KEY ("controlled_id", "controller_id"),
jbe@578 217 "controlled_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@578 218 "controller_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@581 219 "accepted" BOOLEAN,
jbe@578 220 CONSTRAINT "controlled_id_and_controller_id_differ" CHECK (
jbe@578 221 "controlled_id" != "controller_id" ) );
jbe@578 222 CREATE INDEX "agent_controller_id_idx" ON "agent" ("controller_id");
jbe@578 223
jbe@578 224 COMMENT ON TABLE "agent" IS 'Privileges for role accounts';
jbe@578 225
jbe@581 226 COMMENT ON COLUMN "agent"."accepted" IS 'If "accepted" is NULL, then the member was invited to be an agent, but has not reacted yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.';
jbe@581 227
jbe@578 228
jbe@557 229 CREATE TABLE "verification" (
jbe@557 230 "id" SERIAL8 PRIMARY KEY,
jbe@557 231 "requested" TIMESTAMPTZ,
jbe@557 232 "request_origin" JSONB,
jbe@557 233 "request_data" JSONB,
jbe@560 234 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@560 235 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@560 236 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@557 237 "verified" TIMESTAMPTZ,
jbe@557 238 "verification_data" JSONB,
jbe@557 239 "denied" TIMESTAMPTZ,
jbe@557 240 "comment" TEXT,
jbe@557 241 CONSTRAINT "verified_and_denied_conflict" CHECK (
jbe@557 242 "verified" ISNULL OR "denied" ISNULL ) );
jbe@557 243 CREATE INDEX "verification_requested_idx" ON "verification" ("requested");
jbe@557 244 CREATE INDEX "verification_open_request_idx" ON "verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
jbe@560 245 CREATE INDEX "verification_requesting_member_id_idx" ON "verification" ("requesting_member_id");
jbe@560 246 CREATE INDEX "verification_verified_member_id_idx" ON "verification" ("verified_member_id");
jbe@557 247 CREATE INDEX "verification_verified_idx" ON "verification" ("verified");
jbe@557 248 CREATE INDEX "verification_denied_idx" ON "verification" ("denied");
jbe@557 249
jbe@557 250 COMMENT ON TABLE "verification" IS 'Request to verify a participant';
jbe@557 251
jbe@560 252 COMMENT ON COLUMN "verification"."requested" IS 'Timestamp when request for verification has been submitted';
jbe@560 253 COMMENT ON COLUMN "verification"."request_origin" IS 'JSON data containing information about the origin of the request (e.g. IP address or hostname)';
jbe@560 254 COMMENT ON COLUMN "verification"."request_data" IS 'JSON data containing information about the entity to be verified (e.g. real name, address, etc.)';
jbe@560 255 COMMENT ON COLUMN "verification"."requesting_member_id" IS 'Member who requested verification';
jbe@560 256 COMMENT ON COLUMN "verification"."verifying_member_id" IS 'Member who processed the verification request (i.e. who accepted or denied the request)';
jbe@560 257 COMMENT ON COLUMN "verification"."verified_member_id" IS 'Member entry containing verified information (not necessarily equal to "requesting_member_id" but may be merged with requesting member later)';
jbe@560 258 COMMENT ON COLUMN "verification"."verified" IS 'Timestamp when request for verification has been accepted by authority';
jbe@560 259 COMMENT ON COLUMN "verification"."verification_data" IS 'JSON data containing additional verified data or information about the authority or operator who accepted or denied the request, but all public information shall be copied to "member"."identification", "member"."verification" and/or "member"."name" if applicable for setup';
jbe@560 260 COMMENT ON COLUMN "verification"."denied" IS 'Timestamp when request for verification has been denied by authority';
jbe@560 261 COMMENT ON COLUMN "verification"."comment" IS 'Administrative comment';
jbe@557 262
jbe@557 263
jbe@580 264 -- TODO: merge tables "verification" and "role_verification"
jbe@580 265
jbe@580 266 CREATE TABLE "role_verification" (
jbe@580 267 "id" SERIAL8 PRIMARY KEY,
jbe@580 268 "requested" TIMESTAMPTZ,
jbe@580 269 "request_origin" JSONB,
jbe@580 270 "request_data" JSONB,
jbe@580 271 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@580 272 "requesting_real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@580 273 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@580 274 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@580 275 "verified" TIMESTAMPTZ,
jbe@580 276 "verification_data" JSONB,
jbe@580 277 "denied" TIMESTAMPTZ,
jbe@580 278 "comment" TEXT,
jbe@580 279 CONSTRAINT "verified_and_denied_conflict" CHECK (
jbe@580 280 "verified" ISNULL OR "denied" ISNULL ) );
jbe@580 281 CREATE INDEX "role_verification_requested_idx" ON "role_verification" ("requested");
jbe@580 282 CREATE INDEX "role_verification_open_request_idx" ON "role_verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
jbe@580 283 CREATE INDEX "role_verification_requesting_member_id_idx" ON "role_verification" ("requesting_member_id");
jbe@580 284 CREATE INDEX "role_verification_verified_member_id_idx" ON "role_verification" ("verified_member_id");
jbe@580 285 CREATE INDEX "role_verification_verified_idx" ON "role_verification" ("verified");
jbe@580 286 CREATE INDEX "role_verification_denied_idx" ON "role_verification" ("denied");
jbe@580 287
jbe@580 288 COMMENT ON TABLE "role_verification" IS 'Request to verify a role account (see table "verification" for documentation of columns not documented for this table)';
jbe@580 289
jbe@580 290 COMMENT ON COLUMN "role_verification"."requesting_member_id" IS 'Member role account to verify';
jbe@580 291 COMMENT ON COLUMN "role_verification"."requesting_real_member_id" IS 'Member account of real person who requested verification';
jbe@580 292
jbe@580 293
jbe@544 294 CREATE TABLE "member_settings" (
jbe@544 295 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@544 296 "settings" JSONB NOT NULL CHECK (jsonb_typeof("settings") = 'object') );
jbe@544 297
jbe@544 298 COMMENT ON TABLE "member_settings" IS 'Stores a JSON document for each member containing optional (additional) settings for the respective member';
jbe@544 299
jbe@544 300
jbe@544 301 CREATE TABLE "member_useterms" (
jbe@559 302 "id" SERIAL8 PRIMARY KEY,
jbe@559 303 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@558 304 "accepted" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@544 305 "contract_identifier" TEXT NOT NULL );
jbe@544 306
jbe@544 307 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
jbe@544 308
jbe@544 309 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
jbe@544 310 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
jbe@544 311
jbe@544 312
jbe@532 313 CREATE TABLE "member_profile" (
jbe@532 314 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 315 "formatting_engine" TEXT,
jbe@532 316 "statement" TEXT,
jbe@544 317 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
jbe@532 318 "profile_text_data" TEXT,
jbe@532 319 "text_search_data" TSVECTOR );
jbe@532 320 CREATE INDEX "member_profile_text_search_data_idx" ON "member_profile" USING gin ("text_search_data");
jbe@532 321 CREATE TRIGGER "update_text_search_data"
jbe@532 322 BEFORE INSERT OR UPDATE ON "member_profile"
jbe@532 323 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 324 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@532 325 'statement', 'profile_text_data');
jbe@532 326
jbe@532 327 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
jbe@532 328 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
jbe@532 329 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
jbe@532 330 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
jbe@532 331
jbe@532 332
jbe@159 333 CREATE TABLE "rendered_member_statement" (
jbe@159 334 PRIMARY KEY ("member_id", "format"),
jbe@461 335 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@159 336 "format" TEXT,
jbe@159 337 "content" TEXT NOT NULL );
jbe@159 338
jbe@159 339 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 340
jbe@9 341
jbe@7 342 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
jbe@7 343
jbe@7 344 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
jbe@7 345
jbe@7 346
jbe@7 347 CREATE TABLE "member_image" (
jbe@7 348 PRIMARY KEY ("member_id", "image_type", "scaled"),
jbe@7 349 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@7 350 "image_type" "member_image_type",
jbe@7 351 "scaled" BOOLEAN,
jbe@7 352 "content_type" TEXT,
jbe@7 353 "data" BYTEA NOT NULL );
jbe@7 354
jbe@7 355 COMMENT ON TABLE "member_image" IS 'Images of members';
jbe@7 356
jbe@7 357 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
jbe@0 358
jbe@0 359
jbe@4 360 CREATE TABLE "member_count" (
jbe@341 361 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@5 362 "total_count" INT4 NOT NULL );
jbe@4 363
jbe@5 364 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 365
jbe@5 366 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
jbe@5 367 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
jbe@4 368
jbe@4 369
jbe@0 370 CREATE TABLE "contact" (
jbe@0 371 PRIMARY KEY ("member_id", "other_member_id"),
jbe@0 372 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 373 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@11 374 "public" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@588 375 "following" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@11 376 CONSTRAINT "cant_save_yourself_as_contact"
jbe@11 377 CHECK ("member_id" != "other_member_id") );
jbe@113 378 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
jbe@0 379
jbe@0 380 COMMENT ON TABLE "contact" IS 'Contact lists';
jbe@0 381
jbe@0 382 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
jbe@0 383 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
jbe@0 384 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
jbe@588 385 COMMENT ON COLUMN "contact"."following" IS 'TRUE = actions of contact are shown in personal timeline';
jbe@0 386
jbe@0 387
jbe@113 388 CREATE TABLE "ignored_member" (
jbe@113 389 PRIMARY KEY ("member_id", "other_member_id"),
jbe@113 390 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 391 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 392 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
jbe@113 393
jbe@113 394 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
jbe@113 395
jbe@113 396 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
jbe@113 397 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
jbe@113 398
jbe@113 399
jbe@220 400 CREATE TABLE "session" (
jbe@532 401 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
jbe@532 402 "id" SERIAL8 PRIMARY KEY,
jbe@532 403 "ident" TEXT NOT NULL UNIQUE,
jbe@220 404 "additional_secret" TEXT,
jbe@532 405 "logout_token" TEXT,
jbe@220 406 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
jbe@461 407 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
jbe@580 408 "real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@440 409 "authority" TEXT,
jbe@440 410 "authority_uid" TEXT,
jbe@440 411 "authority_login" TEXT,
jbe@387 412 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@220 413 "lang" TEXT );
jbe@220 414 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
jbe@220 415
jbe@220 416 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
jbe@220 417
jbe@220 418 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
jbe@220 419 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
jbe@532 420 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
jbe@580 421 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in, or role account in use';
jbe@580 422 COMMENT ON COLUMN "session"."real_member_id" IS 'Reference to member, who is really logged in (real person rather than role account)';
jbe@440 423 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
jbe@440 424 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
jbe@440 425 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
jbe@387 426 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 427 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
jbe@220 428
jbe@220 429
jbe@532 430 CREATE TYPE "authflow" AS ENUM ('code', 'token');
jbe@532 431
jbe@532 432 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
jbe@532 433
jbe@532 434
jbe@532 435 CREATE TABLE "system_application" (
jbe@532 436 "id" SERIAL4 PRIMARY KEY,
jbe@532 437 "name" TEXT NOT NULL,
jbe@575 438 "base_url" TEXT,
jbe@575 439 "manifest_url" TEXT,
jbe@532 440 "client_id" TEXT NOT NULL UNIQUE,
jbe@532 441 "default_redirect_uri" TEXT NOT NULL,
jbe@532 442 "cert_common_name" TEXT,
jbe@532 443 "client_cred_scope" TEXT,
jbe@532 444 "flow" "authflow",
jbe@532 445 "automatic_scope" TEXT,
jbe@532 446 "permitted_scope" TEXT,
jbe@532 447 "forbidden_scope" TEXT );
jbe@532 448
jbe@532 449 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
jbe@532 450
jbe@532 451 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
jbe@576 452 COMMENT ON COLUMN "system_application"."base_url" IS 'Base URL for users';
jbe@576 453 COMMENT ON COLUMN "system_application"."manifest_url" IS 'URL referring to a manifest that can be used for application (type/version) discovery';
jbe@532 454 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
jbe@532 455 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
jbe@532 456 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
jbe@532 457 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
jbe@532 458 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
jbe@532 459 COMMENT ON COLUMN "system_application"."permitted_scope" IS 'Space-separated list of scopes; If set, scope that members may grant to the application is limited to the given value';
jbe@532 460 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
jbe@532 461
jbe@532 462
jbe@532 463 CREATE TABLE "system_application_redirect_uri" (
jbe@532 464 PRIMARY KEY ("system_application_id", "redirect_uri"),
jbe@532 465 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 466 "redirect_uri" TEXT );
jbe@532 467
jbe@532 468 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
jbe@532 469
jbe@532 470
jbe@532 471 CREATE TABLE "dynamic_application_scope" (
jbe@532 472 PRIMARY KEY ("redirect_uri", "flow", "scope"),
jbe@532 473 "redirect_uri" TEXT,
jbe@532 474 "flow" TEXT,
jbe@532 475 "scope" TEXT,
jbe@532 476 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
jbe@532 477 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
jbe@532 478 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
jbe@532 479
jbe@532 480 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
jbe@532 481
jbe@532 482 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
jbe@532 483 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
jbe@532 484 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
jbe@532 485 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
jbe@532 486
jbe@532 487
jbe@532 488 CREATE TABLE "member_application" (
jbe@532 489 "id" SERIAL4 PRIMARY KEY,
jbe@532 490 UNIQUE ("system_application_id", "member_id"),
jbe@532 491 UNIQUE ("domain", "member_id"),
jbe@532 492 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 493 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 494 "domain" TEXT,
jbe@532 495 "session_id" INT8,
jbe@532 496 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 497 "scope" TEXT NOT NULL,
jbe@532 498 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
jbe@532 499 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
jbe@532 500 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
jbe@532 501 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
jbe@532 502
jbe@532 503 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
jbe@532 504
jbe@532 505 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
jbe@532 506 COMMENT ON COLUMN "member_application"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
jbe@532 507 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
jbe@532 508 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
jbe@532 509
jbe@532 510
jbe@532 511 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
jbe@532 512
jbe@532 513 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
jbe@532 514
jbe@532 515
jbe@532 516 CREATE TABLE "token" (
jbe@532 517 "id" SERIAL8 PRIMARY KEY,
jbe@532 518 "token" TEXT NOT NULL UNIQUE,
jbe@532 519 "token_type" "token_type" NOT NULL,
jbe@532 520 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 521 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 522 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 523 "domain" TEXT,
jbe@532 524 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 525 "session_id" INT8,
jbe@532 526 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE, -- NOTE: deletion through "detach_token_from_session" trigger on table "session"
jbe@532 527 "redirect_uri" TEXT,
jbe@532 528 "redirect_uri_explicit" BOOLEAN,
jbe@532 529 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@532 530 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
jbe@532 531 "used" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@532 532 "scope" TEXT NOT NULL,
jbe@532 533 CONSTRAINT "access_token_needs_expiry"
jbe@532 534 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
jbe@532 535 CONSTRAINT "authorization_token_needs_redirect_uri"
jbe@532 536 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
jbe@532 537 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
jbe@532 538 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
jbe@532 539 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
jbe@532 540
jbe@532 541 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
jbe@532 542
jbe@532 543 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
jbe@532 544 COMMENT ON COLUMN "token"."authorization_token_id" IS 'Reference to authorization token if tokens were originally created by Authorization Code flow (allows deletion if code is used twice)';
jbe@532 545 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
jbe@532 546 COMMENT ON COLUMN "token"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
jbe@532 547 COMMENT ON COLUMN "token"."session_id" IS 'If set, then token is tied to a session; Deletion of session sets value to NULL (via trigger) and removes all scopes without suffix ''_detached''';
jbe@532 548 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
jbe@532 549 COMMENT ON COLUMN "token"."redirect_uri_explicit" IS 'True if ''redirect_uri'' parameter was explicitly specified during authorization request of the Authorization Code flow (since RFC 6749 requires it to be included in the access token request in this case)';
jbe@532 550 COMMENT ON COLUMN "token"."expiry" IS 'Point in time when code or token expired; In case of "used" authorization codes, authorization code must not be deleted as long as tokens exist which refer to the authorization code';
jbe@532 551 COMMENT ON COLUMN "token"."used" IS 'Can be set to TRUE for authorization codes that have been used (enables deletion of authorization codes that were used twice)';
jbe@532 552 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
jbe@532 553
jbe@532 554
jbe@532 555 CREATE TABLE "token_scope" (
jbe@532 556 PRIMARY KEY ("token_id", "index"),
jbe@532 557 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 558 "index" INT4,
jbe@532 559 "scope" TEXT NOT NULL );
jbe@532 560
jbe@532 561 COMMENT ON TABLE "token_scope" IS 'Additional scopes for an authorization code if ''scope1'', ''scope2'', etc. parameters were used during Authorization Code flow to request several access and refresh tokens at once';
jbe@532 562
jbe@532 563
jbe@424 564 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
jbe@424 565
jbe@424 566 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 567
jbe@424 568
jbe@424 569 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
jbe@424 570
jbe@424 571 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 572
jbe@424 573
jbe@0 574 CREATE TABLE "policy" (
jbe@0 575 "id" SERIAL4 PRIMARY KEY,
jbe@9 576 "index" INT4 NOT NULL,
jbe@0 577 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 578 "name" TEXT NOT NULL UNIQUE,
jbe@0 579 "description" TEXT NOT NULL DEFAULT '',
jbe@261 580 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@447 581 "min_admission_time" INTERVAL,
jbe@447 582 "max_admission_time" INTERVAL,
jbe@261 583 "discussion_time" INTERVAL,
jbe@261 584 "verification_time" INTERVAL,
jbe@261 585 "voting_time" INTERVAL,
jbe@532 586 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
jbe@532 587 "issue_quorum_num" INT4,
jbe@532 588 "issue_quorum_den" INT4,
jbe@532 589 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
jbe@0 590 "initiative_quorum_num" INT4 NOT NULL,
jbe@10 591 "initiative_quorum_den" INT4 NOT NULL,
jbe@424 592 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
jbe@424 593 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
jbe@167 594 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
jbe@167 595 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
jbe@167 596 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@167 597 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
jbe@167 598 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
jbe@167 599 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
jbe@167 600 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
jbe@167 601 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@167 602 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
jbe@167 603 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
jbe@429 604 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@260 605 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@458 606 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
jbe@532 607 "polling" = ("issue_quorum" ISNULL) AND
jbe@532 608 "polling" = ("issue_quorum_num" ISNULL) AND
jbe@532 609 "polling" = ("issue_quorum_den" ISNULL) ),
jbe@528 610 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
jbe@528 611 "min_admission_time" < "max_admission_time" ),
jbe@528 612 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
jbe@261 613 ( "polling" = FALSE AND
jbe@447 614 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
jbe@447 615 "discussion_time" NOTNULL AND
jbe@447 616 "verification_time" NOTNULL AND
jbe@447 617 "voting_time" NOTNULL ) OR
jbe@261 618 ( "polling" = TRUE AND
jbe@447 619 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@447 620 "discussion_time" NOTNULL AND
jbe@447 621 "verification_time" NOTNULL AND
jbe@447 622 "voting_time" NOTNULL ) OR
jbe@447 623 ( "polling" = TRUE AND
jbe@447 624 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@447 625 "discussion_time" ISNULL AND
jbe@447 626 "verification_time" ISNULL AND
jbe@447 627 "voting_time" ISNULL ) ),
jbe@429 628 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
jbe@429 629 "defeat_strength" = 'tuple'::"defeat_strength" OR
jbe@429 630 "no_reverse_beat_path" = FALSE ) );
jbe@0 631 CREATE INDEX "policy_active_idx" ON "policy" ("active");
jbe@0 632
jbe@0 633 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
jbe@0 634
jbe@9 635 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
jbe@0 636 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
jbe@447 637 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@528 638 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open; Note: should be considerably smaller than "max_admission_time"';
jbe@447 639 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 640 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 641 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 642 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@532 643 COMMENT ON COLUMN "policy"."issue_quorum" IS 'Absolute number of supporters needed by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
jbe@532 644 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
jbe@532 645 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
jbe@532 646 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
jbe@528 647 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 648 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 649 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 650 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
jbe@167 651 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
jbe@167 652 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
jbe@167 653 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 654 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
jbe@167 655 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 656 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 657 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 658 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 659 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 660 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 661 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 662 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 663
jbe@0 664
jbe@97 665 CREATE TABLE "unit" (
jbe@97 666 "id" SERIAL4 PRIMARY KEY,
jbe@97 667 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 668 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@97 669 "name" TEXT NOT NULL,
jbe@97 670 "description" TEXT NOT NULL DEFAULT '',
jbe@444 671 "external_reference" TEXT,
jbe@97 672 "member_count" INT4,
jbe@551 673 "location" JSONB,
jbe@97 674 "text_search_data" TSVECTOR );
jbe@97 675 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
jbe@97 676 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
jbe@97 677 CREATE INDEX "unit_active_idx" ON "unit" ("active");
jbe@551 678 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
jbe@97 679 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
jbe@97 680 CREATE TRIGGER "update_text_search_data"
jbe@97 681 BEFORE INSERT OR UPDATE ON "unit"
jbe@97 682 FOR EACH ROW EXECUTE PROCEDURE
jbe@97 683 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@97 684 "name", "description" );
jbe@97 685
jbe@97 686 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
jbe@97 687
jbe@444 688 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
jbe@444 689 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
jbe@444 690 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
jbe@556 691 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
jbe@551 692 COMMENT ON COLUMN "unit"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
jbe@97 693
jbe@97 694
jbe@465 695 CREATE TABLE "subscription" (
jbe@465 696 PRIMARY KEY ("member_id", "unit_id"),
jbe@465 697 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 698 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 699 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
jbe@465 700
jbe@465 701 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 702
jbe@465 703
jbe@0 704 CREATE TABLE "area" (
jbe@532 705 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "event"
jbe@532 706 "id" SERIAL4 PRIMARY KEY,
jbe@457 707 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 708 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 709 "name" TEXT NOT NULL,
jbe@4 710 "description" TEXT NOT NULL DEFAULT '',
jbe@532 711 "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0),
jbe@532 712 "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0),
jbe@532 713 "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL),
jbe@532 714 "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1),
jbe@532 715 "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1),
jbe@532 716 "quorum_den" INT4 CHECK ("quorum_den" > 0),
jbe@532 717 "issue_quorum" INT4,
jbe@444 718 "external_reference" TEXT,
jbe@551 719 "location" JSONB,
jbe@7 720 "text_search_data" TSVECTOR );
jbe@0 721 CREATE INDEX "area_active_idx" ON "area" ("active");
jbe@551 722 CREATE INDEX "area_location_idx" ON "area" USING gist ((GeoJSON_to_ecluster("location")));
jbe@8 723 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
jbe@7 724 CREATE TRIGGER "update_text_search_data"
jbe@7 725 BEFORE INSERT OR UPDATE ON "area"
jbe@7 726 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 727 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 728 "name", "description" );
jbe@0 729
jbe@0 730 COMMENT ON TABLE "area" IS 'Subject areas';
jbe@0 731
jbe@528 732 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
jbe@532 733 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
jbe@532 734 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
jbe@532 735 COMMENT ON COLUMN "area"."quorum_time" IS 'Parameter for dynamic issue quorum: discussion, verification, and voting time of open issues to result in the given default quorum (open issues with shorter time will increase quorum and open issues with longer time will reduce quorum if "quorum_exponent" is greater than zero)';
jbe@532 736 COMMENT ON COLUMN "area"."quorum_exponent" IS 'Parameter for dynamic issue quorum: set to zero to ignore duration of open issues, set to one to fully take duration of open issues into account; defaults to 0.5';
jbe@532 737 COMMENT ON COLUMN "area"."quorum_factor" IS 'Parameter for dynamic issue quorum: factor to increase dynamic quorum when a number of "quorum_issues" issues with "quorum_time" duration of discussion, verification, and voting phase are added to the number of open admitted issues';
jbe@532 738 COMMENT ON COLUMN "area"."quorum_den" IS 'Parameter for dynamic issue quorum: when set, dynamic quorum is multiplied with "issue"."population" and divided by "quorum_den" (and then rounded up)';
jbe@532 739 COMMENT ON COLUMN "area"."issue_quorum" IS 'Additional dynamic issue quorum based on the number of open accepted issues; automatically calculated by function "issue_admission"';
jbe@528 740 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
jbe@551 741 COMMENT ON COLUMN "area"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
jbe@0 742
jbe@0 743
jbe@465 744 CREATE TABLE "ignored_area" (
jbe@465 745 PRIMARY KEY ("member_id", "area_id"),
jbe@579 746 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 747 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 748 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
jbe@465 749
jbe@465 750 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 751
jbe@465 752
jbe@9 753 CREATE TABLE "allowed_policy" (
jbe@9 754 PRIMARY KEY ("area_id", "policy_id"),
jbe@9 755 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 756 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 757 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@9 758 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
jbe@9 759
jbe@9 760 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
jbe@9 761
jbe@9 762 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
jbe@9 763
jbe@9 764
jbe@528 765 CREATE TABLE "snapshot" (
jbe@532 766 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
jbe@528 767 "id" SERIAL8 PRIMARY KEY,
jbe@532 768 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@532 769 "population" INT4,
jbe@532 770 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 771 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
jbe@528 772
jbe@528 773 COMMENT ON TABLE "snapshot" IS 'Point in time when a snapshot of one or more issues (see table "snapshot_issue") and their supporter situation is taken';
jbe@8 774
jbe@8 775
jbe@532 776 CREATE TABLE "snapshot_population" (
jbe@532 777 PRIMARY KEY ("snapshot_id", "member_id"),
jbe@532 778 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 779 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
jbe@532 780
jbe@532 781 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
jbe@532 782
jbe@532 783
jbe@112 784 CREATE TYPE "issue_state" AS ENUM (
jbe@112 785 'admission', 'discussion', 'verification', 'voting',
jbe@389 786 'canceled_by_admin',
jbe@113 787 'canceled_revoked_before_accepted',
jbe@113 788 'canceled_issue_not_accepted',
jbe@113 789 'canceled_after_revocation_during_discussion',
jbe@113 790 'canceled_after_revocation_during_verification',
jbe@113 791 'canceled_no_initiative_admitted',
jbe@112 792 'finished_without_winner', 'finished_with_winner');
jbe@111 793
jbe@111 794 COMMENT ON TYPE "issue_state" IS 'State of issues';
jbe@111 795
jbe@111 796
jbe@0 797 CREATE TABLE "issue" (
jbe@532 798 UNIQUE ("area_id", "id"), -- index needed for foreign-key on table "event"
jbe@536 799 UNIQUE ("policy_id", "id"), -- index needed for foreign-key on table "event"
jbe@0 800 "id" SERIAL4 PRIMARY KEY,
jbe@0 801 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 802 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@389 803 "admin_notice" TEXT,
jbe@444 804 "external_reference" TEXT,
jbe@111 805 "state" "issue_state" NOT NULL DEFAULT 'admission',
jbe@328 806 "phase_finished" TIMESTAMPTZ,
jbe@0 807 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 808 "accepted" TIMESTAMPTZ,
jbe@3 809 "half_frozen" TIMESTAMPTZ,
jbe@3 810 "fully_frozen" TIMESTAMPTZ,
jbe@0 811 "closed" TIMESTAMPTZ,
jbe@59 812 "cleaned" TIMESTAMPTZ,
jbe@447 813 "min_admission_time" INTERVAL,
jbe@447 814 "max_admission_time" INTERVAL,
jbe@22 815 "discussion_time" INTERVAL NOT NULL,
jbe@22 816 "verification_time" INTERVAL NOT NULL,
jbe@22 817 "voting_time" INTERVAL NOT NULL,
jbe@532 818 "calculated" TIMESTAMPTZ, -- NOTE: copy of "calculated" column of latest snapshot, but no referential integrity to avoid overhead
jbe@528 819 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@528 820 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
jbe@532 821 "half_freeze_snapshot_id" INT8,
jbe@532 822 FOREIGN KEY ("id", "half_freeze_snapshot_id")
jbe@532 823 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@532 824 "full_freeze_snapshot_id" INT8,
jbe@532 825 FOREIGN KEY ("id", "full_freeze_snapshot_id")
jbe@532 826 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@568 827 "issue_quorum" INT4,
jbe@568 828 "initiative_quorum" INT4,
jbe@0 829 "population" INT4,
jbe@4 830 "voter_count" INT4,
jbe@170 831 "status_quo_schulze_rank" INT4,
jbe@291 832 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
jbe@447 833 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
jbe@452 834 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
jbe@340 835 CONSTRAINT "valid_state" CHECK (
jbe@340 836 (
jbe@340 837 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
jbe@340 838 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
jbe@340 839 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
jbe@340 840 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
jbe@340 841 ) AND (
jbe@340 842 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
jbe@340 843 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
jbe@340 844 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@340 845 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
jbe@389 846 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
jbe@340 847 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@340 848 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@340 849 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
jbe@340 850 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@340 851 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
jbe@340 852 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
jbe@340 853 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
jbe@111 854 )),
jbe@328 855 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
jbe@328 856 "phase_finished" ISNULL OR "closed" ISNULL ),
jbe@3 857 CONSTRAINT "state_change_order" CHECK (
jbe@10 858 "created" <= "accepted" AND
jbe@10 859 "accepted" <= "half_frozen" AND
jbe@10 860 "half_frozen" <= "fully_frozen" AND
jbe@3 861 "fully_frozen" <= "closed" ),
jbe@61 862 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
jbe@61 863 "cleaned" ISNULL OR "closed" NOTNULL ),
jbe@528 864 CONSTRAINT "snapshot_required" CHECK (
jbe@528 865 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
jbe@528 866 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
jbe@528 867 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
jbe@528 868 CREATE INDEX "issue_state_idx" ON "issue" ("state");
jbe@16 869 CREATE INDEX "issue_created_idx" ON "issue" ("created");
jbe@16 870 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
jbe@16 871 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
jbe@16 872 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
jbe@16 873 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
jbe@0 874 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
jbe@16 875 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
jbe@528 876 CREATE INDEX "issue_latest_snapshot_id" ON "issue" ("latest_snapshot_id");
jbe@528 877 CREATE INDEX "issue_admission_snapshot_id" ON "issue" ("admission_snapshot_id");
jbe@528 878 CREATE INDEX "issue_half_freeze_snapshot_id" ON "issue" ("half_freeze_snapshot_id");
jbe@528 879 CREATE INDEX "issue_full_freeze_snapshot_id" ON "issue" ("full_freeze_snapshot_id");
jbe@0 880
jbe@0 881 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
jbe@0 882
jbe@389 883 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
jbe@444 884 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
jbe@328 885 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@532 886 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when the issue was accepted for further discussion (see columns "issue_quorum_num" and "issue_quorum_den" of table "policy" and quorum columns of table "area")';
jbe@170 887 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 888 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 889 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 890 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
jbe@447 891 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@447 892 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 893 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 894 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 895 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
jbe@532 896 COMMENT ON COLUMN "issue"."calculated" IS 'Point in time, when most recent snapshot and "population" and *_count values were calculated (NOTE: value is equal to "snapshot"."calculated" of snapshot with "id"="issue"."latest_snapshot_id")';
jbe@528 897 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
jbe@528 898 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
jbe@528 899 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
jbe@528 900 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
jbe@568 901 COMMENT ON COLUMN "issue"."issue_quorum" IS 'Calculated number of supporters needed by an initiative of the issue to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
jbe@568 902 COMMENT ON COLUMN "issue"."initiative_quorum" IS 'Calculated number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
jbe@532 903 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
jbe@170 904 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 905 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
jbe@0 906
jbe@0 907
jbe@532 908 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
jbe@532 909
jbe@532 910
jbe@410 911 CREATE TABLE "issue_order_in_admission_state" (
jbe@532 912 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@410 913 "order_in_area" INT4,
jbe@410 914 "order_in_unit" INT4 );
jbe@410 915
jbe@410 916 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 917
jbe@410 918 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 919 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 920 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 921
jbe@0 922
jbe@0 923 CREATE TABLE "initiative" (
jbe@0 924 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
jbe@0 925 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 926 "id" SERIAL4 PRIMARY KEY,
jbe@0 927 "name" TEXT NOT NULL,
jbe@261 928 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 929 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 930 "revoked" TIMESTAMPTZ,
jbe@112 931 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@532 932 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
jbe@532 933 "location" JSONB,
jbe@444 934 "external_reference" TEXT,
jbe@0 935 "admitted" BOOLEAN,
jbe@0 936 "supporter_count" INT4,
jbe@0 937 "informed_supporter_count" INT4,
jbe@0 938 "satisfied_supporter_count" INT4,
jbe@0 939 "satisfied_informed_supporter_count" INT4,
jbe@313 940 "harmonic_weight" NUMERIC(12, 3),
jbe@352 941 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@414 942 "first_preference_votes" INT4,
jbe@0 943 "positive_votes" INT4,
jbe@0 944 "negative_votes" INT4,
jbe@167 945 "direct_majority" BOOLEAN,
jbe@167 946 "indirect_majority" BOOLEAN,
jbe@170 947 "schulze_rank" INT4,
jbe@167 948 "better_than_status_quo" BOOLEAN,
jbe@167 949 "worse_than_status_quo" BOOLEAN,
jbe@429 950 "reverse_beat_path" BOOLEAN,
jbe@154 951 "multistage_majority" BOOLEAN,
jbe@154 952 "eligible" BOOLEAN,
jbe@126 953 "winner" BOOLEAN,
jbe@0 954 "rank" INT4,
jbe@7 955 "text_search_data" TSVECTOR,
jbe@528 956 "draft_text_search_data" TSVECTOR,
jbe@112 957 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
jbe@447 958 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
jbe@14 959 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
jbe@14 960 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
jbe@0 961 CONSTRAINT "revoked_initiatives_cant_be_admitted"
jbe@0 962 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
jbe@128 963 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
jbe@128 964 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
jbe@414 965 ( "first_preference_votes" ISNULL AND
jbe@414 966 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
jbe@167 967 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
jbe@173 968 "schulze_rank" ISNULL AND
jbe@167 969 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
jbe@429 970 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
jbe@173 971 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
jbe@173 972 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
jbe@175 973 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
jbe@175 974 "eligible" = FALSE OR
jbe@175 975 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
jbe@175 976 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
jbe@175 977 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
jbe@176 978 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
jbe@173 979 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
jbe@16 980 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
jbe@16 981 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
jbe@532 982 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
jbe@8 983 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
jbe@528 984 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
jbe@7 985 CREATE TRIGGER "update_text_search_data"
jbe@7 986 BEFORE INSERT OR UPDATE ON "initiative"
jbe@7 987 FOR EACH ROW EXECUTE PROCEDURE
jbe@450 988 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
jbe@0 989
jbe@10 990 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 991
jbe@289 992 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
jbe@210 993 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
jbe@210 994 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
jbe@532 995 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
jbe@444 996 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
jbe@210 997 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
jbe@0 998 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 999 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 1000 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 1001 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@320 1002 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 1003 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 1004 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
jbe@414 1005 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
jbe@414 1006 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
jbe@210 1007 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 1008 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
jbe@411 1009 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
jbe@411 1010 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
jbe@411 1011 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 1012 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 1013 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 1014 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 1015 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
jbe@210 1016 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 1017
jbe@0 1018
jbe@61 1019 CREATE TABLE "battle" (
jbe@126 1020 "issue_id" INT4 NOT NULL,
jbe@61 1021 "winning_initiative_id" INT4,
jbe@61 1022 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@61 1023 "losing_initiative_id" INT4,
jbe@61 1024 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@126 1025 "count" INT4 NOT NULL,
jbe@126 1026 CONSTRAINT "initiative_ids_not_equal" CHECK (
jbe@126 1027 "winning_initiative_id" != "losing_initiative_id" OR
jbe@126 1028 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
jbe@126 1029 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
jbe@126 1030 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
jbe@126 1031 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
jbe@126 1032 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
jbe@126 1033
jbe@126 1034 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 1035
jbe@61 1036
jbe@113 1037 CREATE TABLE "ignored_initiative" (
jbe@465 1038 PRIMARY KEY ("member_id", "initiative_id"),
jbe@465 1039 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 1040 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 1041 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
jbe@113 1042
jbe@509 1043 COMMENT ON TABLE "ignored_initiative" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given initiative';
jbe@113 1044
jbe@113 1045
jbe@0 1046 CREATE TABLE "draft" (
jbe@0 1047 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
jbe@0 1048 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1049 "id" SERIAL8 PRIMARY KEY,
jbe@0 1050 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 1051 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@9 1052 "formatting_engine" TEXT,
jbe@7 1053 "content" TEXT NOT NULL,
jbe@532 1054 "location" JSONB,
jbe@444 1055 "external_reference" TEXT,
jbe@532 1056 "text_search_data" TSVECTOR );
jbe@16 1057 CREATE INDEX "draft_created_idx" ON "draft" ("created");
jbe@9 1058 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
jbe@532 1059 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
jbe@8 1060 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
jbe@7 1061 CREATE TRIGGER "update_text_search_data"
jbe@7 1062 BEFORE INSERT OR UPDATE ON "draft"
jbe@7 1063 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 1064 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@0 1065
jbe@10 1066 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 1067
jbe@444 1068 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
jbe@444 1069 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
jbe@532 1070 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
jbe@444 1071 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
jbe@9 1072
jbe@0 1073
jbe@63 1074 CREATE TABLE "rendered_draft" (
jbe@63 1075 PRIMARY KEY ("draft_id", "format"),
jbe@63 1076 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@63 1077 "format" TEXT,
jbe@63 1078 "content" TEXT NOT NULL );
jbe@63 1079
jbe@63 1080 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 1081
jbe@63 1082
jbe@0 1083 CREATE TABLE "suggestion" (
jbe@0 1084 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
jbe@0 1085 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1086 "id" SERIAL8 PRIMARY KEY,
jbe@160 1087 "draft_id" INT8 NOT NULL,
jbe@160 1088 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@0 1089 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 1090 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 1091 "name" TEXT NOT NULL,
jbe@159 1092 "formatting_engine" TEXT,
jbe@159 1093 "content" TEXT NOT NULL DEFAULT '',
jbe@532 1094 "location" JSONB,
jbe@444 1095 "external_reference" TEXT,
jbe@7 1096 "text_search_data" TSVECTOR,
jbe@0 1097 "minus2_unfulfilled_count" INT4,
jbe@0 1098 "minus2_fulfilled_count" INT4,
jbe@0 1099 "minus1_unfulfilled_count" INT4,
jbe@0 1100 "minus1_fulfilled_count" INT4,
jbe@0 1101 "plus1_unfulfilled_count" INT4,
jbe@0 1102 "plus1_fulfilled_count" INT4,
jbe@0 1103 "plus2_unfulfilled_count" INT4,
jbe@352 1104 "plus2_fulfilled_count" INT4,
jbe@532 1105 "proportional_order" INT4 );
jbe@16 1106 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
jbe@9 1107 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
jbe@532 1108 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
jbe@8 1109 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
jbe@7 1110 CREATE TRIGGER "update_text_search_data"
jbe@7 1111 BEFORE INSERT OR UPDATE ON "suggestion"
jbe@7 1112 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 1113 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@159 1114 "name", "content");
jbe@0 1115
jbe@10 1116 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 1117
jbe@160 1118 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@532 1119 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
jbe@444 1120 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
jbe@0 1121 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1122 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1123 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1124 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1125 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1126 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1127 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 1128 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@378 1129 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 1130
jbe@0 1131
jbe@159 1132 CREATE TABLE "rendered_suggestion" (
jbe@159 1133 PRIMARY KEY ("suggestion_id", "format"),
jbe@159 1134 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@159 1135 "format" TEXT,
jbe@159 1136 "content" TEXT NOT NULL );
jbe@159 1137
jbe@159 1138 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 1139
jbe@159 1140
jbe@528 1141 CREATE TABLE "temporary_suggestion_counts" (
jbe@532 1142 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@528 1143 "minus2_unfulfilled_count" INT4 NOT NULL,
jbe@528 1144 "minus2_fulfilled_count" INT4 NOT NULL,
jbe@528 1145 "minus1_unfulfilled_count" INT4 NOT NULL,
jbe@528 1146 "minus1_fulfilled_count" INT4 NOT NULL,
jbe@528 1147 "plus1_unfulfilled_count" INT4 NOT NULL,
jbe@528 1148 "plus1_fulfilled_count" INT4 NOT NULL,
jbe@528 1149 "plus2_unfulfilled_count" INT4 NOT NULL,
jbe@528 1150 "plus2_fulfilled_count" INT4 NOT NULL );
jbe@528 1151
jbe@528 1152 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
jbe@528 1153
jbe@528 1154 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
jbe@528 1155
jbe@528 1156
jbe@97 1157 CREATE TABLE "privilege" (
jbe@97 1158 PRIMARY KEY ("unit_id", "member_id"),
jbe@97 1159 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 1160 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 1161 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 1162 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 1163 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@261 1164 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@261 1165 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@261 1166 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@261 1167 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@97 1168
jbe@97 1169 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
jbe@97 1170
jbe@289 1171 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
jbe@289 1172 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
jbe@289 1173 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
jbe@289 1174 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
jbe@289 1175 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
jbe@289 1176 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
jbe@289 1177 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 1178
jbe@97 1179
jbe@0 1180 CREATE TABLE "interest" (
jbe@0 1181 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1182 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1183 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
jbe@0 1184 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
jbe@0 1185
jbe@10 1186 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 1187
jbe@0 1188
jbe@0 1189 CREATE TABLE "initiator" (
jbe@0 1190 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1191 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1192 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@14 1193 "accepted" BOOLEAN );
jbe@0 1194 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
jbe@0 1195
jbe@10 1196 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 1197
jbe@14 1198 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 1199
jbe@0 1200
jbe@0 1201 CREATE TABLE "supporter" (
jbe@0 1202 "issue_id" INT4 NOT NULL,
jbe@0 1203 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1204 "initiative_id" INT4,
jbe@0 1205 "member_id" INT4,
jbe@0 1206 "draft_id" INT8 NOT NULL,
jbe@10 1207 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@160 1208 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
jbe@0 1209 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
jbe@0 1210
jbe@10 1211 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 1212
jbe@207 1213 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 1214 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 1215
jbe@0 1216
jbe@0 1217 CREATE TABLE "opinion" (
jbe@0 1218 "initiative_id" INT4 NOT NULL,
jbe@0 1219 PRIMARY KEY ("suggestion_id", "member_id"),
jbe@0 1220 "suggestion_id" INT8,
jbe@0 1221 "member_id" INT4,
jbe@0 1222 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
jbe@0 1223 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@42 1224 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1225 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@10 1226 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
jbe@0 1227
jbe@10 1228 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 1229
jbe@0 1230 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
jbe@0 1231
jbe@0 1232
jbe@97 1233 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
jbe@97 1234
jbe@97 1235 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
jbe@10 1236
jbe@10 1237
jbe@0 1238 CREATE TABLE "delegation" (
jbe@0 1239 "id" SERIAL8 PRIMARY KEY,
jbe@0 1240 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1241 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@10 1242 "scope" "delegation_scope" NOT NULL,
jbe@97 1243 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1244 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1245 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1246 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
jbe@97 1247 CONSTRAINT "no_unit_delegation_to_null"
jbe@97 1248 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
jbe@10 1249 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
jbe@97 1250 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
jbe@97 1251 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
jbe@97 1252 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
jbe@97 1253 UNIQUE ("unit_id", "truster_id"),
jbe@74 1254 UNIQUE ("area_id", "truster_id"),
jbe@74 1255 UNIQUE ("issue_id", "truster_id") );
jbe@0 1256 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
jbe@0 1257 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
jbe@0 1258
jbe@0 1259 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
jbe@0 1260
jbe@97 1261 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
jbe@0 1262 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
jbe@0 1263 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
jbe@0 1264
jbe@0 1265
jbe@528 1266 CREATE TABLE "snapshot_issue" (
jbe@528 1267 PRIMARY KEY ("snapshot_id", "issue_id"),
jbe@528 1268 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1269 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
jbe@528 1270 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
jbe@528 1271
jbe@528 1272 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
jbe@0 1273
jbe@532 1274 COMMENT ON COLUMN "snapshot_issue"."issue_id" IS 'Issue being part of the snapshot; Trigger "delete_snapshot_on_partial_delete" on "snapshot_issue" table will delete snapshot if an issue of the snapshot is deleted.';
jbe@532 1275
jbe@0 1276
jbe@0 1277 CREATE TABLE "direct_interest_snapshot" (
jbe@528 1278 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
jbe@528 1279 "snapshot_id" INT8,
jbe@528 1280 "issue_id" INT4,
jbe@528 1281 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@528 1282 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1283 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@144 1284 "weight" INT4 );
jbe@0 1285 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
jbe@0 1286
jbe@389 1287 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 1288
jbe@528 1289 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
jbe@0 1290
jbe@0 1291
jbe@0 1292 CREATE TABLE "delegating_interest_snapshot" (
jbe@528 1293 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
jbe@528 1294 "snapshot_id" INT8,
jbe@528 1295 "issue_id" INT4,
jbe@528 1296 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@528 1297 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1298 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 1299 "weight" INT4,
jbe@10 1300 "scope" "delegation_scope" NOT NULL,
jbe@0 1301 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 1302 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
jbe@0 1303
jbe@389 1304 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 1305
jbe@0 1306 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
jbe@8 1307 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
jbe@0 1308 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 1309
jbe@0 1310
jbe@0 1311 CREATE TABLE "direct_supporter_snapshot" (
jbe@528 1312 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
jbe@528 1313 "snapshot_id" INT8,
jbe@0 1314 "issue_id" INT4 NOT NULL,
jbe@528 1315 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@528 1316 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1317 "initiative_id" INT4,
jbe@45 1318 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@204 1319 "draft_id" INT8 NOT NULL,
jbe@0 1320 "informed" BOOLEAN NOT NULL,
jbe@0 1321 "satisfied" BOOLEAN NOT NULL,
jbe@0 1322 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@204 1323 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@528 1324 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 1325 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
jbe@0 1326
jbe@389 1327 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 1328
jbe@207 1329 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 1330 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
jbe@0 1331 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
jbe@0 1332
jbe@0 1333
jbe@113 1334 CREATE TABLE "non_voter" (
jbe@528 1335 PRIMARY KEY ("member_id", "issue_id"),
jbe@528 1336 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@528 1337 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@528 1338 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
jbe@113 1339
jbe@113 1340 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
jbe@113 1341
jbe@113 1342
jbe@0 1343 CREATE TABLE "direct_voter" (
jbe@0 1344 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1345 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1346 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@285 1347 "weight" INT4,
jbe@285 1348 "comment_changed" TIMESTAMPTZ,
jbe@285 1349 "formatting_engine" TEXT,
jbe@285 1350 "comment" TEXT,
jbe@285 1351 "text_search_data" TSVECTOR );
jbe@0 1352 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
jbe@285 1353 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
jbe@285 1354 CREATE TRIGGER "update_text_search_data"
jbe@285 1355 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@285 1356 FOR EACH ROW EXECUTE PROCEDURE
jbe@285 1357 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
jbe@0 1358
jbe@389 1359 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 1360
jbe@285 1361 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
jbe@285 1362 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 1363 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 1364 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 1365
jbe@285 1366
jbe@285 1367 CREATE TABLE "rendered_voter_comment" (
jbe@285 1368 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@285 1369 FOREIGN KEY ("issue_id", "member_id")
jbe@285 1370 REFERENCES "direct_voter" ("issue_id", "member_id")
jbe@285 1371 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@285 1372 "issue_id" INT4,
jbe@285 1373 "member_id" INT4,
jbe@285 1374 "format" TEXT,
jbe@285 1375 "content" TEXT NOT NULL );
jbe@285 1376
jbe@285 1377 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 1378
jbe@0 1379
jbe@0 1380 CREATE TABLE "delegating_voter" (
jbe@0 1381 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1382 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1383 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 1384 "weight" INT4,
jbe@10 1385 "scope" "delegation_scope" NOT NULL,
jbe@0 1386 "delegate_member_ids" INT4[] NOT NULL );
jbe@52 1387 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
jbe@0 1388
jbe@389 1389 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 1390
jbe@0 1391 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
jbe@8 1392 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
jbe@0 1393 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 1394
jbe@0 1395
jbe@0 1396 CREATE TABLE "vote" (
jbe@0 1397 "issue_id" INT4 NOT NULL,
jbe@0 1398 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1399 "initiative_id" INT4,
jbe@0 1400 "member_id" INT4,
jbe@414 1401 "grade" INT4 NOT NULL,
jbe@414 1402 "first_preference" BOOLEAN,
jbe@0 1403 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@414 1404 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@414 1405 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
jbe@414 1406 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
jbe@0 1407 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
jbe@0 1408
jbe@389 1409 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 1410
jbe@414 1411 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 1412 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 1413 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 1414
jbe@0 1415
jbe@588 1416 CREATE TABLE "posting" (
jbe@588 1417 "id" SERIAL8 PRIMARY KEY,
jbe@588 1418 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@588 1419 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@588 1420 "message" TEXT NOT NULL,
jbe@588 1421 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@588 1422 "area_id" INT4,
jbe@588 1423 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@588 1424 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@588 1425 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@588 1426 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@588 1427 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@588 1428 "initiative_id" INT4,
jbe@588 1429 "suggestion_id" INT8,
jbe@588 1430 -- NOTE: no referential integrity for suggestions because those are
jbe@588 1431 -- actually deleted
jbe@588 1432 -- FOREIGN KEY ("initiative_id", "suggestion_id")
jbe@588 1433 -- REFERENCES "suggestion" ("initiative_id", "id")
jbe@588 1434 -- ON DELETE CASCADE ON UPDATE CASCADE,
jbe@588 1435 CONSTRAINT "area_requires_unit" CHECK (
jbe@588 1436 "area_id" ISNULL OR "unit_id" NOTNULL ),
jbe@588 1437 CONSTRAINT "policy_set_when_issue_set" CHECK (
jbe@588 1438 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
jbe@588 1439 CONSTRAINT "issue_requires_area" CHECK (
jbe@588 1440 "issue_id" ISNULL OR "area_id" NOTNULL ),
jbe@588 1441 CONSTRAINT "initiative_requires_issue" CHECK (
jbe@588 1442 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
jbe@588 1443 CONSTRAINT "suggestion_requires_initiative" CHECK (
jbe@588 1444 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
jbe@588 1445 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
jbe@588 1446 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
jbe@588 1447 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
jbe@588 1448 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
jbe@588 1449 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
jbe@588 1450 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
jbe@588 1451 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
jbe@588 1452
jbe@588 1453 COMMENT ON TABLE "posting" IS 'Text postings of members; a text posting may optionally be associated to a unit, area, policy, issue, initiative, or suggestion';
jbe@588 1454
jbe@588 1455
jbe@112 1456 CREATE TYPE "event_type" AS ENUM (
jbe@536 1457 'unit_created',
jbe@536 1458 'unit_updated',
jbe@539 1459 'area_created',
jbe@539 1460 'area_updated',
jbe@536 1461 'policy_created',
jbe@536 1462 'policy_updated',
jbe@112 1463 'issue_state_changed',
jbe@112 1464 'initiative_created_in_new_issue',
jbe@112 1465 'initiative_created_in_existing_issue',
jbe@112 1466 'initiative_revoked',
jbe@112 1467 'new_draft_created',
jbe@532 1468 'suggestion_created',
jbe@554 1469 'suggestion_deleted',
jbe@532 1470 'member_activated',
jbe@554 1471 'member_deleted',
jbe@532 1472 'member_active',
jbe@532 1473 'member_name_updated',
jbe@532 1474 'member_profile_updated',
jbe@532 1475 'member_image_updated',
jbe@532 1476 'interest',
jbe@532 1477 'initiator',
jbe@532 1478 'support',
jbe@532 1479 'support_updated',
jbe@532 1480 'suggestion_rated',
jbe@532 1481 'delegation',
jbe@588 1482 'contact',
jbe@588 1483 'posting_created' );
jbe@112 1484
jbe@112 1485 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
jbe@112 1486
jbe@112 1487
jbe@112 1488 CREATE TABLE "event" (
jbe@112 1489 "id" SERIAL8 PRIMARY KEY,
jbe@112 1490 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@112 1491 "event" "event_type" NOT NULL,
jbe@588 1492 "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@112 1493 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@532 1494 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@532 1495 "scope" "delegation_scope",
jbe@532 1496 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1497 "area_id" INT4,
jbe@532 1498 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@536 1499 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1500 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1501 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@536 1502 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@328 1503 "state" "issue_state",
jbe@112 1504 "initiative_id" INT4,
jbe@112 1505 "draft_id" INT8,
jbe@112 1506 "suggestion_id" INT8,
jbe@532 1507 "boolean_value" BOOLEAN,
jbe@532 1508 "numeric_value" INT4,
jbe@532 1509 "text_value" TEXT,
jbe@532 1510 "old_text_value" TEXT,
jbe@112 1511 FOREIGN KEY ("issue_id", "initiative_id")
jbe@112 1512 REFERENCES "initiative" ("issue_id", "id")
jbe@112 1513 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1514 FOREIGN KEY ("initiative_id", "draft_id")
jbe@112 1515 REFERENCES "draft" ("initiative_id", "id")
jbe@112 1516 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1517 -- NOTE: no referential integrity for suggestions because those are
jbe@532 1518 -- actually deleted
jbe@532 1519 -- FOREIGN KEY ("initiative_id", "suggestion_id")
jbe@532 1520 -- REFERENCES "suggestion" ("initiative_id", "id")
jbe@532 1521 -- ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 1522 CONSTRAINT "constr_for_issue_state_changed" CHECK (
jbe@112 1523 "event" != 'issue_state_changed' OR (
jbe@588 1524 "posting_id" ISNULL AND
jbe@532 1525 "member_id" ISNULL AND
jbe@532 1526 "other_member_id" ISNULL AND
jbe@532 1527 "scope" ISNULL AND
jbe@532 1528 "unit_id" NOTNULL AND
jbe@532 1529 "area_id" NOTNULL AND
jbe@536 1530 "policy_id" NOTNULL AND
jbe@532 1531 "issue_id" NOTNULL AND
jbe@532 1532 "state" NOTNULL AND
jbe@532 1533 "initiative_id" ISNULL AND
jbe@532 1534 "draft_id" ISNULL AND
jbe@532 1535 "suggestion_id" ISNULL AND
jbe@532 1536 "boolean_value" ISNULL AND
jbe@532 1537 "numeric_value" ISNULL AND
jbe@532 1538 "text_value" ISNULL AND
jbe@532 1539 "old_text_value" ISNULL )),
jbe@532 1540 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
jbe@112 1541 "event" NOT IN (
jbe@112 1542 'initiative_created_in_new_issue',
jbe@112 1543 'initiative_created_in_existing_issue',
jbe@112 1544 'initiative_revoked',
jbe@112 1545 'new_draft_created'
jbe@112 1546 ) OR (
jbe@588 1547 "posting_id" ISNULL AND
jbe@532 1548 "member_id" NOTNULL AND
jbe@532 1549 "other_member_id" ISNULL AND
jbe@532 1550 "scope" ISNULL AND
jbe@532 1551 "unit_id" NOTNULL AND
jbe@532 1552 "area_id" NOTNULL AND
jbe@536 1553 "policy_id" NOTNULL AND
jbe@532 1554 "issue_id" NOTNULL AND
jbe@532 1555 "state" NOTNULL AND
jbe@532 1556 "initiative_id" NOTNULL AND
jbe@532 1557 "draft_id" NOTNULL AND
jbe@532 1558 "suggestion_id" ISNULL AND
jbe@532 1559 "boolean_value" ISNULL AND
jbe@532 1560 "numeric_value" ISNULL AND
jbe@532 1561 "text_value" ISNULL AND
jbe@532 1562 "old_text_value" ISNULL )),
jbe@532 1563 CONSTRAINT "constr_for_suggestion_creation" CHECK (
jbe@112 1564 "event" != 'suggestion_created' OR (
jbe@588 1565 "posting_id" ISNULL AND
jbe@532 1566 "member_id" NOTNULL AND
jbe@532 1567 "other_member_id" ISNULL AND
jbe@532 1568 "scope" ISNULL AND
jbe@532 1569 "unit_id" NOTNULL AND
jbe@532 1570 "area_id" NOTNULL AND
jbe@536 1571 "policy_id" NOTNULL AND
jbe@532 1572 "issue_id" NOTNULL AND
jbe@532 1573 "state" NOTNULL AND
jbe@532 1574 "initiative_id" NOTNULL AND
jbe@532 1575 "draft_id" ISNULL AND
jbe@532 1576 "suggestion_id" NOTNULL AND
jbe@532 1577 "boolean_value" ISNULL AND
jbe@532 1578 "numeric_value" ISNULL AND
jbe@532 1579 "text_value" ISNULL AND
jbe@532 1580 "old_text_value" ISNULL )),
jbe@532 1581 CONSTRAINT "constr_for_suggestion_removal" CHECK (
jbe@554 1582 "event" != 'suggestion_deleted' OR (
jbe@588 1583 "posting_id" ISNULL AND
jbe@532 1584 "member_id" ISNULL AND
jbe@532 1585 "other_member_id" ISNULL AND
jbe@532 1586 "scope" ISNULL AND
jbe@532 1587 "unit_id" NOTNULL AND
jbe@532 1588 "area_id" NOTNULL AND
jbe@536 1589 "policy_id" NOTNULL AND
jbe@532 1590 "issue_id" NOTNULL AND
jbe@532 1591 "state" NOTNULL AND
jbe@532 1592 "initiative_id" NOTNULL AND
jbe@532 1593 "draft_id" ISNULL AND
jbe@532 1594 "suggestion_id" NOTNULL AND
jbe@532 1595 "boolean_value" ISNULL AND
jbe@532 1596 "numeric_value" ISNULL AND
jbe@532 1597 "text_value" ISNULL AND
jbe@532 1598 "old_text_value" ISNULL )),
jbe@532 1599 CONSTRAINT "constr_for_value_less_member_event" CHECK (
jbe@532 1600 "event" NOT IN (
jbe@532 1601 'member_activated',
jbe@554 1602 'member_deleted',
jbe@532 1603 'member_profile_updated',
jbe@532 1604 'member_image_updated'
jbe@532 1605 ) OR (
jbe@588 1606 "posting_id" ISNULL AND
jbe@532 1607 "member_id" NOTNULL AND
jbe@532 1608 "other_member_id" ISNULL AND
jbe@532 1609 "scope" ISNULL AND
jbe@532 1610 "unit_id" ISNULL AND
jbe@532 1611 "area_id" ISNULL AND
jbe@536 1612 "policy_id" ISNULL AND
jbe@532 1613 "issue_id" ISNULL AND
jbe@532 1614 "state" ISNULL AND
jbe@532 1615 "initiative_id" ISNULL AND
jbe@532 1616 "draft_id" ISNULL AND
jbe@532 1617 "suggestion_id" ISNULL AND
jbe@532 1618 "boolean_value" ISNULL AND
jbe@532 1619 "numeric_value" ISNULL AND
jbe@532 1620 "text_value" ISNULL AND
jbe@532 1621 "old_text_value" ISNULL )),
jbe@532 1622 CONSTRAINT "constr_for_member_active" CHECK (
jbe@532 1623 "event" != 'member_active' OR (
jbe@588 1624 "posting_id" ISNULL AND
jbe@532 1625 "member_id" NOTNULL AND
jbe@532 1626 "other_member_id" ISNULL AND
jbe@532 1627 "scope" ISNULL AND
jbe@532 1628 "unit_id" ISNULL AND
jbe@532 1629 "area_id" ISNULL AND
jbe@536 1630 "policy_id" ISNULL AND
jbe@532 1631 "issue_id" ISNULL AND
jbe@532 1632 "state" ISNULL AND
jbe@532 1633 "initiative_id" ISNULL AND
jbe@532 1634 "draft_id" ISNULL AND
jbe@532 1635 "suggestion_id" ISNULL AND
jbe@532 1636 "boolean_value" NOTNULL AND
jbe@532 1637 "numeric_value" ISNULL AND
jbe@532 1638 "text_value" ISNULL AND
jbe@532 1639 "old_text_value" ISNULL )),
jbe@532 1640 CONSTRAINT "constr_for_member_name_updated" CHECK (
jbe@532 1641 "event" != 'member_name_updated' OR (
jbe@588 1642 "posting_id" ISNULL AND
jbe@532 1643 "member_id" NOTNULL AND
jbe@532 1644 "other_member_id" ISNULL AND
jbe@532 1645 "scope" ISNULL AND
jbe@532 1646 "unit_id" ISNULL AND
jbe@532 1647 "area_id" ISNULL AND
jbe@536 1648 "policy_id" ISNULL AND
jbe@532 1649 "issue_id" ISNULL AND
jbe@532 1650 "state" ISNULL AND
jbe@532 1651 "initiative_id" ISNULL AND
jbe@532 1652 "draft_id" ISNULL AND
jbe@532 1653 "suggestion_id" ISNULL AND
jbe@532 1654 "boolean_value" ISNULL AND
jbe@532 1655 "numeric_value" ISNULL AND
jbe@532 1656 "text_value" NOTNULL AND
jbe@532 1657 "old_text_value" NOTNULL )),
jbe@532 1658 CONSTRAINT "constr_for_interest" CHECK (
jbe@532 1659 "event" != 'interest' OR (
jbe@588 1660 "posting_id" ISNULL AND
jbe@532 1661 "member_id" NOTNULL AND
jbe@532 1662 "other_member_id" ISNULL AND
jbe@532 1663 "scope" ISNULL AND
jbe@532 1664 "unit_id" NOTNULL AND
jbe@532 1665 "area_id" NOTNULL AND
jbe@536 1666 "policy_id" NOTNULL AND
jbe@532 1667 "issue_id" NOTNULL AND
jbe@532 1668 "state" NOTNULL AND
jbe@532 1669 "initiative_id" ISNULL AND
jbe@532 1670 "draft_id" ISNULL AND
jbe@532 1671 "suggestion_id" ISNULL AND
jbe@532 1672 "boolean_value" NOTNULL AND
jbe@532 1673 "numeric_value" ISNULL AND
jbe@532 1674 "text_value" ISNULL AND
jbe@532 1675 "old_text_value" ISNULL )),
jbe@532 1676 CONSTRAINT "constr_for_initiator" CHECK (
jbe@532 1677 "event" != 'initiator' OR (
jbe@588 1678 "posting_id" ISNULL AND
jbe@532 1679 "member_id" NOTNULL AND
jbe@532 1680 "other_member_id" ISNULL AND
jbe@532 1681 "scope" ISNULL AND
jbe@532 1682 "unit_id" NOTNULL AND
jbe@532 1683 "area_id" NOTNULL AND
jbe@536 1684 "policy_id" NOTNULL AND
jbe@532 1685 "issue_id" NOTNULL AND
jbe@532 1686 "state" NOTNULL AND
jbe@532 1687 "initiative_id" NOTNULL AND
jbe@532 1688 "draft_id" ISNULL AND
jbe@532 1689 "suggestion_id" ISNULL AND
jbe@532 1690 "boolean_value" NOTNULL AND
jbe@532 1691 "numeric_value" ISNULL AND
jbe@532 1692 "text_value" ISNULL AND
jbe@532 1693 "old_text_value" ISNULL )),
jbe@532 1694 CONSTRAINT "constr_for_support" CHECK (
jbe@532 1695 "event" != 'support' OR (
jbe@588 1696 "posting_id" ISNULL AND
jbe@532 1697 "member_id" NOTNULL AND
jbe@532 1698 "other_member_id" ISNULL AND
jbe@532 1699 "scope" ISNULL AND
jbe@532 1700 "unit_id" NOTNULL AND
jbe@532 1701 "area_id" NOTNULL AND
jbe@536 1702 "policy_id" NOTNULL AND
jbe@532 1703 "issue_id" NOTNULL AND
jbe@532 1704 "state" NOTNULL AND
jbe@532 1705 "initiative_id" NOTNULL AND
jbe@532 1706 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
jbe@532 1707 "suggestion_id" ISNULL AND
jbe@532 1708 "boolean_value" NOTNULL AND
jbe@532 1709 "numeric_value" ISNULL AND
jbe@532 1710 "text_value" ISNULL AND
jbe@532 1711 "old_text_value" ISNULL )),
jbe@532 1712 CONSTRAINT "constr_for_support_updated" CHECK (
jbe@532 1713 "event" != 'support_updated' OR (
jbe@588 1714 "posting_id" ISNULL AND
jbe@532 1715 "member_id" NOTNULL AND
jbe@532 1716 "other_member_id" ISNULL AND
jbe@532 1717 "scope" ISNULL AND
jbe@532 1718 "unit_id" NOTNULL AND
jbe@532 1719 "area_id" NOTNULL AND
jbe@536 1720 "policy_id" NOTNULL AND
jbe@532 1721 "issue_id" NOTNULL AND
jbe@532 1722 "state" NOTNULL AND
jbe@532 1723 "initiative_id" NOTNULL AND
jbe@532 1724 "draft_id" NOTNULL AND
jbe@532 1725 "suggestion_id" ISNULL AND
jbe@532 1726 "boolean_value" ISNULL AND
jbe@532 1727 "numeric_value" ISNULL AND
jbe@532 1728 "text_value" ISNULL AND
jbe@532 1729 "old_text_value" ISNULL )),
jbe@532 1730 CONSTRAINT "constr_for_suggestion_rated" CHECK (
jbe@532 1731 "event" != 'suggestion_rated' OR (
jbe@588 1732 "posting_id" ISNULL AND
jbe@532 1733 "member_id" NOTNULL AND
jbe@532 1734 "other_member_id" ISNULL AND
jbe@532 1735 "scope" ISNULL AND
jbe@532 1736 "unit_id" NOTNULL AND
jbe@532 1737 "area_id" NOTNULL AND
jbe@536 1738 "policy_id" NOTNULL AND
jbe@532 1739 "issue_id" NOTNULL AND
jbe@532 1740 "state" NOTNULL AND
jbe@532 1741 "initiative_id" NOTNULL AND
jbe@532 1742 "draft_id" ISNULL AND
jbe@532 1743 "suggestion_id" NOTNULL AND
jbe@532 1744 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
jbe@532 1745 "numeric_value" NOTNULL AND
jbe@532 1746 "numeric_value" IN (-2, -1, 0, 1, 2) AND
jbe@532 1747 "text_value" ISNULL AND
jbe@532 1748 "old_text_value" ISNULL )),
jbe@532 1749 CONSTRAINT "constr_for_delegation" CHECK (
jbe@532 1750 "event" != 'delegation' OR (
jbe@588 1751 "posting_id" ISNULL AND
jbe@532 1752 "member_id" NOTNULL AND
bsw@564 1753 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
jbe@532 1754 "scope" NOTNULL AND
jbe@532 1755 "unit_id" NOTNULL AND
jbe@532 1756 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
jbe@536 1757 "policy_id" ISNULL AND
jbe@532 1758 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
jbe@532 1759 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
jbe@532 1760 "initiative_id" ISNULL AND
jbe@532 1761 "draft_id" ISNULL AND
jbe@532 1762 "suggestion_id" ISNULL AND
jbe@532 1763 "boolean_value" NOTNULL AND
jbe@532 1764 "numeric_value" ISNULL AND
jbe@532 1765 "text_value" ISNULL AND
jbe@532 1766 "old_text_value" ISNULL )),
jbe@532 1767 CONSTRAINT "constr_for_contact" CHECK (
jbe@532 1768 "event" != 'contact' OR (
jbe@588 1769 "posting_id" ISNULL AND
jbe@532 1770 "member_id" NOTNULL AND
jbe@532 1771 "other_member_id" NOTNULL AND
jbe@532 1772 "scope" ISNULL AND
jbe@532 1773 "unit_id" ISNULL AND
jbe@532 1774 "area_id" ISNULL AND
jbe@536 1775 "policy_id" ISNULL AND
jbe@532 1776 "issue_id" ISNULL AND
jbe@532 1777 "state" ISNULL AND
jbe@532 1778 "initiative_id" ISNULL AND
jbe@532 1779 "draft_id" ISNULL AND
jbe@532 1780 "suggestion_id" ISNULL AND
jbe@532 1781 "boolean_value" NOTNULL AND
jbe@532 1782 "numeric_value" ISNULL AND
jbe@532 1783 "text_value" ISNULL AND
jbe@588 1784 "old_text_value" ISNULL )),
jbe@588 1785 CONSTRAINT "constr_for_posting_created" CHECK (
jbe@588 1786 "event" != 'posting_created' OR (
jbe@588 1787 "posting_id" NOTNULL AND
jbe@588 1788 "member_id" NOTNULL AND
jbe@588 1789 "other_member_id" ISNULL AND
jbe@588 1790 "scope" ISNULL AND
jbe@588 1791 "state" ISNULL AND
jbe@588 1792 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
jbe@588 1793 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
jbe@588 1794 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
jbe@588 1795 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
jbe@588 1796 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
jbe@588 1797 "draft_id" ISNULL AND
jbe@588 1798 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
jbe@588 1799 "boolean_value" ISNULL AND
jbe@588 1800 "numeric_value" ISNULL AND
jbe@588 1801 "text_value" ISNULL AND
jbe@532 1802 "old_text_value" ISNULL )) );
jbe@223 1803 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
jbe@588 1804 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
jbe@588 1805 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
jbe@588 1806 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
jbe@588 1807 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
jbe@588 1808 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
jbe@588 1809 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
jbe@588 1810 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
jbe@588 1811
jbe@112 1812
jbe@112 1813 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
jbe@112 1814
jbe@114 1815 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
jbe@114 1816 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
jbe@114 1817 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
jbe@114 1818 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
jbe@114 1819
jbe@112 1820
jbe@534 1821 CREATE TABLE "event_processed" (
jbe@222 1822 "event_id" INT8 NOT NULL );
jbe@534 1823 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
jbe@534 1824
jbe@534 1825 COMMENT ON TABLE "event_processed" IS 'This table stores one row with the last event_id, for which event handlers have been executed (e.g. notifications having been sent out)';
jbe@534 1826 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
jbe@507 1827
jbe@507 1828
jbe@507 1829 CREATE TABLE "notification_initiative_sent" (
jbe@486 1830 PRIMARY KEY ("member_id", "initiative_id"),
jbe@486 1831 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@486 1832 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@486 1833 "last_draft_id" INT8 NOT NULL,
jbe@495 1834 "last_suggestion_id" INT8 );
jbe@507 1835 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
jbe@486 1836
jbe@508 1837 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
jbe@508 1838
jbe@508 1839 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
jbe@508 1840 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
jbe@508 1841
jbe@486 1842
jbe@496 1843 CREATE TABLE "newsletter" (
jbe@496 1844 "id" SERIAL4 PRIMARY KEY,
jbe@496 1845 "published" TIMESTAMPTZ NOT NULL,
jbe@496 1846 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@496 1847 "include_all_members" BOOLEAN NOT NULL,
jbe@496 1848 "sent" TIMESTAMPTZ,
jbe@496 1849 "subject" TEXT NOT NULL,
jbe@496 1850 "content" TEXT NOT NULL );
jbe@496 1851 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
jbe@496 1852 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
jbe@496 1853 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
jbe@496 1854
jbe@508 1855 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
jbe@508 1856
jbe@508 1857 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
jbe@508 1858 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
jbe@508 1859 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
jbe@508 1860 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
jbe@508 1861 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
jbe@508 1862 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
jbe@222 1863
jbe@222 1864
jbe@112 1865
jbe@112 1866 ----------------------------------------------
jbe@112 1867 -- Writing of history entries and event log --
jbe@112 1868 ----------------------------------------------
jbe@13 1869
jbe@181 1870
jbe@13 1871 CREATE FUNCTION "write_member_history_trigger"()
jbe@13 1872 RETURNS TRIGGER
jbe@13 1873 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@13 1874 BEGIN
jbe@42 1875 IF
jbe@230 1876 ( NEW."active" != OLD."active" OR
jbe@230 1877 NEW."name" != OLD."name" ) AND
jbe@230 1878 OLD."activated" NOTNULL
jbe@42 1879 THEN
jbe@42 1880 INSERT INTO "member_history"
jbe@57 1881 ("member_id", "active", "name")
jbe@57 1882 VALUES (NEW."id", OLD."active", OLD."name");
jbe@13 1883 END IF;
jbe@13 1884 RETURN NULL;
jbe@13 1885 END;
jbe@13 1886 $$;
jbe@13 1887
jbe@13 1888 CREATE TRIGGER "write_member_history"
jbe@13 1889 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@13 1890 "write_member_history_trigger"();
jbe@13 1891
jbe@13 1892 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
jbe@57 1893 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 1894
jbe@13 1895
jbe@537 1896 CREATE FUNCTION "write_event_unit_trigger"()
jbe@537 1897 RETURNS TRIGGER
jbe@537 1898 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@538 1899 DECLARE
jbe@538 1900 "event_v" "event_type";
jbe@537 1901 BEGIN
jbe@538 1902 IF TG_OP = 'UPDATE' THEN
jbe@538 1903 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
jbe@538 1904 RETURN NULL;
jbe@547 1905 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
jbe@547 1906 -- "event_v" := 'unit_created';
jbe@547 1907 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
jbe@554 1908 -- "event_v" := 'unit_deleted';
jbe@546 1909 ELSIF OLD != NEW THEN
jbe@546 1910 "event_v" := 'unit_updated';
jbe@538 1911 ELSE
jbe@546 1912 RETURN NULL;
jbe@538 1913 END IF;
jbe@538 1914 ELSE
jbe@538 1915 "event_v" := 'unit_created';
jbe@538 1916 END IF;
jbe@538 1917 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
jbe@537 1918 RETURN NULL;
jbe@537 1919 END;
jbe@537 1920 $$;
jbe@537 1921
jbe@537 1922 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
jbe@537 1923 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
jbe@537 1924
jbe@537 1925 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
jbe@537 1926 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
jbe@537 1927
jbe@537 1928
jbe@537 1929 CREATE FUNCTION "write_event_area_trigger"()
jbe@537 1930 RETURNS TRIGGER
jbe@537 1931 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@538 1932 DECLARE
jbe@538 1933 "event_v" "event_type";
jbe@537 1934 BEGIN
jbe@538 1935 IF TG_OP = 'UPDATE' THEN
jbe@538 1936 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
jbe@538 1937 RETURN NULL;
jbe@547 1938 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
jbe@547 1939 -- "event_v" := 'area_created';
jbe@547 1940 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
jbe@554 1941 -- "event_v" := 'area_deleted';
jbe@546 1942 ELSIF OLD != NEW THEN
jbe@546 1943 "event_v" := 'area_updated';
jbe@538 1944 ELSE
jbe@546 1945 RETURN NULL;
jbe@538 1946 END IF;
jbe@538 1947 ELSE
jbe@538 1948 "event_v" := 'area_created';
jbe@538 1949 END IF;
jbe@538 1950 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
jbe@537 1951 RETURN NULL;
jbe@537 1952 END;
jbe@537 1953 $$;
jbe@537 1954
jbe@537 1955 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
jbe@537 1956 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
jbe@537 1957
jbe@537 1958 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
jbe@537 1959 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
jbe@537 1960
jbe@537 1961
jbe@537 1962 CREATE FUNCTION "write_event_policy_trigger"()
jbe@537 1963 RETURNS TRIGGER
jbe@537 1964 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@538 1965 DECLARE
jbe@538 1966 "event_v" "event_type";
jbe@537 1967 BEGIN
jbe@538 1968 IF TG_OP = 'UPDATE' THEN
jbe@538 1969 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
jbe@538 1970 RETURN NULL;
jbe@547 1971 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
jbe@547 1972 -- "event_v" := 'policy_created';
jbe@547 1973 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
jbe@554 1974 -- "event_v" := 'policy_deleted';
jbe@546 1975 ELSIF OLD != NEW THEN
jbe@546 1976 "event_v" := 'policy_updated';
jbe@538 1977 ELSE
jbe@546 1978 RETURN NULL;
jbe@538 1979 END IF;
jbe@538 1980 ELSE
jbe@538 1981 "event_v" := 'policy_created';
jbe@538 1982 END IF;
jbe@538 1983 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
jbe@537 1984 RETURN NULL;
jbe@537 1985 END;
jbe@537 1986 $$;
jbe@537 1987
jbe@537 1988 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
jbe@537 1989 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
jbe@537 1990
jbe@537 1991 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
jbe@537 1992 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
jbe@537 1993
jbe@537 1994
jbe@112 1995 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
jbe@112 1996 RETURNS TRIGGER
jbe@112 1997 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1998 DECLARE
jbe@532 1999 "area_row" "area"%ROWTYPE;
jbe@112 2000 BEGIN
jbe@328 2001 IF NEW."state" != OLD."state" THEN
jbe@532 2002 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
jbe@532 2003 FOR SHARE;
jbe@532 2004 INSERT INTO "event" (
jbe@532 2005 "event",
jbe@536 2006 "unit_id", "area_id", "policy_id", "issue_id", "state"
jbe@532 2007 ) VALUES (
jbe@532 2008 'issue_state_changed',
jbe@536 2009 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
jbe@536 2010 NEW."id", NEW."state"
jbe@532 2011 );
jbe@112 2012 END IF;
jbe@112 2013 RETURN NULL;
jbe@112 2014 END;
jbe@112 2015 $$;
jbe@112 2016
jbe@112 2017 CREATE TRIGGER "write_event_issue_state_changed"
jbe@112 2018 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2019 "write_event_issue_state_changed_trigger"();
jbe@112 2020
jbe@112 2021 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
jbe@112 2022 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
jbe@112 2023
jbe@112 2024
jbe@112 2025 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
jbe@112 2026 RETURNS TRIGGER
jbe@112 2027 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 2028 DECLARE
jbe@112 2029 "initiative_row" "initiative"%ROWTYPE;
jbe@113 2030 "issue_row" "issue"%ROWTYPE;
jbe@532 2031 "area_row" "area"%ROWTYPE;
jbe@112 2032 "event_v" "event_type";
jbe@112 2033 BEGIN
jbe@112 2034 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 2035 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@113 2036 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2037 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 2038 SELECT * INTO "area_row" FROM "area"
jbe@532 2039 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@112 2040 IF EXISTS (
jbe@112 2041 SELECT NULL FROM "draft"
jbe@532 2042 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
jbe@532 2043 FOR SHARE
jbe@112 2044 ) THEN
jbe@112 2045 "event_v" := 'new_draft_created';
jbe@112 2046 ELSE
jbe@112 2047 IF EXISTS (
jbe@112 2048 SELECT NULL FROM "initiative"
jbe@112 2049 WHERE "issue_id" = "initiative_row"."issue_id"
jbe@112 2050 AND "id" != "initiative_row"."id"
jbe@532 2051 FOR SHARE
jbe@112 2052 ) THEN
jbe@112 2053 "event_v" := 'initiative_created_in_existing_issue';
jbe@112 2054 ELSE
jbe@112 2055 "event_v" := 'initiative_created_in_new_issue';
jbe@112 2056 END IF;
jbe@112 2057 END IF;
jbe@112 2058 INSERT INTO "event" (
jbe@112 2059 "event", "member_id",
jbe@536 2060 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2061 "initiative_id", "draft_id"
jbe@112 2062 ) VALUES (
jbe@532 2063 "event_v", NEW."author_id",
jbe@536 2064 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
jbe@532 2065 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 2066 NEW."initiative_id", NEW."id"
jbe@532 2067 );
jbe@112 2068 RETURN NULL;
jbe@112 2069 END;
jbe@112 2070 $$;
jbe@112 2071
jbe@112 2072 CREATE TRIGGER "write_event_initiative_or_draft_created"
jbe@112 2073 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2074 "write_event_initiative_or_draft_created_trigger"();
jbe@112 2075
jbe@112 2076 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 2077 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
jbe@112 2078
jbe@112 2079
jbe@112 2080 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
jbe@112 2081 RETURNS TRIGGER
jbe@112 2082 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@113 2083 DECLARE
jbe@231 2084 "issue_row" "issue"%ROWTYPE;
jbe@532 2085 "area_row" "area"%ROWTYPE;
jbe@231 2086 "draft_id_v" "draft"."id"%TYPE;
jbe@112 2087 BEGIN
jbe@112 2088 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
jbe@563 2089 -- NOTE: lock for primary key update to avoid new drafts
jbe@582 2090 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
jbe@231 2091 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2092 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 2093 SELECT * INTO "area_row" FROM "area"
jbe@532 2094 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@563 2095 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
jbe@582 2096 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
jbe@231 2097 SELECT "id" INTO "draft_id_v" FROM "current_draft"
jbe@563 2098 WHERE "initiative_id" = NEW."id";
jbe@112 2099 INSERT INTO "event" (
jbe@532 2100 "event", "member_id",
jbe@536 2101 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2102 "initiative_id", "draft_id"
jbe@112 2103 ) VALUES (
jbe@532 2104 'initiative_revoked', NEW."revoked_by_member_id",
jbe@532 2105 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2106 "issue_row"."policy_id",
jbe@532 2107 NEW."issue_id", "issue_row"."state",
jbe@532 2108 NEW."id", "draft_id_v"
jbe@532 2109 );
jbe@112 2110 END IF;
jbe@112 2111 RETURN NULL;
jbe@112 2112 END;
jbe@112 2113 $$;
jbe@112 2114
jbe@112 2115 CREATE TRIGGER "write_event_initiative_revoked"
jbe@112 2116 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2117 "write_event_initiative_revoked_trigger"();
jbe@112 2118
jbe@112 2119 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
jbe@112 2120 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
jbe@112 2121
jbe@112 2122
jbe@112 2123 CREATE FUNCTION "write_event_suggestion_created_trigger"()
jbe@112 2124 RETURNS TRIGGER
jbe@112 2125 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 2126 DECLARE
jbe@112 2127 "initiative_row" "initiative"%ROWTYPE;
jbe@113 2128 "issue_row" "issue"%ROWTYPE;
jbe@532 2129 "area_row" "area"%ROWTYPE;
jbe@112 2130 BEGIN
jbe@112 2131 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 2132 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@113 2133 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2134 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 2135 SELECT * INTO "area_row" FROM "area"
jbe@532 2136 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@112 2137 INSERT INTO "event" (
jbe@112 2138 "event", "member_id",
jbe@536 2139 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2140 "initiative_id", "suggestion_id"
jbe@112 2141 ) VALUES (
jbe@532 2142 'suggestion_created', NEW."author_id",
jbe@536 2143 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
jbe@532 2144 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 2145 NEW."initiative_id", NEW."id"
jbe@532 2146 );
jbe@112 2147 RETURN NULL;
jbe@112 2148 END;
jbe@112 2149 $$;
jbe@112 2150
jbe@112 2151 CREATE TRIGGER "write_event_suggestion_created"
jbe@112 2152 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 2153 "write_event_suggestion_created_trigger"();
jbe@112 2154
jbe@112 2155 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
jbe@112 2156 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
jbe@112 2157
jbe@112 2158
jbe@532 2159 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
jbe@532 2160 RETURNS TRIGGER
jbe@532 2161 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2162 DECLARE
jbe@532 2163 "initiative_row" "initiative"%ROWTYPE;
jbe@532 2164 "issue_row" "issue"%ROWTYPE;
jbe@532 2165 "area_row" "area"%ROWTYPE;
jbe@532 2166 BEGIN
jbe@532 2167 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 2168 WHERE "id" = OLD."initiative_id" FOR SHARE;
jbe@532 2169 IF "initiative_row"."id" NOTNULL THEN
jbe@532 2170 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2171 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 2172 SELECT * INTO "area_row" FROM "area"
jbe@532 2173 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2174 INSERT INTO "event" (
jbe@532 2175 "event",
jbe@536 2176 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2177 "initiative_id", "suggestion_id"
jbe@532 2178 ) VALUES (
jbe@554 2179 'suggestion_deleted',
jbe@532 2180 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2181 "issue_row"."policy_id",
jbe@532 2182 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 2183 OLD."initiative_id", OLD."id"
jbe@532 2184 );
jbe@532 2185 END IF;
jbe@532 2186 RETURN NULL;
jbe@532 2187 END;
jbe@532 2188 $$;
jbe@532 2189
jbe@532 2190 CREATE TRIGGER "write_event_suggestion_removed"
jbe@532 2191 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2192 "write_event_suggestion_removed_trigger"();
jbe@532 2193
jbe@532 2194 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
jbe@532 2195 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
jbe@532 2196
jbe@532 2197
jbe@532 2198 CREATE FUNCTION "write_event_member_trigger"()
jbe@532 2199 RETURNS TRIGGER
jbe@532 2200 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2201 BEGIN
jbe@532 2202 IF TG_OP = 'INSERT' THEN
jbe@552 2203 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
jbe@532 2204 INSERT INTO "event" ("event", "member_id")
jbe@532 2205 VALUES ('member_activated', NEW."id");
jbe@532 2206 END IF;
jbe@532 2207 IF NEW."active" THEN
jbe@532 2208 INSERT INTO "event" ("event", "member_id", "boolean_value")
jbe@532 2209 VALUES ('member_active', NEW."id", TRUE);
jbe@532 2210 END IF;
jbe@532 2211 ELSIF TG_OP = 'UPDATE' THEN
jbe@532 2212 IF OLD."id" != NEW."id" THEN
jbe@532 2213 RAISE EXCEPTION 'Cannot change member ID';
jbe@532 2214 END IF;
jbe@552 2215 IF
jbe@552 2216 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
jbe@552 2217 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
jbe@552 2218 THEN
jbe@552 2219 INSERT INTO "event" ("event", "member_id")
jbe@552 2220 VALUES ('member_activated', NEW."id");
jbe@552 2221 END IF;
jbe@552 2222 IF OLD."active" != NEW."active" THEN
jbe@552 2223 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
jbe@552 2224 'member_active', NEW."id", NEW."active"
jbe@552 2225 );
jbe@552 2226 END IF;
jbe@532 2227 IF OLD."name" != NEW."name" THEN
jbe@532 2228 INSERT INTO "event" (
jbe@532 2229 "event", "member_id", "text_value", "old_text_value"
jbe@532 2230 ) VALUES (
jbe@532 2231 'member_name_updated', NEW."id", NEW."name", OLD."name"
jbe@532 2232 );
jbe@532 2233 END IF;
jbe@532 2234 IF
jbe@552 2235 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
jbe@552 2236 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
jbe@532 2237 THEN
jbe@532 2238 INSERT INTO "event" ("event", "member_id")
jbe@554 2239 VALUES ('member_deleted', NEW."id");
jbe@532 2240 END IF;
jbe@532 2241 END IF;
jbe@532 2242 RETURN NULL;
jbe@532 2243 END;
jbe@532 2244 $$;
jbe@532 2245
jbe@532 2246 CREATE TRIGGER "write_event_member"
jbe@532 2247 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2248 "write_event_member_trigger"();
jbe@532 2249
jbe@532 2250 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
jbe@532 2251 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
jbe@532 2252
jbe@532 2253
jbe@532 2254 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
jbe@532 2255 RETURNS TRIGGER
jbe@532 2256 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2257 BEGIN
jbe@532 2258 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 2259 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
jbe@532 2260 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 2261 'member_profile_updated', OLD."member_id"
jbe@532 2262 );
jbe@532 2263 END IF;
jbe@532 2264 END IF;
jbe@532 2265 IF TG_OP = 'UPDATE' THEN
jbe@532 2266 IF OLD."member_id" = NEW."member_id" THEN
jbe@532 2267 RETURN NULL;
jbe@532 2268 END IF;
jbe@532 2269 END IF;
jbe@532 2270 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 2271 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 2272 'member_profile_updated', NEW."member_id"
jbe@532 2273 );
jbe@532 2274 END IF;
jbe@532 2275 RETURN NULL;
jbe@532 2276 END;
jbe@532 2277 $$;
jbe@532 2278
jbe@532 2279 CREATE TRIGGER "write_event_member_profile_updated"
jbe@532 2280 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
jbe@532 2281 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2282 "write_event_member_profile_updated_trigger"();
jbe@532 2283
jbe@532 2284 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
jbe@532 2285 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
jbe@532 2286
jbe@532 2287
jbe@532 2288 CREATE FUNCTION "write_event_member_image_updated_trigger"()
jbe@532 2289 RETURNS TRIGGER
jbe@532 2290 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2291 BEGIN
jbe@532 2292 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 2293 IF NOT OLD."scaled" THEN
jbe@532 2294 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
jbe@532 2295 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 2296 'member_image_updated', OLD."member_id"
jbe@532 2297 );
jbe@532 2298 END IF;
jbe@532 2299 END IF;
jbe@532 2300 END IF;
jbe@532 2301 IF TG_OP = 'UPDATE' THEN
jbe@532 2302 IF
jbe@532 2303 OLD."member_id" = NEW."member_id" AND
jbe@532 2304 OLD."scaled" = NEW."scaled"
jbe@532 2305 THEN
jbe@532 2306 RETURN NULL;
jbe@532 2307 END IF;
jbe@532 2308 END IF;
jbe@532 2309 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 2310 IF NOT NEW."scaled" THEN
jbe@532 2311 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 2312 'member_image_updated', NEW."member_id"
jbe@532 2313 );
jbe@532 2314 END IF;
jbe@532 2315 END IF;
jbe@532 2316 RETURN NULL;
jbe@532 2317 END;
jbe@532 2318 $$;
jbe@532 2319
jbe@532 2320 CREATE TRIGGER "write_event_member_image_updated"
jbe@532 2321 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
jbe@532 2322 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2323 "write_event_member_image_updated_trigger"();
jbe@532 2324
jbe@532 2325 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
jbe@532 2326 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
jbe@532 2327
jbe@532 2328
jbe@532 2329 CREATE FUNCTION "write_event_interest_trigger"()
jbe@532 2330 RETURNS TRIGGER
jbe@532 2331 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2332 DECLARE
jbe@532 2333 "issue_row" "issue"%ROWTYPE;
jbe@532 2334 "area_row" "area"%ROWTYPE;
jbe@532 2335 BEGIN
jbe@532 2336 IF TG_OP = 'UPDATE' THEN
jbe@532 2337 IF OLD = NEW THEN
jbe@532 2338 RETURN NULL;
jbe@532 2339 END IF;
jbe@532 2340 END IF;
jbe@532 2341 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 2342 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2343 WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@532 2344 SELECT * INTO "area_row" FROM "area"
jbe@532 2345 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2346 IF "issue_row"."id" NOTNULL THEN
jbe@532 2347 INSERT INTO "event" (
jbe@532 2348 "event", "member_id",
jbe@536 2349 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2350 "boolean_value"
jbe@532 2351 ) VALUES (
jbe@532 2352 'interest', OLD."member_id",
jbe@532 2353 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2354 "issue_row"."policy_id",
jbe@532 2355 OLD."issue_id", "issue_row"."state",
jbe@532 2356 FALSE
jbe@532 2357 );
jbe@532 2358 END IF;
jbe@532 2359 END IF;
jbe@532 2360 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 2361 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2362 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 2363 SELECT * INTO "area_row" FROM "area"
jbe@532 2364 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2365 INSERT INTO "event" (
jbe@532 2366 "event", "member_id",
jbe@536 2367 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2368 "boolean_value"
jbe@532 2369 ) VALUES (
jbe@532 2370 'interest', NEW."member_id",
jbe@532 2371 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2372 "issue_row"."policy_id",
jbe@532 2373 NEW."issue_id", "issue_row"."state",
jbe@532 2374 TRUE
jbe@532 2375 );
jbe@532 2376 END IF;
jbe@532 2377 RETURN NULL;
jbe@532 2378 END;
jbe@532 2379 $$;
jbe@532 2380
jbe@532 2381 CREATE TRIGGER "write_event_interest"
jbe@532 2382 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2383 "write_event_interest_trigger"();
jbe@532 2384
jbe@532 2385 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
jbe@532 2386 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
jbe@532 2387
jbe@532 2388
jbe@532 2389 CREATE FUNCTION "write_event_initiator_trigger"()
jbe@532 2390 RETURNS TRIGGER
jbe@532 2391 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2392 DECLARE
jbe@532 2393 "initiative_row" "initiative"%ROWTYPE;
jbe@532 2394 "issue_row" "issue"%ROWTYPE;
jbe@532 2395 "area_row" "area"%ROWTYPE;
jbe@549 2396 "accepted_v" BOOLEAN = FALSE;
jbe@549 2397 "rejected_v" BOOLEAN = FALSE;
jbe@532 2398 BEGIN
jbe@532 2399 IF TG_OP = 'UPDATE' THEN
jbe@532 2400 IF
jbe@532 2401 OLD."initiative_id" = NEW."initiative_id" AND
jbe@549 2402 OLD."member_id" = NEW."member_id"
jbe@532 2403 THEN
jbe@549 2404 IF
jbe@549 2405 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
jbe@549 2406 THEN
jbe@549 2407 RETURN NULL;
jbe@549 2408 END IF;
jbe@549 2409 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
jbe@549 2410 "accepted_v" := TRUE;
jbe@549 2411 ELSE
jbe@549 2412 "rejected_v" := TRUE;
jbe@549 2413 END IF;
jbe@532 2414 END IF;
jbe@532 2415 END IF;
jbe@532 2416 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
jbe@532 2417 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
jbe@532 2418 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 2419 WHERE "id" = OLD."initiative_id" FOR SHARE;
jbe@532 2420 IF "initiative_row"."id" NOTNULL THEN
jbe@532 2421 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2422 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 2423 SELECT * INTO "area_row" FROM "area"
jbe@532 2424 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2425 INSERT INTO "event" (
jbe@532 2426 "event", "member_id",
jbe@536 2427 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2428 "initiative_id", "boolean_value"
jbe@532 2429 ) VALUES (
jbe@532 2430 'initiator', OLD."member_id",
jbe@532 2431 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2432 "issue_row"."policy_id",
jbe@532 2433 "issue_row"."id", "issue_row"."state",
jbe@532 2434 OLD."initiative_id", FALSE
jbe@532 2435 );
jbe@532 2436 END IF;
jbe@532 2437 END IF;
jbe@532 2438 END IF;
jbe@532 2439 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
jbe@532 2440 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
jbe@532 2441 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 2442 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@532 2443 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2444 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 2445 SELECT * INTO "area_row" FROM "area"
jbe@532 2446 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2447 INSERT INTO "event" (
jbe@532 2448 "event", "member_id",
jbe@536 2449 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2450 "initiative_id", "boolean_value"
jbe@532 2451 ) VALUES (
jbe@532 2452 'initiator', NEW."member_id",
jbe@532 2453 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2454 "issue_row"."policy_id",
jbe@532 2455 "issue_row"."id", "issue_row"."state",
jbe@532 2456 NEW."initiative_id", TRUE
jbe@532 2457 );
jbe@532 2458 END IF;
jbe@532 2459 END IF;
jbe@532 2460 RETURN NULL;
jbe@532 2461 END;
jbe@532 2462 $$;
jbe@532 2463
jbe@532 2464 CREATE TRIGGER "write_event_initiator"
jbe@532 2465 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2466 "write_event_initiator_trigger"();
jbe@532 2467
jbe@532 2468 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
jbe@532 2469 COMMENT ON TRIGGER "write_event_initiator" ON "initiator" IS 'Create entry in "event" table when accepting or removing initiatorship (NOTE: trigger does not fire on INSERT to avoid events on initiative creation)';
jbe@532 2470
jbe@532 2471
jbe@532 2472 CREATE FUNCTION "write_event_support_trigger"()
jbe@532 2473 RETURNS TRIGGER
jbe@532 2474 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2475 DECLARE
jbe@532 2476 "issue_row" "issue"%ROWTYPE;
jbe@532 2477 "area_row" "area"%ROWTYPE;
jbe@532 2478 BEGIN
jbe@532 2479 IF TG_OP = 'UPDATE' THEN
jbe@532 2480 IF
jbe@532 2481 OLD."initiative_id" = NEW."initiative_id" AND
jbe@532 2482 OLD."member_id" = NEW."member_id"
jbe@532 2483 THEN
jbe@532 2484 IF OLD."draft_id" != NEW."draft_id" THEN
jbe@532 2485 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2486 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 2487 SELECT * INTO "area_row" FROM "area"
jbe@532 2488 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2489 INSERT INTO "event" (
jbe@532 2490 "event", "member_id",
jbe@536 2491 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2492 "initiative_id", "draft_id"
jbe@532 2493 ) VALUES (
jbe@532 2494 'support_updated', NEW."member_id",
jbe@532 2495 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2496 "issue_row"."policy_id",
jbe@532 2497 "issue_row"."id", "issue_row"."state",
jbe@532 2498 NEW."initiative_id", NEW."draft_id"
jbe@532 2499 );
jbe@532 2500 END IF;
jbe@532 2501 RETURN NULL;
jbe@532 2502 END IF;
jbe@532 2503 END IF;
jbe@532 2504 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 2505 IF EXISTS (
jbe@532 2506 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
jbe@532 2507 FOR SHARE
jbe@532 2508 ) THEN
jbe@532 2509 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2510 WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@532 2511 SELECT * INTO "area_row" FROM "area"
jbe@532 2512 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2513 INSERT INTO "event" (
jbe@532 2514 "event", "member_id",
jbe@536 2515 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@535 2516 "initiative_id", "boolean_value"
jbe@532 2517 ) VALUES (
jbe@532 2518 'support', OLD."member_id",
jbe@532 2519 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2520 "issue_row"."policy_id",
jbe@532 2521 "issue_row"."id", "issue_row"."state",
jbe@535 2522 OLD."initiative_id", FALSE
jbe@532 2523 );
jbe@532 2524 END IF;
jbe@532 2525 END IF;
jbe@532 2526 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 2527 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2528 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 2529 SELECT * INTO "area_row" FROM "area"
jbe@532 2530 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2531 INSERT INTO "event" (
jbe@532 2532 "event", "member_id",
jbe@536 2533 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2534 "initiative_id", "draft_id", "boolean_value"
jbe@532 2535 ) VALUES (
jbe@532 2536 'support', NEW."member_id",
jbe@532 2537 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2538 "issue_row"."policy_id",
jbe@532 2539 "issue_row"."id", "issue_row"."state",
jbe@532 2540 NEW."initiative_id", NEW."draft_id", TRUE
jbe@532 2541 );
jbe@532 2542 END IF;
jbe@532 2543 RETURN NULL;
jbe@532 2544 END;
jbe@532 2545 $$;
jbe@532 2546
jbe@532 2547 CREATE TRIGGER "write_event_support"
jbe@532 2548 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2549 "write_event_support_trigger"();
jbe@532 2550
jbe@532 2551 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
jbe@532 2552 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
jbe@532 2553
jbe@532 2554
jbe@532 2555 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
jbe@532 2556 RETURNS TRIGGER
jbe@532 2557 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2558 DECLARE
jbe@532 2559 "same_pkey_v" BOOLEAN = FALSE;
jbe@532 2560 "initiative_row" "initiative"%ROWTYPE;
jbe@532 2561 "issue_row" "issue"%ROWTYPE;
jbe@532 2562 "area_row" "area"%ROWTYPE;
jbe@532 2563 BEGIN
jbe@532 2564 IF TG_OP = 'UPDATE' THEN
jbe@532 2565 IF
jbe@532 2566 OLD."suggestion_id" = NEW."suggestion_id" AND
jbe@532 2567 OLD."member_id" = NEW."member_id"
jbe@532 2568 THEN
jbe@532 2569 IF
jbe@532 2570 OLD."degree" = NEW."degree" AND
jbe@532 2571 OLD."fulfilled" = NEW."fulfilled"
jbe@532 2572 THEN
jbe@532 2573 RETURN NULL;
jbe@532 2574 END IF;
jbe@532 2575 "same_pkey_v" := TRUE;
jbe@532 2576 END IF;
jbe@532 2577 END IF;
jbe@532 2578 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
jbe@532 2579 IF EXISTS (
jbe@532 2580 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
jbe@532 2581 FOR SHARE
jbe@532 2582 ) THEN
jbe@532 2583 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 2584 WHERE "id" = OLD."initiative_id" FOR SHARE;
jbe@532 2585 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2586 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 2587 SELECT * INTO "area_row" FROM "area"
jbe@532 2588 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2589 INSERT INTO "event" (
jbe@532 2590 "event", "member_id",
jbe@536 2591 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2592 "initiative_id", "suggestion_id",
jbe@532 2593 "boolean_value", "numeric_value"
jbe@532 2594 ) VALUES (
jbe@532 2595 'suggestion_rated', OLD."member_id",
jbe@532 2596 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2597 "issue_row"."policy_id",
jbe@532 2598 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 2599 OLD."initiative_id", OLD."suggestion_id",
jbe@532 2600 NULL, 0
jbe@532 2601 );
jbe@532 2602 END IF;
jbe@532 2603 END IF;
jbe@532 2604 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 2605 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 2606 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@532 2607 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2608 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 2609 SELECT * INTO "area_row" FROM "area"
jbe@532 2610 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 2611 INSERT INTO "event" (
jbe@532 2612 "event", "member_id",
jbe@536 2613 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 2614 "initiative_id", "suggestion_id",
jbe@532 2615 "boolean_value", "numeric_value"
jbe@532 2616 ) VALUES (
jbe@532 2617 'suggestion_rated', NEW."member_id",
jbe@532 2618 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 2619 "issue_row"."policy_id",
jbe@532 2620 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 2621 NEW."initiative_id", NEW."suggestion_id",
jbe@532 2622 NEW."fulfilled", NEW."degree"
jbe@532 2623 );
jbe@532 2624 END IF;
jbe@532 2625 RETURN NULL;
jbe@532 2626 END;
jbe@532 2627 $$;
jbe@532 2628
jbe@532 2629 CREATE TRIGGER "write_event_suggestion_rated"
jbe@532 2630 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2631 "write_event_suggestion_rated_trigger"();
jbe@532 2632
jbe@532 2633 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
jbe@532 2634 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
jbe@532 2635
jbe@532 2636
jbe@532 2637 CREATE FUNCTION "write_event_delegation_trigger"()
jbe@532 2638 RETURNS TRIGGER
jbe@532 2639 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2640 DECLARE
jbe@532 2641 "issue_row" "issue"%ROWTYPE;
jbe@532 2642 "area_row" "area"%ROWTYPE;
jbe@532 2643 BEGIN
jbe@532 2644 IF TG_OP = 'DELETE' THEN
jbe@532 2645 IF EXISTS (
jbe@532 2646 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
jbe@532 2647 ) AND (CASE OLD."scope"
jbe@532 2648 WHEN 'unit'::"delegation_scope" THEN EXISTS (
jbe@532 2649 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
jbe@532 2650 )
jbe@532 2651 WHEN 'area'::"delegation_scope" THEN EXISTS (
jbe@532 2652 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
jbe@532 2653 )
jbe@532 2654 WHEN 'issue'::"delegation_scope" THEN EXISTS (
jbe@532 2655 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
jbe@532 2656 )
jbe@532 2657 END) THEN
jbe@532 2658 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2659 WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@532 2660 SELECT * INTO "area_row" FROM "area"
jbe@532 2661 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
jbe@532 2662 FOR SHARE;
jbe@532 2663 INSERT INTO "event" (
jbe@532 2664 "event", "member_id", "scope",
jbe@532 2665 "unit_id", "area_id", "issue_id", "state",
jbe@532 2666 "boolean_value"
jbe@532 2667 ) VALUES (
jbe@532 2668 'delegation', OLD."truster_id", OLD."scope",
jbe@532 2669 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
jbe@532 2670 OLD."issue_id", "issue_row"."state",
jbe@532 2671 FALSE
jbe@532 2672 );
jbe@532 2673 END IF;
jbe@532 2674 ELSE
jbe@532 2675 SELECT * INTO "issue_row" FROM "issue"
jbe@532 2676 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 2677 SELECT * INTO "area_row" FROM "area"
jbe@532 2678 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
jbe@532 2679 FOR SHARE;
jbe@532 2680 INSERT INTO "event" (
jbe@532 2681 "event", "member_id", "other_member_id", "scope",
jbe@532 2682 "unit_id", "area_id", "issue_id", "state",
jbe@532 2683 "boolean_value"
jbe@532 2684 ) VALUES (
jbe@532 2685 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
jbe@532 2686 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
jbe@532 2687 NEW."issue_id", "issue_row"."state",
jbe@532 2688 TRUE
jbe@532 2689 );
jbe@532 2690 END IF;
jbe@532 2691 RETURN NULL;
jbe@532 2692 END;
jbe@532 2693 $$;
jbe@532 2694
jbe@532 2695 CREATE TRIGGER "write_event_delegation"
jbe@532 2696 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2697 "write_event_delegation_trigger"();
jbe@532 2698
jbe@532 2699 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
jbe@532 2700 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
jbe@532 2701
jbe@532 2702
jbe@532 2703 CREATE FUNCTION "write_event_contact_trigger"()
jbe@532 2704 RETURNS TRIGGER
jbe@532 2705 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2706 BEGIN
jbe@532 2707 IF TG_OP = 'UPDATE' THEN
jbe@532 2708 IF
jbe@532 2709 OLD."member_id" = NEW."member_id" AND
jbe@532 2710 OLD."other_member_id" = NEW."other_member_id" AND
jbe@532 2711 OLD."public" = NEW."public"
jbe@532 2712 THEN
jbe@532 2713 RETURN NULL;
jbe@532 2714 END IF;
jbe@532 2715 END IF;
jbe@532 2716 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 2717 IF OLD."public" THEN
jbe@532 2718 IF EXISTS (
jbe@532 2719 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
jbe@532 2720 FOR SHARE
jbe@532 2721 ) AND EXISTS (
jbe@532 2722 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
jbe@532 2723 FOR SHARE
jbe@532 2724 ) THEN
jbe@532 2725 INSERT INTO "event" (
jbe@532 2726 "event", "member_id", "other_member_id", "boolean_value"
jbe@532 2727 ) VALUES (
jbe@532 2728 'contact', OLD."member_id", OLD."other_member_id", FALSE
jbe@532 2729 );
jbe@532 2730 END IF;
jbe@532 2731 END IF;
jbe@532 2732 END IF;
jbe@532 2733 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 2734 IF NEW."public" THEN
jbe@532 2735 INSERT INTO "event" (
jbe@532 2736 "event", "member_id", "other_member_id", "boolean_value"
jbe@532 2737 ) VALUES (
jbe@532 2738 'contact', NEW."member_id", NEW."other_member_id", TRUE
jbe@532 2739 );
jbe@532 2740 END IF;
jbe@532 2741 END IF;
jbe@532 2742 RETURN NULL;
jbe@532 2743 END;
jbe@532 2744 $$;
jbe@532 2745
jbe@532 2746 CREATE TRIGGER "write_event_contact"
jbe@532 2747 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2748 "write_event_contact_trigger"();
jbe@532 2749
jbe@532 2750 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
jbe@532 2751 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
jbe@532 2752
jbe@532 2753
jbe@588 2754 CREATE FUNCTION "write_event_posting_trigger"()
jbe@588 2755 RETURNS TRIGGER
jbe@588 2756 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@588 2757 BEGIN
jbe@588 2758 INSERT INTO "event" (
jbe@588 2759 "event", "posting_id", "member_id",
jbe@588 2760 "unit_id", "area_id", "policy_id",
jbe@588 2761 "issue_id", "initiative_id", "suggestion_id"
jbe@588 2762 ) VALUES (
jbe@588 2763 'posting_created', NEW."id", NEW."author_id",
jbe@588 2764 NEW."unit_id", NEW."area_id", NEW."policy_id",
jbe@588 2765 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
jbe@588 2766 );
jbe@588 2767 RETURN NULL;
jbe@588 2768 END;
jbe@588 2769 $$;
jbe@588 2770
jbe@588 2771 CREATE TRIGGER "write_event_posting"
jbe@588 2772 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
jbe@588 2773 "write_event_posting_trigger"();
jbe@588 2774
jbe@588 2775 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
jbe@588 2776 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
jbe@588 2777
jbe@588 2778
jbe@532 2779 CREATE FUNCTION "send_event_notify_trigger"()
jbe@532 2780 RETURNS TRIGGER
jbe@532 2781 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2782 BEGIN
jbe@532 2783 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
jbe@532 2784 RETURN NULL;
jbe@532 2785 END;
jbe@532 2786 $$;
jbe@532 2787
jbe@532 2788 CREATE TRIGGER "send_notify"
jbe@532 2789 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2790 "send_event_notify_trigger"();
jbe@532 2791
jbe@532 2792
jbe@13 2793
jbe@0 2794 ----------------------------
jbe@0 2795 -- Additional constraints --
jbe@0 2796 ----------------------------
jbe@0 2797
jbe@0 2798
jbe@532 2799 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
jbe@532 2800 RETURNS TRIGGER
jbe@532 2801 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2802 DECLARE
jbe@532 2803 "system_application_row" "system_application"%ROWTYPE;
jbe@532 2804 BEGIN
jbe@532 2805 IF OLD."system_application_id" NOTNULL THEN
jbe@532 2806 SELECT * FROM "system_application" INTO "system_application_row"
jbe@532 2807 WHERE "id" = OLD."system_application_id";
jbe@532 2808 DELETE FROM "token"
jbe@532 2809 WHERE "member_id" = OLD."member_id"
jbe@532 2810 AND "system_application_id" = OLD."system_application_id"
jbe@532 2811 AND NOT COALESCE(
jbe@532 2812 regexp_split_to_array("scope", E'\\s+') <@
jbe@532 2813 regexp_split_to_array(
jbe@532 2814 "system_application_row"."automatic_scope", E'\\s+'
jbe@532 2815 ),
jbe@532 2816 FALSE
jbe@532 2817 );
jbe@532 2818 END IF;
jbe@532 2819 RETURN OLD;
jbe@532 2820 END;
jbe@532 2821 $$;
jbe@532 2822
jbe@532 2823 CREATE TRIGGER "delete_extended_scope_tokens"
jbe@532 2824 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2825 "delete_extended_scope_tokens_trigger"();
jbe@532 2826
jbe@532 2827
jbe@532 2828 CREATE FUNCTION "detach_token_from_session_trigger"()
jbe@532 2829 RETURNS TRIGGER
jbe@532 2830 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2831 BEGIN
jbe@532 2832 UPDATE "token" SET "session_id" = NULL
jbe@532 2833 WHERE "session_id" = OLD."id";
jbe@532 2834 RETURN OLD;
jbe@532 2835 END;
jbe@532 2836 $$;
jbe@532 2837
jbe@532 2838 CREATE TRIGGER "detach_token_from_session"
jbe@532 2839 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2840 "detach_token_from_session_trigger"();
jbe@532 2841
jbe@532 2842
jbe@532 2843 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
jbe@532 2844 RETURNS TRIGGER
jbe@532 2845 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2846 BEGIN
jbe@532 2847 IF NEW."session_id" ISNULL THEN
jbe@532 2848 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
jbe@532 2849 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
jbe@532 2850 WHERE "element" LIKE '%_detached';
jbe@532 2851 END IF;
jbe@532 2852 RETURN NEW;
jbe@532 2853 END;
jbe@532 2854 $$;
jbe@532 2855
jbe@532 2856 CREATE TRIGGER "delete_non_detached_scope_with_session"
jbe@532 2857 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2858 "delete_non_detached_scope_with_session_trigger"();
jbe@532 2859
jbe@532 2860
jbe@532 2861 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
jbe@532 2862 RETURNS TRIGGER
jbe@532 2863 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2864 BEGIN
jbe@532 2865 IF NEW."scope" = '' THEN
jbe@532 2866 DELETE FROM "token" WHERE "id" = NEW."id";
jbe@532 2867 END IF;
jbe@532 2868 RETURN NULL;
jbe@532 2869 END;
jbe@532 2870 $$;
jbe@532 2871
jbe@532 2872 CREATE TRIGGER "delete_token_with_empty_scope"
jbe@532 2873 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 2874 "delete_token_with_empty_scope_trigger"();
jbe@532 2875
jbe@532 2876
jbe@0 2877 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
jbe@0 2878 RETURNS TRIGGER
jbe@0 2879 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2880 BEGIN
jbe@0 2881 IF NOT EXISTS (
jbe@0 2882 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
jbe@0 2883 ) THEN
jbe@463 2884 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
jbe@463 2885 ERRCODE = 'integrity_constraint_violation',
jbe@463 2886 HINT = 'Create issue, initiative, and draft within the same transaction.';
jbe@0 2887 END IF;
jbe@0 2888 RETURN NULL;
jbe@0 2889 END;
jbe@0 2890 $$;
jbe@0 2891
jbe@0 2892 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
jbe@0 2893 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
jbe@0 2894 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2895 "issue_requires_first_initiative_trigger"();
jbe@0 2896
jbe@0 2897 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
jbe@0 2898 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
jbe@0 2899
jbe@0 2900
jbe@0 2901 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
jbe@0 2902 RETURNS TRIGGER
jbe@0 2903 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2904 DECLARE
jbe@0 2905 "reference_lost" BOOLEAN;
jbe@0 2906 BEGIN
jbe@0 2907 IF TG_OP = 'DELETE' THEN
jbe@0 2908 "reference_lost" := TRUE;
jbe@0 2909 ELSE
jbe@0 2910 "reference_lost" := NEW."issue_id" != OLD."issue_id";
jbe@0 2911 END IF;
jbe@0 2912 IF
jbe@0 2913 "reference_lost" AND NOT EXISTS (
jbe@0 2914 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
jbe@0 2915 )
jbe@0 2916 THEN
jbe@0 2917 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
jbe@0 2918 END IF;
jbe@0 2919 RETURN NULL;
jbe@0 2920 END;
jbe@0 2921 $$;
jbe@0 2922
jbe@0 2923 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
jbe@0 2924 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 2925 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2926 "last_initiative_deletes_issue_trigger"();
jbe@0 2927
jbe@0 2928 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
jbe@0 2929 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
jbe@0 2930
jbe@0 2931
jbe@0 2932 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
jbe@0 2933 RETURNS TRIGGER
jbe@0 2934 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2935 BEGIN
jbe@0 2936 IF NOT EXISTS (
jbe@0 2937 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
jbe@0 2938 ) THEN
jbe@463 2939 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
jbe@463 2940 ERRCODE = 'integrity_constraint_violation',
jbe@463 2941 HINT = 'Create issue, initiative and draft within the same transaction.';
jbe@0 2942 END IF;
jbe@0 2943 RETURN NULL;
jbe@0 2944 END;
jbe@0 2945 $$;
jbe@0 2946
jbe@0 2947 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
jbe@0 2948 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 2949 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2950 "initiative_requires_first_draft_trigger"();
jbe@0 2951
jbe@0 2952 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
jbe@0 2953 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
jbe@0 2954
jbe@0 2955
jbe@0 2956 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
jbe@0 2957 RETURNS TRIGGER
jbe@0 2958 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2959 DECLARE
jbe@0 2960 "reference_lost" BOOLEAN;
jbe@0 2961 BEGIN
jbe@0 2962 IF TG_OP = 'DELETE' THEN
jbe@0 2963 "reference_lost" := TRUE;
jbe@0 2964 ELSE
jbe@0 2965 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
jbe@0 2966 END IF;
jbe@0 2967 IF
jbe@0 2968 "reference_lost" AND NOT EXISTS (
jbe@0 2969 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
jbe@0 2970 )
jbe@0 2971 THEN
jbe@0 2972 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
jbe@0 2973 END IF;
jbe@0 2974 RETURN NULL;
jbe@0 2975 END;
jbe@0 2976 $$;
jbe@0 2977
jbe@0 2978 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
jbe@0 2979 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
jbe@0 2980 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 2981 "last_draft_deletes_initiative_trigger"();
jbe@0 2982
jbe@0 2983 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
jbe@0 2984 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
jbe@0 2985
jbe@0 2986
jbe@0 2987 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
jbe@0 2988 RETURNS TRIGGER
jbe@0 2989 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2990 BEGIN
jbe@0 2991 IF NOT EXISTS (
jbe@0 2992 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
jbe@0 2993 ) THEN
jbe@463 2994 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
jbe@463 2995 ERRCODE = 'integrity_constraint_violation',
jbe@463 2996 HINT = 'Create suggestion and opinion within the same transaction.';
jbe@0 2997 END IF;
jbe@0 2998 RETURN NULL;
jbe@0 2999 END;
jbe@0 3000 $$;
jbe@0 3001
jbe@0 3002 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
jbe@0 3003 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
jbe@0 3004 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 3005 "suggestion_requires_first_opinion_trigger"();
jbe@0 3006
jbe@0 3007 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
jbe@0 3008 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
jbe@0 3009
jbe@0 3010
jbe@0 3011 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
jbe@0 3012 RETURNS TRIGGER
jbe@0 3013 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3014 DECLARE
jbe@0 3015 "reference_lost" BOOLEAN;
jbe@0 3016 BEGIN
jbe@0 3017 IF TG_OP = 'DELETE' THEN
jbe@0 3018 "reference_lost" := TRUE;
jbe@0 3019 ELSE
jbe@0 3020 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
jbe@0 3021 END IF;
jbe@0 3022 IF
jbe@0 3023 "reference_lost" AND NOT EXISTS (
jbe@0 3024 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
jbe@0 3025 )
jbe@0 3026 THEN
jbe@0 3027 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
jbe@0 3028 END IF;
jbe@0 3029 RETURN NULL;
jbe@0 3030 END;
jbe@0 3031 $$;
jbe@0 3032
jbe@0 3033 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
jbe@0 3034 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
jbe@0 3035 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 3036 "last_opinion_deletes_suggestion_trigger"();
jbe@0 3037
jbe@0 3038 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
jbe@0 3039 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
jbe@0 3040
jbe@0 3041
jbe@284 3042 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
jbe@284 3043 RETURNS TRIGGER
jbe@284 3044 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@284 3045 BEGIN
jbe@284 3046 DELETE FROM "direct_voter"
jbe@284 3047 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@284 3048 RETURN NULL;
jbe@284 3049 END;
jbe@284 3050 $$;
jbe@284 3051
jbe@284 3052 CREATE TRIGGER "non_voter_deletes_direct_voter"
jbe@284 3053 AFTER INSERT OR UPDATE ON "non_voter"
jbe@284 3054 FOR EACH ROW EXECUTE PROCEDURE
jbe@284 3055 "non_voter_deletes_direct_voter_trigger"();
jbe@284 3056
jbe@284 3057 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
jbe@284 3058 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 3059
jbe@284 3060
jbe@284 3061 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
jbe@284 3062 RETURNS TRIGGER
jbe@284 3063 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@284 3064 BEGIN
jbe@284 3065 DELETE FROM "non_voter"
jbe@284 3066 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@284 3067 RETURN NULL;
jbe@284 3068 END;
jbe@284 3069 $$;
jbe@284 3070
jbe@284 3071 CREATE TRIGGER "direct_voter_deletes_non_voter"
jbe@284 3072 AFTER INSERT OR UPDATE ON "direct_voter"
jbe@284 3073 FOR EACH ROW EXECUTE PROCEDURE
jbe@284 3074 "direct_voter_deletes_non_voter_trigger"();
jbe@284 3075
jbe@284 3076 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
jbe@284 3077 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 3078
jbe@284 3079
jbe@285 3080 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
jbe@285 3081 RETURNS TRIGGER
jbe@285 3082 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@285 3083 BEGIN
jbe@285 3084 IF NEW."comment" ISNULL THEN
jbe@285 3085 NEW."comment_changed" := NULL;
jbe@285 3086 NEW."formatting_engine" := NULL;
jbe@285 3087 END IF;
jbe@285 3088 RETURN NEW;
jbe@285 3089 END;
jbe@285 3090 $$;
jbe@285 3091
jbe@285 3092 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
jbe@285 3093 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@285 3094 FOR EACH ROW EXECUTE PROCEDURE
jbe@285 3095 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
jbe@285 3096
jbe@285 3097 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 3098 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 3099
jbe@0 3100
jbe@528 3101
jbe@528 3102 ---------------------------------
jbe@528 3103 -- Delete incomplete snapshots --
jbe@528 3104 ---------------------------------
jbe@528 3105
jbe@528 3106
jbe@528 3107 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
jbe@528 3108 RETURNS TRIGGER
jbe@528 3109 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 3110 BEGIN
jbe@532 3111 IF TG_OP = 'UPDATE' THEN
jbe@532 3112 IF
jbe@532 3113 OLD."snapshot_id" = NEW."snapshot_id" AND
jbe@532 3114 OLD."issue_id" = NEW."issue_id"
jbe@532 3115 THEN
jbe@532 3116 RETURN NULL;
jbe@532 3117 END IF;
jbe@532 3118 END IF;
jbe@528 3119 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
jbe@528 3120 RETURN NULL;
jbe@528 3121 END;
jbe@528 3122 $$;
jbe@528 3123
jbe@528 3124 CREATE TRIGGER "delete_snapshot_on_partial_delete"
jbe@532 3125 AFTER UPDATE OR DELETE ON "snapshot_issue"
jbe@528 3126 FOR EACH ROW EXECUTE PROCEDURE
jbe@528 3127 "delete_snapshot_on_partial_delete_trigger"();
jbe@528 3128
jbe@528 3129 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
jbe@528 3130 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
jbe@528 3131
jbe@528 3132
jbe@528 3133
jbe@20 3134 ---------------------------------------------------------------
jbe@333 3135 -- Ensure that votes are not modified when issues are closed --
jbe@20 3136 ---------------------------------------------------------------
jbe@20 3137
jbe@20 3138 -- NOTE: Frontends should ensure this anyway, but in case of programming
jbe@532 3139 -- errors the following triggers ensure data integrity.
jbe@20 3140
jbe@20 3141
jbe@20 3142 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
jbe@20 3143 RETURNS TRIGGER
jbe@20 3144 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@20 3145 DECLARE
jbe@336 3146 "issue_id_v" "issue"."id"%TYPE;
jbe@336 3147 "issue_row" "issue"%ROWTYPE;
jbe@20 3148 BEGIN
jbe@383 3149 IF EXISTS (
jbe@385 3150 SELECT NULL FROM "temporary_transaction_data"
jbe@385 3151 WHERE "txid" = txid_current()
jbe@383 3152 AND "key" = 'override_protection_triggers'
jbe@383 3153 AND "value" = TRUE::TEXT
jbe@383 3154 ) THEN
jbe@383 3155 RETURN NULL;
jbe@383 3156 END IF;
jbe@32 3157 IF TG_OP = 'DELETE' THEN
jbe@32 3158 "issue_id_v" := OLD."issue_id";
jbe@32 3159 ELSE
jbe@32 3160 "issue_id_v" := NEW."issue_id";
jbe@32 3161 END IF;
jbe@20 3162 SELECT INTO "issue_row" * FROM "issue"
jbe@32 3163 WHERE "id" = "issue_id_v" FOR SHARE;
jbe@383 3164 IF (
jbe@383 3165 "issue_row"."closed" NOTNULL OR (
jbe@383 3166 "issue_row"."state" = 'voting' AND
jbe@383 3167 "issue_row"."phase_finished" NOTNULL
jbe@383 3168 )
jbe@383 3169 ) THEN
jbe@332 3170 IF
jbe@332 3171 TG_RELID = 'direct_voter'::regclass AND
jbe@332 3172 TG_OP = 'UPDATE'
jbe@332 3173 THEN
jbe@332 3174 IF
jbe@332 3175 OLD."issue_id" = NEW."issue_id" AND
jbe@332 3176 OLD."member_id" = NEW."member_id" AND
jbe@332 3177 OLD."weight" = NEW."weight"
jbe@332 3178 THEN
jbe@332 3179 RETURN NULL; -- allows changing of voter comment
jbe@332 3180 END IF;
jbe@332 3181 END IF;
jbe@463 3182 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
jbe@463 3183 ERRCODE = 'integrity_constraint_violation';
jbe@20 3184 END IF;
jbe@20 3185 RETURN NULL;
jbe@20 3186 END;
jbe@20 3187 $$;
jbe@20 3188
jbe@20 3189 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 3190 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@20 3191 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 3192 "forbid_changes_on_closed_issue_trigger"();
jbe@20 3193
jbe@20 3194 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 3195 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@20 3196 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 3197 "forbid_changes_on_closed_issue_trigger"();
jbe@20 3198
jbe@20 3199 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 3200 AFTER INSERT OR UPDATE OR DELETE ON "vote"
jbe@20 3201 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 3202 "forbid_changes_on_closed_issue_trigger"();
jbe@20 3203
jbe@20 3204 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 3205 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 3206 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 3207 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 3208
jbe@20 3209
jbe@20 3210
jbe@0 3211 --------------------------------------------------------------------
jbe@0 3212 -- Auto-retrieval of fields only needed for referential integrity --
jbe@0 3213 --------------------------------------------------------------------
jbe@0 3214
jbe@20 3215
jbe@0 3216 CREATE FUNCTION "autofill_issue_id_trigger"()
jbe@0 3217 RETURNS TRIGGER
jbe@0 3218 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3219 BEGIN
jbe@0 3220 IF NEW."issue_id" ISNULL THEN
jbe@0 3221 SELECT "issue_id" INTO NEW."issue_id"
jbe@0 3222 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 3223 END IF;
jbe@0 3224 RETURN NEW;
jbe@0 3225 END;
jbe@0 3226 $$;
jbe@0 3227
jbe@0 3228 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
jbe@0 3229 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 3230
jbe@0 3231 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
jbe@0 3232 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 3233
jbe@0 3234 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
jbe@0 3235 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 3236 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 3237
jbe@0 3238
jbe@0 3239 CREATE FUNCTION "autofill_initiative_id_trigger"()
jbe@0 3240 RETURNS TRIGGER
jbe@0 3241 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3242 BEGIN
jbe@0 3243 IF NEW."initiative_id" ISNULL THEN
jbe@0 3244 SELECT "initiative_id" INTO NEW."initiative_id"
jbe@0 3245 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 3246 END IF;
jbe@0 3247 RETURN NEW;
jbe@0 3248 END;
jbe@0 3249 $$;
jbe@0 3250
jbe@0 3251 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
jbe@0 3252 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
jbe@0 3253
jbe@0 3254 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
jbe@0 3255 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
jbe@0 3256
jbe@0 3257
jbe@0 3258
jbe@528 3259 -------------------------------------------------------
jbe@528 3260 -- Automatic copying of values for indexing purposes --
jbe@528 3261 -------------------------------------------------------
jbe@528 3262
jbe@528 3263
jbe@528 3264 CREATE FUNCTION "copy_current_draft_data"
jbe@528 3265 ("initiative_id_p" "initiative"."id"%TYPE )
jbe@528 3266 RETURNS VOID
jbe@528 3267 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 3268 BEGIN
jbe@528 3269 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
jbe@528 3270 FOR UPDATE;
jbe@528 3271 UPDATE "initiative" SET
jbe@532 3272 "location" = "draft"."location",
jbe@528 3273 "draft_text_search_data" = "draft"."text_search_data"
jbe@528 3274 FROM "current_draft" AS "draft"
jbe@528 3275 WHERE "initiative"."id" = "initiative_id_p"
jbe@528 3276 AND "draft"."initiative_id" = "initiative_id_p";
jbe@528 3277 END;
jbe@528 3278 $$;
jbe@528 3279
jbe@528 3280 COMMENT ON FUNCTION "copy_current_draft_data"
jbe@528 3281 ( "initiative"."id"%TYPE )
jbe@528 3282 IS 'Helper function for function "copy_current_draft_data_trigger"';
jbe@528 3283
jbe@528 3284
jbe@528 3285 CREATE FUNCTION "copy_current_draft_data_trigger"()
jbe@528 3286 RETURNS TRIGGER
jbe@528 3287 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 3288 BEGIN
jbe@528 3289 IF TG_OP='DELETE' THEN
jbe@528 3290 PERFORM "copy_current_draft_data"(OLD."initiative_id");
jbe@528 3291 ELSE
jbe@528 3292 IF TG_OP='UPDATE' THEN
jbe@528 3293 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
jbe@528 3294 PERFORM "copy_current_draft_data"(OLD."initiative_id");
jbe@528 3295 END IF;
jbe@528 3296 END IF;
jbe@528 3297 PERFORM "copy_current_draft_data"(NEW."initiative_id");
jbe@528 3298 END IF;
jbe@528 3299 RETURN NULL;
jbe@528 3300 END;
jbe@528 3301 $$;
jbe@528 3302
jbe@528 3303 CREATE TRIGGER "copy_current_draft_data"
jbe@528 3304 AFTER INSERT OR UPDATE OR DELETE ON "draft"
jbe@528 3305 FOR EACH ROW EXECUTE PROCEDURE
jbe@528 3306 "copy_current_draft_data_trigger"();
jbe@528 3307
jbe@528 3308 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
jbe@528 3309 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
jbe@528 3310
jbe@528 3311
jbe@528 3312
jbe@4 3313 -----------------------------------------------------
jbe@4 3314 -- Automatic calculation of certain default values --
jbe@4 3315 -----------------------------------------------------
jbe@0 3316
jbe@22 3317
jbe@22 3318 CREATE FUNCTION "copy_timings_trigger"()
jbe@22 3319 RETURNS TRIGGER
jbe@22 3320 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@22 3321 DECLARE
jbe@22 3322 "policy_row" "policy"%ROWTYPE;
jbe@22 3323 BEGIN
jbe@22 3324 SELECT * INTO "policy_row" FROM "policy"
jbe@22 3325 WHERE "id" = NEW."policy_id";
jbe@447 3326 IF NEW."min_admission_time" ISNULL THEN
jbe@447 3327 NEW."min_admission_time" := "policy_row"."min_admission_time";
jbe@447 3328 END IF;
jbe@447 3329 IF NEW."max_admission_time" ISNULL THEN
jbe@447 3330 NEW."max_admission_time" := "policy_row"."max_admission_time";
jbe@22 3331 END IF;
jbe@22 3332 IF NEW."discussion_time" ISNULL THEN
jbe@22 3333 NEW."discussion_time" := "policy_row"."discussion_time";
jbe@22 3334 END IF;
jbe@22 3335 IF NEW."verification_time" ISNULL THEN
jbe@22 3336 NEW."verification_time" := "policy_row"."verification_time";
jbe@22 3337 END IF;
jbe@22 3338 IF NEW."voting_time" ISNULL THEN
jbe@22 3339 NEW."voting_time" := "policy_row"."voting_time";
jbe@22 3340 END IF;
jbe@22 3341 RETURN NEW;
jbe@22 3342 END;
jbe@22 3343 $$;
jbe@22 3344
jbe@22 3345 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
jbe@22 3346 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
jbe@22 3347
jbe@22 3348 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
jbe@22 3349 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
jbe@22 3350
jbe@22 3351
jbe@160 3352 CREATE FUNCTION "default_for_draft_id_trigger"()
jbe@2 3353 RETURNS TRIGGER
jbe@2 3354 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@2 3355 BEGIN
jbe@2 3356 IF NEW."draft_id" ISNULL THEN
jbe@2 3357 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@2 3358 WHERE "initiative_id" = NEW."initiative_id";
jbe@2 3359 END IF;
jbe@2 3360 RETURN NEW;
jbe@2 3361 END;
jbe@2 3362 $$;
jbe@2 3363
jbe@160 3364 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
jbe@160 3365 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@2 3366 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@160 3367 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@160 3368
jbe@160 3369 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
jbe@160 3370 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 3371 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 3372
jbe@2 3373
jbe@0 3374
jbe@0 3375 ----------------------------------------
jbe@0 3376 -- Automatic creation of dependencies --
jbe@0 3377 ----------------------------------------
jbe@0 3378
jbe@22 3379
jbe@0 3380 CREATE FUNCTION "autocreate_interest_trigger"()
jbe@0 3381 RETURNS TRIGGER
jbe@0 3382 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3383 BEGIN
jbe@0 3384 IF NOT EXISTS (
jbe@0 3385 SELECT NULL FROM "initiative" JOIN "interest"
jbe@0 3386 ON "initiative"."issue_id" = "interest"."issue_id"
jbe@0 3387 WHERE "initiative"."id" = NEW."initiative_id"
jbe@0 3388 AND "interest"."member_id" = NEW."member_id"
jbe@0 3389 ) THEN
jbe@0 3390 BEGIN
jbe@0 3391 INSERT INTO "interest" ("issue_id", "member_id")
jbe@0 3392 SELECT "issue_id", NEW."member_id"
jbe@0 3393 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 3394 EXCEPTION WHEN unique_violation THEN END;
jbe@0 3395 END IF;
jbe@0 3396 RETURN NEW;
jbe@0 3397 END;
jbe@0 3398 $$;
jbe@0 3399
jbe@0 3400 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
jbe@0 3401 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
jbe@0 3402
jbe@0 3403 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
jbe@0 3404 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 3405
jbe@0 3406
jbe@0 3407 CREATE FUNCTION "autocreate_supporter_trigger"()
jbe@0 3408 RETURNS TRIGGER
jbe@0 3409 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3410 BEGIN
jbe@0 3411 IF NOT EXISTS (
jbe@0 3412 SELECT NULL FROM "suggestion" JOIN "supporter"
jbe@0 3413 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@0 3414 WHERE "suggestion"."id" = NEW."suggestion_id"
jbe@0 3415 AND "supporter"."member_id" = NEW."member_id"
jbe@0 3416 ) THEN
jbe@0 3417 BEGIN
jbe@0 3418 INSERT INTO "supporter" ("initiative_id", "member_id")
jbe@0 3419 SELECT "initiative_id", NEW."member_id"
jbe@0 3420 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 3421 EXCEPTION WHEN unique_violation THEN END;
jbe@0 3422 END IF;
jbe@0 3423 RETURN NEW;
jbe@0 3424 END;
jbe@0 3425 $$;
jbe@0 3426
jbe@0 3427 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
jbe@0 3428 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
jbe@0 3429
jbe@0 3430 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
jbe@0 3431 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 3432
jbe@0 3433
jbe@0 3434
jbe@0 3435 ------------------------------------------
jbe@0 3436 -- Views and helper functions for views --
jbe@0 3437 ------------------------------------------
jbe@0 3438
jbe@5 3439
jbe@524 3440 CREATE VIEW "member_eligible_to_be_notified" AS
jbe@524 3441 SELECT * FROM "member"
jbe@524 3442 WHERE "activated" NOTNULL AND "locked" = FALSE;
jbe@524 3443
jbe@524 3444 COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")';
jbe@524 3445
jbe@524 3446
jbe@524 3447 CREATE VIEW "member_to_notify" AS
jbe@524 3448 SELECT * FROM "member_eligible_to_be_notified"
jbe@524 3449 WHERE "disable_notifications" = FALSE;
jbe@524 3450
jbe@524 3451 COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)';
jbe@524 3452
jbe@524 3453
jbe@588 3454 CREATE VIEW "follower" AS
jbe@588 3455 SELECT
jbe@588 3456 "id" AS "follower_id",
jbe@588 3457 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
jbe@588 3458 FROM "contact"
jbe@588 3459 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
jbe@588 3460 AS "following_ids"
jbe@588 3461 FROM "member";
jbe@588 3462
jbe@588 3463 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
jbe@588 3464
jbe@588 3465
jbe@532 3466 CREATE VIEW "area_quorum" AS
jbe@532 3467 SELECT
jbe@532 3468 "area"."id" AS "area_id",
jbe@532 3469 ceil(
jbe@532 3470 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
jbe@532 3471 coalesce(
jbe@532 3472 ( SELECT sum(
jbe@532 3473 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
jbe@532 3474 extract(epoch from
jbe@532 3475 ("issue"."accepted"-"issue"."created") +
jbe@532 3476 "issue"."discussion_time" +
jbe@532 3477 "issue"."verification_time" +
jbe@532 3478 "issue"."voting_time"
jbe@532 3479 )::FLOAT8
jbe@532 3480 ) ^ "area"."quorum_exponent"::FLOAT8
jbe@532 3481 )
jbe@532 3482 FROM "issue" JOIN "policy"
jbe@532 3483 ON "issue"."policy_id" = "policy"."id"
jbe@532 3484 WHERE "issue"."area_id" = "area"."id"
jbe@532 3485 AND "issue"."accepted" NOTNULL
jbe@532 3486 AND "issue"."closed" ISNULL
jbe@532 3487 AND "policy"."polling" = FALSE
jbe@532 3488 )::FLOAT8, 0::FLOAT8
jbe@532 3489 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
jbe@532 3490 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
jbe@532 3491 SELECT "snapshot"."population"
jbe@532 3492 FROM "snapshot"
jbe@532 3493 WHERE "snapshot"."area_id" = "area"."id"
jbe@532 3494 AND "snapshot"."issue_id" ISNULL
jbe@532 3495 ORDER BY "snapshot"."id" DESC
jbe@532 3496 LIMIT 1
jbe@532 3497 ) END / coalesce("area"."quorum_den", 1)
jbe@532 3498
jbe@532 3499 )::INT4 AS "issue_quorum"
jbe@532 3500 FROM "area";
jbe@532 3501
jbe@532 3502 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
jbe@532 3503
jbe@532 3504
jbe@568 3505 CREATE VIEW "issue_quorum" AS
jbe@568 3506 SELECT DISTINCT ON ("issue_id")
jbe@568 3507 "issue"."id" AS "issue_id",
jbe@568 3508 "subquery"."issue_quorum"
jbe@568 3509 FROM "issue"
jbe@568 3510 CROSS JOIN LATERAL (
jbe@568 3511 SELECT "area_quorum"."issue_quorum"
jbe@568 3512 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
jbe@568 3513 UNION ALL
jbe@568 3514 SELECT "policy"."issue_quorum"
jbe@568 3515 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
jbe@568 3516 UNION ALL
jbe@568 3517 SELECT
jbe@568 3518 ceil(
jbe@568 3519 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
jbe@568 3520 "policy"."issue_quorum_den"::FLOAT8
jbe@568 3521 )::INT4
jbe@568 3522 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
jbe@568 3523 ) AS "subquery"
jbe@568 3524 ORDER BY "issue_id", "issue_quorum" DESC;
jbe@568 3525
jbe@568 3526 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
jbe@568 3527
jbe@568 3528
jbe@532 3529 CREATE VIEW "area_with_unaccepted_issues" AS
jbe@532 3530 SELECT DISTINCT ON ("area"."id") "area".*
jbe@532 3531 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
jbe@532 3532 WHERE "issue"."state" = 'admission';
jbe@532 3533
jbe@532 3534 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
jbe@457 3535
jbe@457 3536
jbe@457 3537 CREATE VIEW "issue_for_admission" AS
jbe@532 3538 SELECT DISTINCT ON ("issue"."area_id")
jbe@457 3539 "issue".*,
jbe@457 3540 max("initiative"."supporter_count") AS "max_supporter_count"
jbe@457 3541 FROM "issue"
jbe@528 3542 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
jbe@457 3543 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@457 3544 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@457 3545 WHERE "issue"."state" = 'admission'::"issue_state"
jbe@528 3546 AND now() >= "issue"."created" + "issue"."min_admission_time"
jbe@528 3547 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
jbe@532 3548 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
jbe@532 3549 "issue"."population" * "policy"."issue_quorum_num"
jbe@532 3550 AND "initiative"."supporter_count" >= "area"."issue_quorum"
jbe@528 3551 AND "initiative"."revoked" ISNULL
jbe@457 3552 GROUP BY "issue"."id"
jbe@532 3553 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
jbe@532 3554
jbe@532 3555 COMMENT ON VIEW "issue_for_admission" IS 'Contains up to 1 issue per area eligible to pass from ''admission'' to ''discussion'' state; needs to be recalculated after admitting the issue in this view';
jbe@457 3556
jbe@457 3557
jbe@97 3558 CREATE VIEW "unit_delegation" AS
jbe@97 3559 SELECT
jbe@97 3560 "unit"."id" AS "unit_id",
jbe@97 3561 "delegation"."id",
jbe@97 3562 "delegation"."truster_id",
jbe@97 3563 "delegation"."trustee_id",
jbe@97 3564 "delegation"."scope"
jbe@97 3565 FROM "unit"
jbe@97 3566 JOIN "delegation"
jbe@97 3567 ON "delegation"."unit_id" = "unit"."id"
jbe@97 3568 JOIN "member"
jbe@97 3569 ON "delegation"."truster_id" = "member"."id"
jbe@556 3570 JOIN "privilege"
jbe@556 3571 ON "delegation"."unit_id" = "privilege"."unit_id"
jbe@556 3572 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@556 3573 WHERE "member"."active" AND "privilege"."voting_right";
jbe@97 3574
jbe@97 3575 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
jbe@5 3576
jbe@5 3577
jbe@5 3578 CREATE VIEW "area_delegation" AS
jbe@70 3579 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@70 3580 "area"."id" AS "area_id",
jbe@70 3581 "delegation"."id",
jbe@70 3582 "delegation"."truster_id",
jbe@70 3583 "delegation"."trustee_id",
jbe@70 3584 "delegation"."scope"
jbe@97 3585 FROM "area"
jbe@97 3586 JOIN "delegation"
jbe@97 3587 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 3588 OR "delegation"."area_id" = "area"."id"
jbe@97 3589 JOIN "member"
jbe@97 3590 ON "delegation"."truster_id" = "member"."id"
jbe@556 3591 JOIN "privilege"
jbe@556 3592 ON "area"."unit_id" = "privilege"."unit_id"
jbe@556 3593 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@556 3594 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 3595 ORDER BY
jbe@70 3596 "area"."id",
jbe@70 3597 "delegation"."truster_id",
jbe@70 3598 "delegation"."scope" DESC;
jbe@70 3599
jbe@97 3600 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
jbe@5 3601
jbe@5 3602
jbe@5 3603 CREATE VIEW "issue_delegation" AS
jbe@70 3604 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@70 3605 "issue"."id" AS "issue_id",
jbe@70 3606 "delegation"."id",
jbe@70 3607 "delegation"."truster_id",
jbe@70 3608 "delegation"."trustee_id",
jbe@70 3609 "delegation"."scope"
jbe@97 3610 FROM "issue"
jbe@97 3611 JOIN "area"
jbe@97 3612 ON "area"."id" = "issue"."area_id"
jbe@97 3613 JOIN "delegation"
jbe@97 3614 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 3615 OR "delegation"."area_id" = "area"."id"
jbe@97 3616 OR "delegation"."issue_id" = "issue"."id"
jbe@97 3617 JOIN "member"
jbe@97 3618 ON "delegation"."truster_id" = "member"."id"
jbe@556 3619 JOIN "privilege"
jbe@556 3620 ON "area"."unit_id" = "privilege"."unit_id"
jbe@556 3621 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@556 3622 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 3623 ORDER BY
jbe@70 3624 "issue"."id",
jbe@70 3625 "delegation"."truster_id",
jbe@70 3626 "delegation"."scope" DESC;
jbe@70 3627
jbe@97 3628 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
jbe@5 3629
jbe@5 3630
jbe@4 3631 CREATE VIEW "member_count_view" AS
jbe@5 3632 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 3633
jbe@4 3634 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 3635
jbe@4 3636
jbe@532 3637 CREATE VIEW "unit_member" AS
jbe@532 3638 SELECT
jbe@532 3639 "unit"."id" AS "unit_id",
jbe@532 3640 "member"."id" AS "member_id"
jbe@556 3641 FROM "privilege"
jbe@569 3642 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
jbe@556 3643 JOIN "member" ON "member"."id" = "privilege"."member_id"
jbe@556 3644 WHERE "privilege"."voting_right" AND "member"."active";
jbe@532 3645
jbe@532 3646 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
jbe@532 3647
jbe@532 3648
jbe@97 3649 CREATE VIEW "unit_member_count" AS
jbe@97 3650 SELECT
jbe@97 3651 "unit"."id" AS "unit_id",
jbe@532 3652 count("unit_member"."member_id") AS "member_count"
jbe@532 3653 FROM "unit" LEFT JOIN "unit_member"
jbe@532 3654 ON "unit"."id" = "unit_member"."unit_id"
jbe@97 3655 GROUP BY "unit"."id";
jbe@97 3656
jbe@97 3657 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@97 3658
jbe@97 3659
jbe@9 3660 CREATE VIEW "opening_draft" AS
jbe@528 3661 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
jbe@528 3662 ORDER BY "initiative_id", "id";
jbe@9 3663
jbe@9 3664 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 3665
jbe@9 3666
jbe@0 3667 CREATE VIEW "current_draft" AS
jbe@528 3668 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
jbe@528 3669 ORDER BY "initiative_id", "id" DESC;
jbe@0 3670
jbe@0 3671 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 3672
jbe@0 3673
jbe@0 3674 CREATE VIEW "critical_opinion" AS
jbe@0 3675 SELECT * FROM "opinion"
jbe@0 3676 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 3677 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 3678
jbe@0 3679 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 3680
jbe@0 3681
jbe@392 3682 CREATE VIEW "issue_supporter_in_admission_state" AS
jbe@528 3683 SELECT
jbe@410 3684 "area"."unit_id",
jbe@392 3685 "issue"."area_id",
jbe@392 3686 "issue"."id" AS "issue_id",
jbe@392 3687 "supporter"."member_id",
jbe@392 3688 "direct_interest_snapshot"."weight"
jbe@392 3689 FROM "issue"
jbe@410 3690 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@392 3691 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
jbe@392 3692 JOIN "direct_interest_snapshot"
jbe@528 3693 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
jbe@528 3694 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@392 3695 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
jbe@392 3696 WHERE "issue"."state" = 'admission'::"issue_state";
jbe@392 3697
jbe@392 3698 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 3699
jbe@392 3700
jbe@352 3701 CREATE VIEW "initiative_suggestion_order_calculation" AS
jbe@352 3702 SELECT
jbe@352 3703 "initiative"."id" AS "initiative_id",
jbe@352 3704 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
jbe@352 3705 FROM "initiative" JOIN "issue"
jbe@352 3706 ON "initiative"."issue_id" = "issue"."id"
jbe@352 3707 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
jbe@352 3708 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
jbe@352 3709
jbe@352 3710 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
jbe@352 3711
jbe@360 3712 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 3713
jbe@352 3714
jbe@352 3715 CREATE VIEW "individual_suggestion_ranking" AS
jbe@352 3716 SELECT
jbe@352 3717 "opinion"."initiative_id",
jbe@352 3718 "opinion"."member_id",
jbe@352 3719 "direct_interest_snapshot"."weight",
jbe@352 3720 CASE WHEN
jbe@352 3721 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 3722 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
jbe@352 3723 THEN 1 ELSE
jbe@352 3724 CASE WHEN
jbe@352 3725 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 3726 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
jbe@352 3727 THEN 2 ELSE
jbe@352 3728 CASE WHEN
jbe@352 3729 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
jbe@352 3730 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
jbe@352 3731 THEN 3 ELSE 4 END
jbe@352 3732 END
jbe@352 3733 END AS "preference",
jbe@352 3734 "opinion"."suggestion_id"
jbe@352 3735 FROM "opinion"
jbe@352 3736 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
jbe@352 3737 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@352 3738 JOIN "direct_interest_snapshot"
jbe@528 3739 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
jbe@528 3740 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@352 3741 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
jbe@352 3742
jbe@352 3743 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 3744
jbe@352 3745
jbe@126 3746 CREATE VIEW "battle_participant" AS
jbe@126 3747 SELECT "initiative"."id", "initiative"."issue_id"
jbe@126 3748 FROM "issue" JOIN "initiative"
jbe@126 3749 ON "issue"."id" = "initiative"."issue_id"
jbe@126 3750 WHERE "initiative"."admitted"
jbe@126 3751 UNION ALL
jbe@126 3752 SELECT NULL, "id" AS "issue_id"
jbe@126 3753 FROM "issue";
jbe@126 3754
jbe@126 3755 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 3756
jbe@126 3757
jbe@61 3758 CREATE VIEW "battle_view" AS
jbe@0 3759 SELECT
jbe@0 3760 "issue"."id" AS "issue_id",
jbe@10 3761 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 3762 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 3763 sum(
jbe@0 3764 CASE WHEN
jbe@0 3765 coalesce("better_vote"."grade", 0) >
jbe@0 3766 coalesce("worse_vote"."grade", 0)
jbe@0 3767 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 3768 ) AS "count"
jbe@0 3769 FROM "issue"
jbe@0 3770 LEFT JOIN "direct_voter"
jbe@0 3771 ON "issue"."id" = "direct_voter"."issue_id"
jbe@126 3772 JOIN "battle_participant" AS "winning_initiative"
jbe@10 3773 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@126 3774 JOIN "battle_participant" AS "losing_initiative"
jbe@10 3775 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@0 3776 LEFT JOIN "vote" AS "better_vote"
jbe@10 3777 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 3778 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 3779 LEFT JOIN "vote" AS "worse_vote"
jbe@10 3780 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 3781 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@328 3782 WHERE "issue"."state" = 'voting'
jbe@328 3783 AND "issue"."phase_finished" NOTNULL
jbe@126 3784 AND (
jbe@126 3785 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@126 3786 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@126 3787 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@0 3788 GROUP BY
jbe@0 3789 "issue"."id",
jbe@10 3790 "winning_initiative"."id",
jbe@10 3791 "losing_initiative"."id";
jbe@0 3792
jbe@126 3793 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 3794
jbe@1 3795
jbe@235 3796 CREATE VIEW "expired_session" AS
jbe@235 3797 SELECT * FROM "session" WHERE now() > "expiry";
jbe@235 3798
jbe@235 3799 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@532 3800 DELETE FROM "session" WHERE "id" = OLD."id";
jbe@235 3801
jbe@235 3802 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@235 3803 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 3804
jbe@235 3805
jbe@532 3806 CREATE VIEW "expired_token" AS
jbe@532 3807 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
jbe@532 3808 "token_type" = 'authorization' AND "used" AND EXISTS (
jbe@532 3809 SELECT NULL FROM "token" AS "other"
jbe@574 3810 WHERE "other"."authorization_token_id" = "token"."id" ) );
jbe@532 3811
jbe@532 3812 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
jbe@532 3813 DELETE FROM "token" WHERE "id" = OLD."id";
jbe@532 3814
jbe@532 3815 COMMENT ON VIEW "expired_token" IS 'View containing all expired tokens where DELETE is possible; Note that used authorization codes must not be deleted if still referred to by other tokens';
jbe@532 3816
jbe@532 3817
jbe@532 3818 CREATE VIEW "unused_snapshot" AS
jbe@532 3819 SELECT "snapshot".* FROM "snapshot"
jbe@532 3820 LEFT JOIN "issue"
jbe@532 3821 ON "snapshot"."id" = "issue"."latest_snapshot_id"
jbe@532 3822 OR "snapshot"."id" = "issue"."admission_snapshot_id"
jbe@532 3823 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
jbe@532 3824 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
jbe@532 3825 WHERE "issue"."id" ISNULL;
jbe@532 3826
jbe@532 3827 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
jbe@532 3828 DELETE FROM "snapshot" WHERE "id" = OLD."id";
jbe@532 3829
jbe@532 3830 COMMENT ON VIEW "unused_snapshot" IS 'Snapshots that are not referenced by any issue (either as latest snapshot or as snapshot at phase/state change)';
jbe@532 3831
jbe@532 3832
jbe@532 3833 CREATE VIEW "expired_snapshot" AS
jbe@532 3834 SELECT "unused_snapshot".* FROM "unused_snapshot" CROSS JOIN "system_setting"
jbe@532 3835 WHERE "unused_snapshot"."calculated" <
jbe@532 3836 now() - "system_setting"."snapshot_retention";
jbe@532 3837
jbe@532 3838 CREATE RULE "delete" AS ON DELETE TO "expired_snapshot" DO INSTEAD
jbe@532 3839 DELETE FROM "snapshot" WHERE "id" = OLD."id";
jbe@532 3840
jbe@532 3841 COMMENT ON VIEW "expired_snapshot" IS 'Contains "unused_snapshot"s that are older than "system_setting"."snapshot_retention" (for deletion)';
jbe@532 3842
jbe@532 3843
jbe@0 3844 CREATE VIEW "open_issue" AS
jbe@0 3845 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 3846
jbe@0 3847 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 3848
jbe@0 3849
jbe@9 3850 CREATE VIEW "member_contingent" AS
jbe@9 3851 SELECT
jbe@9 3852 "member"."id" AS "member_id",
jbe@293 3853 "contingent"."polling",
jbe@9 3854 "contingent"."time_frame",
jbe@9 3855 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 3856 (
jbe@9 3857 SELECT count(1) FROM "draft"
jbe@293 3858 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@9 3859 WHERE "draft"."author_id" = "member"."id"
jbe@293 3860 AND "initiative"."polling" = "contingent"."polling"
jbe@9 3861 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 3862 ) + (
jbe@9 3863 SELECT count(1) FROM "suggestion"
jbe@293 3864 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
jbe@9 3865 WHERE "suggestion"."author_id" = "member"."id"
jbe@293 3866 AND "contingent"."polling" = FALSE
jbe@9 3867 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 3868 )
jbe@9 3869 ELSE NULL END AS "text_entry_count",
jbe@9 3870 "contingent"."text_entry_limit",
jbe@9 3871 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@293 3872 SELECT count(1) FROM "opening_draft" AS "draft"
jbe@293 3873 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@293 3874 WHERE "draft"."author_id" = "member"."id"
jbe@293 3875 AND "initiative"."polling" = "contingent"."polling"
jbe@293 3876 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 3877 ) ELSE NULL END AS "initiative_count",
jbe@9 3878 "contingent"."initiative_limit"
jbe@9 3879 FROM "member" CROSS JOIN "contingent";
jbe@9 3880
jbe@9 3881 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 3882
jbe@9 3883 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 3884 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 3885
jbe@9 3886
jbe@9 3887 CREATE VIEW "member_contingent_left" AS
jbe@9 3888 SELECT
jbe@9 3889 "member_id",
jbe@293 3890 "polling",
jbe@9 3891 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 3892 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@293 3893 FROM "member_contingent" GROUP BY "member_id", "polling";
jbe@9 3894
jbe@9 3895 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 3896
jbe@9 3897
jbe@499 3898 CREATE VIEW "event_for_notification" AS
jbe@113 3899 SELECT
jbe@499 3900 "member"."id" AS "recipient_id",
jbe@113 3901 "event".*
jbe@113 3902 FROM "member" CROSS JOIN "event"
jbe@499 3903 JOIN "issue" ON "issue"."id" = "event"."issue_id"
jbe@499 3904 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@556 3905 LEFT JOIN "privilege" ON
jbe@556 3906 "privilege"."member_id" = "member"."id" AND
jbe@556 3907 "privilege"."unit_id" = "area"."unit_id" AND
jbe@556 3908 "privilege"."voting_right" = TRUE
jbe@499 3909 LEFT JOIN "subscription" ON
jbe@499 3910 "subscription"."member_id" = "member"."id" AND
jbe@499 3911 "subscription"."unit_id" = "area"."unit_id"
jbe@499 3912 LEFT JOIN "ignored_area" ON
jbe@499 3913 "ignored_area"."member_id" = "member"."id" AND
jbe@499 3914 "ignored_area"."area_id" = "issue"."area_id"
jbe@499 3915 LEFT JOIN "interest" ON
jbe@499 3916 "interest"."member_id" = "member"."id" AND
jbe@499 3917 "interest"."issue_id" = "event"."issue_id"
jbe@499 3918 LEFT JOIN "supporter" ON
jbe@499 3919 "supporter"."member_id" = "member"."id" AND
jbe@499 3920 "supporter"."initiative_id" = "event"."initiative_id"
jbe@556 3921 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
jbe@499 3922 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
jbe@499 3923 AND (
jbe@499 3924 "event"."event" = 'issue_state_changed'::"event_type" OR
jbe@499 3925 ( "event"."event" = 'initiative_revoked'::"event_type" AND
jbe@499 3926 "supporter"."member_id" NOTNULL ) );
jbe@499 3927
jbe@508 3928 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
jbe@508 3929
jbe@508 3930 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
jbe@222 3931
jbe@222 3932
jbe@473 3933 CREATE VIEW "updated_initiative" AS
jbe@113 3934 SELECT
jbe@499 3935 "supporter"."member_id" AS "recipient_id",
jbe@477 3936 FALSE AS "featured",
jbe@499 3937 "supporter"."initiative_id"
jbe@499 3938 FROM "supporter"
jbe@499 3939 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
jbe@473 3940 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@507 3941 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 3942 "sent"."member_id" = "supporter"."member_id" AND
jbe@499 3943 "sent"."initiative_id" = "supporter"."initiative_id"
jbe@499 3944 LEFT JOIN "ignored_initiative" ON
jbe@499 3945 "ignored_initiative"."member_id" = "supporter"."member_id" AND
jbe@499 3946 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
jbe@480 3947 WHERE "issue"."state" IN ('admission', 'discussion')
jbe@503 3948 AND "initiative"."revoked" ISNULL
jbe@499 3949 AND "ignored_initiative"."member_id" ISNULL
jbe@473 3950 AND (
jbe@473 3951 EXISTS (
jbe@473 3952 SELECT NULL FROM "draft"
jbe@499 3953 LEFT JOIN "ignored_member" ON
jbe@499 3954 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 3955 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 3956 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
jbe@473 3957 AND "draft"."id" > "supporter"."draft_id"
jbe@499 3958 AND "ignored_member"."member_id" ISNULL
jbe@473 3959 ) OR EXISTS (
jbe@473 3960 SELECT NULL FROM "suggestion"
jbe@487 3961 LEFT JOIN "opinion" ON
jbe@487 3962 "opinion"."member_id" = "supporter"."member_id" AND
jbe@487 3963 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 3964 LEFT JOIN "ignored_member" ON
jbe@499 3965 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 3966 "ignored_member"."other_member_id" = "suggestion"."author_id"
jbe@499 3967 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@487 3968 AND "opinion"."member_id" ISNULL
jbe@499 3969 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 3970 AND "ignored_member"."member_id" ISNULL
jbe@473 3971 )
jbe@473 3972 );
jbe@473 3973
jbe@508 3974 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
jbe@508 3975
jbe@508 3976
jbe@474 3977 CREATE FUNCTION "featured_initiative"
jbe@499 3978 ( "recipient_id_p" "member"."id"%TYPE,
jbe@499 3979 "area_id_p" "area"."id"%TYPE )
jbe@499 3980 RETURNS SETOF "initiative"."id"%TYPE
jbe@474 3981 LANGUAGE 'plpgsql' STABLE AS $$
jbe@474 3982 DECLARE
jbe@499 3983 "counter_v" "member"."notification_counter"%TYPE;
jbe@499 3984 "sample_size_v" "member"."notification_sample_size"%TYPE;
jbe@499 3985 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
jbe@499 3986 "match_v" BOOLEAN;
jbe@474 3987 "member_id_v" "member"."id"%TYPE;
jbe@474 3988 "seed_v" TEXT;
jbe@499 3989 "initiative_id_v" "initiative"."id"%TYPE;
jbe@474 3990 BEGIN
jbe@499 3991 SELECT "notification_counter", "notification_sample_size"
jbe@499 3992 INTO "counter_v", "sample_size_v"
jbe@499 3993 FROM "member" WHERE "id" = "recipient_id_p";
jbe@520 3994 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
jbe@520 3995 RETURN;
jbe@520 3996 END IF;
jbe@474 3997 "initiative_id_ary" := '{}';
jbe@474 3998 LOOP
jbe@474 3999 "match_v" := FALSE;
jbe@474 4000 FOR "member_id_v", "seed_v" IN
jbe@474 4001 SELECT * FROM (
jbe@474 4002 SELECT DISTINCT
jbe@474 4003 "supporter"."member_id",
jbe@499 4004 md5(
jbe@499 4005 "recipient_id_p" || '-' ||
jbe@499 4006 "counter_v" || '-' ||
jbe@499 4007 "area_id_p" || '-' ||
jbe@499 4008 "supporter"."member_id"
jbe@499 4009 ) AS "seed"
jbe@474 4010 FROM "supporter"
jbe@474 4011 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
jbe@474 4012 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 4013 WHERE "supporter"."member_id" != "recipient_id_p"
jbe@474 4014 AND "issue"."area_id" = "area_id_p"
jbe@474 4015 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@474 4016 ) AS "subquery"
jbe@474 4017 ORDER BY "seed"
jbe@474 4018 LOOP
jbe@499 4019 SELECT "initiative"."id" INTO "initiative_id_v"
jbe@476 4020 FROM "initiative"
jbe@474 4021 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 4022 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@474 4023 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
jbe@474 4024 LEFT JOIN "supporter" AS "self_support" ON
jbe@474 4025 "self_support"."initiative_id" = "initiative"."id" AND
jbe@499 4026 "self_support"."member_id" = "recipient_id_p"
jbe@556 4027 LEFT JOIN "privilege" ON
jbe@556 4028 "privilege"."member_id" = "recipient_id_p" AND
jbe@556 4029 "privilege"."unit_id" = "area"."unit_id" AND
jbe@556 4030 "privilege"."voting_right" = TRUE
jbe@499 4031 LEFT JOIN "subscription" ON
jbe@499 4032 "subscription"."member_id" = "recipient_id_p" AND
jbe@499 4033 "subscription"."unit_id" = "area"."unit_id"
jbe@499 4034 LEFT JOIN "ignored_initiative" ON
jbe@499 4035 "ignored_initiative"."member_id" = "recipient_id_p" AND
jbe@499 4036 "ignored_initiative"."initiative_id" = "initiative"."id"
jbe@474 4037 WHERE "supporter"."member_id" = "member_id_v"
jbe@474 4038 AND "issue"."area_id" = "area_id_p"
jbe@474 4039 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@503 4040 AND "initiative"."revoked" ISNULL
jbe@474 4041 AND "self_support"."member_id" ISNULL
jbe@476 4042 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
jbe@499 4043 AND (
jbe@556 4044 "privilege"."member_id" NOTNULL OR
jbe@499 4045 "subscription"."member_id" NOTNULL )
jbe@499 4046 AND "ignored_initiative"."member_id" ISNULL
jbe@499 4047 AND NOT EXISTS (
jbe@499 4048 SELECT NULL FROM "draft"
jbe@499 4049 JOIN "ignored_member" ON
jbe@499 4050 "ignored_member"."member_id" = "recipient_id_p" AND
jbe@499 4051 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 4052 WHERE "draft"."initiative_id" = "initiative"."id"
jbe@499 4053 )
jbe@474 4054 ORDER BY md5("seed_v" || '-' || "initiative"."id")
jbe@476 4055 LIMIT 1;
jbe@476 4056 IF FOUND THEN
jbe@476 4057 "match_v" := TRUE;
jbe@499 4058 RETURN NEXT "initiative_id_v";
jbe@499 4059 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
jbe@476 4060 RETURN;
jbe@474 4061 END IF;
jbe@499 4062 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
jbe@476 4063 END IF;
jbe@474 4064 END LOOP;
jbe@474 4065 EXIT WHEN NOT "match_v";
jbe@474 4066 END LOOP;
jbe@474 4067 RETURN;
jbe@474 4068 END;
jbe@474 4069 $$;
jbe@474 4070
jbe@508 4071 COMMENT ON FUNCTION "featured_initiative"
jbe@508 4072 ( "recipient_id_p" "member"."id"%TYPE,
jbe@508 4073 "area_id_p" "area"."id"%TYPE )
jbe@508 4074 IS 'Helper function for view "updated_or_featured_initiative"';
jbe@508 4075
jbe@508 4076
jbe@474 4077 CREATE VIEW "updated_or_featured_initiative" AS
jbe@474 4078 SELECT
jbe@499 4079 "subquery".*,
jbe@477 4080 NOT EXISTS (
jbe@477 4081 SELECT NULL FROM "initiative" AS "better_initiative"
jbe@499 4082 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
jbe@484 4083 AND
jbe@502 4084 ( COALESCE("better_initiative"."supporter_count", -1),
jbe@484 4085 -"better_initiative"."id" ) >
jbe@502 4086 ( COALESCE("initiative"."supporter_count", -1),
jbe@485 4087 -"initiative"."id" )
jbe@499 4088 ) AS "leading"
jbe@499 4089 FROM (
jbe@499 4090 SELECT * FROM "updated_initiative"
jbe@499 4091 UNION ALL
jbe@499 4092 SELECT
jbe@499 4093 "member"."id" AS "recipient_id",
jbe@499 4094 TRUE AS "featured",
jbe@499 4095 "featured_initiative_id" AS "initiative_id"
jbe@499 4096 FROM "member" CROSS JOIN "area"
jbe@499 4097 CROSS JOIN LATERAL
jbe@499 4098 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
jbe@499 4099 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
jbe@499 4100 ) AS "subquery"
jbe@499 4101 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
jbe@474 4102
jbe@508 4103 COMMENT ON VIEW "updated_or_featured_initiative" IS 'Initiatives to be included in a scheduled notification mail because (a) they have been updated or (b) they are featured';
jbe@508 4104
jbe@508 4105 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 4106 COMMENT ON COLUMN "updated_or_featured_initiative"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
jbe@508 4107 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 4108 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 4109
jbe@508 4110
jbe@474 4111 CREATE VIEW "leading_complement_initiative" AS
jbe@477 4112 SELECT * FROM (
jbe@499 4113 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
jbe@499 4114 "uf_initiative"."recipient_id",
jbe@477 4115 FALSE AS "featured",
jbe@499 4116 "uf_initiative"."initiative_id",
jbe@499 4117 TRUE AS "leading"
jbe@489 4118 FROM "updated_or_featured_initiative" AS "uf_initiative"
jbe@499 4119 JOIN "initiative" AS "uf_initiative_full" ON
jbe@499 4120 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
jbe@489 4121 JOIN "initiative" ON
jbe@499 4122 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
jbe@503 4123 WHERE "initiative"."revoked" ISNULL
jbe@477 4124 ORDER BY
jbe@499 4125 "uf_initiative"."recipient_id",
jbe@477 4126 "initiative"."issue_id",
jbe@502 4127 "initiative"."supporter_count" DESC,
jbe@477 4128 "initiative"."id"
jbe@477 4129 ) AS "subquery"
jbe@477 4130 WHERE NOT EXISTS (
jbe@477 4131 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
jbe@499 4132 WHERE "other"."recipient_id" = "subquery"."recipient_id"
jbe@499 4133 AND "other"."initiative_id" = "subquery"."initiative_id"
jbe@477 4134 );
jbe@474 4135
jbe@508 4136 COMMENT ON VIEW "leading_complement_initiative" IS 'Helper view for view "unfiltered_initiative_for_notification" in order to always include the most supported initiative of an issue';
jbe@508 4137 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
jbe@508 4138 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 4139 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
jbe@508 4140
jbe@508 4141
jbe@490 4142 CREATE VIEW "unfiltered_initiative_for_notification" AS
jbe@499 4143 SELECT
jbe@499 4144 "subquery".*,
jbe@499 4145 "supporter"."member_id" NOTNULL AS "supported",
jbe@499 4146 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 4147 EXISTS (
jbe@499 4148 SELECT NULL FROM "draft"
jbe@499 4149 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 4150 AND "draft"."id" > "supporter"."draft_id"
jbe@499 4151 )
jbe@222 4152 ELSE
jbe@499 4153 EXISTS (
jbe@499 4154 SELECT NULL FROM "draft"
jbe@499 4155 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 4156 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
jbe@499 4157 )
jbe@499 4158 END AS "new_draft",
jbe@499 4159 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 4160 ( SELECT count(1) FROM "suggestion"
jbe@499 4161 LEFT JOIN "opinion" ON
jbe@499 4162 "opinion"."member_id" = "supporter"."member_id" AND
jbe@499 4163 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 4164 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 4165 AND "opinion"."member_id" ISNULL
jbe@499 4166 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 4167 )
jbe@499 4168 ELSE
jbe@499 4169 ( SELECT count(1) FROM "suggestion"
jbe@499 4170 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 4171 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 4172 )
jbe@499 4173 END AS "new_suggestion_count"
jbe@499 4174 FROM (
jbe@499 4175 SELECT * FROM "updated_or_featured_initiative"
jbe@499 4176 UNION ALL
jbe@499 4177 SELECT * FROM "leading_complement_initiative"
jbe@499 4178 ) AS "subquery"
jbe@499 4179 LEFT JOIN "supporter" ON
jbe@499 4180 "supporter"."member_id" = "subquery"."recipient_id" AND
jbe@499 4181 "supporter"."initiative_id" = "subquery"."initiative_id"
jbe@507 4182 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 4183 "sent"."member_id" = "subquery"."recipient_id" AND
jbe@499 4184 "sent"."initiative_id" = "subquery"."initiative_id";
jbe@474 4185
jbe@508 4186 COMMENT ON VIEW "unfiltered_initiative_for_notification" IS 'Helper view which simply combines the views "updated_or_featured_initiative" and "leading_complement_initiative" and adds columns "supported", "new_draft", and "new_suggestion_count';
jbe@508 4187
jbe@508 4188 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 4189 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
jbe@508 4190 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
jbe@508 4191
jbe@508 4192
jbe@490 4193 CREATE VIEW "initiative_for_notification" AS
jbe@499 4194 SELECT "unfiltered1".*
jbe@499 4195 FROM "unfiltered_initiative_for_notification" "unfiltered1"
jbe@499 4196 JOIN "initiative" AS "initiative1" ON
jbe@499 4197 "initiative1"."id" = "unfiltered1"."initiative_id"
jbe@499 4198 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
jbe@490 4199 WHERE EXISTS (
jbe@490 4200 SELECT NULL
jbe@499 4201 FROM "unfiltered_initiative_for_notification" "unfiltered2"
jbe@499 4202 JOIN "initiative" AS "initiative2" ON
jbe@499 4203 "initiative2"."id" = "unfiltered2"."initiative_id"
jbe@499 4204 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
jbe@499 4205 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
jbe@490 4206 AND "issue1"."area_id" = "issue2"."area_id"
jbe@499 4207 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
jbe@490 4208 );
jbe@490 4209
jbe@508 4210 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
jbe@508 4211
jbe@508 4212 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 4213 COMMENT ON COLUMN "initiative_for_notification"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
jbe@508 4214 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 4215 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 4216 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 4217 COMMENT ON COLUMN "initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
jbe@508 4218 COMMENT ON COLUMN "initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
jbe@508 4219
jbe@508 4220
jbe@504 4221 CREATE VIEW "scheduled_notification_to_send" AS
jbe@505 4222 SELECT * FROM (
jbe@505 4223 SELECT
jbe@505 4224 "id" AS "recipient_id",
jbe@505 4225 now() - CASE WHEN "notification_dow" ISNULL THEN
jbe@505 4226 ( "notification_sent"::DATE + CASE
jbe@505 4227 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 4228 THEN 0 ELSE 1 END
jbe@505 4229 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@222 4230 ELSE
jbe@505 4231 ( "notification_sent"::DATE +
jbe@505 4232 ( 7 + "notification_dow" -
jbe@505 4233 EXTRACT(DOW FROM
jbe@505 4234 ( "notification_sent"::DATE + CASE
jbe@505 4235 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 4236 THEN 0 ELSE 1 END
jbe@505 4237 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 4238 )::INTEGER
jbe@505 4239 ) % 7 +
jbe@505 4240 CASE
jbe@505 4241 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 4242 THEN 0 ELSE 1
jbe@505 4243 END
jbe@505 4244 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 4245 END AS "pending"
jbe@505 4246 FROM (
jbe@505 4247 SELECT
jbe@505 4248 "id",
jbe@505 4249 COALESCE("notification_sent", "activated") AS "notification_sent",
jbe@505 4250 "notification_dow",
jbe@505 4251 "notification_hour"
jbe@524 4252 FROM "member_to_notify"
jbe@524 4253 WHERE "notification_hour" NOTNULL
jbe@505 4254 ) AS "subquery1"
jbe@505 4255 ) AS "subquery2"
jbe@505 4256 WHERE "pending" > '0'::INTERVAL;
jbe@504 4257
jbe@508 4258 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
jbe@508 4259
jbe@508 4260 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
jbe@508 4261 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
jbe@508 4262
jbe@508 4263
jbe@497 4264 CREATE VIEW "newsletter_to_send" AS
jbe@497 4265 SELECT
jbe@499 4266 "member"."id" AS "recipient_id",
jbe@514 4267 "newsletter"."id" AS "newsletter_id",
jbe@514 4268 "newsletter"."published"
jbe@524 4269 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
jbe@556 4270 LEFT JOIN "privilege" ON
jbe@556 4271 "privilege"."member_id" = "member"."id" AND
jbe@556 4272 "privilege"."unit_id" = "newsletter"."unit_id" AND
jbe@556 4273 "privilege"."voting_right" = TRUE
jbe@497 4274 LEFT JOIN "subscription" ON
jbe@497 4275 "subscription"."member_id" = "member"."id" AND
jbe@497 4276 "subscription"."unit_id" = "newsletter"."unit_id"
jbe@498 4277 WHERE "newsletter"."published" <= now()
jbe@497 4278 AND "newsletter"."sent" ISNULL
jbe@113 4279 AND (
jbe@497 4280 "member"."disable_notifications" = FALSE OR
jbe@497 4281 "newsletter"."include_all_members" = TRUE )
jbe@497 4282 AND (
jbe@497 4283 "newsletter"."unit_id" ISNULL OR
jbe@556 4284 "privilege"."member_id" NOTNULL OR
jbe@497 4285 "subscription"."member_id" NOTNULL );
jbe@497 4286
jbe@508 4287 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
jbe@508 4288
jbe@514 4289 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
jbe@113 4290
jbe@113 4291
jbe@0 4292
jbe@242 4293 ------------------------------------------------------
jbe@242 4294 -- Row set returning function for delegation chains --
jbe@242 4295 ------------------------------------------------------
jbe@5 4296
jbe@5 4297
jbe@5 4298 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 4299 ('first', 'intermediate', 'last', 'repetition');
jbe@5 4300
jbe@5 4301 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 4302
jbe@5 4303
jbe@5 4304 CREATE TYPE "delegation_chain_row" AS (
jbe@5 4305 "index" INT4,
jbe@5 4306 "member_id" INT4,
jbe@97 4307 "member_valid" BOOLEAN,
jbe@5 4308 "participation" BOOLEAN,
jbe@5 4309 "overridden" BOOLEAN,
jbe@5 4310 "scope_in" "delegation_scope",
jbe@5 4311 "scope_out" "delegation_scope",
jbe@86 4312 "disabled_out" BOOLEAN,
jbe@5 4313 "loop" "delegation_chain_loop_tag" );
jbe@5 4314
jbe@243 4315 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
jbe@5 4316
jbe@5 4317 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@532 4318 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
jbe@5 4319 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 4320 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 4321 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 4322 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 4323 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 4324
jbe@5 4325
jbe@242 4326 CREATE FUNCTION "delegation_chain_for_closed_issue"
jbe@242 4327 ( "member_id_p" "member"."id"%TYPE,
jbe@242 4328 "issue_id_p" "issue"."id"%TYPE )
jbe@242 4329 RETURNS SETOF "delegation_chain_row"
jbe@242 4330 LANGUAGE 'plpgsql' STABLE AS $$
jbe@242 4331 DECLARE
jbe@242 4332 "output_row" "delegation_chain_row";
jbe@242 4333 "direct_voter_row" "direct_voter"%ROWTYPE;
jbe@242 4334 "delegating_voter_row" "delegating_voter"%ROWTYPE;
jbe@242 4335 BEGIN
jbe@242 4336 "output_row"."index" := 0;
jbe@242 4337 "output_row"."member_id" := "member_id_p";
jbe@242 4338 "output_row"."member_valid" := TRUE;
jbe@242 4339 "output_row"."participation" := FALSE;
jbe@242 4340 "output_row"."overridden" := FALSE;
jbe@242 4341 "output_row"."disabled_out" := FALSE;
jbe@242 4342 LOOP
jbe@242 4343 SELECT INTO "direct_voter_row" * FROM "direct_voter"
jbe@242 4344 WHERE "issue_id" = "issue_id_p"
jbe@242 4345 AND "member_id" = "output_row"."member_id";
jbe@242 4346 IF "direct_voter_row"."member_id" NOTNULL THEN
jbe@242 4347 "output_row"."participation" := TRUE;
jbe@242 4348 "output_row"."scope_out" := NULL;
jbe@242 4349 "output_row"."disabled_out" := NULL;
jbe@242 4350 RETURN NEXT "output_row";
jbe@242 4351 RETURN;
jbe@242 4352 END IF;
jbe@242 4353 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
jbe@242 4354 WHERE "issue_id" = "issue_id_p"
jbe@242 4355 AND "member_id" = "output_row"."member_id";
jbe@242 4356 IF "delegating_voter_row"."member_id" ISNULL THEN
jbe@242 4357 RETURN;
jbe@242 4358 END IF;
jbe@242 4359 "output_row"."scope_out" := "delegating_voter_row"."scope";
jbe@242 4360 RETURN NEXT "output_row";
jbe@242 4361 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
jbe@242 4362 "output_row"."scope_in" := "output_row"."scope_out";
jbe@242 4363 END LOOP;
jbe@242 4364 END;
jbe@242 4365 $$;
jbe@242 4366
jbe@242 4367 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
jbe@242 4368 ( "member"."id"%TYPE,
jbe@242 4369 "member"."id"%TYPE )
jbe@242 4370 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
jbe@242 4371
jbe@242 4372
jbe@5 4373 CREATE FUNCTION "delegation_chain"
jbe@5 4374 ( "member_id_p" "member"."id"%TYPE,
jbe@97 4375 "unit_id_p" "unit"."id"%TYPE,
jbe@5 4376 "area_id_p" "area"."id"%TYPE,
jbe@5 4377 "issue_id_p" "issue"."id"%TYPE,
jbe@255 4378 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 4379 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@5 4380 RETURNS SETOF "delegation_chain_row"
jbe@5 4381 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 4382 DECLARE
jbe@97 4383 "scope_v" "delegation_scope";
jbe@97 4384 "unit_id_v" "unit"."id"%TYPE;
jbe@97 4385 "area_id_v" "area"."id"%TYPE;
jbe@241 4386 "issue_row" "issue"%ROWTYPE;
jbe@5 4387 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 4388 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 4389 "output_row" "delegation_chain_row";
jbe@5 4390 "output_rows" "delegation_chain_row"[];
jbe@255 4391 "simulate_v" BOOLEAN;
jbe@255 4392 "simulate_here_v" BOOLEAN;
jbe@5 4393 "delegation_row" "delegation"%ROWTYPE;
jbe@5 4394 "row_count" INT4;
jbe@5 4395 "i" INT4;
jbe@5 4396 "loop_v" BOOLEAN;
jbe@5 4397 BEGIN
jbe@255 4398 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
jbe@255 4399 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
jbe@255 4400 END IF;
jbe@255 4401 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
jbe@255 4402 "simulate_v" := TRUE;
jbe@255 4403 ELSE
jbe@255 4404 "simulate_v" := FALSE;
jbe@255 4405 END IF;
jbe@97 4406 IF
jbe@97 4407 "unit_id_p" NOTNULL AND
jbe@97 4408 "area_id_p" ISNULL AND
jbe@97 4409 "issue_id_p" ISNULL
jbe@97 4410 THEN
jbe@97 4411 "scope_v" := 'unit';
jbe@97 4412 "unit_id_v" := "unit_id_p";
jbe@97 4413 ELSIF
jbe@97 4414 "unit_id_p" ISNULL AND
jbe@97 4415 "area_id_p" NOTNULL AND
jbe@97 4416 "issue_id_p" ISNULL
jbe@97 4417 THEN
jbe@97 4418 "scope_v" := 'area';
jbe@97 4419 "area_id_v" := "area_id_p";
jbe@97 4420 SELECT "unit_id" INTO "unit_id_v"
jbe@97 4421 FROM "area" WHERE "id" = "area_id_v";
jbe@97 4422 ELSIF
jbe@97 4423 "unit_id_p" ISNULL AND
jbe@97 4424 "area_id_p" ISNULL AND
jbe@97 4425 "issue_id_p" NOTNULL
jbe@97 4426 THEN
jbe@242 4427 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@242 4428 IF "issue_row"."id" ISNULL THEN
jbe@242 4429 RETURN;
jbe@242 4430 END IF;
jbe@242 4431 IF "issue_row"."closed" NOTNULL THEN
jbe@255 4432 IF "simulate_v" THEN
jbe@242 4433 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@242 4434 END IF;
jbe@242 4435 FOR "output_row" IN
jbe@242 4436 SELECT * FROM
jbe@242 4437 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@242 4438 LOOP
jbe@242 4439 RETURN NEXT "output_row";
jbe@242 4440 END LOOP;
jbe@242 4441 RETURN;
jbe@242 4442 END IF;
jbe@97 4443 "scope_v" := 'issue';
jbe@97 4444 SELECT "area_id" INTO "area_id_v"
jbe@97 4445 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 4446 SELECT "unit_id" INTO "unit_id_v"
jbe@97 4447 FROM "area" WHERE "id" = "area_id_v";
jbe@97 4448 ELSE
jbe@97 4449 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 4450 END IF;
jbe@5 4451 "visited_member_ids" := '{}';
jbe@5 4452 "loop_member_id_v" := NULL;
jbe@5 4453 "output_rows" := '{}';
jbe@5 4454 "output_row"."index" := 0;
jbe@5 4455 "output_row"."member_id" := "member_id_p";
jbe@97 4456 "output_row"."member_valid" := TRUE;
jbe@5 4457 "output_row"."participation" := FALSE;
jbe@5 4458 "output_row"."overridden" := FALSE;
jbe@86 4459 "output_row"."disabled_out" := FALSE;
jbe@5 4460 "output_row"."scope_out" := NULL;
jbe@5 4461 LOOP
jbe@5 4462 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 4463 "loop_member_id_v" := "output_row"."member_id";
jbe@5 4464 ELSE
jbe@5 4465 "visited_member_ids" :=
jbe@5 4466 "visited_member_ids" || "output_row"."member_id";
jbe@5 4467 END IF;
jbe@241 4468 IF "output_row"."participation" ISNULL THEN
jbe@241 4469 "output_row"."overridden" := NULL;
jbe@241 4470 ELSIF "output_row"."participation" THEN
jbe@5 4471 "output_row"."overridden" := TRUE;
jbe@5 4472 END IF;
jbe@5 4473 "output_row"."scope_in" := "output_row"."scope_out";
jbe@255 4474 "output_row"."member_valid" := EXISTS (
jbe@556 4475 SELECT NULL FROM "member" JOIN "privilege"
jbe@556 4476 ON "privilege"."member_id" = "member"."id"
jbe@556 4477 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 4478 WHERE "id" = "output_row"."member_id"
jbe@556 4479 AND "member"."active" AND "privilege"."voting_right"
jbe@255 4480 );
jbe@255 4481 "simulate_here_v" := (
jbe@255 4482 "simulate_v" AND
jbe@255 4483 "output_row"."member_id" = "member_id_p"
jbe@255 4484 );
jbe@255 4485 "delegation_row" := ROW(NULL);
jbe@255 4486 IF "output_row"."member_valid" OR "simulate_here_v" THEN
jbe@97 4487 IF "scope_v" = 'unit' THEN
jbe@255 4488 IF NOT "simulate_here_v" THEN
jbe@255 4489 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 4490 WHERE "truster_id" = "output_row"."member_id"
jbe@255 4491 AND "unit_id" = "unit_id_v";
jbe@255 4492 END IF;
jbe@97 4493 ELSIF "scope_v" = 'area' THEN
jbe@255 4494 IF "simulate_here_v" THEN
jbe@255 4495 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 4496 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 4497 WHERE "truster_id" = "output_row"."member_id"
jbe@255 4498 AND "unit_id" = "unit_id_v";
jbe@255 4499 END IF;
jbe@255 4500 ELSE
jbe@255 4501 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 4502 WHERE "truster_id" = "output_row"."member_id"
jbe@255 4503 AND (
jbe@255 4504 "unit_id" = "unit_id_v" OR
jbe@255 4505 "area_id" = "area_id_v"
jbe@255 4506 )
jbe@255 4507 ORDER BY "scope" DESC;
jbe@255 4508 END IF;
jbe@97 4509 ELSIF "scope_v" = 'issue' THEN
jbe@241 4510 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@241 4511 "output_row"."participation" := EXISTS (
jbe@241 4512 SELECT NULL FROM "interest"
jbe@241 4513 WHERE "issue_id" = "issue_id_p"
jbe@241 4514 AND "member_id" = "output_row"."member_id"
jbe@241 4515 );
jbe@241 4516 ELSE
jbe@241 4517 IF "output_row"."member_id" = "member_id_p" THEN
jbe@241 4518 "output_row"."participation" := EXISTS (
jbe@241 4519 SELECT NULL FROM "direct_voter"
jbe@241 4520 WHERE "issue_id" = "issue_id_p"
jbe@241 4521 AND "member_id" = "output_row"."member_id"
jbe@241 4522 );
jbe@241 4523 ELSE
jbe@241 4524 "output_row"."participation" := NULL;
jbe@241 4525 END IF;
jbe@241 4526 END IF;
jbe@255 4527 IF "simulate_here_v" THEN
jbe@255 4528 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 4529 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 4530 WHERE "truster_id" = "output_row"."member_id"
jbe@255 4531 AND (
jbe@255 4532 "unit_id" = "unit_id_v" OR
jbe@255 4533 "area_id" = "area_id_v"
jbe@255 4534 )
jbe@255 4535 ORDER BY "scope" DESC;
jbe@255 4536 END IF;
jbe@255 4537 ELSE
jbe@255 4538 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 4539 WHERE "truster_id" = "output_row"."member_id"
jbe@255 4540 AND (
jbe@255 4541 "unit_id" = "unit_id_v" OR
jbe@255 4542 "area_id" = "area_id_v" OR
jbe@255 4543 "issue_id" = "issue_id_p"
jbe@255 4544 )
jbe@255 4545 ORDER BY "scope" DESC;
jbe@255 4546 END IF;
jbe@5 4547 END IF;
jbe@5 4548 ELSE
jbe@5 4549 "output_row"."participation" := FALSE;
jbe@5 4550 END IF;
jbe@255 4551 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
jbe@97 4552 "output_row"."scope_out" := "scope_v";
jbe@5 4553 "output_rows" := "output_rows" || "output_row";
jbe@5 4554 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 4555 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 4556 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 4557 "output_rows" := "output_rows" || "output_row";
jbe@5 4558 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 4559 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 4560 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 4561 "output_row"."disabled_out" := TRUE;
jbe@86 4562 "output_rows" := "output_rows" || "output_row";
jbe@86 4563 EXIT;
jbe@5 4564 ELSE
jbe@5 4565 "output_row"."scope_out" := NULL;
jbe@5 4566 "output_rows" := "output_rows" || "output_row";
jbe@5 4567 EXIT;
jbe@5 4568 END IF;
jbe@5 4569 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 4570 "output_row"."index" := "output_row"."index" + 1;
jbe@5 4571 END LOOP;
jbe@5 4572 "row_count" := array_upper("output_rows", 1);
jbe@5 4573 "i" := 1;
jbe@5 4574 "loop_v" := FALSE;
jbe@5 4575 LOOP
jbe@5 4576 "output_row" := "output_rows"["i"];
jbe@98 4577 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 4578 IF "loop_v" THEN
jbe@5 4579 IF "i" + 1 = "row_count" THEN
jbe@5 4580 "output_row"."loop" := 'last';
jbe@5 4581 ELSIF "i" = "row_count" THEN
jbe@5 4582 "output_row"."loop" := 'repetition';
jbe@5 4583 ELSE
jbe@5 4584 "output_row"."loop" := 'intermediate';
jbe@5 4585 END IF;
jbe@5 4586 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 4587 "output_row"."loop" := 'first';
jbe@5 4588 "loop_v" := TRUE;
jbe@5 4589 END IF;
jbe@97 4590 IF "scope_v" = 'unit' THEN
jbe@5 4591 "output_row"."participation" := NULL;
jbe@5 4592 END IF;
jbe@5 4593 RETURN NEXT "output_row";
jbe@5 4594 "i" := "i" + 1;
jbe@5 4595 END LOOP;
jbe@5 4596 RETURN;
jbe@5 4597 END;
jbe@5 4598 $$;
jbe@5 4599
jbe@5 4600 COMMENT ON FUNCTION "delegation_chain"
jbe@5 4601 ( "member"."id"%TYPE,
jbe@97 4602 "unit"."id"%TYPE,
jbe@5 4603 "area"."id"%TYPE,
jbe@5 4604 "issue"."id"%TYPE,
jbe@255 4605 "member"."id"%TYPE,
jbe@255 4606 BOOLEAN )
jbe@242 4607 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
jbe@242 4608
jbe@242 4609
jbe@242 4610
jbe@242 4611 ---------------------------------------------------------
jbe@242 4612 -- Single row returning function for delegation chains --
jbe@242 4613 ---------------------------------------------------------
jbe@242 4614
jbe@242 4615
jbe@242 4616 CREATE TYPE "delegation_info_loop_type" AS ENUM
jbe@242 4617 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
jbe@240 4618
jbe@243 4619 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 4620
jbe@243 4621
jbe@240 4622 CREATE TYPE "delegation_info_type" AS (
jbe@242 4623 "own_participation" BOOLEAN,
jbe@242 4624 "own_delegation_scope" "delegation_scope",
jbe@242 4625 "first_trustee_id" INT4,
jbe@240 4626 "first_trustee_participation" BOOLEAN,
jbe@242 4627 "first_trustee_ellipsis" BOOLEAN,
jbe@242 4628 "other_trustee_id" INT4,
jbe@240 4629 "other_trustee_participation" BOOLEAN,
jbe@242 4630 "other_trustee_ellipsis" BOOLEAN,
jbe@253 4631 "delegation_loop" "delegation_info_loop_type",
jbe@253 4632 "participating_member_id" INT4 );
jbe@240 4633
jbe@243 4634 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 4635
jbe@243 4636 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
jbe@243 4637 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
jbe@243 4638 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
jbe@243 4639 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
jbe@243 4640 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
jbe@243 4641 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
jbe@243 4642 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 4643 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
jbe@243 4644 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 4645 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
jbe@243 4646
jbe@243 4647
jbe@240 4648 CREATE FUNCTION "delegation_info"
jbe@242 4649 ( "member_id_p" "member"."id"%TYPE,
jbe@242 4650 "unit_id_p" "unit"."id"%TYPE,
jbe@242 4651 "area_id_p" "area"."id"%TYPE,
jbe@242 4652 "issue_id_p" "issue"."id"%TYPE,
jbe@255 4653 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 4654 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@240 4655 RETURNS "delegation_info_type"
jbe@240 4656 LANGUAGE 'plpgsql' STABLE AS $$
jbe@240 4657 DECLARE
jbe@242 4658 "current_row" "delegation_chain_row";
jbe@242 4659 "result" "delegation_info_type";
jbe@240 4660 BEGIN
jbe@242 4661 "result"."own_participation" := FALSE;
jbe@242 4662 FOR "current_row" IN
jbe@242 4663 SELECT * FROM "delegation_chain"(
jbe@242 4664 "member_id_p",
jbe@242 4665 "unit_id_p", "area_id_p", "issue_id_p",
jbe@255 4666 "simulate_trustee_id_p", "simulate_default_p")
jbe@242 4667 LOOP
jbe@253 4668 IF
jbe@253 4669 "result"."participating_member_id" ISNULL AND
jbe@253 4670 "current_row"."participation"
jbe@253 4671 THEN
jbe@253 4672 "result"."participating_member_id" := "current_row"."member_id";
jbe@253 4673 END IF;
jbe@242 4674 IF "current_row"."member_id" = "member_id_p" THEN
jbe@242 4675 "result"."own_participation" := "current_row"."participation";
jbe@242 4676 "result"."own_delegation_scope" := "current_row"."scope_out";
jbe@242 4677 IF "current_row"."loop" = 'first' THEN
jbe@242 4678 "result"."delegation_loop" := 'own';
jbe@242 4679 END IF;
jbe@242 4680 ELSIF
jbe@242 4681 "current_row"."member_valid" AND
jbe@242 4682 ( "current_row"."loop" ISNULL OR
jbe@242 4683 "current_row"."loop" != 'repetition' )
jbe@242 4684 THEN
jbe@242 4685 IF "result"."first_trustee_id" ISNULL THEN
jbe@242 4686 "result"."first_trustee_id" := "current_row"."member_id";
jbe@242 4687 "result"."first_trustee_participation" := "current_row"."participation";
jbe@242 4688 "result"."first_trustee_ellipsis" := FALSE;
jbe@242 4689 IF "current_row"."loop" = 'first' THEN
jbe@242 4690 "result"."delegation_loop" := 'first';
jbe@242 4691 END IF;
jbe@242 4692 ELSIF "result"."other_trustee_id" ISNULL THEN
jbe@247 4693 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
jbe@242 4694 "result"."other_trustee_id" := "current_row"."member_id";
jbe@242 4695 "result"."other_trustee_participation" := TRUE;
jbe@242 4696 "result"."other_trustee_ellipsis" := FALSE;
jbe@242 4697 IF "current_row"."loop" = 'first' THEN
jbe@242 4698 "result"."delegation_loop" := 'other';
jbe@240 4699 END IF;
jbe@240 4700 ELSE
jbe@242 4701 "result"."first_trustee_ellipsis" := TRUE;
jbe@242 4702 IF "current_row"."loop" = 'first' THEN
jbe@242 4703 "result"."delegation_loop" := 'first_ellipsis';
jbe@242 4704 END IF;
jbe@242 4705 END IF;
jbe@242 4706 ELSE
jbe@242 4707 "result"."other_trustee_ellipsis" := TRUE;
jbe@242 4708 IF "current_row"."loop" = 'first' THEN
jbe@242 4709 "result"."delegation_loop" := 'other_ellipsis';
jbe@240 4710 END IF;
jbe@240 4711 END IF;
jbe@240 4712 END IF;
jbe@242 4713 END LOOP;
jbe@240 4714 RETURN "result";
jbe@240 4715 END;
jbe@240 4716 $$;
jbe@240 4717
jbe@243 4718 COMMENT ON FUNCTION "delegation_info"
jbe@243 4719 ( "member"."id"%TYPE,
jbe@243 4720 "unit"."id"%TYPE,
jbe@243 4721 "area"."id"%TYPE,
jbe@243 4722 "issue"."id"%TYPE,
jbe@255 4723 "member"."id"%TYPE,
jbe@255 4724 BOOLEAN )
jbe@243 4725 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
jbe@243 4726
jbe@240 4727
jbe@240 4728
jbe@573 4729 ------------------------
jbe@573 4730 -- Geospatial lookups --
jbe@573 4731 ------------------------
jbe@573 4732
jbe@577 4733 /*
jbe@573 4734 CREATE FUNCTION "closed_initiatives_in_bounding_box"
jbe@573 4735 ( "bounding_box_p" EBOX,
jbe@573 4736 "limit_p" INT4 )
jbe@573 4737 RETURNS SETOF "initiative"
jbe@573 4738 LANGUAGE 'plpgsql' STABLE AS $$
jbe@573 4739 DECLARE
jbe@573 4740 "limit_v" INT4;
jbe@573 4741 "count_v" INT4;
jbe@573 4742 BEGIN
jbe@573 4743 "limit_v" := "limit_p" + 1;
jbe@573 4744 LOOP
jbe@573 4745 SELECT count(1) INTO "count_v"
jbe@573 4746 FROM "initiative"
jbe@573 4747 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@573 4748 WHERE "issue"."closed" NOTNULL
jbe@573 4749 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
jbe@573 4750 LIMIT "limit_v";
jbe@573 4751 IF "count_v" < "limit_v" THEN
jbe@573 4752 RETURN QUERY SELECT "initiative".*
jbe@573 4753 FROM (
jbe@573 4754 SELECT
jbe@573 4755 "initiative"."id" AS "initiative_id",
jbe@573 4756 "issue"."closed"
jbe@573 4757 FROM "initiative"
jbe@573 4758 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@573 4759 WHERE "issue"."closed" NOTNULL
jbe@573 4760 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
jbe@573 4761 ) AS "subquery"
jbe@573 4762 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
jbe@573 4763 ORDER BY "subquery"."closed" DESC
jbe@573 4764 LIMIT "limit_p";
jbe@573 4765 RETURN;
jbe@573 4766 END IF;
jbe@573 4767 SELECT count(1) INTO "count_v"
jbe@573 4768 FROM (
jbe@573 4769 SELECT "initiative"."id" AS "initiative_id"
jbe@573 4770 FROM "initiative"
jbe@573 4771 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@573 4772 WHERE "issue"."closed" NOTNULL
jbe@573 4773 ORDER BY "closed" DESC
jbe@573 4774 LIMIT "limit_v"
jbe@573 4775 ) AS "subquery"
jbe@573 4776 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
jbe@573 4777 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
jbe@573 4778 LIMIT "limit_p";
jbe@573 4779 IF "count_v" >= "limit_p" THEN
jbe@573 4780 RETURN QUERY SELECT "initiative".*
jbe@573 4781 FROM (
jbe@573 4782 SELECT
jbe@573 4783 "initiative"."id" AS "initiative_id",
jbe@573 4784 "issue"."closed"
jbe@573 4785 FROM "initiative"
jbe@573 4786 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@573 4787 WHERE "issue"."closed" NOTNULL
jbe@573 4788 ORDER BY "closed" DESC
jbe@573 4789 LIMIT "limit_v"
jbe@573 4790 ) AS "subquery"
jbe@573 4791 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
jbe@573 4792 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
jbe@573 4793 ORDER BY "subquery"."closed" DESC
jbe@573 4794 LIMIT "limit_p";
jbe@573 4795 RETURN;
jbe@573 4796 END IF;
jbe@573 4797 "limit_v" := "limit_v" * 2;
jbe@573 4798 END LOOP;
jbe@573 4799 END;
jbe@573 4800 $$;
jbe@573 4801
jbe@573 4802 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
jbe@573 4803 ( EBOX, INT4 )
jbe@573 4804 IS 'TODO';
jbe@577 4805 */
jbe@573 4806
jbe@573 4807
jbe@573 4808
jbe@333 4809 ---------------------------
jbe@333 4810 -- Transaction isolation --
jbe@333 4811 ---------------------------
jbe@333 4812
jbe@344 4813
jbe@333 4814 CREATE FUNCTION "require_transaction_isolation"()
jbe@333 4815 RETURNS VOID
jbe@333 4816 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 4817 BEGIN
jbe@333 4818 IF
jbe@333 4819 current_setting('transaction_isolation') NOT IN
jbe@333 4820 ('repeatable read', 'serializable')
jbe@333 4821 THEN
jbe@463 4822 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
jbe@463 4823 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
jbe@333 4824 END IF;
jbe@333 4825 RETURN;
jbe@333 4826 END;
jbe@333 4827 $$;
jbe@333 4828
jbe@344 4829 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
jbe@344 4830
jbe@333 4831
jbe@333 4832 CREATE FUNCTION "dont_require_transaction_isolation"()
jbe@333 4833 RETURNS VOID
jbe@333 4834 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 4835 BEGIN
jbe@333 4836 IF
jbe@333 4837 current_setting('transaction_isolation') IN
jbe@333 4838 ('repeatable read', 'serializable')
jbe@333 4839 THEN
jbe@333 4840 RAISE WARNING 'Unneccessary transaction isolation level: %',
jbe@333 4841 current_setting('transaction_isolation');
jbe@333 4842 END IF;
jbe@333 4843 RETURN;
jbe@333 4844 END;
jbe@333 4845 $$;
jbe@333 4846
jbe@344 4847 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
jbe@344 4848
jbe@333 4849
jbe@333 4850
jbe@491 4851 -------------------------
jbe@491 4852 -- Notification system --
jbe@491 4853 -------------------------
jbe@491 4854
jbe@491 4855 CREATE FUNCTION "get_initiatives_for_notification"
jbe@501 4856 ( "recipient_id_p" "member"."id"%TYPE )
jbe@491 4857 RETURNS SETOF "initiative_for_notification"
jbe@491 4858 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@491 4859 DECLARE
jbe@491 4860 "result_row" "initiative_for_notification"%ROWTYPE;
jbe@491 4861 "last_draft_id_v" "draft"."id"%TYPE;
jbe@491 4862 "last_suggestion_id_v" "suggestion"."id"%TYPE;
jbe@491 4863 BEGIN
jbe@491 4864 PERFORM "require_transaction_isolation"();
jbe@501 4865 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
jbe@491 4866 FOR "result_row" IN
jbe@491 4867 SELECT * FROM "initiative_for_notification"
jbe@501 4868 WHERE "recipient_id" = "recipient_id_p"
jbe@491 4869 LOOP
jbe@491 4870 SELECT "id" INTO "last_draft_id_v" FROM "draft"
jbe@499 4871 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
jbe@491 4872 ORDER BY "id" DESC LIMIT 1;
jbe@491 4873 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
jbe@499 4874 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
jbe@491 4875 ORDER BY "id" DESC LIMIT 1;
jbe@507 4876 INSERT INTO "notification_initiative_sent"
jbe@491 4877 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@491 4878 VALUES (
jbe@501 4879 "recipient_id_p",
jbe@499 4880 "result_row"."initiative_id",
jbe@493 4881 "last_draft_id_v",
jbe@493 4882 "last_suggestion_id_v" )
jbe@491 4883 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
jbe@517 4884 "last_draft_id" = "last_draft_id_v",
jbe@517 4885 "last_suggestion_id" = "last_suggestion_id_v";
jbe@491 4886 RETURN NEXT "result_row";
jbe@491 4887 END LOOP;
jbe@507 4888 DELETE FROM "notification_initiative_sent"
jbe@491 4889 USING "initiative", "issue"
jbe@507 4890 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
jbe@507 4891 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
jbe@491 4892 AND "issue"."id" = "initiative"."issue_id"
jbe@491 4893 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
jbe@505 4894 UPDATE "member" SET
jbe@506 4895 "notification_counter" = "notification_counter" + 1,
jbe@505 4896 "notification_sent" = now()
jbe@501 4897 WHERE "id" = "recipient_id_p";
jbe@491 4898 RETURN;
jbe@491 4899 END;
jbe@491 4900 $$;
jbe@491 4901
jbe@511 4902 COMMENT ON FUNCTION "get_initiatives_for_notification"
jbe@511 4903 ( "member"."id"%TYPE )
jbe@511 4904 IS 'Returns rows from view "initiative_for_notification" for a given recipient while updating table "notification_initiative_sent" and columns "notification_counter" and "notification_sent" of "member" table';
jbe@511 4905
jbe@491 4906
jbe@491 4907
jbe@103 4908 ------------------------------------------------------------------------
jbe@103 4909 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 4910 ------------------------------------------------------------------------
jbe@103 4911
jbe@333 4912
jbe@184 4913 CREATE FUNCTION "check_activity"()
jbe@103 4914 RETURNS VOID
jbe@103 4915 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 4916 DECLARE
jbe@104 4917 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 4918 BEGIN
jbe@333 4919 PERFORM "dont_require_transaction_isolation"();
jbe@104 4920 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@104 4921 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 4922 UPDATE "member" SET "active" = FALSE
jbe@104 4923 WHERE "active" = TRUE
jbe@184 4924 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
jbe@104 4925 END IF;
jbe@103 4926 RETURN;
jbe@103 4927 END;
jbe@103 4928 $$;
jbe@103 4929
jbe@184 4930 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
jbe@103 4931
jbe@4 4932
jbe@4 4933 CREATE FUNCTION "calculate_member_counts"()
jbe@4 4934 RETURNS VOID
jbe@4 4935 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 4936 BEGIN
jbe@333 4937 PERFORM "require_transaction_isolation"();
jbe@4 4938 DELETE FROM "member_count";
jbe@5 4939 INSERT INTO "member_count" ("total_count")
jbe@5 4940 SELECT "total_count" FROM "member_count_view";
jbe@97 4941 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 4942 FROM "unit_member_count" AS "view"
jbe@97 4943 WHERE "view"."unit_id" = "unit"."id";
jbe@4 4944 RETURN;
jbe@4 4945 END;
jbe@4 4946 $$;
jbe@4 4947
jbe@532 4948 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 "unit_member_count"';
jbe@532 4949
jbe@532 4950
jbe@4 4951
jbe@327 4952 ------------------------------------
jbe@327 4953 -- Calculation of harmonic weight --
jbe@327 4954 ------------------------------------
jbe@310 4955
jbe@312 4956
jbe@310 4957 CREATE VIEW "remaining_harmonic_supporter_weight" AS
jbe@310 4958 SELECT
jbe@528 4959 "direct_interest_snapshot"."snapshot_id",
jbe@310 4960 "direct_interest_snapshot"."issue_id",
jbe@310 4961 "direct_interest_snapshot"."member_id",
jbe@310 4962 "direct_interest_snapshot"."weight" AS "weight_num",
jbe@310 4963 count("initiative"."id") AS "weight_den"
jbe@312 4964 FROM "issue"
jbe@312 4965 JOIN "direct_interest_snapshot"
jbe@528 4966 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
jbe@528 4967 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
jbe@327 4968 JOIN "initiative"
jbe@327 4969 ON "issue"."id" = "initiative"."issue_id"
jbe@327 4970 AND "initiative"."harmonic_weight" ISNULL
jbe@310 4971 JOIN "direct_supporter_snapshot"
jbe@528 4972 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
jbe@528 4973 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 4974 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 4975 AND (
jbe@321 4976 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 4977 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 4978 )
jbe@310 4979 GROUP BY
jbe@528 4980 "direct_interest_snapshot"."snapshot_id",
jbe@310 4981 "direct_interest_snapshot"."issue_id",
jbe@310 4982 "direct_interest_snapshot"."member_id",
jbe@310 4983 "direct_interest_snapshot"."weight";
jbe@310 4984
jbe@310 4985 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 4986
jbe@310 4987
jbe@310 4988 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
jbe@310 4989 SELECT
jbe@310 4990 "initiative"."issue_id",
jbe@310 4991 "initiative"."id" AS "initiative_id",
jbe@320 4992 "initiative"."admitted",
jbe@310 4993 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
jbe@310 4994 "remaining_harmonic_supporter_weight"."weight_den"
jbe@310 4995 FROM "remaining_harmonic_supporter_weight"
jbe@327 4996 JOIN "initiative"
jbe@327 4997 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
jbe@327 4998 AND "initiative"."harmonic_weight" ISNULL
jbe@310 4999 JOIN "direct_supporter_snapshot"
jbe@528 5000 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
jbe@528 5001 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 5002 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 5003 AND (
jbe@321 5004 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 5005 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 5006 )
jbe@310 5007 GROUP BY
jbe@310 5008 "initiative"."issue_id",
jbe@310 5009 "initiative"."id",
jbe@320 5010 "initiative"."admitted",
jbe@310 5011 "remaining_harmonic_supporter_weight"."weight_den";
jbe@310 5012
jbe@310 5013 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 5014
jbe@310 5015
jbe@349 5016 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
jbe@349 5017 SELECT
jbe@349 5018 "issue_id",
jbe@349 5019 "id" AS "initiative_id",
jbe@349 5020 "admitted",
jbe@349 5021 0 AS "weight_num",
jbe@349 5022 1 AS "weight_den"
jbe@349 5023 FROM "initiative"
jbe@349 5024 WHERE "harmonic_weight" ISNULL;
jbe@349 5025
jbe@349 5026 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 5027
jbe@349 5028
jbe@310 5029 CREATE FUNCTION "set_harmonic_initiative_weights"
jbe@310 5030 ( "issue_id_p" "issue"."id"%TYPE )
jbe@310 5031 RETURNS VOID
jbe@310 5032 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@310 5033 DECLARE
jbe@310 5034 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
jbe@310 5035 "i" INT4;
jbe@310 5036 "count_v" INT4;
jbe@310 5037 "summand_v" FLOAT;
jbe@310 5038 "id_ary" INT4[];
jbe@310 5039 "weight_ary" FLOAT[];
jbe@310 5040 "min_weight_v" FLOAT;
jbe@310 5041 BEGIN
jbe@333 5042 PERFORM "require_transaction_isolation"();
jbe@312 5043 UPDATE "initiative" SET "harmonic_weight" = NULL
jbe@312 5044 WHERE "issue_id" = "issue_id_p";
jbe@310 5045 LOOP
jbe@310 5046 "min_weight_v" := NULL;
jbe@310 5047 "i" := 0;
jbe@310 5048 "count_v" := 0;
jbe@310 5049 FOR "weight_row" IN
jbe@310 5050 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
jbe@310 5051 WHERE "issue_id" = "issue_id_p"
jbe@320 5052 AND (
jbe@320 5053 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@320 5054 SELECT NULL FROM "initiative"
jbe@320 5055 WHERE "issue_id" = "issue_id_p"
jbe@320 5056 AND "harmonic_weight" ISNULL
jbe@320 5057 AND coalesce("admitted", FALSE) = FALSE
jbe@320 5058 )
jbe@320 5059 )
jbe@349 5060 UNION ALL -- needed for corner cases
jbe@349 5061 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
jbe@349 5062 WHERE "issue_id" = "issue_id_p"
jbe@349 5063 AND (
jbe@349 5064 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@349 5065 SELECT NULL FROM "initiative"
jbe@349 5066 WHERE "issue_id" = "issue_id_p"
jbe@349 5067 AND "harmonic_weight" ISNULL
jbe@349 5068 AND coalesce("admitted", FALSE) = FALSE
jbe@349 5069 )
jbe@349 5070 )
jbe@310 5071 ORDER BY "initiative_id" DESC, "weight_den" DESC
jbe@320 5072 -- NOTE: non-admitted initiatives placed first (at last positions),
jbe@320 5073 -- latest initiatives treated worse in case of tie
jbe@310 5074 LOOP
jbe@310 5075 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
jbe@310 5076 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
jbe@310 5077 "i" := "i" + 1;
jbe@310 5078 "count_v" := "i";
jbe@310 5079 "id_ary"["i"] := "weight_row"."initiative_id";
jbe@310 5080 "weight_ary"["i"] := "summand_v";
jbe@310 5081 ELSE
jbe@310 5082 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
jbe@310 5083 END IF;
jbe@310 5084 END LOOP;
jbe@310 5085 EXIT WHEN "count_v" = 0;
jbe@310 5086 "i" := 1;
jbe@310 5087 LOOP
jbe@313 5088 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
jbe@310 5089 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
jbe@310 5090 "min_weight_v" := "weight_ary"["i"];
jbe@310 5091 END IF;
jbe@310 5092 "i" := "i" + 1;
jbe@310 5093 EXIT WHEN "i" > "count_v";
jbe@310 5094 END LOOP;
jbe@310 5095 "i" := 1;
jbe@310 5096 LOOP
jbe@310 5097 IF "weight_ary"["i"] = "min_weight_v" THEN
jbe@310 5098 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
jbe@310 5099 WHERE "id" = "id_ary"["i"];
jbe@310 5100 EXIT;
jbe@310 5101 END IF;
jbe@310 5102 "i" := "i" + 1;
jbe@310 5103 END LOOP;
jbe@310 5104 END LOOP;
jbe@316 5105 UPDATE "initiative" SET "harmonic_weight" = 0
jbe@316 5106 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
jbe@310 5107 END;
jbe@310 5108 $$;
jbe@310 5109
jbe@310 5110 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
jbe@310 5111 ( "issue"."id"%TYPE )
jbe@310 5112 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
jbe@310 5113
jbe@310 5114
jbe@312 5115
jbe@0 5116 ------------------------------
jbe@0 5117 -- Calculation of snapshots --
jbe@0 5118 ------------------------------
jbe@0 5119
jbe@312 5120
jbe@528 5121 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
jbe@528 5122 ( "snapshot_id_p" "snapshot"."id"%TYPE,
jbe@528 5123 "issue_id_p" "issue"."id"%TYPE,
jbe@0 5124 "member_id_p" "member"."id"%TYPE,
jbe@0 5125 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 5126 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 5127 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5128 DECLARE
jbe@0 5129 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 5130 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 5131 "weight_v" INT4;
jbe@8 5132 "sub_weight_v" INT4;
jbe@0 5133 BEGIN
jbe@336 5134 PERFORM "require_transaction_isolation"();
jbe@0 5135 "weight_v" := 0;
jbe@0 5136 FOR "issue_delegation_row" IN
jbe@0 5137 SELECT * FROM "issue_delegation"
jbe@0 5138 WHERE "trustee_id" = "member_id_p"
jbe@0 5139 AND "issue_id" = "issue_id_p"
jbe@0 5140 LOOP
jbe@0 5141 IF NOT EXISTS (
jbe@0 5142 SELECT NULL FROM "direct_interest_snapshot"
jbe@528 5143 WHERE "snapshot_id" = "snapshot_id_p"
jbe@528 5144 AND "issue_id" = "issue_id_p"
jbe@0 5145 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 5146 ) AND NOT EXISTS (
jbe@0 5147 SELECT NULL FROM "delegating_interest_snapshot"
jbe@528 5148 WHERE "snapshot_id" = "snapshot_id_p"
jbe@528 5149 AND "issue_id" = "issue_id_p"
jbe@0 5150 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 5151 ) THEN
jbe@0 5152 "delegate_member_ids_v" :=
jbe@0 5153 "member_id_p" || "delegate_member_ids_p";
jbe@10 5154 INSERT INTO "delegating_interest_snapshot" (
jbe@528 5155 "snapshot_id",
jbe@10 5156 "issue_id",
jbe@10 5157 "member_id",
jbe@10 5158 "scope",
jbe@10 5159 "delegate_member_ids"
jbe@10 5160 ) VALUES (
jbe@528 5161 "snapshot_id_p",
jbe@0 5162 "issue_id_p",
jbe@0 5163 "issue_delegation_row"."truster_id",
jbe@10 5164 "issue_delegation_row"."scope",
jbe@0 5165 "delegate_member_ids_v"
jbe@0 5166 );
jbe@8 5167 "sub_weight_v" := 1 +
jbe@528 5168 "weight_of_added_delegations_for_snapshot"(
jbe@528 5169 "snapshot_id_p",
jbe@0 5170 "issue_id_p",
jbe@0 5171 "issue_delegation_row"."truster_id",
jbe@0 5172 "delegate_member_ids_v"
jbe@0 5173 );
jbe@8 5174 UPDATE "delegating_interest_snapshot"
jbe@8 5175 SET "weight" = "sub_weight_v"
jbe@528 5176 WHERE "snapshot_id" = "snapshot_id_p"
jbe@528 5177 AND "issue_id" = "issue_id_p"
jbe@8 5178 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 5179 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 5180 END IF;
jbe@0 5181 END LOOP;
jbe@0 5182 RETURN "weight_v";
jbe@0 5183 END;
jbe@0 5184 $$;
jbe@0 5185
jbe@528 5186 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
jbe@528 5187 ( "snapshot"."id"%TYPE,
jbe@528 5188 "issue"."id"%TYPE,
jbe@0 5189 "member"."id"%TYPE,
jbe@0 5190 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@528 5191 IS 'Helper function for "fill_snapshot" function';
jbe@528 5192
jbe@528 5193
jbe@528 5194 CREATE FUNCTION "take_snapshot"
jbe@532 5195 ( "issue_id_p" "issue"."id"%TYPE,
jbe@532 5196 "area_id_p" "area"."id"%TYPE = NULL )
jbe@528 5197 RETURNS "snapshot"."id"%TYPE
jbe@0 5198 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5199 DECLARE
jbe@532 5200 "area_id_v" "area"."id"%TYPE;
jbe@532 5201 "unit_id_v" "unit"."id"%TYPE;
jbe@528 5202 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@528 5203 "issue_id_v" "issue"."id"%TYPE;
jbe@528 5204 "member_id_v" "member"."id"%TYPE;
jbe@0 5205 BEGIN
jbe@532 5206 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
jbe@532 5207 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
jbe@532 5208 END IF;
jbe@336 5209 PERFORM "require_transaction_isolation"();
jbe@532 5210 IF "issue_id_p" ISNULL THEN
jbe@532 5211 "area_id_v" := "area_id_p";
jbe@532 5212 ELSE
jbe@532 5213 SELECT "area_id" INTO "area_id_v"
jbe@532 5214 FROM "issue" WHERE "id" = "issue_id_p";
jbe@532 5215 END IF;
jbe@562 5216 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@532 5217 INSERT INTO "snapshot" ("area_id", "issue_id")
jbe@532 5218 VALUES ("area_id_v", "issue_id_p")
jbe@528 5219 RETURNING "id" INTO "snapshot_id_v";
jbe@532 5220 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
jbe@532 5221 SELECT "snapshot_id_v", "member_id"
jbe@532 5222 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
jbe@532 5223 UPDATE "snapshot" SET
jbe@532 5224 "population" = (
jbe@532 5225 SELECT count(1) FROM "snapshot_population"
jbe@532 5226 WHERE "snapshot_id" = "snapshot_id_v"
jbe@532 5227 ) WHERE "id" = "snapshot_id_v";
jbe@528 5228 FOR "issue_id_v" IN
jbe@528 5229 SELECT "id" FROM "issue"
jbe@528 5230 WHERE CASE WHEN "issue_id_p" ISNULL THEN
jbe@532 5231 "area_id" = "area_id_p" AND
jbe@528 5232 "state" = 'admission'
jbe@528 5233 ELSE
jbe@528 5234 "id" = "issue_id_p"
jbe@528 5235 END
jbe@0 5236 LOOP
jbe@528 5237 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
jbe@528 5238 VALUES ("snapshot_id_v", "issue_id_v");
jbe@528 5239 INSERT INTO "direct_interest_snapshot"
jbe@528 5240 ("snapshot_id", "issue_id", "member_id")
jbe@528 5241 SELECT
jbe@528 5242 "snapshot_id_v" AS "snapshot_id",
jbe@528 5243 "issue_id_v" AS "issue_id",
jbe@528 5244 "member"."id" AS "member_id"
jbe@528 5245 FROM "issue"
jbe@528 5246 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@528 5247 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@528 5248 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@556 5249 JOIN "privilege"
jbe@556 5250 ON "privilege"."unit_id" = "area"."unit_id"
jbe@556 5251 AND "privilege"."member_id" = "member"."id"
jbe@528 5252 WHERE "issue"."id" = "issue_id_v"
jbe@556 5253 AND "member"."active" AND "privilege"."voting_right";
jbe@528 5254 FOR "member_id_v" IN
jbe@528 5255 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@528 5256 WHERE "snapshot_id" = "snapshot_id_v"
jbe@528 5257 AND "issue_id" = "issue_id_v"
jbe@528 5258 LOOP
jbe@528 5259 UPDATE "direct_interest_snapshot" SET
jbe@528 5260 "weight" = 1 +
jbe@528 5261 "weight_of_added_delegations_for_snapshot"(
jbe@528 5262 "snapshot_id_v",
jbe@528 5263 "issue_id_v",
jbe@528 5264 "member_id_v",
jbe@528 5265 '{}'
jbe@528 5266 )
jbe@528 5267 WHERE "snapshot_id" = "snapshot_id_v"
jbe@528 5268 AND "issue_id" = "issue_id_v"
jbe@528 5269 AND "member_id" = "member_id_v";
jbe@528 5270 END LOOP;
jbe@528 5271 INSERT INTO "direct_supporter_snapshot"
jbe@528 5272 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
jbe@528 5273 "draft_id", "informed", "satisfied" )
jbe@528 5274 SELECT
jbe@528 5275 "snapshot_id_v" AS "snapshot_id",
jbe@528 5276 "issue_id_v" AS "issue_id",
jbe@528 5277 "initiative"."id" AS "initiative_id",
jbe@528 5278 "supporter"."member_id" AS "member_id",
jbe@528 5279 "supporter"."draft_id" AS "draft_id",
jbe@528 5280 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@528 5281 NOT EXISTS (
jbe@528 5282 SELECT NULL FROM "critical_opinion"
jbe@528 5283 WHERE "initiative_id" = "initiative"."id"
jbe@528 5284 AND "member_id" = "supporter"."member_id"
jbe@528 5285 ) AS "satisfied"
jbe@528 5286 FROM "initiative"
jbe@528 5287 JOIN "supporter"
jbe@528 5288 ON "supporter"."initiative_id" = "initiative"."id"
jbe@528 5289 JOIN "current_draft"
jbe@528 5290 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@528 5291 JOIN "direct_interest_snapshot"
jbe@528 5292 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
jbe@528 5293 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@528 5294 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@528 5295 WHERE "initiative"."issue_id" = "issue_id_v";
jbe@528 5296 DELETE FROM "temporary_suggestion_counts";
jbe@528 5297 INSERT INTO "temporary_suggestion_counts"
jbe@528 5298 ( "id",
jbe@528 5299 "minus2_unfulfilled_count", "minus2_fulfilled_count",
jbe@528 5300 "minus1_unfulfilled_count", "minus1_fulfilled_count",
jbe@528 5301 "plus1_unfulfilled_count", "plus1_fulfilled_count",
jbe@528 5302 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
jbe@528 5303 SELECT
jbe@528 5304 "suggestion"."id",
jbe@528 5305 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5306 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5307 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5308 AND "di"."issue_id" = "issue_id_v"
jbe@528 5309 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5310 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5311 AND "opinion"."degree" = -2
jbe@528 5312 AND "opinion"."fulfilled" = FALSE
jbe@528 5313 ) AS "minus2_unfulfilled_count",
jbe@528 5314 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5315 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5316 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5317 AND "di"."issue_id" = "issue_id_v"
jbe@528 5318 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5319 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5320 AND "opinion"."degree" = -2
jbe@528 5321 AND "opinion"."fulfilled" = TRUE
jbe@528 5322 ) AS "minus2_fulfilled_count",
jbe@528 5323 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5324 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5325 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5326 AND "di"."issue_id" = "issue_id_v"
jbe@528 5327 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5328 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5329 AND "opinion"."degree" = -1
jbe@528 5330 AND "opinion"."fulfilled" = FALSE
jbe@528 5331 ) AS "minus1_unfulfilled_count",
jbe@528 5332 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5333 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5334 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5335 AND "di"."issue_id" = "issue_id_v"
jbe@528 5336 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5337 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5338 AND "opinion"."degree" = -1
jbe@528 5339 AND "opinion"."fulfilled" = TRUE
jbe@528 5340 ) AS "minus1_fulfilled_count",
jbe@528 5341 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5342 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5343 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5344 AND "di"."issue_id" = "issue_id_v"
jbe@528 5345 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5346 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5347 AND "opinion"."degree" = 1
jbe@528 5348 AND "opinion"."fulfilled" = FALSE
jbe@528 5349 ) AS "plus1_unfulfilled_count",
jbe@528 5350 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5351 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5352 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5353 AND "di"."issue_id" = "issue_id_v"
jbe@528 5354 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5355 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5356 AND "opinion"."degree" = 1
jbe@528 5357 AND "opinion"."fulfilled" = TRUE
jbe@528 5358 ) AS "plus1_fulfilled_count",
jbe@528 5359 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5360 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5361 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5362 AND "di"."issue_id" = "issue_id_v"
jbe@528 5363 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5364 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5365 AND "opinion"."degree" = 2
jbe@528 5366 AND "opinion"."fulfilled" = FALSE
jbe@528 5367 ) AS "plus2_unfulfilled_count",
jbe@528 5368 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5369 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@528 5370 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5371 AND "di"."issue_id" = "issue_id_v"
jbe@528 5372 AND "di"."member_id" = "opinion"."member_id"
jbe@528 5373 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@528 5374 AND "opinion"."degree" = 2
jbe@528 5375 AND "opinion"."fulfilled" = TRUE
jbe@528 5376 ) AS "plus2_fulfilled_count"
jbe@528 5377 FROM "suggestion" JOIN "initiative"
jbe@528 5378 ON "suggestion"."initiative_id" = "initiative"."id"
jbe@528 5379 WHERE "initiative"."issue_id" = "issue_id_v";
jbe@0 5380 END LOOP;
jbe@528 5381 RETURN "snapshot_id_v";
jbe@0 5382 END;
jbe@0 5383 $$;
jbe@0 5384
jbe@528 5385 COMMENT ON FUNCTION "take_snapshot"
jbe@532 5386 ( "issue"."id"%TYPE,
jbe@532 5387 "area"."id"%TYPE )
jbe@532 5388 IS 'This function creates a new interest/supporter snapshot of a particular issue, or, if the first argument is NULL, for all issues in ''admission'' phase of the area given as second argument. It must be executed with TRANSACTION ISOLATION LEVEL REPEATABLE READ. The snapshot must later be finished by calling "finish_snapshot" for every issue.';
jbe@528 5389
jbe@528 5390
jbe@528 5391 CREATE FUNCTION "finish_snapshot"
jbe@0 5392 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 5393 RETURNS VOID
jbe@0 5394 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5395 DECLARE
jbe@528 5396 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@0 5397 BEGIN
jbe@532 5398 -- NOTE: function does not require snapshot isolation but we don't call
jbe@532 5399 -- "dont_require_snapshot_isolation" here because this function is
jbe@532 5400 -- also invoked by "check_issue"
jbe@528 5401 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
jbe@528 5402 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
jbe@528 5403 ORDER BY "id" DESC LIMIT 1;
jbe@0 5404 UPDATE "issue" SET
jbe@532 5405 "calculated" = "snapshot"."calculated",
jbe@528 5406 "latest_snapshot_id" = "snapshot_id_v",
jbe@568 5407 "population" = "snapshot"."population",
jbe@568 5408 "initiative_quorum" = CASE WHEN
jbe@568 5409 "policy"."initiative_quorum" > ceil(
jbe@568 5410 ( "issue"."population"::INT8 *
jbe@568 5411 "policy"."initiative_quorum_num"::INT8 ) /
jbe@568 5412 "policy"."initiative_quorum_den"::FLOAT8
jbe@568 5413 )::INT4
jbe@568 5414 THEN
jbe@568 5415 "policy"."initiative_quorum"
jbe@568 5416 ELSE
jbe@568 5417 ceil(
jbe@568 5418 ( "issue"."population"::INT8 *
jbe@568 5419 "policy"."initiative_quorum_num"::INT8 ) /
jbe@568 5420 "policy"."initiative_quorum_den"::FLOAT8
jbe@568 5421 )::INT4
jbe@568 5422 END
jbe@568 5423 FROM "snapshot", "policy"
jbe@532 5424 WHERE "issue"."id" = "issue_id_p"
jbe@568 5425 AND "snapshot"."id" = "snapshot_id_v"
jbe@568 5426 AND "policy"."id" = "issue"."policy_id";
jbe@528 5427 UPDATE "initiative" SET
jbe@528 5428 "supporter_count" = (
jbe@528 5429 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5430 FROM "direct_interest_snapshot" AS "di"
jbe@528 5431 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 5432 ON "di"."member_id" = "ds"."member_id"
jbe@528 5433 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5434 AND "di"."issue_id" = "issue_id_p"
jbe@528 5435 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 5436 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 5437 ),
jbe@528 5438 "informed_supporter_count" = (
jbe@528 5439 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5440 FROM "direct_interest_snapshot" AS "di"
jbe@528 5441 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 5442 ON "di"."member_id" = "ds"."member_id"
jbe@528 5443 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5444 AND "di"."issue_id" = "issue_id_p"
jbe@528 5445 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 5446 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 5447 AND "ds"."informed"
jbe@528 5448 ),
jbe@528 5449 "satisfied_supporter_count" = (
jbe@528 5450 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5451 FROM "direct_interest_snapshot" AS "di"
jbe@528 5452 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 5453 ON "di"."member_id" = "ds"."member_id"
jbe@528 5454 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5455 AND "di"."issue_id" = "issue_id_p"
jbe@528 5456 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 5457 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 5458 AND "ds"."satisfied"
jbe@528 5459 ),
jbe@528 5460 "satisfied_informed_supporter_count" = (
jbe@528 5461 SELECT coalesce(sum("di"."weight"), 0)
jbe@528 5462 FROM "direct_interest_snapshot" AS "di"
jbe@528 5463 JOIN "direct_supporter_snapshot" AS "ds"
jbe@528 5464 ON "di"."member_id" = "ds"."member_id"
jbe@528 5465 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@528 5466 AND "di"."issue_id" = "issue_id_p"
jbe@528 5467 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@528 5468 AND "ds"."initiative_id" = "initiative"."id"
jbe@528 5469 AND "ds"."informed"
jbe@528 5470 AND "ds"."satisfied"
jbe@528 5471 )
jbe@528 5472 WHERE "issue_id" = "issue_id_p";
jbe@528 5473 UPDATE "suggestion" SET
jbe@528 5474 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
jbe@528 5475 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
jbe@528 5476 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
jbe@528 5477 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
jbe@528 5478 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
jbe@528 5479 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
jbe@528 5480 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
jbe@528 5481 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
jbe@528 5482 FROM "temporary_suggestion_counts" AS "temp", "initiative"
jbe@528 5483 WHERE "temp"."id" = "suggestion"."id"
jbe@528 5484 AND "initiative"."issue_id" = "issue_id_p"
jbe@528 5485 AND "suggestion"."initiative_id" = "initiative"."id";
jbe@528 5486 DELETE FROM "temporary_suggestion_counts";
jbe@0 5487 RETURN;
jbe@0 5488 END;
jbe@0 5489 $$;
jbe@0 5490
jbe@528 5491 COMMENT ON FUNCTION "finish_snapshot"
jbe@0 5492 ( "issue"."id"%TYPE )
jbe@528 5493 IS 'After calling "take_snapshot", this function "finish_snapshot" needs to be called for every issue in the snapshot (separate function calls keep locking time minimal)';
jbe@0 5494
jbe@0 5495
jbe@0 5496
jbe@0 5497 -----------------------
jbe@0 5498 -- Counting of votes --
jbe@0 5499 -----------------------
jbe@0 5500
jbe@0 5501
jbe@5 5502 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 5503 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 5504 "member_id_p" "member"."id"%TYPE,
jbe@0 5505 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 5506 RETURNS "direct_voter"."weight"%TYPE
jbe@0 5507 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5508 DECLARE
jbe@0 5509 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 5510 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 5511 "weight_v" INT4;
jbe@8 5512 "sub_weight_v" INT4;
jbe@0 5513 BEGIN
jbe@336 5514 PERFORM "require_transaction_isolation"();
jbe@0 5515 "weight_v" := 0;
jbe@0 5516 FOR "issue_delegation_row" IN
jbe@0 5517 SELECT * FROM "issue_delegation"
jbe@0 5518 WHERE "trustee_id" = "member_id_p"
jbe@0 5519 AND "issue_id" = "issue_id_p"
jbe@0 5520 LOOP
jbe@0 5521 IF NOT EXISTS (
jbe@0 5522 SELECT NULL FROM "direct_voter"
jbe@0 5523 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 5524 AND "issue_id" = "issue_id_p"
jbe@0 5525 ) AND NOT EXISTS (
jbe@0 5526 SELECT NULL FROM "delegating_voter"
jbe@0 5527 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 5528 AND "issue_id" = "issue_id_p"
jbe@0 5529 ) THEN
jbe@0 5530 "delegate_member_ids_v" :=
jbe@0 5531 "member_id_p" || "delegate_member_ids_p";
jbe@10 5532 INSERT INTO "delegating_voter" (
jbe@10 5533 "issue_id",
jbe@10 5534 "member_id",
jbe@10 5535 "scope",
jbe@10 5536 "delegate_member_ids"
jbe@10 5537 ) VALUES (
jbe@5 5538 "issue_id_p",
jbe@5 5539 "issue_delegation_row"."truster_id",
jbe@10 5540 "issue_delegation_row"."scope",
jbe@5 5541 "delegate_member_ids_v"
jbe@5 5542 );
jbe@8 5543 "sub_weight_v" := 1 +
jbe@8 5544 "weight_of_added_vote_delegations"(
jbe@8 5545 "issue_id_p",
jbe@8 5546 "issue_delegation_row"."truster_id",
jbe@8 5547 "delegate_member_ids_v"
jbe@8 5548 );
jbe@8 5549 UPDATE "delegating_voter"
jbe@8 5550 SET "weight" = "sub_weight_v"
jbe@8 5551 WHERE "issue_id" = "issue_id_p"
jbe@8 5552 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 5553 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 5554 END IF;
jbe@0 5555 END LOOP;
jbe@0 5556 RETURN "weight_v";
jbe@0 5557 END;
jbe@0 5558 $$;
jbe@0 5559
jbe@5 5560 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 5561 ( "issue"."id"%TYPE,
jbe@0 5562 "member"."id"%TYPE,
jbe@0 5563 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 5564 IS 'Helper function for "add_vote_delegations" function';
jbe@0 5565
jbe@0 5566
jbe@0 5567 CREATE FUNCTION "add_vote_delegations"
jbe@0 5568 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 5569 RETURNS VOID
jbe@0 5570 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5571 DECLARE
jbe@0 5572 "member_id_v" "member"."id"%TYPE;
jbe@0 5573 BEGIN
jbe@336 5574 PERFORM "require_transaction_isolation"();
jbe@0 5575 FOR "member_id_v" IN
jbe@0 5576 SELECT "member_id" FROM "direct_voter"
jbe@0 5577 WHERE "issue_id" = "issue_id_p"
jbe@0 5578 LOOP
jbe@0 5579 UPDATE "direct_voter" SET
jbe@5 5580 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 5581 "issue_id_p",
jbe@0 5582 "member_id_v",
jbe@0 5583 '{}'
jbe@0 5584 )
jbe@0 5585 WHERE "member_id" = "member_id_v"
jbe@0 5586 AND "issue_id" = "issue_id_p";
jbe@0 5587 END LOOP;
jbe@0 5588 RETURN;
jbe@0 5589 END;
jbe@0 5590 $$;
jbe@0 5591
jbe@0 5592 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 5593 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 5594 IS 'Helper function for "close_voting" function';
jbe@0 5595
jbe@0 5596
jbe@0 5597 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 5598 RETURNS VOID
jbe@0 5599 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5600 DECLARE
jbe@97 5601 "area_id_v" "area"."id"%TYPE;
jbe@97 5602 "unit_id_v" "unit"."id"%TYPE;
jbe@0 5603 "member_id_v" "member"."id"%TYPE;
jbe@0 5604 BEGIN
jbe@333 5605 PERFORM "require_transaction_isolation"();
jbe@129 5606 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 5607 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@383 5608 -- override protection triggers:
jbe@385 5609 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 5610 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@285 5611 -- delete timestamp of voting comment:
jbe@285 5612 UPDATE "direct_voter" SET "comment_changed" = NULL
jbe@285 5613 WHERE "issue_id" = "issue_id_p";
jbe@169 5614 -- delete delegating votes (in cases of manual reset of issue state):
jbe@0 5615 DELETE FROM "delegating_voter"
jbe@0 5616 WHERE "issue_id" = "issue_id_p";
jbe@169 5617 -- delete votes from non-privileged voters:
jbe@97 5618 DELETE FROM "direct_voter"
jbe@97 5619 USING (
jbe@97 5620 SELECT
jbe@97 5621 "direct_voter"."member_id"
jbe@97 5622 FROM "direct_voter"
jbe@97 5623 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@556 5624 LEFT JOIN "privilege"
jbe@556 5625 ON "privilege"."unit_id" = "unit_id_v"
jbe@556 5626 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 5627 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 5628 "member"."active" = FALSE OR
jbe@556 5629 "privilege"."voting_right" ISNULL OR
jbe@556 5630 "privilege"."voting_right" = FALSE
jbe@97 5631 )
jbe@97 5632 ) AS "subquery"
jbe@97 5633 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 5634 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@169 5635 -- consider delegations:
jbe@0 5636 UPDATE "direct_voter" SET "weight" = 1
jbe@0 5637 WHERE "issue_id" = "issue_id_p";
jbe@0 5638 PERFORM "add_vote_delegations"("issue_id_p");
jbe@414 5639 -- mark first preferences:
jbe@414 5640 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
jbe@414 5641 FROM (
jbe@414 5642 SELECT
jbe@414 5643 "vote"."initiative_id",
jbe@414 5644 "vote"."member_id",
jbe@414 5645 CASE WHEN "vote"."grade" > 0 THEN
jbe@414 5646 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
jbe@414 5647 ELSE NULL
jbe@414 5648 END AS "first_preference"
jbe@415 5649 FROM "vote"
jbe@415 5650 JOIN "initiative" -- NOTE: due to missing index on issue_id
jbe@415 5651 ON "vote"."issue_id" = "initiative"."issue_id"
jbe@415 5652 JOIN "vote" AS "agg"
jbe@415 5653 ON "initiative"."id" = "agg"."initiative_id"
jbe@415 5654 AND "vote"."member_id" = "agg"."member_id"
jbe@433 5655 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
jbe@414 5656 ) AS "subquery"
jbe@414 5657 WHERE "vote"."issue_id" = "issue_id_p"
jbe@414 5658 AND "vote"."initiative_id" = "subquery"."initiative_id"
jbe@414 5659 AND "vote"."member_id" = "subquery"."member_id";
jbe@385 5660 -- finish overriding protection triggers (avoids garbage):
jbe@385 5661 DELETE FROM "temporary_transaction_data"
jbe@385 5662 WHERE "key" = 'override_protection_triggers';
jbe@137 5663 -- materialize battle_view:
jbe@61 5664 -- NOTE: "closed" column of issue must be set at this point
jbe@61 5665 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 5666 INSERT INTO "battle" (
jbe@61 5667 "issue_id",
jbe@61 5668 "winning_initiative_id", "losing_initiative_id",
jbe@61 5669 "count"
jbe@61 5670 ) SELECT
jbe@61 5671 "issue_id",
jbe@61 5672 "winning_initiative_id", "losing_initiative_id",
jbe@61 5673 "count"
jbe@61 5674 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@331 5675 -- set voter count:
jbe@331 5676 UPDATE "issue" SET
jbe@331 5677 "voter_count" = (
jbe@331 5678 SELECT coalesce(sum("weight"), 0)
jbe@331 5679 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@331 5680 )
jbe@331 5681 WHERE "id" = "issue_id_p";
jbe@437 5682 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@437 5683 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
jbe@437 5684 UPDATE "initiative" SET
jbe@437 5685 "first_preference_votes" = 0,
jbe@437 5686 "positive_votes" = "battle_win"."count",
jbe@437 5687 "negative_votes" = "battle_lose"."count"
jbe@437 5688 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@437 5689 WHERE
jbe@437 5690 "battle_win"."issue_id" = "issue_id_p" AND
jbe@437 5691 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@437 5692 "battle_win"."losing_initiative_id" ISNULL AND
jbe@437 5693 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@437 5694 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@437 5695 "battle_lose"."winning_initiative_id" ISNULL;
jbe@414 5696 -- calculate "first_preference_votes":
jbe@437 5697 -- NOTE: will only set values not equal to zero
jbe@437 5698 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
jbe@414 5699 FROM (
jbe@414 5700 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
jbe@414 5701 FROM "vote" JOIN "direct_voter"
jbe@414 5702 ON "vote"."issue_id" = "direct_voter"."issue_id"
jbe@414 5703 AND "vote"."member_id" = "direct_voter"."member_id"
jbe@414 5704 WHERE "vote"."first_preference"
jbe@414 5705 GROUP BY "vote"."initiative_id"
jbe@414 5706 ) AS "subquery"
jbe@414 5707 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@414 5708 AND "initiative"."admitted"
jbe@414 5709 AND "initiative"."id" = "subquery"."initiative_id";
jbe@0 5710 END;
jbe@0 5711 $$;
jbe@0 5712
jbe@0 5713 COMMENT ON FUNCTION "close_voting"
jbe@0 5714 ( "issue"."id"%TYPE )
jbe@0 5715 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 5716
jbe@0 5717
jbe@30 5718 CREATE FUNCTION "defeat_strength"
jbe@424 5719 ( "positive_votes_p" INT4,
jbe@424 5720 "negative_votes_p" INT4,
jbe@424 5721 "defeat_strength_p" "defeat_strength" )
jbe@30 5722 RETURNS INT8
jbe@30 5723 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 5724 BEGIN
jbe@424 5725 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
jbe@424 5726 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 5727 RETURN "positive_votes_p";
jbe@424 5728 ELSE
jbe@424 5729 RETURN 0;
jbe@424 5730 END IF;
jbe@30 5731 ELSE
jbe@424 5732 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 5733 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@424 5734 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@424 5735 RETURN 0;
jbe@424 5736 ELSE
jbe@424 5737 RETURN -1;
jbe@424 5738 END IF;
jbe@30 5739 END IF;
jbe@30 5740 END;
jbe@30 5741 $$;
jbe@30 5742
jbe@425 5743 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 5744
jbe@30 5745
jbe@423 5746 CREATE FUNCTION "secondary_link_strength"
jbe@426 5747 ( "initiative1_ord_p" INT4,
jbe@426 5748 "initiative2_ord_p" INT4,
jbe@424 5749 "tie_breaking_p" "tie_breaking" )
jbe@423 5750 RETURNS INT8
jbe@423 5751 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@423 5752 BEGIN
jbe@426 5753 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
jbe@423 5754 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
jbe@423 5755 END IF;
jbe@423 5756 RETURN (
jbe@426 5757 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
jbe@426 5758 0
jbe@424 5759 ELSE
jbe@426 5760 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
jbe@426 5761 1::INT8 << 62
jbe@426 5762 ELSE 0 END
jbe@426 5763 +
jbe@426 5764 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
jbe@426 5765 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
jbe@426 5766 ELSE
jbe@426 5767 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
jbe@426 5768 END
jbe@424 5769 END
jbe@423 5770 );
jbe@423 5771 END;
jbe@423 5772 $$;
jbe@423 5773
jbe@424 5774 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 5775
jbe@423 5776
jbe@426 5777 CREATE TYPE "link_strength" AS (
jbe@426 5778 "primary" INT8,
jbe@426 5779 "secondary" INT8 );
jbe@426 5780
jbe@428 5781 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 5782
jbe@427 5783
jbe@427 5784 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
jbe@427 5785 RETURNS "link_strength"[][]
jbe@427 5786 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@427 5787 DECLARE
jbe@427 5788 "dimension_v" INT4;
jbe@427 5789 "matrix_p" "link_strength"[][];
jbe@427 5790 "i" INT4;
jbe@427 5791 "j" INT4;
jbe@427 5792 "k" INT4;
jbe@427 5793 BEGIN
jbe@427 5794 "dimension_v" := array_upper("matrix_d", 1);
jbe@427 5795 "matrix_p" := "matrix_d";
jbe@427 5796 "i" := 1;
jbe@427 5797 LOOP
jbe@427 5798 "j" := 1;
jbe@427 5799 LOOP
jbe@427 5800 IF "i" != "j" THEN
jbe@427 5801 "k" := 1;
jbe@427 5802 LOOP
jbe@427 5803 IF "i" != "k" AND "j" != "k" THEN
jbe@427 5804 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
jbe@427 5805 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
jbe@427 5806 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
jbe@427 5807 END IF;
jbe@427 5808 ELSE
jbe@427 5809 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
jbe@427 5810 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
jbe@427 5811 END IF;
jbe@427 5812 END IF;
jbe@427 5813 END IF;
jbe@427 5814 EXIT WHEN "k" = "dimension_v";
jbe@427 5815 "k" := "k" + 1;
jbe@427 5816 END LOOP;
jbe@427 5817 END IF;
jbe@427 5818 EXIT WHEN "j" = "dimension_v";
jbe@427 5819 "j" := "j" + 1;
jbe@427 5820 END LOOP;
jbe@427 5821 EXIT WHEN "i" = "dimension_v";
jbe@427 5822 "i" := "i" + 1;
jbe@427 5823 END LOOP;
jbe@427 5824 RETURN "matrix_p";
jbe@427 5825 END;
jbe@427 5826 $$;
jbe@427 5827
jbe@428 5828 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
jbe@426 5829
jbe@426 5830
jbe@0 5831 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 5832 RETURNS VOID
jbe@0 5833 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5834 DECLARE
jbe@427 5835 "issue_row" "issue"%ROWTYPE;
jbe@427 5836 "policy_row" "policy"%ROWTYPE;
jbe@427 5837 "dimension_v" INT4;
jbe@427 5838 "matrix_a" INT4[][]; -- absolute votes
jbe@427 5839 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
jbe@427 5840 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
jbe@427 5841 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
jbe@427 5842 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
jbe@427 5843 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
jbe@427 5844 "i" INT4;
jbe@427 5845 "j" INT4;
jbe@427 5846 "m" INT4;
jbe@427 5847 "n" INT4;
jbe@427 5848 "battle_row" "battle"%ROWTYPE;
jbe@427 5849 "rank_ary" INT4[];
jbe@427 5850 "rank_v" INT4;
jbe@427 5851 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 5852 BEGIN
jbe@333 5853 PERFORM "require_transaction_isolation"();
jbe@155 5854 SELECT * INTO "issue_row"
jbe@331 5855 FROM "issue" WHERE "id" = "issue_id_p";
jbe@155 5856 SELECT * INTO "policy_row"
jbe@155 5857 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@126 5858 SELECT count(1) INTO "dimension_v"
jbe@126 5859 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@428 5860 -- create "matrix_a" with absolute number of votes in pairwise
jbe@170 5861 -- comparison:
jbe@427 5862 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@170 5863 "i" := 1;
jbe@170 5864 "j" := 2;
jbe@170 5865 FOR "battle_row" IN
jbe@170 5866 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@170 5867 ORDER BY
jbe@411 5868 "winning_initiative_id" NULLS FIRST,
jbe@411 5869 "losing_initiative_id" NULLS FIRST
jbe@170 5870 LOOP
jbe@427 5871 "matrix_a"["i"]["j"] := "battle_row"."count";
jbe@170 5872 IF "j" = "dimension_v" THEN
jbe@170 5873 "i" := "i" + 1;
jbe@170 5874 "j" := 1;
jbe@170 5875 ELSE
jbe@170 5876 "j" := "j" + 1;
jbe@170 5877 IF "j" = "i" THEN
jbe@170 5878 "j" := "j" + 1;
jbe@170 5879 END IF;
jbe@170 5880 END IF;
jbe@170 5881 END LOOP;
jbe@170 5882 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@170 5883 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@170 5884 END IF;
jbe@428 5885 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
jbe@427 5886 -- and "secondary_link_strength" functions:
jbe@427 5887 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@170 5888 "i" := 1;
jbe@170 5889 LOOP
jbe@170 5890 "j" := 1;
jbe@0 5891 LOOP
jbe@170 5892 IF "i" != "j" THEN
jbe@427 5893 "matrix_d"["i"]["j"] := (
jbe@426 5894 "defeat_strength"(
jbe@427 5895 "matrix_a"["i"]["j"],
jbe@427 5896 "matrix_a"["j"]["i"],
jbe@426 5897 "policy_row"."defeat_strength"
jbe@426 5898 ),
jbe@426 5899 "secondary_link_strength"(
jbe@426 5900 "i",
jbe@426 5901 "j",
jbe@426 5902 "policy_row"."tie_breaking"
jbe@426 5903 )
jbe@426 5904 )::"link_strength";
jbe@0 5905 END IF;
jbe@170 5906 EXIT WHEN "j" = "dimension_v";
jbe@170 5907 "j" := "j" + 1;
jbe@0 5908 END LOOP;
jbe@170 5909 EXIT WHEN "i" = "dimension_v";
jbe@170 5910 "i" := "i" + 1;
jbe@170 5911 END LOOP;
jbe@428 5912 -- find best paths:
jbe@427 5913 "matrix_p" := "find_best_paths"("matrix_d");
jbe@428 5914 -- create partial order:
jbe@427 5915 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
jbe@170 5916 "i" := 1;
jbe@170 5917 LOOP
jbe@427 5918 "j" := "i" + 1;
jbe@170 5919 LOOP
jbe@170 5920 IF "i" != "j" THEN
jbe@427 5921 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
jbe@427 5922 "matrix_b"["i"]["j"] := TRUE;
jbe@427 5923 "matrix_b"["j"]["i"] := FALSE;
jbe@427 5924 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
jbe@427 5925 "matrix_b"["i"]["j"] := FALSE;
jbe@427 5926 "matrix_b"["j"]["i"] := TRUE;
jbe@427 5927 END IF;
jbe@170 5928 END IF;
jbe@170 5929 EXIT WHEN "j" = "dimension_v";
jbe@170 5930 "j" := "j" + 1;
jbe@170 5931 END LOOP;
jbe@427 5932 EXIT WHEN "i" = "dimension_v" - 1;
jbe@170 5933 "i" := "i" + 1;
jbe@170 5934 END LOOP;
jbe@428 5935 -- tie-breaking by forbidding shared weakest links in beat-paths
jbe@428 5936 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
jbe@428 5937 -- is performed later by initiative id):
jbe@427 5938 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
jbe@427 5939 "m" := 1;
jbe@427 5940 LOOP
jbe@427 5941 "n" := "m" + 1;
jbe@427 5942 LOOP
jbe@428 5943 -- only process those candidates m and n, which are tied:
jbe@427 5944 IF "matrix_b"["m"]["n"] ISNULL THEN
jbe@428 5945 -- start with beat-paths prior tie-breaking:
jbe@427 5946 "matrix_t" := "matrix_p";
jbe@428 5947 -- start with all links allowed:
jbe@427 5948 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
jbe@427 5949 LOOP
jbe@428 5950 -- determine (and forbid) that link that is the weakest link
jbe@428 5951 -- in both the best path from candidate m to candidate n and
jbe@428 5952 -- from candidate n to candidate m:
jbe@427 5953 "i" := 1;
jbe@427 5954 <<forbid_one_link>>
jbe@427 5955 LOOP
jbe@427 5956 "j" := 1;
jbe@427 5957 LOOP
jbe@427 5958 IF "i" != "j" THEN
jbe@427 5959 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
jbe@427 5960 "matrix_f"["i"]["j"] := TRUE;
jbe@427 5961 -- exit for performance reasons,
jbe@428 5962 -- as exactly one link will be found:
jbe@427 5963 EXIT forbid_one_link;
jbe@427 5964 END IF;
jbe@427 5965 END IF;
jbe@427 5966 EXIT WHEN "j" = "dimension_v";
jbe@427 5967 "j" := "j" + 1;
jbe@427 5968 END LOOP;
jbe@427 5969 IF "i" = "dimension_v" THEN
jbe@428 5970 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
jbe@427 5971 END IF;
jbe@427 5972 "i" := "i" + 1;
jbe@427 5973 END LOOP;
jbe@428 5974 -- calculate best beat-paths while ignoring forbidden links:
jbe@427 5975 "i" := 1;
jbe@427 5976 LOOP
jbe@427 5977 "j" := 1;
jbe@427 5978 LOOP
jbe@427 5979 IF "i" != "j" THEN
jbe@427 5980 "matrix_t"["i"]["j"] := CASE
jbe@427 5981 WHEN "matrix_f"["i"]["j"]
jbe@431 5982 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
jbe@427 5983 ELSE "matrix_d"["i"]["j"] END;
jbe@427 5984 END IF;
jbe@427 5985 EXIT WHEN "j" = "dimension_v";
jbe@427 5986 "j" := "j" + 1;
jbe@427 5987 END LOOP;
jbe@427 5988 EXIT WHEN "i" = "dimension_v";
jbe@427 5989 "i" := "i" + 1;
jbe@427 5990 END LOOP;
jbe@427 5991 "matrix_t" := "find_best_paths"("matrix_t");
jbe@428 5992 -- extend partial order, if tie-breaking was successful:
jbe@427 5993 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
jbe@427 5994 "matrix_b"["m"]["n"] := TRUE;
jbe@427 5995 "matrix_b"["n"]["m"] := FALSE;
jbe@427 5996 EXIT;
jbe@427 5997 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
jbe@427 5998 "matrix_b"["m"]["n"] := FALSE;
jbe@427 5999 "matrix_b"["n"]["m"] := TRUE;
jbe@427 6000 EXIT;
jbe@427 6001 END IF;
jbe@427 6002 END LOOP;
jbe@427 6003 END IF;
jbe@427 6004 EXIT WHEN "n" = "dimension_v";
jbe@427 6005 "n" := "n" + 1;
jbe@427 6006 END LOOP;
jbe@427 6007 EXIT WHEN "m" = "dimension_v" - 1;
jbe@427 6008 "m" := "m" + 1;
jbe@427 6009 END LOOP;
jbe@427 6010 END IF;
jbe@428 6011 -- store a unique ranking in "rank_ary":
jbe@170 6012 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@170 6013 "rank_v" := 1;
jbe@170 6014 LOOP
jbe@0 6015 "i" := 1;
jbe@428 6016 <<assign_next_rank>>
jbe@0 6017 LOOP
jbe@170 6018 IF "rank_ary"["i"] ISNULL THEN
jbe@170 6019 "j" := 1;
jbe@170 6020 LOOP
jbe@170 6021 IF
jbe@170 6022 "i" != "j" AND
jbe@170 6023 "rank_ary"["j"] ISNULL AND
jbe@427 6024 ( "matrix_b"["j"]["i"] OR
jbe@411 6025 -- tie-breaking by "id"
jbe@427 6026 ( "matrix_b"["j"]["i"] ISNULL AND
jbe@411 6027 "j" < "i" ) )
jbe@170 6028 THEN
jbe@170 6029 -- someone else is better
jbe@170 6030 EXIT;
jbe@170 6031 END IF;
jbe@428 6032 IF "j" = "dimension_v" THEN
jbe@170 6033 -- noone is better
jbe@411 6034 "rank_ary"["i"] := "rank_v";
jbe@428 6035 EXIT assign_next_rank;
jbe@170 6036 END IF;
jbe@428 6037 "j" := "j" + 1;
jbe@170 6038 END LOOP;
jbe@170 6039 END IF;
jbe@0 6040 "i" := "i" + 1;
jbe@411 6041 IF "i" > "dimension_v" THEN
jbe@411 6042 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
jbe@411 6043 END IF;
jbe@0 6044 END LOOP;
jbe@411 6045 EXIT WHEN "rank_v" = "dimension_v";
jbe@170 6046 "rank_v" := "rank_v" + 1;
jbe@170 6047 END LOOP;
jbe@170 6048 -- write preliminary results:
jbe@411 6049 "i" := 2; -- omit status quo with "i" = 1
jbe@170 6050 FOR "initiative_id_v" IN
jbe@170 6051 SELECT "id" FROM "initiative"
jbe@170 6052 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@170 6053 ORDER BY "id"
jbe@170 6054 LOOP
jbe@170 6055 UPDATE "initiative" SET
jbe@170 6056 "direct_majority" =
jbe@170 6057 CASE WHEN "policy_row"."direct_majority_strict" THEN
jbe@170 6058 "positive_votes" * "policy_row"."direct_majority_den" >
jbe@170 6059 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 6060 ELSE
jbe@170 6061 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@170 6062 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 6063 END
jbe@170 6064 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@170 6065 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 6066 "policy_row"."direct_majority_non_negative",
jbe@170 6067 "indirect_majority" =
jbe@170 6068 CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 6069 "positive_votes" * "policy_row"."indirect_majority_den" >
jbe@170 6070 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 6071 ELSE
jbe@170 6072 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@170 6073 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 6074 END
jbe@170 6075 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@170 6076 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 6077 "policy_row"."indirect_majority_non_negative",
jbe@171 6078 "schulze_rank" = "rank_ary"["i"],
jbe@411 6079 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
jbe@411 6080 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
jbe@411 6081 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
jbe@429 6082 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
jbe@429 6083 THEN NULL
jbe@429 6084 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
jbe@216 6085 "eligible" = FALSE,
jbe@250 6086 "winner" = FALSE,
jbe@250 6087 "rank" = NULL -- NOTE: in cases of manual reset of issue state
jbe@170 6088 WHERE "id" = "initiative_id_v";
jbe@170 6089 "i" := "i" + 1;
jbe@170 6090 END LOOP;
jbe@411 6091 IF "i" != "dimension_v" + 1 THEN
jbe@170 6092 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 6093 END IF;
jbe@170 6094 -- take indirect majorities into account:
jbe@170 6095 LOOP
jbe@170 6096 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@139 6097 FROM (
jbe@170 6098 SELECT "new_initiative"."id" AS "initiative_id"
jbe@170 6099 FROM "initiative" "old_initiative"
jbe@170 6100 JOIN "initiative" "new_initiative"
jbe@170 6101 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@170 6102 AND "new_initiative"."indirect_majority" = FALSE
jbe@139 6103 JOIN "battle" "battle_win"
jbe@139 6104 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 6105 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@170 6106 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@139 6107 JOIN "battle" "battle_lose"
jbe@139 6108 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 6109 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@170 6110 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@170 6111 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@170 6112 AND "old_initiative"."indirect_majority" = TRUE
jbe@170 6113 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 6114 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@170 6115 "policy_row"."indirect_majority_num" *
jbe@170 6116 ("battle_win"."count"+"battle_lose"."count")
jbe@170 6117 ELSE
jbe@170 6118 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@170 6119 "policy_row"."indirect_majority_num" *
jbe@170 6120 ("battle_win"."count"+"battle_lose"."count")
jbe@170 6121 END
jbe@170 6122 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@170 6123 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@170 6124 "policy_row"."indirect_majority_non_negative"
jbe@139 6125 ) AS "subquery"
jbe@139 6126 WHERE "id" = "subquery"."initiative_id";
jbe@170 6127 EXIT WHEN NOT FOUND;
jbe@170 6128 END LOOP;
jbe@170 6129 -- set "multistage_majority" for remaining matching initiatives:
jbe@216 6130 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@170 6131 FROM (
jbe@170 6132 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@170 6133 FROM "initiative" "losing_initiative"
jbe@170 6134 JOIN "initiative" "winning_initiative"
jbe@170 6135 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@170 6136 AND "winning_initiative"."admitted"
jbe@170 6137 JOIN "battle" "battle_win"
jbe@170 6138 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 6139 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@170 6140 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@170 6141 JOIN "battle" "battle_lose"
jbe@170 6142 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 6143 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@170 6144 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@170 6145 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@170 6146 AND "losing_initiative"."admitted"
jbe@170 6147 AND "winning_initiative"."schulze_rank" <
jbe@170 6148 "losing_initiative"."schulze_rank"
jbe@170 6149 AND "battle_win"."count" > "battle_lose"."count"
jbe@170 6150 AND (
jbe@170 6151 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@170 6152 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@170 6153 ) AS "subquery"
jbe@170 6154 WHERE "id" = "subquery"."initiative_id";
jbe@170 6155 -- mark eligible initiatives:
jbe@170 6156 UPDATE "initiative" SET "eligible" = TRUE
jbe@171 6157 WHERE "issue_id" = "issue_id_p"
jbe@171 6158 AND "initiative"."direct_majority"
jbe@171 6159 AND "initiative"."indirect_majority"
jbe@171 6160 AND "initiative"."better_than_status_quo"
jbe@171 6161 AND (
jbe@171 6162 "policy_row"."no_multistage_majority" = FALSE OR
jbe@429 6163 "initiative"."multistage_majority" = FALSE )
jbe@429 6164 AND (
jbe@429 6165 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@429 6166 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
jbe@170 6167 -- mark final winner:
jbe@170 6168 UPDATE "initiative" SET "winner" = TRUE
jbe@170 6169 FROM (
jbe@170 6170 SELECT "id" AS "initiative_id"
jbe@170 6171 FROM "initiative"
jbe@170 6172 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@217 6173 ORDER BY
jbe@217 6174 "schulze_rank",
jbe@217 6175 "id"
jbe@170 6176 LIMIT 1
jbe@170 6177 ) AS "subquery"
jbe@170 6178 WHERE "id" = "subquery"."initiative_id";
jbe@173 6179 -- write (final) ranks:
jbe@173 6180 "rank_v" := 1;
jbe@173 6181 FOR "initiative_id_v" IN
jbe@173 6182 SELECT "id"
jbe@173 6183 FROM "initiative"
jbe@173 6184 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@174 6185 ORDER BY
jbe@174 6186 "winner" DESC,
jbe@217 6187 "eligible" DESC,
jbe@174 6188 "schulze_rank",
jbe@174 6189 "id"
jbe@173 6190 LOOP
jbe@173 6191 UPDATE "initiative" SET "rank" = "rank_v"
jbe@173 6192 WHERE "id" = "initiative_id_v";
jbe@173 6193 "rank_v" := "rank_v" + 1;
jbe@173 6194 END LOOP;
jbe@170 6195 -- set schulze rank of status quo and mark issue as finished:
jbe@111 6196 UPDATE "issue" SET
jbe@411 6197 "status_quo_schulze_rank" = "rank_ary"[1],
jbe@111 6198 "state" =
jbe@139 6199 CASE WHEN EXISTS (
jbe@139 6200 SELECT NULL FROM "initiative"
jbe@139 6201 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@139 6202 ) THEN
jbe@139 6203 'finished_with_winner'::"issue_state"
jbe@139 6204 ELSE
jbe@121 6205 'finished_without_winner'::"issue_state"
jbe@111 6206 END,
jbe@331 6207 "closed" = "phase_finished",
jbe@331 6208 "phase_finished" = NULL
jbe@0 6209 WHERE "id" = "issue_id_p";
jbe@0 6210 RETURN;
jbe@0 6211 END;
jbe@0 6212 $$;
jbe@0 6213
jbe@0 6214 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 6215 ( "issue"."id"%TYPE )
jbe@0 6216 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 6217
jbe@0 6218
jbe@0 6219
jbe@0 6220 -----------------------------
jbe@0 6221 -- Automatic state changes --
jbe@0 6222 -----------------------------
jbe@0 6223
jbe@0 6224
jbe@532 6225 CREATE FUNCTION "issue_admission"
jbe@532 6226 ( "area_id_p" "area"."id"%TYPE )
jbe@528 6227 RETURNS BOOLEAN
jbe@528 6228 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@528 6229 DECLARE
jbe@528 6230 "issue_id_v" "issue"."id"%TYPE;
jbe@528 6231 BEGIN
jbe@528 6232 PERFORM "dont_require_transaction_isolation"();
jbe@528 6233 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
jbe@532 6234 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
jbe@532 6235 FROM "area_quorum" AS "view"
jbe@532 6236 WHERE "area"."id" = "view"."area_id"
jbe@532 6237 AND "area"."id" = "area_id_p";
jbe@532 6238 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
jbe@532 6239 WHERE "area_id" = "area_id_p";
jbe@528 6240 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
jbe@528 6241 UPDATE "issue" SET
jbe@528 6242 "admission_snapshot_id" = "latest_snapshot_id",
jbe@528 6243 "state" = 'discussion',
jbe@528 6244 "accepted" = now(),
jbe@568 6245 "phase_finished" = NULL,
jbe@568 6246 "issue_quorum" = "issue_quorum"."issue_quorum"
jbe@568 6247 FROM "issue_quorum"
jbe@568 6248 WHERE "id" = "issue_id_v"
jbe@568 6249 AND "issue_quorum"."issue_id" = "issue_id_v";
jbe@528 6250 RETURN TRUE;
jbe@528 6251 END;
jbe@528 6252 $$;
jbe@528 6253
jbe@532 6254 COMMENT ON FUNCTION "issue_admission"
jbe@532 6255 ( "area"."id"%TYPE )
jbe@532 6256 IS 'Checks if an issue in the area can be admitted for further discussion; returns TRUE on success in which case the function must be called again until it returns FALSE';
jbe@528 6257
jbe@528 6258
jbe@331 6259 CREATE TYPE "check_issue_persistence" AS (
jbe@331 6260 "state" "issue_state",
jbe@331 6261 "phase_finished" BOOLEAN,
jbe@331 6262 "issue_revoked" BOOLEAN,
jbe@331 6263 "snapshot_created" BOOLEAN,
jbe@331 6264 "harmonic_weights_set" BOOLEAN,
jbe@331 6265 "closed_voting" BOOLEAN );
jbe@331 6266
jbe@336 6267 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 6268
jbe@336 6269
jbe@0 6270 CREATE FUNCTION "check_issue"
jbe@331 6271 ( "issue_id_p" "issue"."id"%TYPE,
jbe@331 6272 "persist" "check_issue_persistence" )
jbe@331 6273 RETURNS "check_issue_persistence"
jbe@0 6274 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 6275 DECLARE
jbe@528 6276 "issue_row" "issue"%ROWTYPE;
jbe@528 6277 "last_calculated_v" "snapshot"."calculated"%TYPE;
jbe@528 6278 "policy_row" "policy"%ROWTYPE;
jbe@528 6279 "initiative_row" "initiative"%ROWTYPE;
jbe@528 6280 "state_v" "issue_state";
jbe@0 6281 BEGIN
jbe@333 6282 PERFORM "require_transaction_isolation"();
jbe@331 6283 IF "persist" ISNULL THEN
jbe@331 6284 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@331 6285 FOR UPDATE;
jbe@528 6286 SELECT "calculated" INTO "last_calculated_v"
jbe@528 6287 FROM "snapshot" JOIN "snapshot_issue"
jbe@528 6288 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
jbe@587 6289 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
jbe@587 6290 ORDER BY "snapshot"."id" DESC;
jbe@331 6291 IF "issue_row"."closed" NOTNULL THEN
jbe@331 6292 RETURN NULL;
jbe@0 6293 END IF;
jbe@331 6294 "persist"."state" := "issue_row"."state";
jbe@331 6295 IF
jbe@528 6296 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
jbe@447 6297 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
jbe@331 6298 ( "issue_row"."state" = 'discussion' AND now() >=
jbe@331 6299 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
jbe@331 6300 ( "issue_row"."state" = 'verification' AND now() >=
jbe@331 6301 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
jbe@331 6302 ( "issue_row"."state" = 'voting' AND now() >=
jbe@331 6303 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
jbe@331 6304 THEN
jbe@331 6305 "persist"."phase_finished" := TRUE;
jbe@331 6306 ELSE
jbe@331 6307 "persist"."phase_finished" := FALSE;
jbe@0 6308 END IF;
jbe@0 6309 IF
jbe@24 6310 NOT EXISTS (
jbe@24 6311 -- all initiatives are revoked
jbe@24 6312 SELECT NULL FROM "initiative"
jbe@24 6313 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 6314 ) AND (
jbe@111 6315 -- and issue has not been accepted yet
jbe@331 6316 "persist"."state" = 'admission' OR
jbe@331 6317 -- or verification time has elapsed
jbe@331 6318 ( "persist"."state" = 'verification' AND
jbe@331 6319 "persist"."phase_finished" ) OR
jbe@331 6320 -- or no initiatives have been revoked lately
jbe@24 6321 NOT EXISTS (
jbe@24 6322 SELECT NULL FROM "initiative"
jbe@24 6323 WHERE "issue_id" = "issue_id_p"
jbe@24 6324 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 6325 )
jbe@24 6326 )
jbe@24 6327 THEN
jbe@331 6328 "persist"."issue_revoked" := TRUE;
jbe@331 6329 ELSE
jbe@331 6330 "persist"."issue_revoked" := FALSE;
jbe@24 6331 END IF;
jbe@331 6332 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
jbe@331 6333 UPDATE "issue" SET "phase_finished" = now()
jbe@331 6334 WHERE "id" = "issue_row"."id";
jbe@331 6335 RETURN "persist";
jbe@331 6336 ELSIF
jbe@331 6337 "persist"."state" IN ('admission', 'discussion', 'verification')
jbe@3 6338 THEN
jbe@331 6339 RETURN "persist";
jbe@331 6340 ELSE
jbe@331 6341 RETURN NULL;
jbe@322 6342 END IF;
jbe@0 6343 END IF;
jbe@331 6344 IF
jbe@331 6345 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 6346 coalesce("persist"."snapshot_created", FALSE) = FALSE
jbe@331 6347 THEN
jbe@528 6348 IF "persist"."state" != 'admission' THEN
jbe@528 6349 PERFORM "take_snapshot"("issue_id_p");
jbe@528 6350 PERFORM "finish_snapshot"("issue_id_p");
jbe@568 6351 ELSE
jbe@568 6352 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
jbe@568 6353 FROM "issue_quorum"
jbe@568 6354 WHERE "id" = "issue_id_p"
jbe@568 6355 AND "issue_quorum"."issue_id" = "issue_id_p";
jbe@528 6356 END IF;
jbe@331 6357 "persist"."snapshot_created" = TRUE;
jbe@331 6358 IF "persist"."phase_finished" THEN
jbe@331 6359 IF "persist"."state" = 'admission' THEN
jbe@561 6360 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
jbe@561 6361 WHERE "id" = "issue_id_p";
jbe@331 6362 ELSIF "persist"."state" = 'discussion' THEN
jbe@561 6363 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
jbe@561 6364 WHERE "id" = "issue_id_p";
jbe@331 6365 ELSIF "persist"."state" = 'verification' THEN
jbe@561 6366 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
jbe@561 6367 WHERE "id" = "issue_id_p";
jbe@336 6368 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@336 6369 FOR "initiative_row" IN
jbe@336 6370 SELECT * FROM "initiative"
jbe@336 6371 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@336 6372 FOR UPDATE
jbe@336 6373 LOOP
jbe@336 6374 IF
jbe@568 6375 "initiative_row"."polling" OR
jbe@568 6376 "initiative_row"."satisfied_supporter_count" >=
jbe@568 6377 "issue_row"."initiative_quorum"
jbe@336 6378 THEN
jbe@336 6379 UPDATE "initiative" SET "admitted" = TRUE
jbe@336 6380 WHERE "id" = "initiative_row"."id";
jbe@336 6381 ELSE
jbe@336 6382 UPDATE "initiative" SET "admitted" = FALSE
jbe@336 6383 WHERE "id" = "initiative_row"."id";
jbe@336 6384 END IF;
jbe@336 6385 END LOOP;
jbe@331 6386 END IF;
jbe@331 6387 END IF;
jbe@331 6388 RETURN "persist";
jbe@331 6389 END IF;
jbe@331 6390 IF
jbe@331 6391 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 6392 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
jbe@331 6393 THEN
jbe@331 6394 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@331 6395 "persist"."harmonic_weights_set" = TRUE;
jbe@332 6396 IF
jbe@332 6397 "persist"."phase_finished" OR
jbe@332 6398 "persist"."issue_revoked" OR
jbe@332 6399 "persist"."state" = 'admission'
jbe@332 6400 THEN
jbe@331 6401 RETURN "persist";
jbe@331 6402 ELSE
jbe@331 6403 RETURN NULL;
jbe@331 6404 END IF;
jbe@331 6405 END IF;
jbe@331 6406 IF "persist"."issue_revoked" THEN
jbe@331 6407 IF "persist"."state" = 'admission' THEN
jbe@331 6408 "state_v" := 'canceled_revoked_before_accepted';
jbe@331 6409 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 6410 "state_v" := 'canceled_after_revocation_during_discussion';
jbe@331 6411 ELSIF "persist"."state" = 'verification' THEN
jbe@331 6412 "state_v" := 'canceled_after_revocation_during_verification';
jbe@331 6413 END IF;
jbe@331 6414 UPDATE "issue" SET
jbe@331 6415 "state" = "state_v",
jbe@331 6416 "closed" = "phase_finished",
jbe@331 6417 "phase_finished" = NULL
jbe@332 6418 WHERE "id" = "issue_id_p";
jbe@331 6419 RETURN NULL;
jbe@331 6420 END IF;
jbe@331 6421 IF "persist"."state" = 'admission' THEN
jbe@336 6422 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 6423 FOR UPDATE;
jbe@528 6424 IF "issue_row"."phase_finished" NOTNULL THEN
jbe@336 6425 UPDATE "issue" SET
jbe@336 6426 "state" = 'canceled_issue_not_accepted',
jbe@336 6427 "closed" = "phase_finished",
jbe@336 6428 "phase_finished" = NULL
jbe@336 6429 WHERE "id" = "issue_id_p";
jbe@336 6430 END IF;
jbe@331 6431 RETURN NULL;
jbe@331 6432 END IF;
jbe@332 6433 IF "persist"."phase_finished" THEN
jbe@443 6434 IF "persist"."state" = 'discussion' THEN
jbe@332 6435 UPDATE "issue" SET
jbe@332 6436 "state" = 'verification',
jbe@332 6437 "half_frozen" = "phase_finished",
jbe@332 6438 "phase_finished" = NULL
jbe@332 6439 WHERE "id" = "issue_id_p";
jbe@332 6440 RETURN NULL;
jbe@332 6441 END IF;
jbe@332 6442 IF "persist"."state" = 'verification' THEN
jbe@336 6443 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 6444 FOR UPDATE;
jbe@336 6445 SELECT * INTO "policy_row" FROM "policy"
jbe@336 6446 WHERE "id" = "issue_row"."policy_id";
jbe@336 6447 IF EXISTS (
jbe@336 6448 SELECT NULL FROM "initiative"
jbe@336 6449 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@336 6450 ) THEN
jbe@336 6451 UPDATE "issue" SET
jbe@343 6452 "state" = 'voting',
jbe@343 6453 "fully_frozen" = "phase_finished",
jbe@336 6454 "phase_finished" = NULL
jbe@336 6455 WHERE "id" = "issue_id_p";
jbe@336 6456 ELSE
jbe@336 6457 UPDATE "issue" SET
jbe@343 6458 "state" = 'canceled_no_initiative_admitted',
jbe@343 6459 "fully_frozen" = "phase_finished",
jbe@343 6460 "closed" = "phase_finished",
jbe@343 6461 "phase_finished" = NULL
jbe@336 6462 WHERE "id" = "issue_id_p";
jbe@336 6463 -- NOTE: The following DELETE statements have effect only when
jbe@336 6464 -- issue state has been manipulated
jbe@336 6465 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 6466 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 6467 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@336 6468 END IF;
jbe@332 6469 RETURN NULL;
jbe@332 6470 END IF;
jbe@332 6471 IF "persist"."state" = 'voting' THEN
jbe@332 6472 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
jbe@332 6473 PERFORM "close_voting"("issue_id_p");
jbe@332 6474 "persist"."closed_voting" = TRUE;
jbe@332 6475 RETURN "persist";
jbe@332 6476 END IF;
jbe@332 6477 PERFORM "calculate_ranks"("issue_id_p");
jbe@332 6478 RETURN NULL;
jbe@332 6479 END IF;
jbe@331 6480 END IF;
jbe@331 6481 RAISE WARNING 'should not happen';
jbe@331 6482 RETURN NULL;
jbe@0 6483 END;
jbe@0 6484 $$;
jbe@0 6485
jbe@0 6486 COMMENT ON FUNCTION "check_issue"
jbe@331 6487 ( "issue"."id"%TYPE,
jbe@331 6488 "check_issue_persistence" )
jbe@336 6489 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 6490
jbe@0 6491
jbe@0 6492 CREATE FUNCTION "check_everything"()
jbe@0 6493 RETURNS VOID
jbe@0 6494 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 6495 DECLARE
jbe@532 6496 "area_id_v" "area"."id"%TYPE;
jbe@528 6497 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@528 6498 "issue_id_v" "issue"."id"%TYPE;
jbe@528 6499 "persist_v" "check_issue_persistence";
jbe@0 6500 BEGIN
jbe@333 6501 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
jbe@235 6502 DELETE FROM "expired_session";
jbe@532 6503 DELETE FROM "expired_token";
jbe@532 6504 DELETE FROM "expired_snapshot";
jbe@184 6505 PERFORM "check_activity"();
jbe@4 6506 PERFORM "calculate_member_counts"();
jbe@532 6507 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
jbe@532 6508 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
jbe@532 6509 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
jbe@532 6510 WHERE "snapshot_id" = "snapshot_id_v";
jbe@532 6511 LOOP
jbe@532 6512 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
jbe@532 6513 END LOOP;
jbe@528 6514 END LOOP;
jbe@4 6515 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@331 6516 "persist_v" := NULL;
jbe@331 6517 LOOP
jbe@331 6518 "persist_v" := "check_issue"("issue_id_v", "persist_v");
jbe@331 6519 EXIT WHEN "persist_v" ISNULL;
jbe@331 6520 END LOOP;
jbe@0 6521 END LOOP;
jbe@0 6522 RETURN;
jbe@0 6523 END;
jbe@0 6524 $$;
jbe@0 6525
jbe@532 6526 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. For production, use lf_update binary instead';
jbe@0 6527
jbe@0 6528
jbe@0 6529
jbe@59 6530 ----------------------
jbe@59 6531 -- Deletion of data --
jbe@59 6532 ----------------------
jbe@59 6533
jbe@59 6534
jbe@59 6535 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 6536 RETURNS VOID
jbe@59 6537 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 6538 BEGIN
jbe@385 6539 IF EXISTS (
jbe@385 6540 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
jbe@385 6541 ) THEN
jbe@385 6542 -- override protection triggers:
jbe@385 6543 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 6544 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@385 6545 -- clean data:
jbe@59 6546 DELETE FROM "delegating_voter"
jbe@59 6547 WHERE "issue_id" = "issue_id_p";
jbe@59 6548 DELETE FROM "direct_voter"
jbe@59 6549 WHERE "issue_id" = "issue_id_p";
jbe@59 6550 DELETE FROM "delegating_interest_snapshot"
jbe@59 6551 WHERE "issue_id" = "issue_id_p";
jbe@59 6552 DELETE FROM "direct_interest_snapshot"
jbe@59 6553 WHERE "issue_id" = "issue_id_p";
jbe@113 6554 DELETE FROM "non_voter"
jbe@94 6555 WHERE "issue_id" = "issue_id_p";
jbe@59 6556 DELETE FROM "delegation"
jbe@59 6557 WHERE "issue_id" = "issue_id_p";
jbe@59 6558 DELETE FROM "supporter"
jbe@329 6559 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 6560 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 6561 AND "supporter"."initiative_id" = "initiative_id";
jbe@385 6562 -- mark issue as cleaned:
jbe@385 6563 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
jbe@385 6564 -- finish overriding protection triggers (avoids garbage):
jbe@385 6565 DELETE FROM "temporary_transaction_data"
jbe@385 6566 WHERE "key" = 'override_protection_triggers';
jbe@59 6567 END IF;
jbe@59 6568 RETURN;
jbe@59 6569 END;
jbe@59 6570 $$;
jbe@59 6571
jbe@59 6572 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 6573
jbe@8 6574
jbe@54 6575 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 6576 RETURNS VOID
jbe@8 6577 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 6578 BEGIN
jbe@9 6579 UPDATE "member" SET
jbe@57 6580 "last_login" = NULL,
jbe@387 6581 "last_delegation_check" = NULL,
jbe@45 6582 "login" = NULL,
jbe@11 6583 "password" = NULL,
jbe@441 6584 "authority" = NULL,
jbe@441 6585 "authority_uid" = NULL,
jbe@441 6586 "authority_login" = NULL,
jbe@552 6587 "deleted" = coalesce("deleted", now()),
jbe@101 6588 "locked" = TRUE,
jbe@54 6589 "active" = FALSE,
jbe@11 6590 "notify_email" = NULL,
jbe@11 6591 "notify_email_unconfirmed" = NULL,
jbe@11 6592 "notify_email_secret" = NULL,
jbe@11 6593 "notify_email_secret_expiry" = NULL,
jbe@57 6594 "notify_email_lock_expiry" = NULL,
jbe@522 6595 "disable_notifications" = TRUE,
jbe@522 6596 "notification_counter" = DEFAULT,
jbe@522 6597 "notification_sample_size" = 0,
jbe@499 6598 "notification_dow" = NULL,
jbe@499 6599 "notification_hour" = NULL,
jbe@543 6600 "notification_sent" = NULL,
jbe@387 6601 "login_recovery_expiry" = NULL,
jbe@11 6602 "password_reset_secret" = NULL,
jbe@11 6603 "password_reset_secret_expiry" = NULL,
jbe@532 6604 "location" = NULL
jbe@45 6605 WHERE "id" = "member_id_p";
jbe@11 6606 -- "text_search_data" is updated by triggers
jbe@544 6607 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
jbe@543 6608 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
jbe@543 6609 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
jbe@45 6610 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 6611 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 6612 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@235 6613 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@543 6614 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
jbe@543 6615 DELETE FROM "token" WHERE "member_id" = "member_id_p";
jbe@543 6616 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
jbe@543 6617 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
jbe@113 6618 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@54 6619 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 6620 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 6621 DELETE FROM "direct_voter" USING "issue"
jbe@57 6622 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 6623 AND "issue"."closed" ISNULL
jbe@57 6624 AND "member_id" = "member_id_p";
jbe@543 6625 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
jbe@45 6626 RETURN;
jbe@45 6627 END;
jbe@45 6628 $$;
jbe@45 6629
jbe@57 6630 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 6631
jbe@45 6632
jbe@45 6633 CREATE FUNCTION "delete_private_data"()
jbe@45 6634 RETURNS VOID
jbe@45 6635 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 6636 BEGIN
jbe@385 6637 DELETE FROM "temporary_transaction_data";
jbe@543 6638 DELETE FROM "temporary_suggestion_counts";
jbe@226 6639 DELETE FROM "member" WHERE "activated" ISNULL;
jbe@50 6640 UPDATE "member" SET
jbe@206 6641 "invite_code" = NULL,
jbe@232 6642 "invite_code_expiry" = NULL,
jbe@228 6643 "admin_comment" = NULL,
jbe@57 6644 "last_login" = NULL,
jbe@387 6645 "last_delegation_check" = NULL,
jbe@50 6646 "login" = NULL,
jbe@50 6647 "password" = NULL,
jbe@441 6648 "authority" = NULL,
jbe@441 6649 "authority_uid" = NULL,
jbe@441 6650 "authority_login" = NULL,
jbe@238 6651 "lang" = NULL,
jbe@50 6652 "notify_email" = NULL,
jbe@50 6653 "notify_email_unconfirmed" = NULL,
jbe@50 6654 "notify_email_secret" = NULL,
jbe@50 6655 "notify_email_secret_expiry" = NULL,
jbe@57 6656 "notify_email_lock_expiry" = NULL,
jbe@522 6657 "disable_notifications" = TRUE,
jbe@522 6658 "notification_counter" = DEFAULT,
jbe@522 6659 "notification_sample_size" = 0,
jbe@499 6660 "notification_dow" = NULL,
jbe@499 6661 "notification_hour" = NULL,
jbe@543 6662 "notification_sent" = NULL,
jbe@387 6663 "login_recovery_expiry" = NULL,
jbe@50 6664 "password_reset_secret" = NULL,
jbe@50 6665 "password_reset_secret_expiry" = NULL,
jbe@532 6666 "location" = NULL;
jbe@50 6667 -- "text_search_data" is updated by triggers
jbe@557 6668 DELETE FROM "verification";
jbe@544 6669 DELETE FROM "member_settings";
jbe@544 6670 DELETE FROM "member_useterms";
jbe@543 6671 DELETE FROM "member_profile";
jbe@543 6672 DELETE FROM "rendered_member_statement";
jbe@50 6673 DELETE FROM "member_image";
jbe@50 6674 DELETE FROM "contact";
jbe@113 6675 DELETE FROM "ignored_member";
jbe@235 6676 DELETE FROM "session";
jbe@543 6677 DELETE FROM "system_application";
jbe@543 6678 DELETE FROM "system_application_redirect_uri";
jbe@543 6679 DELETE FROM "dynamic_application_scope";
jbe@543 6680 DELETE FROM "member_application";
jbe@543 6681 DELETE FROM "token";
jbe@543 6682 DELETE FROM "subscription";
jbe@543 6683 DELETE FROM "ignored_area";
jbe@113 6684 DELETE FROM "ignored_initiative";
jbe@113 6685 DELETE FROM "non_voter";
jbe@8 6686 DELETE FROM "direct_voter" USING "issue"
jbe@8 6687 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 6688 AND "issue"."closed" ISNULL;
jbe@543 6689 DELETE FROM "event_processed";
jbe@543 6690 DELETE FROM "notification_initiative_sent";
jbe@543 6691 DELETE FROM "newsletter";
jbe@8 6692 RETURN;
jbe@8 6693 END;
jbe@8 6694 $$;
jbe@8 6695
jbe@273 6696 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 6697
jbe@8 6698
jbe@8 6699
jbe@0 6700 COMMIT;

Impressum / About Us