liquid_feedback_core

annotate core.sql @ 577:3536fb4148dc

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

Impressum / About Us