liquid_feedback_core

annotate core.sql @ 598:f02b7ea48971

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

Impressum / About Us