liquid_feedback_core

annotate core.sql @ 580:78f6833f5f19

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

Impressum / About Us