liquid_feedback_core

annotate core.sql @ 555:5d098bcc631a

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

Impressum / About Us