liquid_feedback_core

annotate core.sql @ 559:71f431fb78d4

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

Impressum / About Us