liquid_feedback_core

annotate core.sql @ 620:e0b8175fda29

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

Impressum / About Us