liquid_feedback_core

annotate core.sql @ 616:ae53fc96c953

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

Impressum / About Us