liquid_feedback_core

annotate core.sql @ 578:02a6149822e0

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

Impressum / About Us