liquid_feedback_core

annotate core.sql @ 547:3cde0bb68adf

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

Impressum / About Us