liquid_feedback_core

annotate core.sql @ 596:85489702edd2

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

Impressum / About Us