liquid_feedback_core

annotate core.sql @ 611:a94f7cb8ed19

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

Impressum / About Us