liquid_feedback_core

annotate core.sql @ 546:f46ebb677898

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

Impressum / About Us