liquid_feedback_core

annotate core.sql @ 600:f61caa45de94

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

Impressum / About Us