liquid_feedback_core

annotate core.sql @ 538:1bc3dfe5823e

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

Impressum / About Us