liquid_feedback_core

annotate core.sql @ 567:797282760db4

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

Impressum / About Us