liquid_feedback_core

annotate core.sql @ 603:617ac1725557

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

Impressum / About Us