liquid_feedback_core

annotate core.sql @ 624:82387194519b

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

Impressum / About Us