liquid_feedback_core

annotate core.sql @ 595:87914d1b757f

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

Impressum / About Us