liquid_feedback_core

annotate core.sql @ 532:5855ff9e5c8f

Several changes/additions for upcoming major release

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

Impressum / About Us