liquid_feedback_core

annotate core.sql @ 562:c3931054bb55

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

Impressum / About Us