liquid_feedback_core

annotate core.sql @ 619:63092784fe9d

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

Impressum / About Us