liquid_feedback_core

annotate core.sql @ 585:b8f106eb5dbf

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

Impressum / About Us