liquid_feedback_core

annotate core.sql @ 543:4e0ee8416bbc

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

Impressum / About Us