liquid_feedback_core

annotate core.sql @ 573:f28662013308

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

Impressum / About Us