liquid_feedback_core

annotate core.sql @ 591:d955519f7471

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

Impressum / About Us