liquid_feedback_core

annotate core.sql @ 608:fa3c406a6775

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

Impressum / About Us