liquid_feedback_core

annotate core.sql @ 537:aa261389c993

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

Impressum / About Us