liquid_feedback_core

annotate core.sql @ 582:225a0c047691

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

Impressum / About Us