liquid_feedback_core

annotate core.sql @ 593:e7f772ca0621

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

Impressum / About Us