liquid_feedback_core

annotate core.sql @ 548:1adb0ad5900c

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

Impressum / About Us