liquid_feedback_core

annotate core.sql @ 552:a676d305502f

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

Impressum / About Us