liquid_feedback_core

annotate core.sql @ 524:bc6d9dc60ca4

Require members to be "activated" in order to receive messages/notifications; New views "member_eligible_to_be_notified" and "member_to_notify"
author jbe
date Thu May 05 21:13:09 2016 +0200 (2016-05-05)
parents 2f1c06608def
children 2a2f76da1177
rev   line source
jbe@0 1
jbe@92 2 -- Execute the following command manually for PostgreSQL prior version 9.0:
jbe@92 3 -- CREATE LANGUAGE plpgsql;
jbe@0 4
jbe@0 5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
jbe@0 6
jbe@0 7 BEGIN;
jbe@0 8
jbe@5 9 CREATE VIEW "liquid_feedback_version" AS
jbe@520 10 SELECT * FROM (VALUES ('3.2.2', 3, 2, 2))
jbe@5 11 AS "subquery"("string", "major", "minor", "revision");
jbe@5 12
jbe@0 13
jbe@0 14
jbe@7 15 ----------------------
jbe@7 16 -- Full text search --
jbe@7 17 ----------------------
jbe@7 18
jbe@7 19
jbe@7 20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
jbe@7 21 RETURNS TSQUERY
jbe@7 22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 23 BEGIN
jbe@7 24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
jbe@7 25 END;
jbe@7 26 $$;
jbe@7 27
jbe@7 28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
jbe@7 29
jbe@7 30
jbe@7 31 CREATE FUNCTION "highlight"
jbe@7 32 ( "body_p" TEXT,
jbe@7 33 "query_text_p" TEXT )
jbe@7 34 RETURNS TEXT
jbe@7 35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@7 36 BEGIN
jbe@7 37 RETURN ts_headline(
jbe@7 38 'pg_catalog.simple',
jbe@8 39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
jbe@7 40 "text_search_query"("query_text_p"),
jbe@7 41 'StartSel=* StopSel=* HighlightAll=TRUE' );
jbe@7 42 END;
jbe@7 43 $$;
jbe@7 44
jbe@7 45 COMMENT ON FUNCTION "highlight"
jbe@7 46 ( "body_p" TEXT,
jbe@7 47 "query_text_p" TEXT )
jbe@7 48 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@7 49
jbe@7 50
jbe@7 51
jbe@0 52 -------------------------
jbe@0 53 -- Tables and indicies --
jbe@0 54 -------------------------
jbe@0 55
jbe@8 56
jbe@385 57 CREATE TABLE "temporary_transaction_data" (
jbe@385 58 PRIMARY KEY ("txid", "key"),
jbe@385 59 "txid" INT8 DEFAULT txid_current(),
jbe@383 60 "key" TEXT,
jbe@383 61 "value" TEXT NOT NULL );
jbe@383 62
jbe@385 63 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
jbe@385 64
jbe@385 65 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 66
jbe@383 67
jbe@104 68 CREATE TABLE "system_setting" (
jbe@104 69 "member_ttl" INTERVAL );
jbe@104 70 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
jbe@104 71
jbe@104 72 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
jbe@104 73 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
jbe@104 74
jbe@184 75 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 76
jbe@104 77
jbe@111 78 CREATE TABLE "contingent" (
jbe@293 79 PRIMARY KEY ("polling", "time_frame"),
jbe@293 80 "polling" BOOLEAN,
jbe@293 81 "time_frame" INTERVAL,
jbe@111 82 "text_entry_limit" INT4,
jbe@111 83 "initiative_limit" INT4 );
jbe@111 84
jbe@111 85 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 86
jbe@293 87 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
jbe@111 88 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 89 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
jbe@111 90
jbe@111 91
jbe@0 92 CREATE TABLE "member" (
jbe@0 93 "id" SERIAL4 PRIMARY KEY,
jbe@13 94 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@181 95 "invite_code" TEXT UNIQUE,
jbe@232 96 "invite_code_expiry" TIMESTAMPTZ,
jbe@182 97 "admin_comment" TEXT,
jbe@181 98 "activated" TIMESTAMPTZ,
jbe@184 99 "last_activity" DATE,
jbe@42 100 "last_login" TIMESTAMPTZ,
jbe@387 101 "last_delegation_check" TIMESTAMPTZ,
jbe@45 102 "login" TEXT UNIQUE,
jbe@0 103 "password" TEXT,
jbe@440 104 "authority" TEXT,
jbe@440 105 "authority_uid" TEXT,
jbe@440 106 "authority_login" TEXT,
jbe@99 107 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@181 108 "active" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 109 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@221 110 "lang" TEXT,
jbe@7 111 "notify_email" TEXT,
jbe@11 112 "notify_email_unconfirmed" TEXT,
jbe@11 113 "notify_email_secret" TEXT UNIQUE,
jbe@11 114 "notify_email_secret_expiry" TIMESTAMPTZ,
jbe@55 115 "notify_email_lock_expiry" TIMESTAMPTZ,
jbe@486 116 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@486 117 "notification_counter" INT4 NOT NULL DEFAULT 1,
jbe@486 118 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
jbe@486 119 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
jbe@515 120 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
jbe@504 121 "notification_sent" TIMESTAMP,
jbe@387 122 "login_recovery_expiry" TIMESTAMPTZ,
jbe@11 123 "password_reset_secret" TEXT UNIQUE,
jbe@11 124 "password_reset_secret_expiry" TIMESTAMPTZ,
jbe@225 125 "name" TEXT UNIQUE,
jbe@7 126 "identification" TEXT UNIQUE,
jbe@214 127 "authentication" TEXT,
jbe@7 128 "organizational_unit" TEXT,
jbe@7 129 "internal_posts" TEXT,
jbe@7 130 "realname" TEXT,
jbe@7 131 "birthday" DATE,
jbe@7 132 "address" TEXT,
jbe@7 133 "email" TEXT,
jbe@7 134 "xmpp_address" TEXT,
jbe@7 135 "website" TEXT,
jbe@7 136 "phone" TEXT,
jbe@7 137 "mobile_phone" TEXT,
jbe@7 138 "profession" TEXT,
jbe@7 139 "external_memberships" TEXT,
jbe@7 140 "external_posts" TEXT,
jbe@159 141 "formatting_engine" TEXT,
jbe@7 142 "statement" TEXT,
jbe@181 143 "text_search_data" TSVECTOR,
jbe@184 144 CONSTRAINT "active_requires_activated_and_last_activity"
jbe@225 145 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
jbe@440 146 CONSTRAINT "authority_requires_uid_and_vice_versa"
jbe@447 147 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
jbe@440 148 CONSTRAINT "authority_uid_unique_per_authority"
jbe@440 149 UNIQUE ("authority", "authority_uid"),
jbe@440 150 CONSTRAINT "authority_login_requires_authority"
jbe@440 151 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
jbe@505 152 CONSTRAINT "notification_dow_requires_notification_hour"
jbe@505 153 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
jbe@225 154 CONSTRAINT "name_not_null_if_activated"
jbe@225 155 CHECK ("activated" ISNULL OR "name" NOTNULL) );
jbe@440 156 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
jbe@0 157 CREATE INDEX "member_active_idx" ON "member" ("active");
jbe@8 158 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
jbe@7 159 CREATE TRIGGER "update_text_search_data"
jbe@7 160 BEFORE INSERT OR UPDATE ON "member"
jbe@7 161 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 162 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 163 "name", "identification", "organizational_unit", "internal_posts",
jbe@7 164 "realname", "external_memberships", "external_posts", "statement" );
jbe@0 165
jbe@0 166 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
jbe@0 167
jbe@181 168 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
jbe@181 169 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
jbe@232 170 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
jbe@182 171 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
jbe@207 172 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 173 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
jbe@103 174 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
jbe@387 175 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
jbe@10 176 COMMENT ON COLUMN "member"."login" IS 'Login name';
jbe@10 177 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
jbe@440 178 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 179 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 180 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
jbe@99 181 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
jbe@184 182 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 183 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
jbe@221 184 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
jbe@10 185 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
jbe@10 186 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 187 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
jbe@10 188 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
jbe@55 189 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
jbe@508 190 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
jbe@508 191 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 192 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
jbe@508 193 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
jbe@508 194 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
jbe@508 195 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
jbe@387 196 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
jbe@387 197 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
jbe@387 198 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 199 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
jbe@10 200 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
jbe@214 201 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
jbe@10 202 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
jbe@10 203 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
jbe@10 204 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
jbe@10 205 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
jbe@10 206 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
jbe@10 207 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
jbe@159 208 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
jbe@207 209 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
jbe@7 210
jbe@7 211
jbe@13 212 CREATE TABLE "member_history" (
jbe@13 213 "id" SERIAL8 PRIMARY KEY,
jbe@13 214 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@13 215 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@42 216 "active" BOOLEAN NOT NULL,
jbe@13 217 "name" TEXT NOT NULL );
jbe@45 218 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
jbe@13 219
jbe@57 220 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
jbe@13 221
jbe@13 222 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
jbe@57 223 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
jbe@13 224
jbe@13 225
jbe@159 226 CREATE TABLE "rendered_member_statement" (
jbe@159 227 PRIMARY KEY ("member_id", "format"),
jbe@461 228 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@159 229 "format" TEXT,
jbe@159 230 "content" TEXT NOT NULL );
jbe@159 231
jbe@159 232 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 233
jbe@9 234
jbe@9 235 CREATE TABLE "setting" (
jbe@9 236 PRIMARY KEY ("member_id", "key"),
jbe@9 237 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 238 "key" TEXT NOT NULL,
jbe@9 239 "value" TEXT NOT NULL );
jbe@9 240 CREATE INDEX "setting_key_idx" ON "setting" ("key");
jbe@9 241
jbe@38 242 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
jbe@9 243
jbe@9 244 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@9 245
jbe@9 246
jbe@16 247 CREATE TABLE "setting_map" (
jbe@16 248 PRIMARY KEY ("member_id", "key", "subkey"),
jbe@16 249 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@16 250 "key" TEXT NOT NULL,
jbe@16 251 "subkey" TEXT NOT NULL,
jbe@16 252 "value" TEXT NOT NULL );
jbe@16 253 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
jbe@16 254
jbe@23 255 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
jbe@16 256
jbe@16 257 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
jbe@16 258 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
jbe@16 259 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
jbe@16 260
jbe@16 261
jbe@23 262 CREATE TABLE "member_relation_setting" (
jbe@23 263 PRIMARY KEY ("member_id", "key", "other_member_id"),
jbe@23 264 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 265 "key" TEXT NOT NULL,
jbe@23 266 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 267 "value" TEXT NOT NULL );
jbe@23 268
jbe@38 269 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
jbe@23 270
jbe@23 271
jbe@7 272 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
jbe@7 273
jbe@7 274 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
jbe@7 275
jbe@7 276
jbe@7 277 CREATE TABLE "member_image" (
jbe@7 278 PRIMARY KEY ("member_id", "image_type", "scaled"),
jbe@7 279 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@7 280 "image_type" "member_image_type",
jbe@7 281 "scaled" BOOLEAN,
jbe@7 282 "content_type" TEXT,
jbe@7 283 "data" BYTEA NOT NULL );
jbe@7 284
jbe@7 285 COMMENT ON TABLE "member_image" IS 'Images of members';
jbe@7 286
jbe@7 287 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
jbe@0 288
jbe@0 289
jbe@4 290 CREATE TABLE "member_count" (
jbe@341 291 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@5 292 "total_count" INT4 NOT NULL );
jbe@4 293
jbe@5 294 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 295
jbe@5 296 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
jbe@5 297 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
jbe@4 298
jbe@4 299
jbe@0 300 CREATE TABLE "contact" (
jbe@0 301 PRIMARY KEY ("member_id", "other_member_id"),
jbe@0 302 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 303 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@11 304 "public" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@11 305 CONSTRAINT "cant_save_yourself_as_contact"
jbe@11 306 CHECK ("member_id" != "other_member_id") );
jbe@113 307 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
jbe@0 308
jbe@0 309 COMMENT ON TABLE "contact" IS 'Contact lists';
jbe@0 310
jbe@0 311 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
jbe@0 312 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
jbe@0 313 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
jbe@0 314
jbe@0 315
jbe@113 316 CREATE TABLE "ignored_member" (
jbe@113 317 PRIMARY KEY ("member_id", "other_member_id"),
jbe@113 318 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 319 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 320 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
jbe@113 321
jbe@113 322 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
jbe@113 323
jbe@113 324 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
jbe@113 325 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
jbe@113 326
jbe@113 327
jbe@220 328 CREATE TABLE "session" (
jbe@220 329 "ident" TEXT PRIMARY KEY,
jbe@220 330 "additional_secret" TEXT,
jbe@220 331 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
jbe@461 332 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
jbe@440 333 "authority" TEXT,
jbe@440 334 "authority_uid" TEXT,
jbe@440 335 "authority_login" TEXT,
jbe@387 336 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@220 337 "lang" TEXT );
jbe@220 338 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
jbe@220 339
jbe@220 340 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
jbe@220 341
jbe@220 342 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
jbe@220 343 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
jbe@220 344 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
jbe@440 345 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
jbe@440 346 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
jbe@440 347 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
jbe@387 348 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 349 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
jbe@220 350
jbe@220 351
jbe@424 352 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
jbe@424 353
jbe@424 354 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 355
jbe@424 356
jbe@424 357 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
jbe@424 358
jbe@424 359 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 360
jbe@424 361
jbe@0 362 CREATE TABLE "policy" (
jbe@0 363 "id" SERIAL4 PRIMARY KEY,
jbe@9 364 "index" INT4 NOT NULL,
jbe@0 365 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 366 "name" TEXT NOT NULL UNIQUE,
jbe@0 367 "description" TEXT NOT NULL DEFAULT '',
jbe@261 368 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@447 369 "min_admission_time" INTERVAL,
jbe@447 370 "max_admission_time" INTERVAL,
jbe@261 371 "discussion_time" INTERVAL,
jbe@261 372 "verification_time" INTERVAL,
jbe@261 373 "voting_time" INTERVAL,
jbe@292 374 "issue_quorum_num" INT4,
jbe@292 375 "issue_quorum_den" INT4,
jbe@0 376 "initiative_quorum_num" INT4 NOT NULL,
jbe@10 377 "initiative_quorum_den" INT4 NOT NULL,
jbe@424 378 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
jbe@424 379 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
jbe@167 380 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
jbe@167 381 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
jbe@167 382 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@167 383 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
jbe@167 384 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
jbe@167 385 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
jbe@167 386 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
jbe@167 387 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@167 388 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
jbe@167 389 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
jbe@429 390 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@260 391 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@260 392 CONSTRAINT "timing" CHECK (
jbe@261 393 ( "polling" = FALSE AND
jbe@447 394 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
jbe@454 395 "min_admission_time" <= "max_admission_time" AND
jbe@447 396 "discussion_time" NOTNULL AND
jbe@447 397 "verification_time" NOTNULL AND
jbe@447 398 "voting_time" NOTNULL ) OR
jbe@261 399 ( "polling" = TRUE AND
jbe@447 400 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@447 401 "discussion_time" NOTNULL AND
jbe@447 402 "verification_time" NOTNULL AND
jbe@447 403 "voting_time" NOTNULL ) OR
jbe@447 404 ( "polling" = TRUE AND
jbe@447 405 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@447 406 "discussion_time" ISNULL AND
jbe@447 407 "verification_time" ISNULL AND
jbe@447 408 "voting_time" ISNULL ) ),
jbe@292 409 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
jbe@447 410 "polling" = ("issue_quorum_num" ISNULL) AND
jbe@447 411 "polling" = ("issue_quorum_den" ISNULL) ),
jbe@429 412 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
jbe@429 413 "defeat_strength" = 'tuple'::"defeat_strength" OR
jbe@429 414 "no_reverse_beat_path" = FALSE ) );
jbe@0 415 CREATE INDEX "policy_active_idx" ON "policy" ("active");
jbe@0 416
jbe@0 417 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
jbe@0 418
jbe@9 419 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
jbe@0 420 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
jbe@447 421 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@447 422 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open';
jbe@447 423 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 424 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 425 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 426 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@207 427 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
jbe@207 428 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
jbe@10 429 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 430 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 431 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 432 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
jbe@167 433 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
jbe@167 434 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
jbe@167 435 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 436 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
jbe@167 437 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 438 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 439 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 440 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 441 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 442 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 443 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 444 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 445
jbe@0 446
jbe@97 447 CREATE TABLE "unit" (
jbe@97 448 "id" SERIAL4 PRIMARY KEY,
jbe@97 449 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 450 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@97 451 "name" TEXT NOT NULL,
jbe@97 452 "description" TEXT NOT NULL DEFAULT '',
jbe@444 453 "external_reference" TEXT,
jbe@97 454 "member_count" INT4,
jbe@97 455 "text_search_data" TSVECTOR );
jbe@97 456 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
jbe@97 457 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
jbe@97 458 CREATE INDEX "unit_active_idx" ON "unit" ("active");
jbe@97 459 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
jbe@97 460 CREATE TRIGGER "update_text_search_data"
jbe@97 461 BEFORE INSERT OR UPDATE ON "unit"
jbe@97 462 FOR EACH ROW EXECUTE PROCEDURE
jbe@97 463 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@97 464 "name", "description" );
jbe@97 465
jbe@97 466 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
jbe@97 467
jbe@444 468 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
jbe@444 469 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
jbe@444 470 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
jbe@444 471 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
jbe@97 472
jbe@97 473
jbe@465 474 CREATE TABLE "subscription" (
jbe@465 475 PRIMARY KEY ("member_id", "unit_id"),
jbe@465 476 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 477 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 478 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
jbe@465 479
jbe@465 480 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 481
jbe@465 482
jbe@203 483 CREATE TABLE "unit_setting" (
jbe@203 484 PRIMARY KEY ("member_id", "key", "unit_id"),
jbe@203 485 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@203 486 "key" TEXT NOT NULL,
jbe@203 487 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@203 488 "value" TEXT NOT NULL );
jbe@203 489
jbe@203 490 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
jbe@203 491
jbe@203 492
jbe@0 493 CREATE TABLE "area" (
jbe@0 494 "id" SERIAL4 PRIMARY KEY,
jbe@97 495 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 496 "active" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@0 497 "name" TEXT NOT NULL,
jbe@4 498 "description" TEXT NOT NULL DEFAULT '',
jbe@444 499 "external_reference" TEXT,
jbe@5 500 "direct_member_count" INT4,
jbe@5 501 "member_weight" INT4,
jbe@7 502 "text_search_data" TSVECTOR );
jbe@97 503 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
jbe@0 504 CREATE INDEX "area_active_idx" ON "area" ("active");
jbe@8 505 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
jbe@7 506 CREATE TRIGGER "update_text_search_data"
jbe@7 507 BEFORE INSERT OR UPDATE ON "area"
jbe@7 508 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 509 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@7 510 "name", "description" );
jbe@0 511
jbe@0 512 COMMENT ON TABLE "area" IS 'Subject areas';
jbe@0 513
jbe@5 514 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
jbe@444 515 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
jbe@5 516 COMMENT ON COLUMN "area"."direct_member_count" IS 'Number of active members of that area (ignoring their weight), as calculated from view "area_member_count"';
jbe@5 517 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
jbe@0 518
jbe@0 519
jbe@465 520 CREATE TABLE "ignored_area" (
jbe@465 521 PRIMARY KEY ("member_id", "area_id"),
jbe@465 522 "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 523 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 524 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
jbe@465 525
jbe@465 526 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 527
jbe@465 528
jbe@23 529 CREATE TABLE "area_setting" (
jbe@23 530 PRIMARY KEY ("member_id", "key", "area_id"),
jbe@23 531 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 532 "key" TEXT NOT NULL,
jbe@23 533 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 534 "value" TEXT NOT NULL );
jbe@23 535
jbe@23 536 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
jbe@23 537
jbe@23 538
jbe@9 539 CREATE TABLE "allowed_policy" (
jbe@9 540 PRIMARY KEY ("area_id", "policy_id"),
jbe@9 541 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 542 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@9 543 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@9 544 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
jbe@9 545
jbe@9 546 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
jbe@9 547
jbe@9 548 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
jbe@9 549
jbe@9 550
jbe@21 551 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
jbe@21 552
jbe@21 553 COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period';
jbe@8 554
jbe@8 555
jbe@112 556 CREATE TYPE "issue_state" AS ENUM (
jbe@112 557 'admission', 'discussion', 'verification', 'voting',
jbe@389 558 'canceled_by_admin',
jbe@113 559 'canceled_revoked_before_accepted',
jbe@113 560 'canceled_issue_not_accepted',
jbe@113 561 'canceled_after_revocation_during_discussion',
jbe@113 562 'canceled_after_revocation_during_verification',
jbe@113 563 'canceled_no_initiative_admitted',
jbe@112 564 'finished_without_winner', 'finished_with_winner');
jbe@111 565
jbe@111 566 COMMENT ON TYPE "issue_state" IS 'State of issues';
jbe@111 567
jbe@111 568
jbe@0 569 CREATE TABLE "issue" (
jbe@0 570 "id" SERIAL4 PRIMARY KEY,
jbe@0 571 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 572 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@389 573 "admin_notice" TEXT,
jbe@444 574 "external_reference" TEXT,
jbe@111 575 "state" "issue_state" NOT NULL DEFAULT 'admission',
jbe@328 576 "phase_finished" TIMESTAMPTZ,
jbe@0 577 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 578 "accepted" TIMESTAMPTZ,
jbe@3 579 "half_frozen" TIMESTAMPTZ,
jbe@3 580 "fully_frozen" TIMESTAMPTZ,
jbe@0 581 "closed" TIMESTAMPTZ,
jbe@59 582 "cleaned" TIMESTAMPTZ,
jbe@447 583 "min_admission_time" INTERVAL,
jbe@447 584 "max_admission_time" INTERVAL,
jbe@22 585 "discussion_time" INTERVAL NOT NULL,
jbe@22 586 "verification_time" INTERVAL NOT NULL,
jbe@22 587 "voting_time" INTERVAL NOT NULL,
jbe@0 588 "snapshot" TIMESTAMPTZ,
jbe@8 589 "latest_snapshot_event" "snapshot_event",
jbe@0 590 "population" INT4,
jbe@4 591 "voter_count" INT4,
jbe@170 592 "status_quo_schulze_rank" INT4,
jbe@291 593 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
jbe@447 594 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
jbe@452 595 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
jbe@340 596 CONSTRAINT "valid_state" CHECK (
jbe@340 597 (
jbe@340 598 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
jbe@340 599 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
jbe@340 600 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
jbe@340 601 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
jbe@340 602 ) AND (
jbe@340 603 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
jbe@340 604 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
jbe@340 605 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@340 606 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
jbe@389 607 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
jbe@340 608 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@340 609 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
jbe@340 610 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
jbe@340 611 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
jbe@340 612 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
jbe@340 613 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
jbe@340 614 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
jbe@111 615 )),
jbe@328 616 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
jbe@328 617 "phase_finished" ISNULL OR "closed" ISNULL ),
jbe@3 618 CONSTRAINT "state_change_order" CHECK (
jbe@10 619 "created" <= "accepted" AND
jbe@10 620 "accepted" <= "half_frozen" AND
jbe@10 621 "half_frozen" <= "fully_frozen" AND
jbe@3 622 "fully_frozen" <= "closed" ),
jbe@61 623 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
jbe@61 624 "cleaned" ISNULL OR "closed" NOTNULL ),
jbe@10 625 CONSTRAINT "last_snapshot_on_full_freeze"
jbe@10 626 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
jbe@10 627 CONSTRAINT "freeze_requires_snapshot"
jbe@10 628 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
jbe@10 629 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
jbe@447 630 CHECK (("snapshot" NOTNULL) = ("latest_snapshot_event" NOTNULL)) );
jbe@0 631 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
jbe@0 632 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
jbe@16 633 CREATE INDEX "issue_created_idx" ON "issue" ("created");
jbe@16 634 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
jbe@16 635 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
jbe@16 636 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
jbe@16 637 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
jbe@0 638 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
jbe@16 639 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
jbe@0 640
jbe@0 641 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
jbe@0 642
jbe@389 643 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
jbe@444 644 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
jbe@328 645 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@170 646 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
jbe@170 647 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 648 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 649 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 650 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
jbe@447 651 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@447 652 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 653 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 654 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 655 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
jbe@170 656 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
jbe@170 657 COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables';
jbe@170 658 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
jbe@170 659 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 660 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
jbe@0 661
jbe@0 662
jbe@410 663 CREATE TABLE "issue_order_in_admission_state" (
jbe@400 664 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@410 665 "order_in_area" INT4,
jbe@410 666 "order_in_unit" INT4 );
jbe@410 667
jbe@410 668 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 669
jbe@410 670 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 671 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 672 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 673
jbe@0 674
jbe@23 675 CREATE TABLE "issue_setting" (
jbe@23 676 PRIMARY KEY ("member_id", "key", "issue_id"),
jbe@23 677 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 678 "key" TEXT NOT NULL,
jbe@23 679 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 680 "value" TEXT NOT NULL );
jbe@23 681
jbe@23 682 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
jbe@23 683
jbe@23 684
jbe@0 685 CREATE TABLE "initiative" (
jbe@0 686 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
jbe@0 687 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 688 "id" SERIAL4 PRIMARY KEY,
jbe@0 689 "name" TEXT NOT NULL,
jbe@261 690 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@0 691 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 692 "revoked" TIMESTAMPTZ,
jbe@112 693 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@14 694 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@444 695 "external_reference" TEXT,
jbe@0 696 "admitted" BOOLEAN,
jbe@0 697 "supporter_count" INT4,
jbe@0 698 "informed_supporter_count" INT4,
jbe@0 699 "satisfied_supporter_count" INT4,
jbe@0 700 "satisfied_informed_supporter_count" INT4,
jbe@313 701 "harmonic_weight" NUMERIC(12, 3),
jbe@352 702 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@414 703 "first_preference_votes" INT4,
jbe@0 704 "positive_votes" INT4,
jbe@0 705 "negative_votes" INT4,
jbe@167 706 "direct_majority" BOOLEAN,
jbe@167 707 "indirect_majority" BOOLEAN,
jbe@170 708 "schulze_rank" INT4,
jbe@167 709 "better_than_status_quo" BOOLEAN,
jbe@167 710 "worse_than_status_quo" BOOLEAN,
jbe@429 711 "reverse_beat_path" BOOLEAN,
jbe@154 712 "multistage_majority" BOOLEAN,
jbe@154 713 "eligible" BOOLEAN,
jbe@126 714 "winner" BOOLEAN,
jbe@0 715 "rank" INT4,
jbe@7 716 "text_search_data" TSVECTOR,
jbe@112 717 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
jbe@447 718 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
jbe@14 719 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
jbe@14 720 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
jbe@0 721 CONSTRAINT "revoked_initiatives_cant_be_admitted"
jbe@0 722 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
jbe@128 723 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
jbe@128 724 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
jbe@414 725 ( "first_preference_votes" ISNULL AND
jbe@414 726 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
jbe@167 727 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
jbe@173 728 "schulze_rank" ISNULL AND
jbe@167 729 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
jbe@429 730 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
jbe@173 731 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
jbe@173 732 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
jbe@175 733 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
jbe@175 734 "eligible" = FALSE OR
jbe@175 735 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
jbe@175 736 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
jbe@175 737 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
jbe@176 738 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
jbe@173 739 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
jbe@16 740 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
jbe@16 741 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
jbe@8 742 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
jbe@7 743 CREATE TRIGGER "update_text_search_data"
jbe@7 744 BEFORE INSERT OR UPDATE ON "initiative"
jbe@7 745 FOR EACH ROW EXECUTE PROCEDURE
jbe@450 746 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
jbe@0 747
jbe@10 748 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 749
jbe@289 750 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
jbe@210 751 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
jbe@210 752 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
jbe@444 753 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
jbe@210 754 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
jbe@0 755 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 756 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 757 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@0 758 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
jbe@320 759 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 760 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 761 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
jbe@414 762 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
jbe@414 763 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
jbe@210 764 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 765 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
jbe@411 766 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
jbe@411 767 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
jbe@411 768 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 769 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 770 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 771 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 772 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
jbe@210 773 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 774
jbe@0 775
jbe@61 776 CREATE TABLE "battle" (
jbe@126 777 "issue_id" INT4 NOT NULL,
jbe@61 778 "winning_initiative_id" INT4,
jbe@61 779 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@61 780 "losing_initiative_id" INT4,
jbe@61 781 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@126 782 "count" INT4 NOT NULL,
jbe@126 783 CONSTRAINT "initiative_ids_not_equal" CHECK (
jbe@126 784 "winning_initiative_id" != "losing_initiative_id" OR
jbe@126 785 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
jbe@126 786 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
jbe@126 787 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
jbe@126 788 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
jbe@126 789 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
jbe@126 790
jbe@126 791 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 792
jbe@61 793
jbe@113 794 CREATE TABLE "ignored_initiative" (
jbe@465 795 PRIMARY KEY ("member_id", "initiative_id"),
jbe@465 796 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@465 797 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@465 798 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
jbe@113 799
jbe@509 800 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 801
jbe@113 802
jbe@23 803 CREATE TABLE "initiative_setting" (
jbe@23 804 PRIMARY KEY ("member_id", "key", "initiative_id"),
jbe@23 805 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 806 "key" TEXT NOT NULL,
jbe@23 807 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 808 "value" TEXT NOT NULL );
jbe@23 809
jbe@23 810 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
jbe@23 811
jbe@23 812
jbe@0 813 CREATE TABLE "draft" (
jbe@0 814 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
jbe@0 815 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 816 "id" SERIAL8 PRIMARY KEY,
jbe@0 817 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 818 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@9 819 "formatting_engine" TEXT,
jbe@7 820 "content" TEXT NOT NULL,
jbe@444 821 "external_reference" TEXT,
jbe@7 822 "text_search_data" TSVECTOR );
jbe@16 823 CREATE INDEX "draft_created_idx" ON "draft" ("created");
jbe@9 824 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
jbe@8 825 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
jbe@7 826 CREATE TRIGGER "update_text_search_data"
jbe@7 827 BEFORE INSERT OR UPDATE ON "draft"
jbe@7 828 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 829 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
jbe@0 830
jbe@10 831 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 832
jbe@444 833 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
jbe@444 834 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
jbe@444 835 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
jbe@9 836
jbe@0 837
jbe@63 838 CREATE TABLE "rendered_draft" (
jbe@63 839 PRIMARY KEY ("draft_id", "format"),
jbe@63 840 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@63 841 "format" TEXT,
jbe@63 842 "content" TEXT NOT NULL );
jbe@63 843
jbe@63 844 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 845
jbe@63 846
jbe@0 847 CREATE TABLE "suggestion" (
jbe@0 848 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
jbe@0 849 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 850 "id" SERIAL8 PRIMARY KEY,
jbe@160 851 "draft_id" INT8 NOT NULL,
jbe@160 852 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@0 853 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@0 854 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@0 855 "name" TEXT NOT NULL,
jbe@159 856 "formatting_engine" TEXT,
jbe@159 857 "content" TEXT NOT NULL DEFAULT '',
jbe@444 858 "external_reference" TEXT,
jbe@7 859 "text_search_data" TSVECTOR,
jbe@0 860 "minus2_unfulfilled_count" INT4,
jbe@0 861 "minus2_fulfilled_count" INT4,
jbe@0 862 "minus1_unfulfilled_count" INT4,
jbe@0 863 "minus1_fulfilled_count" INT4,
jbe@0 864 "plus1_unfulfilled_count" INT4,
jbe@0 865 "plus1_fulfilled_count" INT4,
jbe@0 866 "plus2_unfulfilled_count" INT4,
jbe@352 867 "plus2_fulfilled_count" INT4,
jbe@352 868 "proportional_order" INT4 );
jbe@16 869 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
jbe@9 870 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
jbe@8 871 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
jbe@7 872 CREATE TRIGGER "update_text_search_data"
jbe@7 873 BEFORE INSERT OR UPDATE ON "suggestion"
jbe@7 874 FOR EACH ROW EXECUTE PROCEDURE
jbe@7 875 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@159 876 "name", "content");
jbe@0 877
jbe@10 878 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 879
jbe@160 880 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@444 881 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
jbe@0 882 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 883 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 884 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 885 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 886 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 887 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 888 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@0 889 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
jbe@378 890 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 891
jbe@0 892
jbe@159 893 CREATE TABLE "rendered_suggestion" (
jbe@159 894 PRIMARY KEY ("suggestion_id", "format"),
jbe@159 895 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@159 896 "format" TEXT,
jbe@159 897 "content" TEXT NOT NULL );
jbe@159 898
jbe@159 899 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 900
jbe@159 901
jbe@23 902 CREATE TABLE "suggestion_setting" (
jbe@23 903 PRIMARY KEY ("member_id", "key", "suggestion_id"),
jbe@23 904 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 905 "key" TEXT NOT NULL,
jbe@23 906 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@23 907 "value" TEXT NOT NULL );
jbe@23 908
jbe@23 909 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
jbe@23 910
jbe@23 911
jbe@97 912 CREATE TABLE "privilege" (
jbe@97 913 PRIMARY KEY ("unit_id", "member_id"),
jbe@97 914 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 915 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@97 916 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 917 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@97 918 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@261 919 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@261 920 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@261 921 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
jbe@261 922 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
jbe@97 923
jbe@97 924 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
jbe@97 925
jbe@289 926 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
jbe@289 927 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
jbe@289 928 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
jbe@289 929 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
jbe@289 930 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
jbe@289 931 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
jbe@289 932 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 933
jbe@97 934
jbe@0 935 CREATE TABLE "membership" (
jbe@0 936 PRIMARY KEY ("area_id", "member_id"),
jbe@0 937 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@169 938 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 939 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
jbe@0 940
jbe@0 941 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
jbe@0 942
jbe@0 943
jbe@0 944 CREATE TABLE "interest" (
jbe@0 945 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 946 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@148 947 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 948 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
jbe@0 949
jbe@10 950 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 951
jbe@0 952
jbe@0 953 CREATE TABLE "initiator" (
jbe@0 954 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 955 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 956 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@14 957 "accepted" BOOLEAN );
jbe@0 958 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
jbe@0 959
jbe@10 960 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 961
jbe@14 962 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 963
jbe@0 964
jbe@0 965 CREATE TABLE "supporter" (
jbe@0 966 "issue_id" INT4 NOT NULL,
jbe@0 967 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 968 "initiative_id" INT4,
jbe@0 969 "member_id" INT4,
jbe@0 970 "draft_id" INT8 NOT NULL,
jbe@10 971 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@160 972 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
jbe@0 973 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
jbe@0 974
jbe@10 975 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 976
jbe@207 977 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 978 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 979
jbe@0 980
jbe@0 981 CREATE TABLE "opinion" (
jbe@0 982 "initiative_id" INT4 NOT NULL,
jbe@0 983 PRIMARY KEY ("suggestion_id", "member_id"),
jbe@0 984 "suggestion_id" INT8,
jbe@0 985 "member_id" INT4,
jbe@0 986 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
jbe@0 987 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@42 988 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 989 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@10 990 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
jbe@0 991
jbe@10 992 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 993
jbe@0 994 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
jbe@0 995
jbe@0 996
jbe@97 997 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
jbe@97 998
jbe@97 999 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
jbe@10 1000
jbe@10 1001
jbe@0 1002 CREATE TABLE "delegation" (
jbe@0 1003 "id" SERIAL8 PRIMARY KEY,
jbe@0 1004 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@86 1005 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@10 1006 "scope" "delegation_scope" NOT NULL,
jbe@97 1007 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1008 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1009 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1010 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
jbe@97 1011 CONSTRAINT "no_unit_delegation_to_null"
jbe@97 1012 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
jbe@10 1013 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
jbe@97 1014 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
jbe@97 1015 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
jbe@97 1016 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
jbe@97 1017 UNIQUE ("unit_id", "truster_id"),
jbe@74 1018 UNIQUE ("area_id", "truster_id"),
jbe@74 1019 UNIQUE ("issue_id", "truster_id") );
jbe@0 1020 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
jbe@0 1021 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
jbe@0 1022
jbe@0 1023 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
jbe@0 1024
jbe@97 1025 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
jbe@0 1026 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
jbe@0 1027 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
jbe@0 1028
jbe@0 1029
jbe@0 1030 CREATE TABLE "direct_population_snapshot" (
jbe@0 1031 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 1032 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1033 "event" "snapshot_event",
jbe@45 1034 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@54 1035 "weight" INT4 );
jbe@0 1036 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
jbe@0 1037
jbe@389 1038 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1039
jbe@148 1040 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@148 1041 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
jbe@0 1042
jbe@0 1043
jbe@0 1044 CREATE TABLE "delegating_population_snapshot" (
jbe@0 1045 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 1046 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1047 "event" "snapshot_event",
jbe@45 1048 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 1049 "weight" INT4,
jbe@10 1050 "scope" "delegation_scope" NOT NULL,
jbe@0 1051 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 1052 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
jbe@0 1053
jbe@389 1054 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
jbe@0 1055
jbe@0 1056 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 1057 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
jbe@8 1058 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
jbe@0 1059 COMMENT ON COLUMN "delegating_population_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_population_snapshot"';
jbe@0 1060
jbe@0 1061
jbe@0 1062 CREATE TABLE "direct_interest_snapshot" (
jbe@0 1063 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 1064 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1065 "event" "snapshot_event",
jbe@45 1066 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@144 1067 "weight" INT4 );
jbe@0 1068 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
jbe@0 1069
jbe@389 1070 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 1071
jbe@0 1072 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 1073 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
jbe@0 1074
jbe@0 1075
jbe@0 1076 CREATE TABLE "delegating_interest_snapshot" (
jbe@0 1077 PRIMARY KEY ("issue_id", "event", "member_id"),
jbe@0 1078 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@0 1079 "event" "snapshot_event",
jbe@45 1080 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 1081 "weight" INT4,
jbe@10 1082 "scope" "delegation_scope" NOT NULL,
jbe@0 1083 "delegate_member_ids" INT4[] NOT NULL );
jbe@0 1084 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
jbe@0 1085
jbe@389 1086 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 1087
jbe@0 1088 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 1089 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
jbe@8 1090 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
jbe@0 1091 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 1092
jbe@0 1093
jbe@0 1094 CREATE TABLE "direct_supporter_snapshot" (
jbe@0 1095 "issue_id" INT4 NOT NULL,
jbe@0 1096 PRIMARY KEY ("initiative_id", "event", "member_id"),
jbe@0 1097 "initiative_id" INT4,
jbe@0 1098 "event" "snapshot_event",
jbe@45 1099 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@204 1100 "draft_id" INT8 NOT NULL,
jbe@0 1101 "informed" BOOLEAN NOT NULL,
jbe@0 1102 "satisfied" BOOLEAN NOT NULL,
jbe@0 1103 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@204 1104 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@0 1105 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@0 1106 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
jbe@0 1107
jbe@389 1108 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 1109
jbe@207 1110 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 1111 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
jbe@0 1112 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
jbe@0 1113 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
jbe@0 1114
jbe@0 1115
jbe@113 1116 CREATE TABLE "non_voter" (
jbe@113 1117 PRIMARY KEY ("issue_id", "member_id"),
jbe@113 1118 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@113 1119 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@113 1120 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
jbe@113 1121
jbe@113 1122 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
jbe@113 1123
jbe@113 1124
jbe@0 1125 CREATE TABLE "direct_voter" (
jbe@0 1126 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1127 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1128 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@285 1129 "weight" INT4,
jbe@285 1130 "comment_changed" TIMESTAMPTZ,
jbe@285 1131 "formatting_engine" TEXT,
jbe@285 1132 "comment" TEXT,
jbe@285 1133 "text_search_data" TSVECTOR );
jbe@0 1134 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
jbe@285 1135 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
jbe@285 1136 CREATE TRIGGER "update_text_search_data"
jbe@285 1137 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@285 1138 FOR EACH ROW EXECUTE PROCEDURE
jbe@285 1139 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
jbe@0 1140
jbe@389 1141 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 1142
jbe@285 1143 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
jbe@285 1144 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 1145 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 1146 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 1147
jbe@285 1148
jbe@285 1149 CREATE TABLE "rendered_voter_comment" (
jbe@285 1150 PRIMARY KEY ("issue_id", "member_id", "format"),
jbe@285 1151 FOREIGN KEY ("issue_id", "member_id")
jbe@285 1152 REFERENCES "direct_voter" ("issue_id", "member_id")
jbe@285 1153 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@285 1154 "issue_id" INT4,
jbe@285 1155 "member_id" INT4,
jbe@285 1156 "format" TEXT,
jbe@285 1157 "content" TEXT NOT NULL );
jbe@285 1158
jbe@285 1159 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 1160
jbe@0 1161
jbe@0 1162 CREATE TABLE "delegating_voter" (
jbe@0 1163 PRIMARY KEY ("issue_id", "member_id"),
jbe@0 1164 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@45 1165 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@8 1166 "weight" INT4,
jbe@10 1167 "scope" "delegation_scope" NOT NULL,
jbe@0 1168 "delegate_member_ids" INT4[] NOT NULL );
jbe@52 1169 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
jbe@0 1170
jbe@389 1171 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 1172
jbe@0 1173 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
jbe@8 1174 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
jbe@0 1175 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 1176
jbe@0 1177
jbe@0 1178 CREATE TABLE "vote" (
jbe@0 1179 "issue_id" INT4 NOT NULL,
jbe@0 1180 PRIMARY KEY ("initiative_id", "member_id"),
jbe@0 1181 "initiative_id" INT4,
jbe@0 1182 "member_id" INT4,
jbe@414 1183 "grade" INT4 NOT NULL,
jbe@414 1184 "first_preference" BOOLEAN,
jbe@0 1185 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@414 1186 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@414 1187 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
jbe@414 1188 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
jbe@0 1189 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
jbe@0 1190
jbe@389 1191 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 1192
jbe@414 1193 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 1194 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 1195 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 1196
jbe@0 1197
jbe@112 1198 CREATE TYPE "event_type" AS ENUM (
jbe@112 1199 'issue_state_changed',
jbe@112 1200 'initiative_created_in_new_issue',
jbe@112 1201 'initiative_created_in_existing_issue',
jbe@112 1202 'initiative_revoked',
jbe@112 1203 'new_draft_created',
jbe@112 1204 'suggestion_created');
jbe@112 1205
jbe@112 1206 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
jbe@112 1207
jbe@112 1208
jbe@112 1209 CREATE TABLE "event" (
jbe@112 1210 "id" SERIAL8 PRIMARY KEY,
jbe@112 1211 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@112 1212 "event" "event_type" NOT NULL,
jbe@112 1213 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
jbe@112 1214 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@328 1215 "state" "issue_state",
jbe@112 1216 "initiative_id" INT4,
jbe@112 1217 "draft_id" INT8,
jbe@112 1218 "suggestion_id" INT8,
jbe@112 1219 FOREIGN KEY ("issue_id", "initiative_id")
jbe@112 1220 REFERENCES "initiative" ("issue_id", "id")
jbe@112 1221 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1222 FOREIGN KEY ("initiative_id", "draft_id")
jbe@112 1223 REFERENCES "draft" ("initiative_id", "id")
jbe@112 1224 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@112 1225 FOREIGN KEY ("initiative_id", "suggestion_id")
jbe@112 1226 REFERENCES "suggestion" ("initiative_id", "id")
jbe@112 1227 ON DELETE CASCADE ON UPDATE CASCADE,
jbe@451 1228 CONSTRAINT "null_constr_for_issue_state_changed" CHECK (
jbe@112 1229 "event" != 'issue_state_changed' OR (
jbe@112 1230 "member_id" ISNULL AND
jbe@112 1231 "issue_id" NOTNULL AND
jbe@113 1232 "state" NOTNULL AND
jbe@112 1233 "initiative_id" ISNULL AND
jbe@112 1234 "draft_id" ISNULL AND
jbe@112 1235 "suggestion_id" ISNULL )),
jbe@451 1236 CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
jbe@112 1237 "event" NOT IN (
jbe@112 1238 'initiative_created_in_new_issue',
jbe@112 1239 'initiative_created_in_existing_issue',
jbe@112 1240 'initiative_revoked',
jbe@112 1241 'new_draft_created'
jbe@112 1242 ) OR (
jbe@112 1243 "member_id" NOTNULL AND
jbe@112 1244 "issue_id" NOTNULL AND
jbe@113 1245 "state" NOTNULL AND
jbe@112 1246 "initiative_id" NOTNULL AND
jbe@112 1247 "draft_id" NOTNULL AND
jbe@112 1248 "suggestion_id" ISNULL )),
jbe@451 1249 CONSTRAINT "null_constr_for_suggestion_creation" CHECK (
jbe@112 1250 "event" != 'suggestion_created' OR (
jbe@112 1251 "member_id" NOTNULL AND
jbe@112 1252 "issue_id" NOTNULL AND
jbe@113 1253 "state" NOTNULL AND
jbe@112 1254 "initiative_id" NOTNULL AND
jbe@112 1255 "draft_id" ISNULL AND
jbe@112 1256 "suggestion_id" NOTNULL )) );
jbe@223 1257 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
jbe@112 1258
jbe@112 1259 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
jbe@112 1260
jbe@114 1261 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
jbe@114 1262 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
jbe@114 1263 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
jbe@114 1264 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
jbe@114 1265
jbe@112 1266
jbe@507 1267 CREATE TABLE "notification_event_sent" (
jbe@222 1268 "event_id" INT8 NOT NULL );
jbe@507 1269 CREATE UNIQUE INDEX "notification_event_sent_singleton_idx" ON "notification_event_sent" ((1));
jbe@507 1270
jbe@507 1271 COMMENT ON TABLE "notification_event_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
jbe@507 1272 COMMENT ON INDEX "notification_event_sent_singleton_idx" IS 'This index ensures that "notification_event_sent" only contains one row maximum.';
jbe@507 1273
jbe@507 1274
jbe@507 1275 CREATE TABLE "notification_initiative_sent" (
jbe@486 1276 PRIMARY KEY ("member_id", "initiative_id"),
jbe@486 1277 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@486 1278 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@486 1279 "last_draft_id" INT8 NOT NULL,
jbe@495 1280 "last_suggestion_id" INT8 );
jbe@507 1281 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
jbe@486 1282
jbe@508 1283 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
jbe@508 1284
jbe@508 1285 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
jbe@508 1286 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
jbe@508 1287
jbe@486 1288
jbe@496 1289 CREATE TABLE "newsletter" (
jbe@496 1290 "id" SERIAL4 PRIMARY KEY,
jbe@496 1291 "published" TIMESTAMPTZ NOT NULL,
jbe@496 1292 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@496 1293 "include_all_members" BOOLEAN NOT NULL,
jbe@496 1294 "sent" TIMESTAMPTZ,
jbe@496 1295 "subject" TEXT NOT NULL,
jbe@496 1296 "content" TEXT NOT NULL );
jbe@496 1297 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
jbe@496 1298 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
jbe@496 1299 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
jbe@496 1300
jbe@508 1301 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
jbe@508 1302
jbe@508 1303 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
jbe@508 1304 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 1305 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
jbe@508 1306 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
jbe@508 1307 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
jbe@508 1308 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
jbe@508 1309
jbe@496 1310
jbe@112 1311
jbe@112 1312 ----------------------------------------------
jbe@112 1313 -- Writing of history entries and event log --
jbe@112 1314 ----------------------------------------------
jbe@13 1315
jbe@181 1316
jbe@13 1317 CREATE FUNCTION "write_member_history_trigger"()
jbe@13 1318 RETURNS TRIGGER
jbe@13 1319 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@13 1320 BEGIN
jbe@42 1321 IF
jbe@230 1322 ( NEW."active" != OLD."active" OR
jbe@230 1323 NEW."name" != OLD."name" ) AND
jbe@230 1324 OLD."activated" NOTNULL
jbe@42 1325 THEN
jbe@42 1326 INSERT INTO "member_history"
jbe@57 1327 ("member_id", "active", "name")
jbe@57 1328 VALUES (NEW."id", OLD."active", OLD."name");
jbe@13 1329 END IF;
jbe@13 1330 RETURN NULL;
jbe@13 1331 END;
jbe@13 1332 $$;
jbe@13 1333
jbe@13 1334 CREATE TRIGGER "write_member_history"
jbe@13 1335 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@13 1336 "write_member_history_trigger"();
jbe@13 1337
jbe@13 1338 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
jbe@57 1339 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 1340
jbe@13 1341
jbe@112 1342 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
jbe@112 1343 RETURNS TRIGGER
jbe@112 1344 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1345 BEGIN
jbe@328 1346 IF NEW."state" != OLD."state" THEN
jbe@112 1347 INSERT INTO "event" ("event", "issue_id", "state")
jbe@112 1348 VALUES ('issue_state_changed', NEW."id", NEW."state");
jbe@112 1349 END IF;
jbe@112 1350 RETURN NULL;
jbe@112 1351 END;
jbe@112 1352 $$;
jbe@112 1353
jbe@112 1354 CREATE TRIGGER "write_event_issue_state_changed"
jbe@112 1355 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1356 "write_event_issue_state_changed_trigger"();
jbe@112 1357
jbe@112 1358 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
jbe@112 1359 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
jbe@112 1360
jbe@112 1361
jbe@112 1362 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
jbe@112 1363 RETURNS TRIGGER
jbe@112 1364 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1365 DECLARE
jbe@112 1366 "initiative_row" "initiative"%ROWTYPE;
jbe@113 1367 "issue_row" "issue"%ROWTYPE;
jbe@112 1368 "event_v" "event_type";
jbe@112 1369 BEGIN
jbe@112 1370 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 1371 WHERE "id" = NEW."initiative_id";
jbe@113 1372 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1373 WHERE "id" = "initiative_row"."issue_id";
jbe@112 1374 IF EXISTS (
jbe@112 1375 SELECT NULL FROM "draft"
jbe@112 1376 WHERE "initiative_id" = NEW."initiative_id"
jbe@112 1377 AND "id" != NEW."id"
jbe@112 1378 ) THEN
jbe@112 1379 "event_v" := 'new_draft_created';
jbe@112 1380 ELSE
jbe@112 1381 IF EXISTS (
jbe@112 1382 SELECT NULL FROM "initiative"
jbe@112 1383 WHERE "issue_id" = "initiative_row"."issue_id"
jbe@112 1384 AND "id" != "initiative_row"."id"
jbe@112 1385 ) THEN
jbe@112 1386 "event_v" := 'initiative_created_in_existing_issue';
jbe@112 1387 ELSE
jbe@112 1388 "event_v" := 'initiative_created_in_new_issue';
jbe@112 1389 END IF;
jbe@112 1390 END IF;
jbe@112 1391 INSERT INTO "event" (
jbe@112 1392 "event", "member_id",
jbe@113 1393 "issue_id", "state", "initiative_id", "draft_id"
jbe@112 1394 ) VALUES (
jbe@112 1395 "event_v",
jbe@112 1396 NEW."author_id",
jbe@112 1397 "initiative_row"."issue_id",
jbe@113 1398 "issue_row"."state",
jbe@112 1399 "initiative_row"."id",
jbe@112 1400 NEW."id" );
jbe@112 1401 RETURN NULL;
jbe@112 1402 END;
jbe@112 1403 $$;
jbe@112 1404
jbe@112 1405 CREATE TRIGGER "write_event_initiative_or_draft_created"
jbe@112 1406 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1407 "write_event_initiative_or_draft_created_trigger"();
jbe@112 1408
jbe@112 1409 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 1410 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
jbe@112 1411
jbe@112 1412
jbe@112 1413 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
jbe@112 1414 RETURNS TRIGGER
jbe@112 1415 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@113 1416 DECLARE
jbe@231 1417 "issue_row" "issue"%ROWTYPE;
jbe@231 1418 "draft_id_v" "draft"."id"%TYPE;
jbe@112 1419 BEGIN
jbe@112 1420 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
jbe@231 1421 SELECT * INTO "issue_row" FROM "issue"
jbe@231 1422 WHERE "id" = NEW."issue_id";
jbe@231 1423 SELECT "id" INTO "draft_id_v" FROM "current_draft"
jbe@231 1424 WHERE "initiative_id" = NEW."id";
jbe@112 1425 INSERT INTO "event" (
jbe@231 1426 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
jbe@112 1427 ) VALUES (
jbe@112 1428 'initiative_revoked',
jbe@112 1429 NEW."revoked_by_member_id",
jbe@112 1430 NEW."issue_id",
jbe@113 1431 "issue_row"."state",
jbe@231 1432 NEW."id",
jbe@231 1433 "draft_id_v");
jbe@112 1434 END IF;
jbe@112 1435 RETURN NULL;
jbe@112 1436 END;
jbe@112 1437 $$;
jbe@112 1438
jbe@112 1439 CREATE TRIGGER "write_event_initiative_revoked"
jbe@112 1440 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1441 "write_event_initiative_revoked_trigger"();
jbe@112 1442
jbe@112 1443 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
jbe@112 1444 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
jbe@112 1445
jbe@112 1446
jbe@112 1447 CREATE FUNCTION "write_event_suggestion_created_trigger"()
jbe@112 1448 RETURNS TRIGGER
jbe@112 1449 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@112 1450 DECLARE
jbe@112 1451 "initiative_row" "initiative"%ROWTYPE;
jbe@113 1452 "issue_row" "issue"%ROWTYPE;
jbe@112 1453 BEGIN
jbe@112 1454 SELECT * INTO "initiative_row" FROM "initiative"
jbe@112 1455 WHERE "id" = NEW."initiative_id";
jbe@113 1456 SELECT * INTO "issue_row" FROM "issue"
jbe@113 1457 WHERE "id" = "initiative_row"."issue_id";
jbe@112 1458 INSERT INTO "event" (
jbe@112 1459 "event", "member_id",
jbe@113 1460 "issue_id", "state", "initiative_id", "suggestion_id"
jbe@112 1461 ) VALUES (
jbe@112 1462 'suggestion_created',
jbe@112 1463 NEW."author_id",
jbe@112 1464 "initiative_row"."issue_id",
jbe@113 1465 "issue_row"."state",
jbe@112 1466 "initiative_row"."id",
jbe@112 1467 NEW."id" );
jbe@112 1468 RETURN NULL;
jbe@112 1469 END;
jbe@112 1470 $$;
jbe@112 1471
jbe@112 1472 CREATE TRIGGER "write_event_suggestion_created"
jbe@112 1473 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
jbe@112 1474 "write_event_suggestion_created_trigger"();
jbe@112 1475
jbe@112 1476 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
jbe@112 1477 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
jbe@112 1478
jbe@112 1479
jbe@13 1480
jbe@0 1481 ----------------------------
jbe@0 1482 -- Additional constraints --
jbe@0 1483 ----------------------------
jbe@0 1484
jbe@0 1485
jbe@0 1486 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
jbe@0 1487 RETURNS TRIGGER
jbe@0 1488 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1489 BEGIN
jbe@0 1490 IF NOT EXISTS (
jbe@0 1491 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
jbe@0 1492 ) THEN
jbe@463 1493 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
jbe@463 1494 ERRCODE = 'integrity_constraint_violation',
jbe@463 1495 HINT = 'Create issue, initiative, and draft within the same transaction.';
jbe@0 1496 END IF;
jbe@0 1497 RETURN NULL;
jbe@0 1498 END;
jbe@0 1499 $$;
jbe@0 1500
jbe@0 1501 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
jbe@0 1502 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
jbe@0 1503 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1504 "issue_requires_first_initiative_trigger"();
jbe@0 1505
jbe@0 1506 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
jbe@0 1507 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
jbe@0 1508
jbe@0 1509
jbe@0 1510 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
jbe@0 1511 RETURNS TRIGGER
jbe@0 1512 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1513 DECLARE
jbe@0 1514 "reference_lost" BOOLEAN;
jbe@0 1515 BEGIN
jbe@0 1516 IF TG_OP = 'DELETE' THEN
jbe@0 1517 "reference_lost" := TRUE;
jbe@0 1518 ELSE
jbe@0 1519 "reference_lost" := NEW."issue_id" != OLD."issue_id";
jbe@0 1520 END IF;
jbe@0 1521 IF
jbe@0 1522 "reference_lost" AND NOT EXISTS (
jbe@0 1523 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
jbe@0 1524 )
jbe@0 1525 THEN
jbe@0 1526 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
jbe@0 1527 END IF;
jbe@0 1528 RETURN NULL;
jbe@0 1529 END;
jbe@0 1530 $$;
jbe@0 1531
jbe@0 1532 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
jbe@0 1533 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 1534 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1535 "last_initiative_deletes_issue_trigger"();
jbe@0 1536
jbe@0 1537 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
jbe@0 1538 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
jbe@0 1539
jbe@0 1540
jbe@0 1541 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
jbe@0 1542 RETURNS TRIGGER
jbe@0 1543 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1544 BEGIN
jbe@0 1545 IF NOT EXISTS (
jbe@0 1546 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
jbe@0 1547 ) THEN
jbe@463 1548 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
jbe@463 1549 ERRCODE = 'integrity_constraint_violation',
jbe@463 1550 HINT = 'Create issue, initiative and draft within the same transaction.';
jbe@0 1551 END IF;
jbe@0 1552 RETURN NULL;
jbe@0 1553 END;
jbe@0 1554 $$;
jbe@0 1555
jbe@0 1556 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
jbe@0 1557 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
jbe@0 1558 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1559 "initiative_requires_first_draft_trigger"();
jbe@0 1560
jbe@0 1561 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
jbe@0 1562 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
jbe@0 1563
jbe@0 1564
jbe@0 1565 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
jbe@0 1566 RETURNS TRIGGER
jbe@0 1567 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1568 DECLARE
jbe@0 1569 "reference_lost" BOOLEAN;
jbe@0 1570 BEGIN
jbe@0 1571 IF TG_OP = 'DELETE' THEN
jbe@0 1572 "reference_lost" := TRUE;
jbe@0 1573 ELSE
jbe@0 1574 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
jbe@0 1575 END IF;
jbe@0 1576 IF
jbe@0 1577 "reference_lost" AND NOT EXISTS (
jbe@0 1578 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
jbe@0 1579 )
jbe@0 1580 THEN
jbe@0 1581 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
jbe@0 1582 END IF;
jbe@0 1583 RETURN NULL;
jbe@0 1584 END;
jbe@0 1585 $$;
jbe@0 1586
jbe@0 1587 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
jbe@0 1588 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
jbe@0 1589 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1590 "last_draft_deletes_initiative_trigger"();
jbe@0 1591
jbe@0 1592 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
jbe@0 1593 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
jbe@0 1594
jbe@0 1595
jbe@0 1596 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
jbe@0 1597 RETURNS TRIGGER
jbe@0 1598 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1599 BEGIN
jbe@0 1600 IF NOT EXISTS (
jbe@0 1601 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
jbe@0 1602 ) THEN
jbe@463 1603 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
jbe@463 1604 ERRCODE = 'integrity_constraint_violation',
jbe@463 1605 HINT = 'Create suggestion and opinion within the same transaction.';
jbe@0 1606 END IF;
jbe@0 1607 RETURN NULL;
jbe@0 1608 END;
jbe@0 1609 $$;
jbe@0 1610
jbe@0 1611 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
jbe@0 1612 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
jbe@0 1613 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1614 "suggestion_requires_first_opinion_trigger"();
jbe@0 1615
jbe@0 1616 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
jbe@0 1617 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
jbe@0 1618
jbe@0 1619
jbe@0 1620 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
jbe@0 1621 RETURNS TRIGGER
jbe@0 1622 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1623 DECLARE
jbe@0 1624 "reference_lost" BOOLEAN;
jbe@0 1625 BEGIN
jbe@0 1626 IF TG_OP = 'DELETE' THEN
jbe@0 1627 "reference_lost" := TRUE;
jbe@0 1628 ELSE
jbe@0 1629 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
jbe@0 1630 END IF;
jbe@0 1631 IF
jbe@0 1632 "reference_lost" AND NOT EXISTS (
jbe@0 1633 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
jbe@0 1634 )
jbe@0 1635 THEN
jbe@0 1636 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
jbe@0 1637 END IF;
jbe@0 1638 RETURN NULL;
jbe@0 1639 END;
jbe@0 1640 $$;
jbe@0 1641
jbe@0 1642 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
jbe@0 1643 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
jbe@0 1644 FOR EACH ROW EXECUTE PROCEDURE
jbe@0 1645 "last_opinion_deletes_suggestion_trigger"();
jbe@0 1646
jbe@0 1647 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
jbe@0 1648 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
jbe@0 1649
jbe@0 1650
jbe@284 1651 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
jbe@284 1652 RETURNS TRIGGER
jbe@284 1653 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@284 1654 BEGIN
jbe@284 1655 DELETE FROM "direct_voter"
jbe@284 1656 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@284 1657 RETURN NULL;
jbe@284 1658 END;
jbe@284 1659 $$;
jbe@284 1660
jbe@284 1661 CREATE TRIGGER "non_voter_deletes_direct_voter"
jbe@284 1662 AFTER INSERT OR UPDATE ON "non_voter"
jbe@284 1663 FOR EACH ROW EXECUTE PROCEDURE
jbe@284 1664 "non_voter_deletes_direct_voter_trigger"();
jbe@284 1665
jbe@284 1666 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
jbe@284 1667 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 1668
jbe@284 1669
jbe@284 1670 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
jbe@284 1671 RETURNS TRIGGER
jbe@284 1672 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@284 1673 BEGIN
jbe@284 1674 DELETE FROM "non_voter"
jbe@284 1675 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
jbe@284 1676 RETURN NULL;
jbe@284 1677 END;
jbe@284 1678 $$;
jbe@284 1679
jbe@284 1680 CREATE TRIGGER "direct_voter_deletes_non_voter"
jbe@284 1681 AFTER INSERT OR UPDATE ON "direct_voter"
jbe@284 1682 FOR EACH ROW EXECUTE PROCEDURE
jbe@284 1683 "direct_voter_deletes_non_voter_trigger"();
jbe@284 1684
jbe@284 1685 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
jbe@284 1686 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 1687
jbe@284 1688
jbe@285 1689 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
jbe@285 1690 RETURNS TRIGGER
jbe@285 1691 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@285 1692 BEGIN
jbe@285 1693 IF NEW."comment" ISNULL THEN
jbe@285 1694 NEW."comment_changed" := NULL;
jbe@285 1695 NEW."formatting_engine" := NULL;
jbe@285 1696 END IF;
jbe@285 1697 RETURN NEW;
jbe@285 1698 END;
jbe@285 1699 $$;
jbe@285 1700
jbe@285 1701 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
jbe@285 1702 BEFORE INSERT OR UPDATE ON "direct_voter"
jbe@285 1703 FOR EACH ROW EXECUTE PROCEDURE
jbe@285 1704 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
jbe@285 1705
jbe@285 1706 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 1707 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 1708
jbe@0 1709
jbe@20 1710 ---------------------------------------------------------------
jbe@333 1711 -- Ensure that votes are not modified when issues are closed --
jbe@20 1712 ---------------------------------------------------------------
jbe@20 1713
jbe@20 1714 -- NOTE: Frontends should ensure this anyway, but in case of programming
jbe@20 1715 -- errors the following triggers ensure data integrity.
jbe@20 1716
jbe@20 1717
jbe@20 1718 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
jbe@20 1719 RETURNS TRIGGER
jbe@20 1720 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@20 1721 DECLARE
jbe@336 1722 "issue_id_v" "issue"."id"%TYPE;
jbe@336 1723 "issue_row" "issue"%ROWTYPE;
jbe@20 1724 BEGIN
jbe@383 1725 IF EXISTS (
jbe@385 1726 SELECT NULL FROM "temporary_transaction_data"
jbe@385 1727 WHERE "txid" = txid_current()
jbe@383 1728 AND "key" = 'override_protection_triggers'
jbe@383 1729 AND "value" = TRUE::TEXT
jbe@383 1730 ) THEN
jbe@383 1731 RETURN NULL;
jbe@383 1732 END IF;
jbe@32 1733 IF TG_OP = 'DELETE' THEN
jbe@32 1734 "issue_id_v" := OLD."issue_id";
jbe@32 1735 ELSE
jbe@32 1736 "issue_id_v" := NEW."issue_id";
jbe@32 1737 END IF;
jbe@20 1738 SELECT INTO "issue_row" * FROM "issue"
jbe@32 1739 WHERE "id" = "issue_id_v" FOR SHARE;
jbe@383 1740 IF (
jbe@383 1741 "issue_row"."closed" NOTNULL OR (
jbe@383 1742 "issue_row"."state" = 'voting' AND
jbe@383 1743 "issue_row"."phase_finished" NOTNULL
jbe@383 1744 )
jbe@383 1745 ) THEN
jbe@332 1746 IF
jbe@332 1747 TG_RELID = 'direct_voter'::regclass AND
jbe@332 1748 TG_OP = 'UPDATE'
jbe@332 1749 THEN
jbe@332 1750 IF
jbe@332 1751 OLD."issue_id" = NEW."issue_id" AND
jbe@332 1752 OLD."member_id" = NEW."member_id" AND
jbe@332 1753 OLD."weight" = NEW."weight"
jbe@332 1754 THEN
jbe@332 1755 RETURN NULL; -- allows changing of voter comment
jbe@332 1756 END IF;
jbe@332 1757 END IF;
jbe@463 1758 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
jbe@463 1759 ERRCODE = 'integrity_constraint_violation';
jbe@20 1760 END IF;
jbe@20 1761 RETURN NULL;
jbe@20 1762 END;
jbe@20 1763 $$;
jbe@20 1764
jbe@20 1765 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1766 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@20 1767 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1768 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1769
jbe@20 1770 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1771 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@20 1772 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1773 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1774
jbe@20 1775 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1776 AFTER INSERT OR UPDATE OR DELETE ON "vote"
jbe@20 1777 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1778 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1779
jbe@20 1780 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 1781 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 1782 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 1783 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 1784
jbe@20 1785
jbe@20 1786
jbe@0 1787 --------------------------------------------------------------------
jbe@0 1788 -- Auto-retrieval of fields only needed for referential integrity --
jbe@0 1789 --------------------------------------------------------------------
jbe@0 1790
jbe@20 1791
jbe@0 1792 CREATE FUNCTION "autofill_issue_id_trigger"()
jbe@0 1793 RETURNS TRIGGER
jbe@0 1794 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1795 BEGIN
jbe@0 1796 IF NEW."issue_id" ISNULL THEN
jbe@0 1797 SELECT "issue_id" INTO NEW."issue_id"
jbe@0 1798 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1799 END IF;
jbe@0 1800 RETURN NEW;
jbe@0 1801 END;
jbe@0 1802 $$;
jbe@0 1803
jbe@0 1804 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
jbe@0 1805 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1806
jbe@0 1807 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
jbe@0 1808 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1809
jbe@0 1810 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
jbe@0 1811 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1812 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1813
jbe@0 1814
jbe@0 1815 CREATE FUNCTION "autofill_initiative_id_trigger"()
jbe@0 1816 RETURNS TRIGGER
jbe@0 1817 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1818 BEGIN
jbe@0 1819 IF NEW."initiative_id" ISNULL THEN
jbe@0 1820 SELECT "initiative_id" INTO NEW."initiative_id"
jbe@0 1821 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1822 END IF;
jbe@0 1823 RETURN NEW;
jbe@0 1824 END;
jbe@0 1825 $$;
jbe@0 1826
jbe@0 1827 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
jbe@0 1828 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
jbe@0 1829
jbe@0 1830 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
jbe@0 1831 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
jbe@0 1832
jbe@0 1833
jbe@0 1834
jbe@4 1835 -----------------------------------------------------
jbe@4 1836 -- Automatic calculation of certain default values --
jbe@4 1837 -----------------------------------------------------
jbe@0 1838
jbe@22 1839
jbe@22 1840 CREATE FUNCTION "copy_timings_trigger"()
jbe@22 1841 RETURNS TRIGGER
jbe@22 1842 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@22 1843 DECLARE
jbe@22 1844 "policy_row" "policy"%ROWTYPE;
jbe@22 1845 BEGIN
jbe@22 1846 SELECT * INTO "policy_row" FROM "policy"
jbe@22 1847 WHERE "id" = NEW."policy_id";
jbe@447 1848 IF NEW."min_admission_time" ISNULL THEN
jbe@447 1849 NEW."min_admission_time" := "policy_row"."min_admission_time";
jbe@447 1850 END IF;
jbe@447 1851 IF NEW."max_admission_time" ISNULL THEN
jbe@447 1852 NEW."max_admission_time" := "policy_row"."max_admission_time";
jbe@22 1853 END IF;
jbe@22 1854 IF NEW."discussion_time" ISNULL THEN
jbe@22 1855 NEW."discussion_time" := "policy_row"."discussion_time";
jbe@22 1856 END IF;
jbe@22 1857 IF NEW."verification_time" ISNULL THEN
jbe@22 1858 NEW."verification_time" := "policy_row"."verification_time";
jbe@22 1859 END IF;
jbe@22 1860 IF NEW."voting_time" ISNULL THEN
jbe@22 1861 NEW."voting_time" := "policy_row"."voting_time";
jbe@22 1862 END IF;
jbe@22 1863 RETURN NEW;
jbe@22 1864 END;
jbe@22 1865 $$;
jbe@22 1866
jbe@22 1867 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
jbe@22 1868 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
jbe@22 1869
jbe@22 1870 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
jbe@22 1871 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
jbe@22 1872
jbe@22 1873
jbe@160 1874 CREATE FUNCTION "default_for_draft_id_trigger"()
jbe@2 1875 RETURNS TRIGGER
jbe@2 1876 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@2 1877 BEGIN
jbe@2 1878 IF NEW."draft_id" ISNULL THEN
jbe@2 1879 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@2 1880 WHERE "initiative_id" = NEW."initiative_id";
jbe@2 1881 END IF;
jbe@2 1882 RETURN NEW;
jbe@2 1883 END;
jbe@2 1884 $$;
jbe@2 1885
jbe@160 1886 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
jbe@160 1887 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@2 1888 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@160 1889 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@160 1890
jbe@160 1891 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
jbe@160 1892 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 1893 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 1894
jbe@2 1895
jbe@0 1896
jbe@0 1897 ----------------------------------------
jbe@0 1898 -- Automatic creation of dependencies --
jbe@0 1899 ----------------------------------------
jbe@0 1900
jbe@22 1901
jbe@0 1902 CREATE FUNCTION "autocreate_interest_trigger"()
jbe@0 1903 RETURNS TRIGGER
jbe@0 1904 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1905 BEGIN
jbe@0 1906 IF NOT EXISTS (
jbe@0 1907 SELECT NULL FROM "initiative" JOIN "interest"
jbe@0 1908 ON "initiative"."issue_id" = "interest"."issue_id"
jbe@0 1909 WHERE "initiative"."id" = NEW."initiative_id"
jbe@0 1910 AND "interest"."member_id" = NEW."member_id"
jbe@0 1911 ) THEN
jbe@0 1912 BEGIN
jbe@0 1913 INSERT INTO "interest" ("issue_id", "member_id")
jbe@0 1914 SELECT "issue_id", NEW."member_id"
jbe@0 1915 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1916 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1917 END IF;
jbe@0 1918 RETURN NEW;
jbe@0 1919 END;
jbe@0 1920 $$;
jbe@0 1921
jbe@0 1922 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
jbe@0 1923 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
jbe@0 1924
jbe@0 1925 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
jbe@0 1926 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 1927
jbe@0 1928
jbe@0 1929 CREATE FUNCTION "autocreate_supporter_trigger"()
jbe@0 1930 RETURNS TRIGGER
jbe@0 1931 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1932 BEGIN
jbe@0 1933 IF NOT EXISTS (
jbe@0 1934 SELECT NULL FROM "suggestion" JOIN "supporter"
jbe@0 1935 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@0 1936 WHERE "suggestion"."id" = NEW."suggestion_id"
jbe@0 1937 AND "supporter"."member_id" = NEW."member_id"
jbe@0 1938 ) THEN
jbe@0 1939 BEGIN
jbe@0 1940 INSERT INTO "supporter" ("initiative_id", "member_id")
jbe@0 1941 SELECT "initiative_id", NEW."member_id"
jbe@0 1942 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1943 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1944 END IF;
jbe@0 1945 RETURN NEW;
jbe@0 1946 END;
jbe@0 1947 $$;
jbe@0 1948
jbe@0 1949 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
jbe@0 1950 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
jbe@0 1951
jbe@0 1952 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
jbe@0 1953 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 1954
jbe@0 1955
jbe@0 1956
jbe@0 1957 ------------------------------------------
jbe@0 1958 -- Views and helper functions for views --
jbe@0 1959 ------------------------------------------
jbe@0 1960
jbe@5 1961
jbe@524 1962 CREATE VIEW "member_eligible_to_be_notified" AS
jbe@524 1963 SELECT * FROM "member"
jbe@524 1964 WHERE "activated" NOTNULL AND "locked" = FALSE;
jbe@524 1965
jbe@524 1966 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 1967
jbe@524 1968
jbe@524 1969 CREATE VIEW "member_to_notify" AS
jbe@524 1970 SELECT * FROM "member_eligible_to_be_notified"
jbe@524 1971 WHERE "disable_notifications" = FALSE;
jbe@524 1972
jbe@524 1973 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 1974
jbe@524 1975
jbe@97 1976 CREATE VIEW "unit_delegation" AS
jbe@97 1977 SELECT
jbe@97 1978 "unit"."id" AS "unit_id",
jbe@97 1979 "delegation"."id",
jbe@97 1980 "delegation"."truster_id",
jbe@97 1981 "delegation"."trustee_id",
jbe@97 1982 "delegation"."scope"
jbe@97 1983 FROM "unit"
jbe@97 1984 JOIN "delegation"
jbe@97 1985 ON "delegation"."unit_id" = "unit"."id"
jbe@97 1986 JOIN "member"
jbe@97 1987 ON "delegation"."truster_id" = "member"."id"
jbe@97 1988 JOIN "privilege"
jbe@97 1989 ON "delegation"."unit_id" = "privilege"."unit_id"
jbe@97 1990 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1991 WHERE "member"."active" AND "privilege"."voting_right";
jbe@97 1992
jbe@97 1993 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
jbe@5 1994
jbe@5 1995
jbe@5 1996 CREATE VIEW "area_delegation" AS
jbe@70 1997 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@70 1998 "area"."id" AS "area_id",
jbe@70 1999 "delegation"."id",
jbe@70 2000 "delegation"."truster_id",
jbe@70 2001 "delegation"."trustee_id",
jbe@70 2002 "delegation"."scope"
jbe@97 2003 FROM "area"
jbe@97 2004 JOIN "delegation"
jbe@97 2005 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 2006 OR "delegation"."area_id" = "area"."id"
jbe@97 2007 JOIN "member"
jbe@97 2008 ON "delegation"."truster_id" = "member"."id"
jbe@97 2009 JOIN "privilege"
jbe@97 2010 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 2011 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2012 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 2013 ORDER BY
jbe@70 2014 "area"."id",
jbe@70 2015 "delegation"."truster_id",
jbe@70 2016 "delegation"."scope" DESC;
jbe@70 2017
jbe@97 2018 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
jbe@5 2019
jbe@5 2020
jbe@5 2021 CREATE VIEW "issue_delegation" AS
jbe@70 2022 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@70 2023 "issue"."id" AS "issue_id",
jbe@70 2024 "delegation"."id",
jbe@70 2025 "delegation"."truster_id",
jbe@70 2026 "delegation"."trustee_id",
jbe@70 2027 "delegation"."scope"
jbe@97 2028 FROM "issue"
jbe@97 2029 JOIN "area"
jbe@97 2030 ON "area"."id" = "issue"."area_id"
jbe@97 2031 JOIN "delegation"
jbe@97 2032 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 2033 OR "delegation"."area_id" = "area"."id"
jbe@97 2034 OR "delegation"."issue_id" = "issue"."id"
jbe@97 2035 JOIN "member"
jbe@97 2036 ON "delegation"."truster_id" = "member"."id"
jbe@97 2037 JOIN "privilege"
jbe@97 2038 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 2039 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2040 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 2041 ORDER BY
jbe@70 2042 "issue"."id",
jbe@70 2043 "delegation"."truster_id",
jbe@70 2044 "delegation"."scope" DESC;
jbe@70 2045
jbe@97 2046 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
jbe@5 2047
jbe@5 2048
jbe@5 2049 CREATE FUNCTION "membership_weight_with_skipping"
jbe@5 2050 ( "area_id_p" "area"."id"%TYPE,
jbe@5 2051 "member_id_p" "member"."id"%TYPE,
jbe@5 2052 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
jbe@5 2053 RETURNS INT4
jbe@5 2054 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2055 DECLARE
jbe@5 2056 "sum_v" INT4;
jbe@5 2057 "delegation_row" "area_delegation"%ROWTYPE;
jbe@5 2058 BEGIN
jbe@5 2059 "sum_v" := 1;
jbe@5 2060 FOR "delegation_row" IN
jbe@5 2061 SELECT "area_delegation".*
jbe@5 2062 FROM "area_delegation" LEFT JOIN "membership"
jbe@5 2063 ON "membership"."area_id" = "area_id_p"
jbe@5 2064 AND "membership"."member_id" = "area_delegation"."truster_id"
jbe@5 2065 WHERE "area_delegation"."area_id" = "area_id_p"
jbe@5 2066 AND "area_delegation"."trustee_id" = "member_id_p"
jbe@5 2067 AND "membership"."member_id" ISNULL
jbe@5 2068 LOOP
jbe@5 2069 IF NOT
jbe@5 2070 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
jbe@5 2071 THEN
jbe@5 2072 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
jbe@5 2073 "area_id_p",
jbe@5 2074 "delegation_row"."truster_id",
jbe@5 2075 "skip_member_ids_p" || "delegation_row"."truster_id"
jbe@5 2076 );
jbe@5 2077 END IF;
jbe@5 2078 END LOOP;
jbe@5 2079 RETURN "sum_v";
jbe@5 2080 END;
jbe@5 2081 $$;
jbe@5 2082
jbe@8 2083 COMMENT ON FUNCTION "membership_weight_with_skipping"
jbe@8 2084 ( "area"."id"%TYPE,
jbe@8 2085 "member"."id"%TYPE,
jbe@8 2086 INT4[] )
jbe@8 2087 IS 'Helper function for "membership_weight" function';
jbe@8 2088
jbe@8 2089
jbe@5 2090 CREATE FUNCTION "membership_weight"
jbe@5 2091 ( "area_id_p" "area"."id"%TYPE,
jbe@5 2092 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
jbe@5 2093 RETURNS INT4
jbe@5 2094 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2095 BEGIN
jbe@5 2096 RETURN "membership_weight_with_skipping"(
jbe@5 2097 "area_id_p",
jbe@5 2098 "member_id_p",
jbe@5 2099 ARRAY["member_id_p"]
jbe@5 2100 );
jbe@5 2101 END;
jbe@5 2102 $$;
jbe@5 2103
jbe@8 2104 COMMENT ON FUNCTION "membership_weight"
jbe@8 2105 ( "area"."id"%TYPE,
jbe@8 2106 "member"."id"%TYPE )
jbe@8 2107 IS 'Calculates the potential voting weight of a member in a given area';
jbe@8 2108
jbe@5 2109
jbe@4 2110 CREATE VIEW "member_count_view" AS
jbe@5 2111 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 2112
jbe@4 2113 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 2114
jbe@4 2115
jbe@97 2116 CREATE VIEW "unit_member_count" AS
jbe@97 2117 SELECT
jbe@97 2118 "unit"."id" AS "unit_id",
jbe@248 2119 count("member"."id") AS "member_count"
jbe@97 2120 FROM "unit"
jbe@97 2121 LEFT JOIN "privilege"
jbe@97 2122 ON "privilege"."unit_id" = "unit"."id"
jbe@97 2123 AND "privilege"."voting_right"
jbe@97 2124 LEFT JOIN "member"
jbe@97 2125 ON "member"."id" = "privilege"."member_id"
jbe@97 2126 AND "member"."active"
jbe@97 2127 GROUP BY "unit"."id";
jbe@97 2128
jbe@97 2129 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@97 2130
jbe@97 2131
jbe@4 2132 CREATE VIEW "area_member_count" AS
jbe@5 2133 SELECT
jbe@5 2134 "area"."id" AS "area_id",
jbe@5 2135 count("member"."id") AS "direct_member_count",
jbe@5 2136 coalesce(
jbe@5 2137 sum(
jbe@5 2138 CASE WHEN "member"."id" NOTNULL THEN
jbe@5 2139 "membership_weight"("area"."id", "member"."id")
jbe@5 2140 ELSE 0 END
jbe@5 2141 )
jbe@169 2142 ) AS "member_weight"
jbe@4 2143 FROM "area"
jbe@4 2144 LEFT JOIN "membership"
jbe@4 2145 ON "area"."id" = "membership"."area_id"
jbe@97 2146 LEFT JOIN "privilege"
jbe@97 2147 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2148 AND "privilege"."member_id" = "membership"."member_id"
jbe@97 2149 AND "privilege"."voting_right"
jbe@4 2150 LEFT JOIN "member"
jbe@97 2151 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
jbe@4 2152 AND "member"."active"
jbe@4 2153 GROUP BY "area"."id";
jbe@4 2154
jbe@169 2155 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
jbe@4 2156
jbe@4 2157
jbe@9 2158 CREATE VIEW "opening_draft" AS
jbe@9 2159 SELECT "draft".* FROM (
jbe@9 2160 SELECT
jbe@9 2161 "initiative"."id" AS "initiative_id",
jbe@9 2162 min("draft"."id") AS "draft_id"
jbe@9 2163 FROM "initiative" JOIN "draft"
jbe@9 2164 ON "initiative"."id" = "draft"."initiative_id"
jbe@9 2165 GROUP BY "initiative"."id"
jbe@9 2166 ) AS "subquery"
jbe@9 2167 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@9 2168
jbe@9 2169 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 2170
jbe@9 2171
jbe@0 2172 CREATE VIEW "current_draft" AS
jbe@0 2173 SELECT "draft".* FROM (
jbe@0 2174 SELECT
jbe@0 2175 "initiative"."id" AS "initiative_id",
jbe@0 2176 max("draft"."id") AS "draft_id"
jbe@0 2177 FROM "initiative" JOIN "draft"
jbe@0 2178 ON "initiative"."id" = "draft"."initiative_id"
jbe@0 2179 GROUP BY "initiative"."id"
jbe@0 2180 ) AS "subquery"
jbe@0 2181 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@0 2182
jbe@0 2183 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 2184
jbe@0 2185
jbe@0 2186 CREATE VIEW "critical_opinion" AS
jbe@0 2187 SELECT * FROM "opinion"
jbe@0 2188 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 2189 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 2190
jbe@0 2191 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 2192
jbe@0 2193
jbe@392 2194 CREATE VIEW "issue_supporter_in_admission_state" AS
jbe@466 2195 SELECT DISTINCT -- TODO: DISTINCT needed?
jbe@410 2196 "area"."unit_id",
jbe@392 2197 "issue"."area_id",
jbe@392 2198 "issue"."id" AS "issue_id",
jbe@392 2199 "supporter"."member_id",
jbe@392 2200 "direct_interest_snapshot"."weight"
jbe@392 2201 FROM "issue"
jbe@410 2202 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@392 2203 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
jbe@392 2204 JOIN "direct_interest_snapshot"
jbe@392 2205 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@392 2206 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
jbe@392 2207 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
jbe@392 2208 WHERE "issue"."state" = 'admission'::"issue_state";
jbe@392 2209
jbe@392 2210 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 2211
jbe@392 2212
jbe@352 2213 CREATE VIEW "initiative_suggestion_order_calculation" AS
jbe@352 2214 SELECT
jbe@352 2215 "initiative"."id" AS "initiative_id",
jbe@352 2216 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
jbe@352 2217 FROM "initiative" JOIN "issue"
jbe@352 2218 ON "initiative"."issue_id" = "issue"."id"
jbe@352 2219 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
jbe@352 2220 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
jbe@352 2221
jbe@352 2222 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
jbe@352 2223
jbe@360 2224 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 2225
jbe@352 2226
jbe@352 2227 CREATE VIEW "individual_suggestion_ranking" AS
jbe@352 2228 SELECT
jbe@352 2229 "opinion"."initiative_id",
jbe@352 2230 "opinion"."member_id",
jbe@352 2231 "direct_interest_snapshot"."weight",
jbe@352 2232 CASE WHEN
jbe@352 2233 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 2234 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
jbe@352 2235 THEN 1 ELSE
jbe@352 2236 CASE WHEN
jbe@352 2237 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 2238 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
jbe@352 2239 THEN 2 ELSE
jbe@352 2240 CASE WHEN
jbe@352 2241 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
jbe@352 2242 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
jbe@352 2243 THEN 3 ELSE 4 END
jbe@352 2244 END
jbe@352 2245 END AS "preference",
jbe@352 2246 "opinion"."suggestion_id"
jbe@352 2247 FROM "opinion"
jbe@352 2248 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
jbe@352 2249 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@352 2250 JOIN "direct_interest_snapshot"
jbe@352 2251 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@352 2252 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
jbe@352 2253 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
jbe@352 2254
jbe@352 2255 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 2256
jbe@352 2257
jbe@126 2258 CREATE VIEW "battle_participant" AS
jbe@126 2259 SELECT "initiative"."id", "initiative"."issue_id"
jbe@126 2260 FROM "issue" JOIN "initiative"
jbe@126 2261 ON "issue"."id" = "initiative"."issue_id"
jbe@126 2262 WHERE "initiative"."admitted"
jbe@126 2263 UNION ALL
jbe@126 2264 SELECT NULL, "id" AS "issue_id"
jbe@126 2265 FROM "issue";
jbe@126 2266
jbe@126 2267 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 2268
jbe@126 2269
jbe@61 2270 CREATE VIEW "battle_view" AS
jbe@0 2271 SELECT
jbe@0 2272 "issue"."id" AS "issue_id",
jbe@10 2273 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 2274 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 2275 sum(
jbe@0 2276 CASE WHEN
jbe@0 2277 coalesce("better_vote"."grade", 0) >
jbe@0 2278 coalesce("worse_vote"."grade", 0)
jbe@0 2279 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 2280 ) AS "count"
jbe@0 2281 FROM "issue"
jbe@0 2282 LEFT JOIN "direct_voter"
jbe@0 2283 ON "issue"."id" = "direct_voter"."issue_id"
jbe@126 2284 JOIN "battle_participant" AS "winning_initiative"
jbe@10 2285 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@126 2286 JOIN "battle_participant" AS "losing_initiative"
jbe@10 2287 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@0 2288 LEFT JOIN "vote" AS "better_vote"
jbe@10 2289 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 2290 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 2291 LEFT JOIN "vote" AS "worse_vote"
jbe@10 2292 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 2293 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@328 2294 WHERE "issue"."state" = 'voting'
jbe@328 2295 AND "issue"."phase_finished" NOTNULL
jbe@126 2296 AND (
jbe@126 2297 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@126 2298 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@126 2299 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@0 2300 GROUP BY
jbe@0 2301 "issue"."id",
jbe@10 2302 "winning_initiative"."id",
jbe@10 2303 "losing_initiative"."id";
jbe@0 2304
jbe@126 2305 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 2306
jbe@1 2307
jbe@235 2308 CREATE VIEW "expired_session" AS
jbe@235 2309 SELECT * FROM "session" WHERE now() > "expiry";
jbe@235 2310
jbe@235 2311 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@235 2312 DELETE FROM "session" WHERE "ident" = OLD."ident";
jbe@235 2313
jbe@235 2314 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@235 2315 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 2316
jbe@235 2317
jbe@0 2318 CREATE VIEW "open_issue" AS
jbe@0 2319 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 2320
jbe@0 2321 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 2322
jbe@0 2323
jbe@9 2324 CREATE VIEW "member_contingent" AS
jbe@9 2325 SELECT
jbe@9 2326 "member"."id" AS "member_id",
jbe@293 2327 "contingent"."polling",
jbe@9 2328 "contingent"."time_frame",
jbe@9 2329 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 2330 (
jbe@9 2331 SELECT count(1) FROM "draft"
jbe@293 2332 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@9 2333 WHERE "draft"."author_id" = "member"."id"
jbe@293 2334 AND "initiative"."polling" = "contingent"."polling"
jbe@9 2335 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 2336 ) + (
jbe@9 2337 SELECT count(1) FROM "suggestion"
jbe@293 2338 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
jbe@9 2339 WHERE "suggestion"."author_id" = "member"."id"
jbe@293 2340 AND "contingent"."polling" = FALSE
jbe@9 2341 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 2342 )
jbe@9 2343 ELSE NULL END AS "text_entry_count",
jbe@9 2344 "contingent"."text_entry_limit",
jbe@9 2345 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@293 2346 SELECT count(1) FROM "opening_draft" AS "draft"
jbe@293 2347 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@293 2348 WHERE "draft"."author_id" = "member"."id"
jbe@293 2349 AND "initiative"."polling" = "contingent"."polling"
jbe@293 2350 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 2351 ) ELSE NULL END AS "initiative_count",
jbe@9 2352 "contingent"."initiative_limit"
jbe@9 2353 FROM "member" CROSS JOIN "contingent";
jbe@9 2354
jbe@9 2355 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 2356
jbe@9 2357 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 2358 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 2359
jbe@9 2360
jbe@9 2361 CREATE VIEW "member_contingent_left" AS
jbe@9 2362 SELECT
jbe@9 2363 "member_id",
jbe@293 2364 "polling",
jbe@9 2365 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 2366 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@293 2367 FROM "member_contingent" GROUP BY "member_id", "polling";
jbe@9 2368
jbe@9 2369 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 2370
jbe@9 2371
jbe@499 2372 CREATE VIEW "event_for_notification" AS
jbe@113 2373 SELECT
jbe@499 2374 "member"."id" AS "recipient_id",
jbe@113 2375 "event".*
jbe@113 2376 FROM "member" CROSS JOIN "event"
jbe@499 2377 JOIN "issue" ON "issue"."id" = "event"."issue_id"
jbe@499 2378 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@499 2379 LEFT JOIN "privilege" ON
jbe@499 2380 "privilege"."member_id" = "member"."id" AND
jbe@499 2381 "privilege"."unit_id" = "area"."unit_id" AND
jbe@499 2382 "privilege"."voting_right" = TRUE
jbe@499 2383 LEFT JOIN "subscription" ON
jbe@499 2384 "subscription"."member_id" = "member"."id" AND
jbe@499 2385 "subscription"."unit_id" = "area"."unit_id"
jbe@499 2386 LEFT JOIN "ignored_area" ON
jbe@499 2387 "ignored_area"."member_id" = "member"."id" AND
jbe@499 2388 "ignored_area"."area_id" = "issue"."area_id"
jbe@499 2389 LEFT JOIN "interest" ON
jbe@499 2390 "interest"."member_id" = "member"."id" AND
jbe@499 2391 "interest"."issue_id" = "event"."issue_id"
jbe@499 2392 LEFT JOIN "supporter" ON
jbe@499 2393 "supporter"."member_id" = "member"."id" AND
jbe@499 2394 "supporter"."initiative_id" = "event"."initiative_id"
jbe@499 2395 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
jbe@499 2396 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
jbe@499 2397 AND (
jbe@499 2398 "event"."event" = 'issue_state_changed'::"event_type" OR
jbe@499 2399 ( "event"."event" = 'initiative_revoked'::"event_type" AND
jbe@499 2400 "supporter"."member_id" NOTNULL ) );
jbe@499 2401
jbe@508 2402 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
jbe@508 2403
jbe@508 2404 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
jbe@222 2405
jbe@222 2406
jbe@473 2407 CREATE VIEW "updated_initiative" AS
jbe@473 2408 SELECT
jbe@499 2409 "supporter"."member_id" AS "recipient_id",
jbe@477 2410 FALSE AS "featured",
jbe@499 2411 "supporter"."initiative_id"
jbe@499 2412 FROM "supporter"
jbe@499 2413 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
jbe@473 2414 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@507 2415 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 2416 "sent"."member_id" = "supporter"."member_id" AND
jbe@499 2417 "sent"."initiative_id" = "supporter"."initiative_id"
jbe@499 2418 LEFT JOIN "ignored_initiative" ON
jbe@499 2419 "ignored_initiative"."member_id" = "supporter"."member_id" AND
jbe@499 2420 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
jbe@480 2421 WHERE "issue"."state" IN ('admission', 'discussion')
jbe@503 2422 AND "initiative"."revoked" ISNULL
jbe@499 2423 AND "ignored_initiative"."member_id" ISNULL
jbe@473 2424 AND (
jbe@473 2425 EXISTS (
jbe@473 2426 SELECT NULL FROM "draft"
jbe@499 2427 LEFT JOIN "ignored_member" ON
jbe@499 2428 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 2429 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 2430 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
jbe@473 2431 AND "draft"."id" > "supporter"."draft_id"
jbe@499 2432 AND "ignored_member"."member_id" ISNULL
jbe@473 2433 ) OR EXISTS (
jbe@473 2434 SELECT NULL FROM "suggestion"
jbe@487 2435 LEFT JOIN "opinion" ON
jbe@487 2436 "opinion"."member_id" = "supporter"."member_id" AND
jbe@487 2437 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 2438 LEFT JOIN "ignored_member" ON
jbe@499 2439 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 2440 "ignored_member"."other_member_id" = "suggestion"."author_id"
jbe@499 2441 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@487 2442 AND "opinion"."member_id" ISNULL
jbe@499 2443 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 2444 AND "ignored_member"."member_id" ISNULL
jbe@473 2445 )
jbe@473 2446 );
jbe@473 2447
jbe@508 2448 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
jbe@508 2449
jbe@508 2450
jbe@474 2451 CREATE FUNCTION "featured_initiative"
jbe@499 2452 ( "recipient_id_p" "member"."id"%TYPE,
jbe@499 2453 "area_id_p" "area"."id"%TYPE )
jbe@499 2454 RETURNS SETOF "initiative"."id"%TYPE
jbe@474 2455 LANGUAGE 'plpgsql' STABLE AS $$
jbe@474 2456 DECLARE
jbe@499 2457 "counter_v" "member"."notification_counter"%TYPE;
jbe@499 2458 "sample_size_v" "member"."notification_sample_size"%TYPE;
jbe@499 2459 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
jbe@499 2460 "match_v" BOOLEAN;
jbe@474 2461 "member_id_v" "member"."id"%TYPE;
jbe@474 2462 "seed_v" TEXT;
jbe@499 2463 "initiative_id_v" "initiative"."id"%TYPE;
jbe@474 2464 BEGIN
jbe@499 2465 SELECT "notification_counter", "notification_sample_size"
jbe@499 2466 INTO "counter_v", "sample_size_v"
jbe@499 2467 FROM "member" WHERE "id" = "recipient_id_p";
jbe@520 2468 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
jbe@520 2469 RETURN;
jbe@520 2470 END IF;
jbe@474 2471 "initiative_id_ary" := '{}';
jbe@474 2472 LOOP
jbe@474 2473 "match_v" := FALSE;
jbe@474 2474 FOR "member_id_v", "seed_v" IN
jbe@474 2475 SELECT * FROM (
jbe@474 2476 SELECT DISTINCT
jbe@474 2477 "supporter"."member_id",
jbe@499 2478 md5(
jbe@499 2479 "recipient_id_p" || '-' ||
jbe@499 2480 "counter_v" || '-' ||
jbe@499 2481 "area_id_p" || '-' ||
jbe@499 2482 "supporter"."member_id"
jbe@499 2483 ) AS "seed"
jbe@474 2484 FROM "supporter"
jbe@474 2485 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
jbe@474 2486 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 2487 WHERE "supporter"."member_id" != "recipient_id_p"
jbe@474 2488 AND "issue"."area_id" = "area_id_p"
jbe@474 2489 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@474 2490 ) AS "subquery"
jbe@474 2491 ORDER BY "seed"
jbe@474 2492 LOOP
jbe@499 2493 SELECT "initiative"."id" INTO "initiative_id_v"
jbe@476 2494 FROM "initiative"
jbe@474 2495 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 2496 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@474 2497 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
jbe@474 2498 LEFT JOIN "supporter" AS "self_support" ON
jbe@474 2499 "self_support"."initiative_id" = "initiative"."id" AND
jbe@499 2500 "self_support"."member_id" = "recipient_id_p"
jbe@499 2501 LEFT JOIN "privilege" ON
jbe@499 2502 "privilege"."member_id" = "recipient_id_p" AND
jbe@499 2503 "privilege"."unit_id" = "area"."unit_id" AND
jbe@499 2504 "privilege"."voting_right" = TRUE
jbe@499 2505 LEFT JOIN "subscription" ON
jbe@499 2506 "subscription"."member_id" = "recipient_id_p" AND
jbe@499 2507 "subscription"."unit_id" = "area"."unit_id"
jbe@499 2508 LEFT JOIN "ignored_initiative" ON
jbe@499 2509 "ignored_initiative"."member_id" = "recipient_id_p" AND
jbe@499 2510 "ignored_initiative"."initiative_id" = "initiative"."id"
jbe@474 2511 WHERE "supporter"."member_id" = "member_id_v"
jbe@474 2512 AND "issue"."area_id" = "area_id_p"
jbe@474 2513 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@503 2514 AND "initiative"."revoked" ISNULL
jbe@474 2515 AND "self_support"."member_id" ISNULL
jbe@476 2516 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
jbe@499 2517 AND (
jbe@499 2518 "privilege"."member_id" NOTNULL OR
jbe@499 2519 "subscription"."member_id" NOTNULL )
jbe@499 2520 AND "ignored_initiative"."member_id" ISNULL
jbe@499 2521 AND NOT EXISTS (
jbe@499 2522 SELECT NULL FROM "draft"
jbe@499 2523 JOIN "ignored_member" ON
jbe@499 2524 "ignored_member"."member_id" = "recipient_id_p" AND
jbe@499 2525 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 2526 WHERE "draft"."initiative_id" = "initiative"."id"
jbe@499 2527 )
jbe@474 2528 ORDER BY md5("seed_v" || '-' || "initiative"."id")
jbe@476 2529 LIMIT 1;
jbe@476 2530 IF FOUND THEN
jbe@476 2531 "match_v" := TRUE;
jbe@499 2532 RETURN NEXT "initiative_id_v";
jbe@499 2533 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
jbe@476 2534 RETURN;
jbe@474 2535 END IF;
jbe@499 2536 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
jbe@476 2537 END IF;
jbe@474 2538 END LOOP;
jbe@474 2539 EXIT WHEN NOT "match_v";
jbe@474 2540 END LOOP;
jbe@474 2541 RETURN;
jbe@474 2542 END;
jbe@474 2543 $$;
jbe@474 2544
jbe@508 2545 COMMENT ON FUNCTION "featured_initiative"
jbe@508 2546 ( "recipient_id_p" "member"."id"%TYPE,
jbe@508 2547 "area_id_p" "area"."id"%TYPE )
jbe@508 2548 IS 'Helper function for view "updated_or_featured_initiative"';
jbe@508 2549
jbe@508 2550
jbe@474 2551 CREATE VIEW "updated_or_featured_initiative" AS
jbe@474 2552 SELECT
jbe@499 2553 "subquery".*,
jbe@477 2554 NOT EXISTS (
jbe@477 2555 SELECT NULL FROM "initiative" AS "better_initiative"
jbe@499 2556 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
jbe@484 2557 AND
jbe@502 2558 ( COALESCE("better_initiative"."supporter_count", -1),
jbe@484 2559 -"better_initiative"."id" ) >
jbe@502 2560 ( COALESCE("initiative"."supporter_count", -1),
jbe@485 2561 -"initiative"."id" )
jbe@499 2562 ) AS "leading"
jbe@499 2563 FROM (
jbe@499 2564 SELECT * FROM "updated_initiative"
jbe@499 2565 UNION ALL
jbe@499 2566 SELECT
jbe@499 2567 "member"."id" AS "recipient_id",
jbe@499 2568 TRUE AS "featured",
jbe@499 2569 "featured_initiative_id" AS "initiative_id"
jbe@499 2570 FROM "member" CROSS JOIN "area"
jbe@499 2571 CROSS JOIN LATERAL
jbe@499 2572 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
jbe@499 2573 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
jbe@499 2574 ) AS "subquery"
jbe@499 2575 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
jbe@474 2576
jbe@508 2577 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 2578
jbe@508 2579 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 2580 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 2581 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 2582 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 2583
jbe@508 2584
jbe@474 2585 CREATE VIEW "leading_complement_initiative" AS
jbe@477 2586 SELECT * FROM (
jbe@499 2587 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
jbe@499 2588 "uf_initiative"."recipient_id",
jbe@477 2589 FALSE AS "featured",
jbe@499 2590 "uf_initiative"."initiative_id",
jbe@499 2591 TRUE AS "leading"
jbe@489 2592 FROM "updated_or_featured_initiative" AS "uf_initiative"
jbe@499 2593 JOIN "initiative" AS "uf_initiative_full" ON
jbe@499 2594 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
jbe@489 2595 JOIN "initiative" ON
jbe@499 2596 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
jbe@503 2597 WHERE "initiative"."revoked" ISNULL
jbe@477 2598 ORDER BY
jbe@499 2599 "uf_initiative"."recipient_id",
jbe@477 2600 "initiative"."issue_id",
jbe@502 2601 "initiative"."supporter_count" DESC,
jbe@477 2602 "initiative"."id"
jbe@477 2603 ) AS "subquery"
jbe@477 2604 WHERE NOT EXISTS (
jbe@477 2605 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
jbe@499 2606 WHERE "other"."recipient_id" = "subquery"."recipient_id"
jbe@499 2607 AND "other"."initiative_id" = "subquery"."initiative_id"
jbe@477 2608 );
jbe@474 2609
jbe@508 2610 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 2611 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
jbe@508 2612 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 2613 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
jbe@508 2614
jbe@508 2615
jbe@490 2616 CREATE VIEW "unfiltered_initiative_for_notification" AS
jbe@499 2617 SELECT
jbe@499 2618 "subquery".*,
jbe@499 2619 "supporter"."member_id" NOTNULL AS "supported",
jbe@499 2620 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 2621 EXISTS (
jbe@499 2622 SELECT NULL FROM "draft"
jbe@499 2623 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 2624 AND "draft"."id" > "supporter"."draft_id"
jbe@499 2625 )
jbe@499 2626 ELSE
jbe@499 2627 EXISTS (
jbe@499 2628 SELECT NULL FROM "draft"
jbe@499 2629 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 2630 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
jbe@499 2631 )
jbe@499 2632 END AS "new_draft",
jbe@499 2633 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 2634 ( SELECT count(1) FROM "suggestion"
jbe@499 2635 LEFT JOIN "opinion" ON
jbe@499 2636 "opinion"."member_id" = "supporter"."member_id" AND
jbe@499 2637 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 2638 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 2639 AND "opinion"."member_id" ISNULL
jbe@499 2640 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 2641 )
jbe@499 2642 ELSE
jbe@499 2643 ( SELECT count(1) FROM "suggestion"
jbe@499 2644 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 2645 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 2646 )
jbe@499 2647 END AS "new_suggestion_count"
jbe@499 2648 FROM (
jbe@499 2649 SELECT * FROM "updated_or_featured_initiative"
jbe@499 2650 UNION ALL
jbe@499 2651 SELECT * FROM "leading_complement_initiative"
jbe@499 2652 ) AS "subquery"
jbe@499 2653 LEFT JOIN "supporter" ON
jbe@499 2654 "supporter"."member_id" = "subquery"."recipient_id" AND
jbe@499 2655 "supporter"."initiative_id" = "subquery"."initiative_id"
jbe@507 2656 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 2657 "sent"."member_id" = "subquery"."recipient_id" AND
jbe@499 2658 "sent"."initiative_id" = "subquery"."initiative_id";
jbe@474 2659
jbe@508 2660 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 2661
jbe@508 2662 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 2663 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 2664 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 2665
jbe@508 2666
jbe@490 2667 CREATE VIEW "initiative_for_notification" AS
jbe@499 2668 SELECT "unfiltered1".*
jbe@499 2669 FROM "unfiltered_initiative_for_notification" "unfiltered1"
jbe@499 2670 JOIN "initiative" AS "initiative1" ON
jbe@499 2671 "initiative1"."id" = "unfiltered1"."initiative_id"
jbe@499 2672 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
jbe@490 2673 WHERE EXISTS (
jbe@490 2674 SELECT NULL
jbe@499 2675 FROM "unfiltered_initiative_for_notification" "unfiltered2"
jbe@499 2676 JOIN "initiative" AS "initiative2" ON
jbe@499 2677 "initiative2"."id" = "unfiltered2"."initiative_id"
jbe@499 2678 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
jbe@499 2679 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
jbe@490 2680 AND "issue1"."area_id" = "issue2"."area_id"
jbe@499 2681 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
jbe@490 2682 );
jbe@490 2683
jbe@508 2684 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
jbe@508 2685
jbe@508 2686 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 2687 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 2688 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 2689 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 2690 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 2691 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 2692 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 2693
jbe@508 2694
jbe@504 2695 CREATE VIEW "scheduled_notification_to_send" AS
jbe@505 2696 SELECT * FROM (
jbe@505 2697 SELECT
jbe@505 2698 "id" AS "recipient_id",
jbe@505 2699 now() - CASE WHEN "notification_dow" ISNULL THEN
jbe@505 2700 ( "notification_sent"::DATE + CASE
jbe@505 2701 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 2702 THEN 0 ELSE 1 END
jbe@505 2703 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 2704 ELSE
jbe@505 2705 ( "notification_sent"::DATE +
jbe@505 2706 ( 7 + "notification_dow" -
jbe@505 2707 EXTRACT(DOW FROM
jbe@505 2708 ( "notification_sent"::DATE + CASE
jbe@505 2709 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 2710 THEN 0 ELSE 1 END
jbe@505 2711 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 2712 )::INTEGER
jbe@505 2713 ) % 7 +
jbe@505 2714 CASE
jbe@505 2715 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 2716 THEN 0 ELSE 1
jbe@505 2717 END
jbe@505 2718 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 2719 END AS "pending"
jbe@505 2720 FROM (
jbe@505 2721 SELECT
jbe@505 2722 "id",
jbe@505 2723 COALESCE("notification_sent", "activated") AS "notification_sent",
jbe@505 2724 "notification_dow",
jbe@505 2725 "notification_hour"
jbe@524 2726 FROM "member_to_notify"
jbe@524 2727 WHERE "notification_hour" NOTNULL
jbe@505 2728 ) AS "subquery1"
jbe@505 2729 ) AS "subquery2"
jbe@505 2730 WHERE "pending" > '0'::INTERVAL;
jbe@504 2731
jbe@508 2732 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
jbe@508 2733
jbe@508 2734 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
jbe@508 2735 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
jbe@508 2736
jbe@508 2737
jbe@497 2738 CREATE VIEW "newsletter_to_send" AS
jbe@497 2739 SELECT
jbe@499 2740 "member"."id" AS "recipient_id",
jbe@514 2741 "newsletter"."id" AS "newsletter_id",
jbe@514 2742 "newsletter"."published"
jbe@524 2743 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
jbe@497 2744 LEFT JOIN "privilege" ON
jbe@497 2745 "privilege"."member_id" = "member"."id" AND
jbe@497 2746 "privilege"."unit_id" = "newsletter"."unit_id" AND
jbe@497 2747 "privilege"."voting_right" = TRUE
jbe@497 2748 LEFT JOIN "subscription" ON
jbe@497 2749 "subscription"."member_id" = "member"."id" AND
jbe@497 2750 "subscription"."unit_id" = "newsletter"."unit_id"
jbe@498 2751 WHERE "newsletter"."published" <= now()
jbe@497 2752 AND "newsletter"."sent" ISNULL
jbe@497 2753 AND (
jbe@497 2754 "member"."disable_notifications" = FALSE OR
jbe@497 2755 "newsletter"."include_all_members" = TRUE )
jbe@497 2756 AND (
jbe@497 2757 "newsletter"."unit_id" ISNULL OR
jbe@497 2758 "privilege"."member_id" NOTNULL OR
jbe@497 2759 "subscription"."member_id" NOTNULL );
jbe@497 2760
jbe@508 2761 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
jbe@508 2762
jbe@514 2763 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
jbe@514 2764
jbe@473 2765
jbe@0 2766
jbe@242 2767 ------------------------------------------------------
jbe@242 2768 -- Row set returning function for delegation chains --
jbe@242 2769 ------------------------------------------------------
jbe@5 2770
jbe@5 2771
jbe@5 2772 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 2773 ('first', 'intermediate', 'last', 'repetition');
jbe@5 2774
jbe@5 2775 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 2776
jbe@5 2777
jbe@5 2778 CREATE TYPE "delegation_chain_row" AS (
jbe@5 2779 "index" INT4,
jbe@5 2780 "member_id" INT4,
jbe@97 2781 "member_valid" BOOLEAN,
jbe@5 2782 "participation" BOOLEAN,
jbe@5 2783 "overridden" BOOLEAN,
jbe@5 2784 "scope_in" "delegation_scope",
jbe@5 2785 "scope_out" "delegation_scope",
jbe@86 2786 "disabled_out" BOOLEAN,
jbe@5 2787 "loop" "delegation_chain_loop_tag" );
jbe@5 2788
jbe@243 2789 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
jbe@5 2790
jbe@5 2791 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 2792 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest, for areas: membership, for global delegation chains: always null';
jbe@5 2793 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 2794 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 2795 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 2796 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 2797 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 2798
jbe@5 2799
jbe@242 2800 CREATE FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2801 ( "member_id_p" "member"."id"%TYPE,
jbe@242 2802 "issue_id_p" "issue"."id"%TYPE )
jbe@242 2803 RETURNS SETOF "delegation_chain_row"
jbe@242 2804 LANGUAGE 'plpgsql' STABLE AS $$
jbe@242 2805 DECLARE
jbe@242 2806 "output_row" "delegation_chain_row";
jbe@242 2807 "direct_voter_row" "direct_voter"%ROWTYPE;
jbe@242 2808 "delegating_voter_row" "delegating_voter"%ROWTYPE;
jbe@242 2809 BEGIN
jbe@242 2810 "output_row"."index" := 0;
jbe@242 2811 "output_row"."member_id" := "member_id_p";
jbe@242 2812 "output_row"."member_valid" := TRUE;
jbe@242 2813 "output_row"."participation" := FALSE;
jbe@242 2814 "output_row"."overridden" := FALSE;
jbe@242 2815 "output_row"."disabled_out" := FALSE;
jbe@242 2816 LOOP
jbe@242 2817 SELECT INTO "direct_voter_row" * FROM "direct_voter"
jbe@242 2818 WHERE "issue_id" = "issue_id_p"
jbe@242 2819 AND "member_id" = "output_row"."member_id";
jbe@242 2820 IF "direct_voter_row"."member_id" NOTNULL THEN
jbe@242 2821 "output_row"."participation" := TRUE;
jbe@242 2822 "output_row"."scope_out" := NULL;
jbe@242 2823 "output_row"."disabled_out" := NULL;
jbe@242 2824 RETURN NEXT "output_row";
jbe@242 2825 RETURN;
jbe@242 2826 END IF;
jbe@242 2827 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
jbe@242 2828 WHERE "issue_id" = "issue_id_p"
jbe@242 2829 AND "member_id" = "output_row"."member_id";
jbe@242 2830 IF "delegating_voter_row"."member_id" ISNULL THEN
jbe@242 2831 RETURN;
jbe@242 2832 END IF;
jbe@242 2833 "output_row"."scope_out" := "delegating_voter_row"."scope";
jbe@242 2834 RETURN NEXT "output_row";
jbe@242 2835 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
jbe@242 2836 "output_row"."scope_in" := "output_row"."scope_out";
jbe@242 2837 END LOOP;
jbe@242 2838 END;
jbe@242 2839 $$;
jbe@242 2840
jbe@242 2841 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2842 ( "member"."id"%TYPE,
jbe@242 2843 "member"."id"%TYPE )
jbe@242 2844 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
jbe@242 2845
jbe@242 2846
jbe@5 2847 CREATE FUNCTION "delegation_chain"
jbe@5 2848 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2849 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2850 "area_id_p" "area"."id"%TYPE,
jbe@5 2851 "issue_id_p" "issue"."id"%TYPE,
jbe@255 2852 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 2853 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@5 2854 RETURNS SETOF "delegation_chain_row"
jbe@5 2855 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2856 DECLARE
jbe@97 2857 "scope_v" "delegation_scope";
jbe@97 2858 "unit_id_v" "unit"."id"%TYPE;
jbe@97 2859 "area_id_v" "area"."id"%TYPE;
jbe@241 2860 "issue_row" "issue"%ROWTYPE;
jbe@5 2861 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 2862 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 2863 "output_row" "delegation_chain_row";
jbe@5 2864 "output_rows" "delegation_chain_row"[];
jbe@255 2865 "simulate_v" BOOLEAN;
jbe@255 2866 "simulate_here_v" BOOLEAN;
jbe@5 2867 "delegation_row" "delegation"%ROWTYPE;
jbe@5 2868 "row_count" INT4;
jbe@5 2869 "i" INT4;
jbe@5 2870 "loop_v" BOOLEAN;
jbe@5 2871 BEGIN
jbe@255 2872 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
jbe@255 2873 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
jbe@255 2874 END IF;
jbe@255 2875 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
jbe@255 2876 "simulate_v" := TRUE;
jbe@255 2877 ELSE
jbe@255 2878 "simulate_v" := FALSE;
jbe@255 2879 END IF;
jbe@97 2880 IF
jbe@97 2881 "unit_id_p" NOTNULL AND
jbe@97 2882 "area_id_p" ISNULL AND
jbe@97 2883 "issue_id_p" ISNULL
jbe@97 2884 THEN
jbe@97 2885 "scope_v" := 'unit';
jbe@97 2886 "unit_id_v" := "unit_id_p";
jbe@97 2887 ELSIF
jbe@97 2888 "unit_id_p" ISNULL AND
jbe@97 2889 "area_id_p" NOTNULL AND
jbe@97 2890 "issue_id_p" ISNULL
jbe@97 2891 THEN
jbe@97 2892 "scope_v" := 'area';
jbe@97 2893 "area_id_v" := "area_id_p";
jbe@97 2894 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2895 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2896 ELSIF
jbe@97 2897 "unit_id_p" ISNULL AND
jbe@97 2898 "area_id_p" ISNULL AND
jbe@97 2899 "issue_id_p" NOTNULL
jbe@97 2900 THEN
jbe@242 2901 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@242 2902 IF "issue_row"."id" ISNULL THEN
jbe@242 2903 RETURN;
jbe@242 2904 END IF;
jbe@242 2905 IF "issue_row"."closed" NOTNULL THEN
jbe@255 2906 IF "simulate_v" THEN
jbe@242 2907 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@242 2908 END IF;
jbe@242 2909 FOR "output_row" IN
jbe@242 2910 SELECT * FROM
jbe@242 2911 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@242 2912 LOOP
jbe@242 2913 RETURN NEXT "output_row";
jbe@242 2914 END LOOP;
jbe@242 2915 RETURN;
jbe@242 2916 END IF;
jbe@97 2917 "scope_v" := 'issue';
jbe@97 2918 SELECT "area_id" INTO "area_id_v"
jbe@97 2919 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 2920 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2921 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2922 ELSE
jbe@97 2923 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 2924 END IF;
jbe@5 2925 "visited_member_ids" := '{}';
jbe@5 2926 "loop_member_id_v" := NULL;
jbe@5 2927 "output_rows" := '{}';
jbe@5 2928 "output_row"."index" := 0;
jbe@5 2929 "output_row"."member_id" := "member_id_p";
jbe@97 2930 "output_row"."member_valid" := TRUE;
jbe@5 2931 "output_row"."participation" := FALSE;
jbe@5 2932 "output_row"."overridden" := FALSE;
jbe@86 2933 "output_row"."disabled_out" := FALSE;
jbe@5 2934 "output_row"."scope_out" := NULL;
jbe@5 2935 LOOP
jbe@5 2936 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 2937 "loop_member_id_v" := "output_row"."member_id";
jbe@5 2938 ELSE
jbe@5 2939 "visited_member_ids" :=
jbe@5 2940 "visited_member_ids" || "output_row"."member_id";
jbe@5 2941 END IF;
jbe@241 2942 IF "output_row"."participation" ISNULL THEN
jbe@241 2943 "output_row"."overridden" := NULL;
jbe@241 2944 ELSIF "output_row"."participation" THEN
jbe@5 2945 "output_row"."overridden" := TRUE;
jbe@5 2946 END IF;
jbe@5 2947 "output_row"."scope_in" := "output_row"."scope_out";
jbe@255 2948 "output_row"."member_valid" := EXISTS (
jbe@97 2949 SELECT NULL FROM "member" JOIN "privilege"
jbe@97 2950 ON "privilege"."member_id" = "member"."id"
jbe@97 2951 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 2952 WHERE "id" = "output_row"."member_id"
jbe@97 2953 AND "member"."active" AND "privilege"."voting_right"
jbe@255 2954 );
jbe@255 2955 "simulate_here_v" := (
jbe@255 2956 "simulate_v" AND
jbe@255 2957 "output_row"."member_id" = "member_id_p"
jbe@255 2958 );
jbe@255 2959 "delegation_row" := ROW(NULL);
jbe@255 2960 IF "output_row"."member_valid" OR "simulate_here_v" THEN
jbe@97 2961 IF "scope_v" = 'unit' THEN
jbe@255 2962 IF NOT "simulate_here_v" THEN
jbe@255 2963 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2964 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2965 AND "unit_id" = "unit_id_v";
jbe@255 2966 END IF;
jbe@97 2967 ELSIF "scope_v" = 'area' THEN
jbe@5 2968 "output_row"."participation" := EXISTS (
jbe@5 2969 SELECT NULL FROM "membership"
jbe@5 2970 WHERE "area_id" = "area_id_p"
jbe@5 2971 AND "member_id" = "output_row"."member_id"
jbe@5 2972 );
jbe@255 2973 IF "simulate_here_v" THEN
jbe@255 2974 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 2975 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2976 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2977 AND "unit_id" = "unit_id_v";
jbe@255 2978 END IF;
jbe@255 2979 ELSE
jbe@255 2980 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2981 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2982 AND (
jbe@255 2983 "unit_id" = "unit_id_v" OR
jbe@255 2984 "area_id" = "area_id_v"
jbe@255 2985 )
jbe@255 2986 ORDER BY "scope" DESC;
jbe@255 2987 END IF;
jbe@97 2988 ELSIF "scope_v" = 'issue' THEN
jbe@241 2989 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@241 2990 "output_row"."participation" := EXISTS (
jbe@241 2991 SELECT NULL FROM "interest"
jbe@241 2992 WHERE "issue_id" = "issue_id_p"
jbe@241 2993 AND "member_id" = "output_row"."member_id"
jbe@241 2994 );
jbe@241 2995 ELSE
jbe@241 2996 IF "output_row"."member_id" = "member_id_p" THEN
jbe@241 2997 "output_row"."participation" := EXISTS (
jbe@241 2998 SELECT NULL FROM "direct_voter"
jbe@241 2999 WHERE "issue_id" = "issue_id_p"
jbe@241 3000 AND "member_id" = "output_row"."member_id"
jbe@241 3001 );
jbe@241 3002 ELSE
jbe@241 3003 "output_row"."participation" := NULL;
jbe@241 3004 END IF;
jbe@241 3005 END IF;
jbe@255 3006 IF "simulate_here_v" THEN
jbe@255 3007 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 3008 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3009 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3010 AND (
jbe@255 3011 "unit_id" = "unit_id_v" OR
jbe@255 3012 "area_id" = "area_id_v"
jbe@255 3013 )
jbe@255 3014 ORDER BY "scope" DESC;
jbe@255 3015 END IF;
jbe@255 3016 ELSE
jbe@255 3017 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3018 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3019 AND (
jbe@255 3020 "unit_id" = "unit_id_v" OR
jbe@255 3021 "area_id" = "area_id_v" OR
jbe@255 3022 "issue_id" = "issue_id_p"
jbe@255 3023 )
jbe@255 3024 ORDER BY "scope" DESC;
jbe@255 3025 END IF;
jbe@5 3026 END IF;
jbe@5 3027 ELSE
jbe@5 3028 "output_row"."participation" := FALSE;
jbe@5 3029 END IF;
jbe@255 3030 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
jbe@97 3031 "output_row"."scope_out" := "scope_v";
jbe@5 3032 "output_rows" := "output_rows" || "output_row";
jbe@5 3033 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 3034 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 3035 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 3036 "output_rows" := "output_rows" || "output_row";
jbe@5 3037 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 3038 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 3039 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 3040 "output_row"."disabled_out" := TRUE;
jbe@86 3041 "output_rows" := "output_rows" || "output_row";
jbe@86 3042 EXIT;
jbe@5 3043 ELSE
jbe@5 3044 "output_row"."scope_out" := NULL;
jbe@5 3045 "output_rows" := "output_rows" || "output_row";
jbe@5 3046 EXIT;
jbe@5 3047 END IF;
jbe@5 3048 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 3049 "output_row"."index" := "output_row"."index" + 1;
jbe@5 3050 END LOOP;
jbe@5 3051 "row_count" := array_upper("output_rows", 1);
jbe@5 3052 "i" := 1;
jbe@5 3053 "loop_v" := FALSE;
jbe@5 3054 LOOP
jbe@5 3055 "output_row" := "output_rows"["i"];
jbe@98 3056 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 3057 IF "loop_v" THEN
jbe@5 3058 IF "i" + 1 = "row_count" THEN
jbe@5 3059 "output_row"."loop" := 'last';
jbe@5 3060 ELSIF "i" = "row_count" THEN
jbe@5 3061 "output_row"."loop" := 'repetition';
jbe@5 3062 ELSE
jbe@5 3063 "output_row"."loop" := 'intermediate';
jbe@5 3064 END IF;
jbe@5 3065 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 3066 "output_row"."loop" := 'first';
jbe@5 3067 "loop_v" := TRUE;
jbe@5 3068 END IF;
jbe@97 3069 IF "scope_v" = 'unit' THEN
jbe@5 3070 "output_row"."participation" := NULL;
jbe@5 3071 END IF;
jbe@5 3072 RETURN NEXT "output_row";
jbe@5 3073 "i" := "i" + 1;
jbe@5 3074 END LOOP;
jbe@5 3075 RETURN;
jbe@5 3076 END;
jbe@5 3077 $$;
jbe@5 3078
jbe@5 3079 COMMENT ON FUNCTION "delegation_chain"
jbe@5 3080 ( "member"."id"%TYPE,
jbe@97 3081 "unit"."id"%TYPE,
jbe@5 3082 "area"."id"%TYPE,
jbe@5 3083 "issue"."id"%TYPE,
jbe@255 3084 "member"."id"%TYPE,
jbe@255 3085 BOOLEAN )
jbe@242 3086 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
jbe@242 3087
jbe@242 3088
jbe@242 3089
jbe@242 3090 ---------------------------------------------------------
jbe@242 3091 -- Single row returning function for delegation chains --
jbe@242 3092 ---------------------------------------------------------
jbe@242 3093
jbe@242 3094
jbe@242 3095 CREATE TYPE "delegation_info_loop_type" AS ENUM
jbe@242 3096 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
jbe@240 3097
jbe@243 3098 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 3099
jbe@243 3100
jbe@240 3101 CREATE TYPE "delegation_info_type" AS (
jbe@242 3102 "own_participation" BOOLEAN,
jbe@242 3103 "own_delegation_scope" "delegation_scope",
jbe@242 3104 "first_trustee_id" INT4,
jbe@240 3105 "first_trustee_participation" BOOLEAN,
jbe@242 3106 "first_trustee_ellipsis" BOOLEAN,
jbe@242 3107 "other_trustee_id" INT4,
jbe@240 3108 "other_trustee_participation" BOOLEAN,
jbe@242 3109 "other_trustee_ellipsis" BOOLEAN,
jbe@253 3110 "delegation_loop" "delegation_info_loop_type",
jbe@253 3111 "participating_member_id" INT4 );
jbe@240 3112
jbe@243 3113 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 3114
jbe@243 3115 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
jbe@243 3116 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
jbe@243 3117 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
jbe@243 3118 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
jbe@243 3119 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
jbe@243 3120 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
jbe@243 3121 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 3122 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
jbe@243 3123 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 3124 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
jbe@243 3125
jbe@243 3126
jbe@240 3127 CREATE FUNCTION "delegation_info"
jbe@242 3128 ( "member_id_p" "member"."id"%TYPE,
jbe@242 3129 "unit_id_p" "unit"."id"%TYPE,
jbe@242 3130 "area_id_p" "area"."id"%TYPE,
jbe@242 3131 "issue_id_p" "issue"."id"%TYPE,
jbe@255 3132 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 3133 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@240 3134 RETURNS "delegation_info_type"
jbe@240 3135 LANGUAGE 'plpgsql' STABLE AS $$
jbe@240 3136 DECLARE
jbe@242 3137 "current_row" "delegation_chain_row";
jbe@242 3138 "result" "delegation_info_type";
jbe@240 3139 BEGIN
jbe@242 3140 "result"."own_participation" := FALSE;
jbe@242 3141 FOR "current_row" IN
jbe@242 3142 SELECT * FROM "delegation_chain"(
jbe@242 3143 "member_id_p",
jbe@242 3144 "unit_id_p", "area_id_p", "issue_id_p",
jbe@255 3145 "simulate_trustee_id_p", "simulate_default_p")
jbe@242 3146 LOOP
jbe@253 3147 IF
jbe@253 3148 "result"."participating_member_id" ISNULL AND
jbe@253 3149 "current_row"."participation"
jbe@253 3150 THEN
jbe@253 3151 "result"."participating_member_id" := "current_row"."member_id";
jbe@253 3152 END IF;
jbe@242 3153 IF "current_row"."member_id" = "member_id_p" THEN
jbe@242 3154 "result"."own_participation" := "current_row"."participation";
jbe@242 3155 "result"."own_delegation_scope" := "current_row"."scope_out";
jbe@242 3156 IF "current_row"."loop" = 'first' THEN
jbe@242 3157 "result"."delegation_loop" := 'own';
jbe@242 3158 END IF;
jbe@242 3159 ELSIF
jbe@242 3160 "current_row"."member_valid" AND
jbe@242 3161 ( "current_row"."loop" ISNULL OR
jbe@242 3162 "current_row"."loop" != 'repetition' )
jbe@242 3163 THEN
jbe@242 3164 IF "result"."first_trustee_id" ISNULL THEN
jbe@242 3165 "result"."first_trustee_id" := "current_row"."member_id";
jbe@242 3166 "result"."first_trustee_participation" := "current_row"."participation";
jbe@242 3167 "result"."first_trustee_ellipsis" := FALSE;
jbe@242 3168 IF "current_row"."loop" = 'first' THEN
jbe@242 3169 "result"."delegation_loop" := 'first';
jbe@242 3170 END IF;
jbe@242 3171 ELSIF "result"."other_trustee_id" ISNULL THEN
jbe@247 3172 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
jbe@242 3173 "result"."other_trustee_id" := "current_row"."member_id";
jbe@242 3174 "result"."other_trustee_participation" := TRUE;
jbe@242 3175 "result"."other_trustee_ellipsis" := FALSE;
jbe@242 3176 IF "current_row"."loop" = 'first' THEN
jbe@242 3177 "result"."delegation_loop" := 'other';
jbe@240 3178 END IF;
jbe@240 3179 ELSE
jbe@242 3180 "result"."first_trustee_ellipsis" := TRUE;
jbe@242 3181 IF "current_row"."loop" = 'first' THEN
jbe@242 3182 "result"."delegation_loop" := 'first_ellipsis';
jbe@242 3183 END IF;
jbe@242 3184 END IF;
jbe@242 3185 ELSE
jbe@242 3186 "result"."other_trustee_ellipsis" := TRUE;
jbe@242 3187 IF "current_row"."loop" = 'first' THEN
jbe@242 3188 "result"."delegation_loop" := 'other_ellipsis';
jbe@240 3189 END IF;
jbe@240 3190 END IF;
jbe@240 3191 END IF;
jbe@242 3192 END LOOP;
jbe@240 3193 RETURN "result";
jbe@240 3194 END;
jbe@240 3195 $$;
jbe@240 3196
jbe@243 3197 COMMENT ON FUNCTION "delegation_info"
jbe@243 3198 ( "member"."id"%TYPE,
jbe@243 3199 "unit"."id"%TYPE,
jbe@243 3200 "area"."id"%TYPE,
jbe@243 3201 "issue"."id"%TYPE,
jbe@255 3202 "member"."id"%TYPE,
jbe@255 3203 BOOLEAN )
jbe@243 3204 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
jbe@243 3205
jbe@240 3206
jbe@240 3207
jbe@333 3208 ---------------------------
jbe@333 3209 -- Transaction isolation --
jbe@333 3210 ---------------------------
jbe@333 3211
jbe@344 3212
jbe@333 3213 CREATE FUNCTION "require_transaction_isolation"()
jbe@333 3214 RETURNS VOID
jbe@333 3215 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 3216 BEGIN
jbe@333 3217 IF
jbe@333 3218 current_setting('transaction_isolation') NOT IN
jbe@333 3219 ('repeatable read', 'serializable')
jbe@333 3220 THEN
jbe@463 3221 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
jbe@463 3222 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
jbe@333 3223 END IF;
jbe@333 3224 RETURN;
jbe@333 3225 END;
jbe@333 3226 $$;
jbe@333 3227
jbe@344 3228 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
jbe@344 3229
jbe@333 3230
jbe@333 3231 CREATE FUNCTION "dont_require_transaction_isolation"()
jbe@333 3232 RETURNS VOID
jbe@333 3233 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 3234 BEGIN
jbe@333 3235 IF
jbe@333 3236 current_setting('transaction_isolation') IN
jbe@333 3237 ('repeatable read', 'serializable')
jbe@333 3238 THEN
jbe@333 3239 RAISE WARNING 'Unneccessary transaction isolation level: %',
jbe@333 3240 current_setting('transaction_isolation');
jbe@333 3241 END IF;
jbe@333 3242 RETURN;
jbe@333 3243 END;
jbe@333 3244 $$;
jbe@333 3245
jbe@344 3246 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
jbe@344 3247
jbe@333 3248
jbe@333 3249
jbe@491 3250 -------------------------
jbe@491 3251 -- Notification system --
jbe@491 3252 -------------------------
jbe@491 3253
jbe@491 3254 CREATE FUNCTION "get_initiatives_for_notification"
jbe@501 3255 ( "recipient_id_p" "member"."id"%TYPE )
jbe@491 3256 RETURNS SETOF "initiative_for_notification"
jbe@491 3257 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@491 3258 DECLARE
jbe@491 3259 "result_row" "initiative_for_notification"%ROWTYPE;
jbe@491 3260 "last_draft_id_v" "draft"."id"%TYPE;
jbe@491 3261 "last_suggestion_id_v" "suggestion"."id"%TYPE;
jbe@491 3262 BEGIN
jbe@491 3263 PERFORM "require_transaction_isolation"();
jbe@501 3264 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
jbe@491 3265 FOR "result_row" IN
jbe@491 3266 SELECT * FROM "initiative_for_notification"
jbe@501 3267 WHERE "recipient_id" = "recipient_id_p"
jbe@491 3268 LOOP
jbe@491 3269 SELECT "id" INTO "last_draft_id_v" FROM "draft"
jbe@499 3270 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
jbe@491 3271 ORDER BY "id" DESC LIMIT 1;
jbe@491 3272 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
jbe@499 3273 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
jbe@491 3274 ORDER BY "id" DESC LIMIT 1;
jbe@517 3275 /* compatibility with PostgreSQL 9.1 */
jbe@517 3276 DELETE FROM "notification_initiative_sent"
jbe@517 3277 WHERE "member_id" = "recipient_id_p"
jbe@517 3278 AND "initiative_id" = "result_row"."initiative_id";
jbe@517 3279 INSERT INTO "notification_initiative_sent"
jbe@517 3280 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@517 3281 VALUES (
jbe@517 3282 "recipient_id_p",
jbe@517 3283 "result_row"."initiative_id",
jbe@517 3284 "last_draft_id_v",
jbe@517 3285 "last_suggestion_id_v" );
jbe@517 3286 /* TODO: use alternative code below, requires PostgreSQL 9.5 or higher
jbe@507 3287 INSERT INTO "notification_initiative_sent"
jbe@491 3288 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@491 3289 VALUES (
jbe@501 3290 "recipient_id_p",
jbe@499 3291 "result_row"."initiative_id",
jbe@493 3292 "last_draft_id_v",
jbe@493 3293 "last_suggestion_id_v" )
jbe@491 3294 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
jbe@517 3295 "last_draft_id" = "last_draft_id_v",
jbe@517 3296 "last_suggestion_id" = "last_suggestion_id_v";
jbe@517 3297 */
jbe@491 3298 RETURN NEXT "result_row";
jbe@491 3299 END LOOP;
jbe@507 3300 DELETE FROM "notification_initiative_sent"
jbe@491 3301 USING "initiative", "issue"
jbe@507 3302 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
jbe@507 3303 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
jbe@491 3304 AND "issue"."id" = "initiative"."issue_id"
jbe@491 3305 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
jbe@505 3306 UPDATE "member" SET
jbe@506 3307 "notification_counter" = "notification_counter" + 1,
jbe@505 3308 "notification_sent" = now()
jbe@501 3309 WHERE "id" = "recipient_id_p";
jbe@491 3310 RETURN;
jbe@491 3311 END;
jbe@491 3312 $$;
jbe@491 3313
jbe@511 3314 COMMENT ON FUNCTION "get_initiatives_for_notification"
jbe@511 3315 ( "member"."id"%TYPE )
jbe@511 3316 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 3317
jbe@491 3318
jbe@491 3319
jbe@103 3320 ------------------------------------------------------------------------
jbe@103 3321 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 3322 ------------------------------------------------------------------------
jbe@103 3323
jbe@333 3324
jbe@184 3325 CREATE FUNCTION "check_activity"()
jbe@103 3326 RETURNS VOID
jbe@103 3327 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 3328 DECLARE
jbe@104 3329 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 3330 BEGIN
jbe@333 3331 PERFORM "dont_require_transaction_isolation"();
jbe@104 3332 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@104 3333 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 3334 UPDATE "member" SET "active" = FALSE
jbe@104 3335 WHERE "active" = TRUE
jbe@184 3336 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
jbe@104 3337 END IF;
jbe@103 3338 RETURN;
jbe@103 3339 END;
jbe@103 3340 $$;
jbe@103 3341
jbe@184 3342 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
jbe@103 3343
jbe@4 3344
jbe@4 3345 CREATE FUNCTION "calculate_member_counts"()
jbe@4 3346 RETURNS VOID
jbe@4 3347 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 3348 BEGIN
jbe@333 3349 PERFORM "require_transaction_isolation"();
jbe@4 3350 DELETE FROM "member_count";
jbe@5 3351 INSERT INTO "member_count" ("total_count")
jbe@5 3352 SELECT "total_count" FROM "member_count_view";
jbe@97 3353 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 3354 FROM "unit_member_count" AS "view"
jbe@97 3355 WHERE "view"."unit_id" = "unit"."id";
jbe@5 3356 UPDATE "area" SET
jbe@5 3357 "direct_member_count" = "view"."direct_member_count",
jbe@169 3358 "member_weight" = "view"."member_weight"
jbe@5 3359 FROM "area_member_count" AS "view"
jbe@5 3360 WHERE "view"."area_id" = "area"."id";
jbe@4 3361 RETURN;
jbe@4 3362 END;
jbe@4 3363 $$;
jbe@4 3364
jbe@4 3365 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 "area_member_count"';
jbe@4 3366
jbe@4 3367
jbe@4 3368
jbe@327 3369 ------------------------------------
jbe@327 3370 -- Calculation of harmonic weight --
jbe@327 3371 ------------------------------------
jbe@310 3372
jbe@312 3373
jbe@310 3374 CREATE VIEW "remaining_harmonic_supporter_weight" AS
jbe@310 3375 SELECT
jbe@310 3376 "direct_interest_snapshot"."issue_id",
jbe@310 3377 "direct_interest_snapshot"."event",
jbe@310 3378 "direct_interest_snapshot"."member_id",
jbe@310 3379 "direct_interest_snapshot"."weight" AS "weight_num",
jbe@310 3380 count("initiative"."id") AS "weight_den"
jbe@312 3381 FROM "issue"
jbe@312 3382 JOIN "direct_interest_snapshot"
jbe@312 3383 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
jbe@312 3384 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
jbe@327 3385 JOIN "initiative"
jbe@327 3386 ON "issue"."id" = "initiative"."issue_id"
jbe@327 3387 AND "initiative"."harmonic_weight" ISNULL
jbe@310 3388 JOIN "direct_supporter_snapshot"
jbe@327 3389 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 3390 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
jbe@310 3391 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 3392 AND (
jbe@321 3393 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 3394 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 3395 )
jbe@310 3396 GROUP BY
jbe@310 3397 "direct_interest_snapshot"."issue_id",
jbe@310 3398 "direct_interest_snapshot"."event",
jbe@310 3399 "direct_interest_snapshot"."member_id",
jbe@310 3400 "direct_interest_snapshot"."weight";
jbe@310 3401
jbe@310 3402 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 3403
jbe@310 3404
jbe@310 3405 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
jbe@310 3406 SELECT
jbe@310 3407 "initiative"."issue_id",
jbe@310 3408 "initiative"."id" AS "initiative_id",
jbe@320 3409 "initiative"."admitted",
jbe@310 3410 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
jbe@310 3411 "remaining_harmonic_supporter_weight"."weight_den"
jbe@310 3412 FROM "remaining_harmonic_supporter_weight"
jbe@327 3413 JOIN "initiative"
jbe@327 3414 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
jbe@327 3415 AND "initiative"."harmonic_weight" ISNULL
jbe@310 3416 JOIN "direct_supporter_snapshot"
jbe@327 3417 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 3418 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
jbe@310 3419 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 3420 AND (
jbe@321 3421 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 3422 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 3423 )
jbe@310 3424 GROUP BY
jbe@310 3425 "initiative"."issue_id",
jbe@310 3426 "initiative"."id",
jbe@320 3427 "initiative"."admitted",
jbe@310 3428 "remaining_harmonic_supporter_weight"."weight_den";
jbe@310 3429
jbe@310 3430 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 3431
jbe@310 3432
jbe@349 3433 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
jbe@349 3434 SELECT
jbe@349 3435 "issue_id",
jbe@349 3436 "id" AS "initiative_id",
jbe@349 3437 "admitted",
jbe@349 3438 0 AS "weight_num",
jbe@349 3439 1 AS "weight_den"
jbe@349 3440 FROM "initiative"
jbe@349 3441 WHERE "harmonic_weight" ISNULL;
jbe@349 3442
jbe@349 3443 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 3444
jbe@349 3445
jbe@310 3446 CREATE FUNCTION "set_harmonic_initiative_weights"
jbe@310 3447 ( "issue_id_p" "issue"."id"%TYPE )
jbe@310 3448 RETURNS VOID
jbe@310 3449 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@310 3450 DECLARE
jbe@310 3451 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
jbe@310 3452 "i" INT4;
jbe@310 3453 "count_v" INT4;
jbe@310 3454 "summand_v" FLOAT;
jbe@310 3455 "id_ary" INT4[];
jbe@310 3456 "weight_ary" FLOAT[];
jbe@310 3457 "min_weight_v" FLOAT;
jbe@310 3458 BEGIN
jbe@333 3459 PERFORM "require_transaction_isolation"();
jbe@312 3460 UPDATE "initiative" SET "harmonic_weight" = NULL
jbe@312 3461 WHERE "issue_id" = "issue_id_p";
jbe@310 3462 LOOP
jbe@310 3463 "min_weight_v" := NULL;
jbe@310 3464 "i" := 0;
jbe@310 3465 "count_v" := 0;
jbe@310 3466 FOR "weight_row" IN
jbe@310 3467 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
jbe@310 3468 WHERE "issue_id" = "issue_id_p"
jbe@320 3469 AND (
jbe@320 3470 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@320 3471 SELECT NULL FROM "initiative"
jbe@320 3472 WHERE "issue_id" = "issue_id_p"
jbe@320 3473 AND "harmonic_weight" ISNULL
jbe@320 3474 AND coalesce("admitted", FALSE) = FALSE
jbe@320 3475 )
jbe@320 3476 )
jbe@349 3477 UNION ALL -- needed for corner cases
jbe@349 3478 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
jbe@349 3479 WHERE "issue_id" = "issue_id_p"
jbe@349 3480 AND (
jbe@349 3481 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@349 3482 SELECT NULL FROM "initiative"
jbe@349 3483 WHERE "issue_id" = "issue_id_p"
jbe@349 3484 AND "harmonic_weight" ISNULL
jbe@349 3485 AND coalesce("admitted", FALSE) = FALSE
jbe@349 3486 )
jbe@349 3487 )
jbe@310 3488 ORDER BY "initiative_id" DESC, "weight_den" DESC
jbe@320 3489 -- NOTE: non-admitted initiatives placed first (at last positions),
jbe@320 3490 -- latest initiatives treated worse in case of tie
jbe@310 3491 LOOP
jbe@310 3492 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
jbe@310 3493 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
jbe@310 3494 "i" := "i" + 1;
jbe@310 3495 "count_v" := "i";
jbe@310 3496 "id_ary"["i"] := "weight_row"."initiative_id";
jbe@310 3497 "weight_ary"["i"] := "summand_v";
jbe@310 3498 ELSE
jbe@310 3499 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
jbe@310 3500 END IF;
jbe@310 3501 END LOOP;
jbe@310 3502 EXIT WHEN "count_v" = 0;
jbe@310 3503 "i" := 1;
jbe@310 3504 LOOP
jbe@313 3505 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
jbe@310 3506 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
jbe@310 3507 "min_weight_v" := "weight_ary"["i"];
jbe@310 3508 END IF;
jbe@310 3509 "i" := "i" + 1;
jbe@310 3510 EXIT WHEN "i" > "count_v";
jbe@310 3511 END LOOP;
jbe@310 3512 "i" := 1;
jbe@310 3513 LOOP
jbe@310 3514 IF "weight_ary"["i"] = "min_weight_v" THEN
jbe@310 3515 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
jbe@310 3516 WHERE "id" = "id_ary"["i"];
jbe@310 3517 EXIT;
jbe@310 3518 END IF;
jbe@310 3519 "i" := "i" + 1;
jbe@310 3520 END LOOP;
jbe@310 3521 END LOOP;
jbe@316 3522 UPDATE "initiative" SET "harmonic_weight" = 0
jbe@316 3523 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
jbe@310 3524 END;
jbe@310 3525 $$;
jbe@310 3526
jbe@310 3527 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
jbe@310 3528 ( "issue"."id"%TYPE )
jbe@310 3529 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
jbe@310 3530
jbe@310 3531
jbe@312 3532
jbe@0 3533 ------------------------------
jbe@0 3534 -- Calculation of snapshots --
jbe@0 3535 ------------------------------
jbe@0 3536
jbe@312 3537
jbe@0 3538 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3539 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3540 "member_id_p" "member"."id"%TYPE,
jbe@0 3541 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3542 RETURNS "direct_population_snapshot"."weight"%TYPE
jbe@0 3543 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3544 DECLARE
jbe@0 3545 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3546 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3547 "weight_v" INT4;
jbe@8 3548 "sub_weight_v" INT4;
jbe@0 3549 BEGIN
jbe@336 3550 PERFORM "require_transaction_isolation"();
jbe@0 3551 "weight_v" := 0;
jbe@0 3552 FOR "issue_delegation_row" IN
jbe@0 3553 SELECT * FROM "issue_delegation"
jbe@0 3554 WHERE "trustee_id" = "member_id_p"
jbe@0 3555 AND "issue_id" = "issue_id_p"
jbe@0 3556 LOOP
jbe@0 3557 IF NOT EXISTS (
jbe@0 3558 SELECT NULL FROM "direct_population_snapshot"
jbe@0 3559 WHERE "issue_id" = "issue_id_p"
jbe@0 3560 AND "event" = 'periodic'
jbe@0 3561 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3562 ) AND NOT EXISTS (
jbe@0 3563 SELECT NULL FROM "delegating_population_snapshot"
jbe@0 3564 WHERE "issue_id" = "issue_id_p"
jbe@0 3565 AND "event" = 'periodic'
jbe@0 3566 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3567 ) THEN
jbe@0 3568 "delegate_member_ids_v" :=
jbe@0 3569 "member_id_p" || "delegate_member_ids_p";
jbe@10 3570 INSERT INTO "delegating_population_snapshot" (
jbe@10 3571 "issue_id",
jbe@10 3572 "event",
jbe@10 3573 "member_id",
jbe@10 3574 "scope",
jbe@10 3575 "delegate_member_ids"
jbe@10 3576 ) VALUES (
jbe@0 3577 "issue_id_p",
jbe@0 3578 'periodic',
jbe@0 3579 "issue_delegation_row"."truster_id",
jbe@10 3580 "issue_delegation_row"."scope",
jbe@0 3581 "delegate_member_ids_v"
jbe@0 3582 );
jbe@8 3583 "sub_weight_v" := 1 +
jbe@0 3584 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3585 "issue_id_p",
jbe@0 3586 "issue_delegation_row"."truster_id",
jbe@0 3587 "delegate_member_ids_v"
jbe@0 3588 );
jbe@8 3589 UPDATE "delegating_population_snapshot"
jbe@8 3590 SET "weight" = "sub_weight_v"
jbe@8 3591 WHERE "issue_id" = "issue_id_p"
jbe@8 3592 AND "event" = 'periodic'
jbe@8 3593 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3594 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3595 END IF;
jbe@0 3596 END LOOP;
jbe@0 3597 RETURN "weight_v";
jbe@0 3598 END;
jbe@0 3599 $$;
jbe@0 3600
jbe@0 3601 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3602 ( "issue"."id"%TYPE,
jbe@0 3603 "member"."id"%TYPE,
jbe@0 3604 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3605 IS 'Helper function for "create_population_snapshot" function';
jbe@0 3606
jbe@0 3607
jbe@0 3608 CREATE FUNCTION "create_population_snapshot"
jbe@0 3609 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3610 RETURNS VOID
jbe@0 3611 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3612 DECLARE
jbe@0 3613 "member_id_v" "member"."id"%TYPE;
jbe@0 3614 BEGIN
jbe@336 3615 PERFORM "require_transaction_isolation"();
jbe@0 3616 DELETE FROM "direct_population_snapshot"
jbe@0 3617 WHERE "issue_id" = "issue_id_p"
jbe@0 3618 AND "event" = 'periodic';
jbe@0 3619 DELETE FROM "delegating_population_snapshot"
jbe@0 3620 WHERE "issue_id" = "issue_id_p"
jbe@0 3621 AND "event" = 'periodic';
jbe@0 3622 INSERT INTO "direct_population_snapshot"
jbe@54 3623 ("issue_id", "event", "member_id")
jbe@54 3624 SELECT
jbe@54 3625 "issue_id_p" AS "issue_id",
jbe@54 3626 'periodic'::"snapshot_event" AS "event",
jbe@54 3627 "member"."id" AS "member_id"
jbe@54 3628 FROM "issue"
jbe@54 3629 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@54 3630 JOIN "membership" ON "area"."id" = "membership"."area_id"
jbe@54 3631 JOIN "member" ON "membership"."member_id" = "member"."id"
jbe@97 3632 JOIN "privilege"
jbe@97 3633 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3634 AND "privilege"."member_id" = "member"."id"
jbe@54 3635 WHERE "issue"."id" = "issue_id_p"
jbe@97 3636 AND "member"."active" AND "privilege"."voting_right"
jbe@54 3637 UNION
jbe@54 3638 SELECT
jbe@54 3639 "issue_id_p" AS "issue_id",
jbe@54 3640 'periodic'::"snapshot_event" AS "event",
jbe@54 3641 "member"."id" AS "member_id"
jbe@97 3642 FROM "issue"
jbe@97 3643 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3644 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3645 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3646 JOIN "privilege"
jbe@97 3647 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3648 AND "privilege"."member_id" = "member"."id"
jbe@97 3649 WHERE "issue"."id" = "issue_id_p"
jbe@97 3650 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3651 FOR "member_id_v" IN
jbe@0 3652 SELECT "member_id" FROM "direct_population_snapshot"
jbe@0 3653 WHERE "issue_id" = "issue_id_p"
jbe@0 3654 AND "event" = 'periodic'
jbe@0 3655 LOOP
jbe@0 3656 UPDATE "direct_population_snapshot" SET
jbe@0 3657 "weight" = 1 +
jbe@0 3658 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3659 "issue_id_p",
jbe@0 3660 "member_id_v",
jbe@0 3661 '{}'
jbe@0 3662 )
jbe@0 3663 WHERE "issue_id" = "issue_id_p"
jbe@0 3664 AND "event" = 'periodic'
jbe@0 3665 AND "member_id" = "member_id_v";
jbe@0 3666 END LOOP;
jbe@0 3667 RETURN;
jbe@0 3668 END;
jbe@0 3669 $$;
jbe@0 3670
jbe@0 3671 COMMENT ON FUNCTION "create_population_snapshot"
jbe@67 3672 ( "issue"."id"%TYPE )
jbe@0 3673 IS 'This function creates a new ''periodic'' population snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
jbe@0 3674
jbe@0 3675
jbe@0 3676 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3677 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3678 "member_id_p" "member"."id"%TYPE,
jbe@0 3679 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3680 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 3681 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3682 DECLARE
jbe@0 3683 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3684 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3685 "weight_v" INT4;
jbe@8 3686 "sub_weight_v" INT4;
jbe@0 3687 BEGIN
jbe@336 3688 PERFORM "require_transaction_isolation"();
jbe@0 3689 "weight_v" := 0;
jbe@0 3690 FOR "issue_delegation_row" IN
jbe@0 3691 SELECT * FROM "issue_delegation"
jbe@0 3692 WHERE "trustee_id" = "member_id_p"
jbe@0 3693 AND "issue_id" = "issue_id_p"
jbe@0 3694 LOOP
jbe@0 3695 IF NOT EXISTS (
jbe@0 3696 SELECT NULL FROM "direct_interest_snapshot"
jbe@0 3697 WHERE "issue_id" = "issue_id_p"
jbe@0 3698 AND "event" = 'periodic'
jbe@0 3699 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3700 ) AND NOT EXISTS (
jbe@0 3701 SELECT NULL FROM "delegating_interest_snapshot"
jbe@0 3702 WHERE "issue_id" = "issue_id_p"
jbe@0 3703 AND "event" = 'periodic'
jbe@0 3704 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3705 ) THEN
jbe@0 3706 "delegate_member_ids_v" :=
jbe@0 3707 "member_id_p" || "delegate_member_ids_p";
jbe@10 3708 INSERT INTO "delegating_interest_snapshot" (
jbe@10 3709 "issue_id",
jbe@10 3710 "event",
jbe@10 3711 "member_id",
jbe@10 3712 "scope",
jbe@10 3713 "delegate_member_ids"
jbe@10 3714 ) VALUES (
jbe@0 3715 "issue_id_p",
jbe@0 3716 'periodic',
jbe@0 3717 "issue_delegation_row"."truster_id",
jbe@10 3718 "issue_delegation_row"."scope",
jbe@0 3719 "delegate_member_ids_v"
jbe@0 3720 );
jbe@8 3721 "sub_weight_v" := 1 +
jbe@0 3722 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3723 "issue_id_p",
jbe@0 3724 "issue_delegation_row"."truster_id",
jbe@0 3725 "delegate_member_ids_v"
jbe@0 3726 );
jbe@8 3727 UPDATE "delegating_interest_snapshot"
jbe@8 3728 SET "weight" = "sub_weight_v"
jbe@8 3729 WHERE "issue_id" = "issue_id_p"
jbe@8 3730 AND "event" = 'periodic'
jbe@8 3731 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3732 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3733 END IF;
jbe@0 3734 END LOOP;
jbe@0 3735 RETURN "weight_v";
jbe@0 3736 END;
jbe@0 3737 $$;
jbe@0 3738
jbe@0 3739 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3740 ( "issue"."id"%TYPE,
jbe@0 3741 "member"."id"%TYPE,
jbe@0 3742 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3743 IS 'Helper function for "create_interest_snapshot" function';
jbe@0 3744
jbe@0 3745
jbe@0 3746 CREATE FUNCTION "create_interest_snapshot"
jbe@0 3747 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3748 RETURNS VOID
jbe@0 3749 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3750 DECLARE
jbe@0 3751 "member_id_v" "member"."id"%TYPE;
jbe@0 3752 BEGIN
jbe@336 3753 PERFORM "require_transaction_isolation"();
jbe@0 3754 DELETE FROM "direct_interest_snapshot"
jbe@0 3755 WHERE "issue_id" = "issue_id_p"
jbe@0 3756 AND "event" = 'periodic';
jbe@0 3757 DELETE FROM "delegating_interest_snapshot"
jbe@0 3758 WHERE "issue_id" = "issue_id_p"
jbe@0 3759 AND "event" = 'periodic';
jbe@0 3760 DELETE FROM "direct_supporter_snapshot"
jbe@325 3761 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 3762 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 3763 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 3764 AND "direct_supporter_snapshot"."event" = 'periodic';
jbe@0 3765 INSERT INTO "direct_interest_snapshot"
jbe@144 3766 ("issue_id", "event", "member_id")
jbe@0 3767 SELECT
jbe@0 3768 "issue_id_p" AS "issue_id",
jbe@0 3769 'periodic' AS "event",
jbe@144 3770 "member"."id" AS "member_id"
jbe@97 3771 FROM "issue"
jbe@97 3772 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3773 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3774 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3775 JOIN "privilege"
jbe@97 3776 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3777 AND "privilege"."member_id" = "member"."id"
jbe@97 3778 WHERE "issue"."id" = "issue_id_p"
jbe@97 3779 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3780 FOR "member_id_v" IN
jbe@0 3781 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@0 3782 WHERE "issue_id" = "issue_id_p"
jbe@0 3783 AND "event" = 'periodic'
jbe@0 3784 LOOP
jbe@0 3785 UPDATE "direct_interest_snapshot" SET
jbe@0 3786 "weight" = 1 +
jbe@0 3787 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3788 "issue_id_p",
jbe@0 3789 "member_id_v",
jbe@0 3790 '{}'
jbe@0 3791 )
jbe@0 3792 WHERE "issue_id" = "issue_id_p"
jbe@0 3793 AND "event" = 'periodic'
jbe@0 3794 AND "member_id" = "member_id_v";
jbe@0 3795 END LOOP;
jbe@0 3796 INSERT INTO "direct_supporter_snapshot"
jbe@0 3797 ( "issue_id", "initiative_id", "event", "member_id",
jbe@204 3798 "draft_id", "informed", "satisfied" )
jbe@0 3799 SELECT
jbe@96 3800 "issue_id_p" AS "issue_id",
jbe@96 3801 "initiative"."id" AS "initiative_id",
jbe@96 3802 'periodic' AS "event",
jbe@96 3803 "supporter"."member_id" AS "member_id",
jbe@204 3804 "supporter"."draft_id" AS "draft_id",
jbe@0 3805 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@0 3806 NOT EXISTS (
jbe@0 3807 SELECT NULL FROM "critical_opinion"
jbe@0 3808 WHERE "initiative_id" = "initiative"."id"
jbe@96 3809 AND "member_id" = "supporter"."member_id"
jbe@0 3810 ) AS "satisfied"
jbe@96 3811 FROM "initiative"
jbe@96 3812 JOIN "supporter"
jbe@0 3813 ON "supporter"."initiative_id" = "initiative"."id"
jbe@0 3814 JOIN "current_draft"
jbe@0 3815 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@0 3816 JOIN "direct_interest_snapshot"
jbe@96 3817 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@0 3818 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@3 3819 AND "event" = 'periodic'
jbe@96 3820 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@0 3821 RETURN;
jbe@0 3822 END;
jbe@0 3823 $$;
jbe@0 3824
jbe@0 3825 COMMENT ON FUNCTION "create_interest_snapshot"
jbe@0 3826 ( "issue"."id"%TYPE )
jbe@0 3827 IS 'This function creates a new ''periodic'' interest/supporter snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.';
jbe@0 3828
jbe@0 3829
jbe@0 3830 CREATE FUNCTION "create_snapshot"
jbe@0 3831 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3832 RETURNS VOID
jbe@0 3833 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3834 DECLARE
jbe@0 3835 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3836 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@0 3837 BEGIN
jbe@333 3838 PERFORM "require_transaction_isolation"();
jbe@0 3839 PERFORM "create_population_snapshot"("issue_id_p");
jbe@0 3840 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@0 3841 UPDATE "issue" SET
jbe@331 3842 "snapshot" = coalesce("phase_finished", now()),
jbe@8 3843 "latest_snapshot_event" = 'periodic',
jbe@0 3844 "population" = (
jbe@0 3845 SELECT coalesce(sum("weight"), 0)
jbe@0 3846 FROM "direct_population_snapshot"
jbe@0 3847 WHERE "issue_id" = "issue_id_p"
jbe@0 3848 AND "event" = 'periodic'
jbe@0 3849 )
jbe@0 3850 WHERE "id" = "issue_id_p";
jbe@0 3851 FOR "initiative_id_v" IN
jbe@0 3852 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@0 3853 LOOP
jbe@0 3854 UPDATE "initiative" SET
jbe@0 3855 "supporter_count" = (
jbe@0 3856 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3857 FROM "direct_interest_snapshot" AS "di"
jbe@0 3858 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3859 ON "di"."member_id" = "ds"."member_id"
jbe@0 3860 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3861 AND "di"."event" = 'periodic'
jbe@0 3862 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3863 AND "ds"."event" = 'periodic'
jbe@0 3864 ),
jbe@0 3865 "informed_supporter_count" = (
jbe@0 3866 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3867 FROM "direct_interest_snapshot" AS "di"
jbe@0 3868 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3869 ON "di"."member_id" = "ds"."member_id"
jbe@0 3870 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3871 AND "di"."event" = 'periodic'
jbe@0 3872 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3873 AND "ds"."event" = 'periodic'
jbe@0 3874 AND "ds"."informed"
jbe@0 3875 ),
jbe@0 3876 "satisfied_supporter_count" = (
jbe@0 3877 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3878 FROM "direct_interest_snapshot" AS "di"
jbe@0 3879 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3880 ON "di"."member_id" = "ds"."member_id"
jbe@0 3881 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3882 AND "di"."event" = 'periodic'
jbe@0 3883 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3884 AND "ds"."event" = 'periodic'
jbe@0 3885 AND "ds"."satisfied"
jbe@0 3886 ),
jbe@0 3887 "satisfied_informed_supporter_count" = (
jbe@0 3888 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3889 FROM "direct_interest_snapshot" AS "di"
jbe@0 3890 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3891 ON "di"."member_id" = "ds"."member_id"
jbe@0 3892 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3893 AND "di"."event" = 'periodic'
jbe@0 3894 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3895 AND "ds"."event" = 'periodic'
jbe@0 3896 AND "ds"."informed"
jbe@0 3897 AND "ds"."satisfied"
jbe@0 3898 )
jbe@0 3899 WHERE "id" = "initiative_id_v";
jbe@0 3900 FOR "suggestion_id_v" IN
jbe@0 3901 SELECT "id" FROM "suggestion"
jbe@0 3902 WHERE "initiative_id" = "initiative_id_v"
jbe@0 3903 LOOP
jbe@0 3904 UPDATE "suggestion" SET
jbe@0 3905 "minus2_unfulfilled_count" = (
jbe@0 3906 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3907 FROM "issue" CROSS JOIN "opinion"
jbe@36 3908 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3909 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3910 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3911 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3912 WHERE "issue"."id" = "issue_id_p"
jbe@36 3913 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3914 AND "opinion"."degree" = -2
jbe@0 3915 AND "opinion"."fulfilled" = FALSE
jbe@0 3916 ),
jbe@0 3917 "minus2_fulfilled_count" = (
jbe@0 3918 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3919 FROM "issue" CROSS JOIN "opinion"
jbe@36 3920 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3921 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3922 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3923 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3924 WHERE "issue"."id" = "issue_id_p"
jbe@36 3925 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3926 AND "opinion"."degree" = -2
jbe@0 3927 AND "opinion"."fulfilled" = TRUE
jbe@0 3928 ),
jbe@0 3929 "minus1_unfulfilled_count" = (
jbe@0 3930 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3931 FROM "issue" CROSS JOIN "opinion"
jbe@36 3932 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3933 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3934 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3935 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3936 WHERE "issue"."id" = "issue_id_p"
jbe@36 3937 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3938 AND "opinion"."degree" = -1
jbe@0 3939 AND "opinion"."fulfilled" = FALSE
jbe@0 3940 ),
jbe@0 3941 "minus1_fulfilled_count" = (
jbe@0 3942 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3943 FROM "issue" CROSS JOIN "opinion"
jbe@36 3944 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3945 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3946 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3947 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3948 WHERE "issue"."id" = "issue_id_p"
jbe@36 3949 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3950 AND "opinion"."degree" = -1
jbe@0 3951 AND "opinion"."fulfilled" = TRUE
jbe@0 3952 ),
jbe@0 3953 "plus1_unfulfilled_count" = (
jbe@0 3954 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3955 FROM "issue" CROSS JOIN "opinion"
jbe@36 3956 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3957 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3958 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3959 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3960 WHERE "issue"."id" = "issue_id_p"
jbe@36 3961 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3962 AND "opinion"."degree" = 1
jbe@0 3963 AND "opinion"."fulfilled" = FALSE
jbe@0 3964 ),
jbe@0 3965 "plus1_fulfilled_count" = (
jbe@0 3966 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3967 FROM "issue" CROSS JOIN "opinion"
jbe@36 3968 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3969 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3970 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3971 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3972 WHERE "issue"."id" = "issue_id_p"
jbe@36 3973 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3974 AND "opinion"."degree" = 1
jbe@0 3975 AND "opinion"."fulfilled" = TRUE
jbe@0 3976 ),
jbe@0 3977 "plus2_unfulfilled_count" = (
jbe@0 3978 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3979 FROM "issue" CROSS JOIN "opinion"
jbe@36 3980 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3981 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3982 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3983 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3984 WHERE "issue"."id" = "issue_id_p"
jbe@36 3985 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3986 AND "opinion"."degree" = 2
jbe@0 3987 AND "opinion"."fulfilled" = FALSE
jbe@0 3988 ),
jbe@0 3989 "plus2_fulfilled_count" = (
jbe@0 3990 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3991 FROM "issue" CROSS JOIN "opinion"
jbe@36 3992 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3993 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3994 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3995 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3996 WHERE "issue"."id" = "issue_id_p"
jbe@36 3997 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3998 AND "opinion"."degree" = 2
jbe@0 3999 AND "opinion"."fulfilled" = TRUE
jbe@0 4000 )
jbe@0 4001 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@0 4002 END LOOP;
jbe@0 4003 END LOOP;
jbe@0 4004 RETURN;
jbe@0 4005 END;
jbe@0 4006 $$;
jbe@0 4007
jbe@0 4008 COMMENT ON FUNCTION "create_snapshot"
jbe@0 4009 ( "issue"."id"%TYPE )
jbe@0 4010 IS 'This function creates a complete new ''periodic'' snapshot of population, interest and support for the given issue. All involved tables are locked, and after completion precalculated values in the source tables are updated.';
jbe@0 4011
jbe@0 4012
jbe@0 4013 CREATE FUNCTION "set_snapshot_event"
jbe@0 4014 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 4015 "event_p" "snapshot_event" )
jbe@0 4016 RETURNS VOID
jbe@0 4017 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@21 4018 DECLARE
jbe@21 4019 "event_v" "issue"."latest_snapshot_event"%TYPE;
jbe@0 4020 BEGIN
jbe@333 4021 PERFORM "require_transaction_isolation"();
jbe@21 4022 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
jbe@21 4023 WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@8 4024 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
jbe@8 4025 WHERE "id" = "issue_id_p";
jbe@3 4026 UPDATE "direct_population_snapshot" SET "event" = "event_p"
jbe@21 4027 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4028 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
jbe@21 4029 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4030 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
jbe@21 4031 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4032 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
jbe@21 4033 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4034 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
jbe@325 4035 FROM "initiative" -- NOTE: due to missing index on issue_id
jbe@325 4036 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 4037 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 4038 AND "direct_supporter_snapshot"."event" = "event_v";
jbe@0 4039 RETURN;
jbe@0 4040 END;
jbe@0 4041 $$;
jbe@0 4042
jbe@0 4043 COMMENT ON FUNCTION "set_snapshot_event"
jbe@0 4044 ( "issue"."id"%TYPE,
jbe@0 4045 "snapshot_event" )
jbe@0 4046 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
jbe@0 4047
jbe@0 4048
jbe@0 4049
jbe@0 4050 -----------------------
jbe@0 4051 -- Counting of votes --
jbe@0 4052 -----------------------
jbe@0 4053
jbe@0 4054
jbe@5 4055 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 4056 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 4057 "member_id_p" "member"."id"%TYPE,
jbe@0 4058 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 4059 RETURNS "direct_voter"."weight"%TYPE
jbe@0 4060 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4061 DECLARE
jbe@0 4062 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 4063 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 4064 "weight_v" INT4;
jbe@8 4065 "sub_weight_v" INT4;
jbe@0 4066 BEGIN
jbe@336 4067 PERFORM "require_transaction_isolation"();
jbe@0 4068 "weight_v" := 0;
jbe@0 4069 FOR "issue_delegation_row" IN
jbe@0 4070 SELECT * FROM "issue_delegation"
jbe@0 4071 WHERE "trustee_id" = "member_id_p"
jbe@0 4072 AND "issue_id" = "issue_id_p"
jbe@0 4073 LOOP
jbe@0 4074 IF NOT EXISTS (
jbe@0 4075 SELECT NULL FROM "direct_voter"
jbe@0 4076 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4077 AND "issue_id" = "issue_id_p"
jbe@0 4078 ) AND NOT EXISTS (
jbe@0 4079 SELECT NULL FROM "delegating_voter"
jbe@0 4080 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4081 AND "issue_id" = "issue_id_p"
jbe@0 4082 ) THEN
jbe@0 4083 "delegate_member_ids_v" :=
jbe@0 4084 "member_id_p" || "delegate_member_ids_p";
jbe@10 4085 INSERT INTO "delegating_voter" (
jbe@10 4086 "issue_id",
jbe@10 4087 "member_id",
jbe@10 4088 "scope",
jbe@10 4089 "delegate_member_ids"
jbe@10 4090 ) VALUES (
jbe@5 4091 "issue_id_p",
jbe@5 4092 "issue_delegation_row"."truster_id",
jbe@10 4093 "issue_delegation_row"."scope",
jbe@5 4094 "delegate_member_ids_v"
jbe@5 4095 );
jbe@8 4096 "sub_weight_v" := 1 +
jbe@8 4097 "weight_of_added_vote_delegations"(
jbe@8 4098 "issue_id_p",
jbe@8 4099 "issue_delegation_row"."truster_id",
jbe@8 4100 "delegate_member_ids_v"
jbe@8 4101 );
jbe@8 4102 UPDATE "delegating_voter"
jbe@8 4103 SET "weight" = "sub_weight_v"
jbe@8 4104 WHERE "issue_id" = "issue_id_p"
jbe@8 4105 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 4106 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 4107 END IF;
jbe@0 4108 END LOOP;
jbe@0 4109 RETURN "weight_v";
jbe@0 4110 END;
jbe@0 4111 $$;
jbe@0 4112
jbe@5 4113 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 4114 ( "issue"."id"%TYPE,
jbe@0 4115 "member"."id"%TYPE,
jbe@0 4116 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 4117 IS 'Helper function for "add_vote_delegations" function';
jbe@0 4118
jbe@0 4119
jbe@0 4120 CREATE FUNCTION "add_vote_delegations"
jbe@0 4121 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4122 RETURNS VOID
jbe@0 4123 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4124 DECLARE
jbe@0 4125 "member_id_v" "member"."id"%TYPE;
jbe@0 4126 BEGIN
jbe@336 4127 PERFORM "require_transaction_isolation"();
jbe@0 4128 FOR "member_id_v" IN
jbe@0 4129 SELECT "member_id" FROM "direct_voter"
jbe@0 4130 WHERE "issue_id" = "issue_id_p"
jbe@0 4131 LOOP
jbe@0 4132 UPDATE "direct_voter" SET
jbe@5 4133 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 4134 "issue_id_p",
jbe@0 4135 "member_id_v",
jbe@0 4136 '{}'
jbe@0 4137 )
jbe@0 4138 WHERE "member_id" = "member_id_v"
jbe@0 4139 AND "issue_id" = "issue_id_p";
jbe@0 4140 END LOOP;
jbe@0 4141 RETURN;
jbe@0 4142 END;
jbe@0 4143 $$;
jbe@0 4144
jbe@0 4145 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 4146 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4147 IS 'Helper function for "close_voting" function';
jbe@0 4148
jbe@0 4149
jbe@0 4150 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 4151 RETURNS VOID
jbe@0 4152 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4153 DECLARE
jbe@97 4154 "area_id_v" "area"."id"%TYPE;
jbe@97 4155 "unit_id_v" "unit"."id"%TYPE;
jbe@0 4156 "member_id_v" "member"."id"%TYPE;
jbe@0 4157 BEGIN
jbe@333 4158 PERFORM "require_transaction_isolation"();
jbe@129 4159 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 4160 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@383 4161 -- override protection triggers:
jbe@385 4162 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 4163 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@285 4164 -- delete timestamp of voting comment:
jbe@285 4165 UPDATE "direct_voter" SET "comment_changed" = NULL
jbe@285 4166 WHERE "issue_id" = "issue_id_p";
jbe@169 4167 -- delete delegating votes (in cases of manual reset of issue state):
jbe@0 4168 DELETE FROM "delegating_voter"
jbe@0 4169 WHERE "issue_id" = "issue_id_p";
jbe@169 4170 -- delete votes from non-privileged voters:
jbe@97 4171 DELETE FROM "direct_voter"
jbe@97 4172 USING (
jbe@97 4173 SELECT
jbe@97 4174 "direct_voter"."member_id"
jbe@97 4175 FROM "direct_voter"
jbe@97 4176 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@97 4177 LEFT JOIN "privilege"
jbe@97 4178 ON "privilege"."unit_id" = "unit_id_v"
jbe@97 4179 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 4180 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 4181 "member"."active" = FALSE OR
jbe@97 4182 "privilege"."voting_right" ISNULL OR
jbe@97 4183 "privilege"."voting_right" = FALSE
jbe@97 4184 )
jbe@97 4185 ) AS "subquery"
jbe@97 4186 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 4187 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@169 4188 -- consider delegations:
jbe@0 4189 UPDATE "direct_voter" SET "weight" = 1
jbe@0 4190 WHERE "issue_id" = "issue_id_p";
jbe@0 4191 PERFORM "add_vote_delegations"("issue_id_p");
jbe@414 4192 -- mark first preferences:
jbe@414 4193 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
jbe@414 4194 FROM (
jbe@414 4195 SELECT
jbe@414 4196 "vote"."initiative_id",
jbe@414 4197 "vote"."member_id",
jbe@414 4198 CASE WHEN "vote"."grade" > 0 THEN
jbe@414 4199 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
jbe@414 4200 ELSE NULL
jbe@414 4201 END AS "first_preference"
jbe@415 4202 FROM "vote"
jbe@415 4203 JOIN "initiative" -- NOTE: due to missing index on issue_id
jbe@415 4204 ON "vote"."issue_id" = "initiative"."issue_id"
jbe@415 4205 JOIN "vote" AS "agg"
jbe@415 4206 ON "initiative"."id" = "agg"."initiative_id"
jbe@415 4207 AND "vote"."member_id" = "agg"."member_id"
jbe@433 4208 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
jbe@414 4209 ) AS "subquery"
jbe@414 4210 WHERE "vote"."issue_id" = "issue_id_p"
jbe@414 4211 AND "vote"."initiative_id" = "subquery"."initiative_id"
jbe@414 4212 AND "vote"."member_id" = "subquery"."member_id";
jbe@385 4213 -- finish overriding protection triggers (avoids garbage):
jbe@385 4214 DELETE FROM "temporary_transaction_data"
jbe@385 4215 WHERE "key" = 'override_protection_triggers';
jbe@137 4216 -- materialize battle_view:
jbe@61 4217 -- NOTE: "closed" column of issue must be set at this point
jbe@61 4218 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 4219 INSERT INTO "battle" (
jbe@61 4220 "issue_id",
jbe@61 4221 "winning_initiative_id", "losing_initiative_id",
jbe@61 4222 "count"
jbe@61 4223 ) SELECT
jbe@61 4224 "issue_id",
jbe@61 4225 "winning_initiative_id", "losing_initiative_id",
jbe@61 4226 "count"
jbe@61 4227 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@331 4228 -- set voter count:
jbe@331 4229 UPDATE "issue" SET
jbe@331 4230 "voter_count" = (
jbe@331 4231 SELECT coalesce(sum("weight"), 0)
jbe@331 4232 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@331 4233 )
jbe@331 4234 WHERE "id" = "issue_id_p";
jbe@437 4235 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@437 4236 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
jbe@437 4237 UPDATE "initiative" SET
jbe@437 4238 "first_preference_votes" = 0,
jbe@437 4239 "positive_votes" = "battle_win"."count",
jbe@437 4240 "negative_votes" = "battle_lose"."count"
jbe@437 4241 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@437 4242 WHERE
jbe@437 4243 "battle_win"."issue_id" = "issue_id_p" AND
jbe@437 4244 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@437 4245 "battle_win"."losing_initiative_id" ISNULL AND
jbe@437 4246 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@437 4247 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@437 4248 "battle_lose"."winning_initiative_id" ISNULL;
jbe@414 4249 -- calculate "first_preference_votes":
jbe@437 4250 -- NOTE: will only set values not equal to zero
jbe@437 4251 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
jbe@414 4252 FROM (
jbe@414 4253 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
jbe@414 4254 FROM "vote" JOIN "direct_voter"
jbe@414 4255 ON "vote"."issue_id" = "direct_voter"."issue_id"
jbe@414 4256 AND "vote"."member_id" = "direct_voter"."member_id"
jbe@414 4257 WHERE "vote"."first_preference"
jbe@414 4258 GROUP BY "vote"."initiative_id"
jbe@414 4259 ) AS "subquery"
jbe@414 4260 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@414 4261 AND "initiative"."admitted"
jbe@414 4262 AND "initiative"."id" = "subquery"."initiative_id";
jbe@0 4263 END;
jbe@0 4264 $$;
jbe@0 4265
jbe@0 4266 COMMENT ON FUNCTION "close_voting"
jbe@0 4267 ( "issue"."id"%TYPE )
jbe@0 4268 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 4269
jbe@0 4270
jbe@30 4271 CREATE FUNCTION "defeat_strength"
jbe@424 4272 ( "positive_votes_p" INT4,
jbe@424 4273 "negative_votes_p" INT4,
jbe@424 4274 "defeat_strength_p" "defeat_strength" )
jbe@30 4275 RETURNS INT8
jbe@30 4276 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 4277 BEGIN
jbe@424 4278 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
jbe@424 4279 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 4280 RETURN "positive_votes_p";
jbe@424 4281 ELSE
jbe@424 4282 RETURN 0;
jbe@424 4283 END IF;
jbe@30 4284 ELSE
jbe@424 4285 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 4286 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@424 4287 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@424 4288 RETURN 0;
jbe@424 4289 ELSE
jbe@424 4290 RETURN -1;
jbe@424 4291 END IF;
jbe@30 4292 END IF;
jbe@30 4293 END;
jbe@30 4294 $$;
jbe@30 4295
jbe@425 4296 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 4297
jbe@30 4298
jbe@423 4299 CREATE FUNCTION "secondary_link_strength"
jbe@426 4300 ( "initiative1_ord_p" INT4,
jbe@426 4301 "initiative2_ord_p" INT4,
jbe@424 4302 "tie_breaking_p" "tie_breaking" )
jbe@423 4303 RETURNS INT8
jbe@423 4304 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@423 4305 BEGIN
jbe@426 4306 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
jbe@423 4307 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
jbe@423 4308 END IF;
jbe@423 4309 RETURN (
jbe@426 4310 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
jbe@426 4311 0
jbe@424 4312 ELSE
jbe@426 4313 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
jbe@426 4314 1::INT8 << 62
jbe@426 4315 ELSE 0 END
jbe@426 4316 +
jbe@426 4317 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
jbe@426 4318 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
jbe@426 4319 ELSE
jbe@426 4320 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
jbe@426 4321 END
jbe@424 4322 END
jbe@423 4323 );
jbe@423 4324 END;
jbe@423 4325 $$;
jbe@423 4326
jbe@424 4327 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 4328
jbe@423 4329
jbe@426 4330 CREATE TYPE "link_strength" AS (
jbe@426 4331 "primary" INT8,
jbe@426 4332 "secondary" INT8 );
jbe@426 4333
jbe@428 4334 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 4335
jbe@427 4336
jbe@427 4337 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
jbe@427 4338 RETURNS "link_strength"[][]
jbe@427 4339 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@427 4340 DECLARE
jbe@427 4341 "dimension_v" INT4;
jbe@427 4342 "matrix_p" "link_strength"[][];
jbe@427 4343 "i" INT4;
jbe@427 4344 "j" INT4;
jbe@427 4345 "k" INT4;
jbe@427 4346 BEGIN
jbe@427 4347 "dimension_v" := array_upper("matrix_d", 1);
jbe@427 4348 "matrix_p" := "matrix_d";
jbe@427 4349 "i" := 1;
jbe@427 4350 LOOP
jbe@427 4351 "j" := 1;
jbe@427 4352 LOOP
jbe@427 4353 IF "i" != "j" THEN
jbe@427 4354 "k" := 1;
jbe@427 4355 LOOP
jbe@427 4356 IF "i" != "k" AND "j" != "k" THEN
jbe@427 4357 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
jbe@427 4358 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
jbe@427 4359 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
jbe@427 4360 END IF;
jbe@427 4361 ELSE
jbe@427 4362 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
jbe@427 4363 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
jbe@427 4364 END IF;
jbe@427 4365 END IF;
jbe@427 4366 END IF;
jbe@427 4367 EXIT WHEN "k" = "dimension_v";
jbe@427 4368 "k" := "k" + 1;
jbe@427 4369 END LOOP;
jbe@427 4370 END IF;
jbe@427 4371 EXIT WHEN "j" = "dimension_v";
jbe@427 4372 "j" := "j" + 1;
jbe@427 4373 END LOOP;
jbe@427 4374 EXIT WHEN "i" = "dimension_v";
jbe@427 4375 "i" := "i" + 1;
jbe@427 4376 END LOOP;
jbe@427 4377 RETURN "matrix_p";
jbe@427 4378 END;
jbe@427 4379 $$;
jbe@427 4380
jbe@428 4381 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
jbe@426 4382
jbe@426 4383
jbe@0 4384 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 4385 RETURNS VOID
jbe@0 4386 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4387 DECLARE
jbe@427 4388 "issue_row" "issue"%ROWTYPE;
jbe@427 4389 "policy_row" "policy"%ROWTYPE;
jbe@427 4390 "dimension_v" INT4;
jbe@427 4391 "matrix_a" INT4[][]; -- absolute votes
jbe@427 4392 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
jbe@427 4393 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
jbe@427 4394 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
jbe@427 4395 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
jbe@427 4396 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
jbe@427 4397 "i" INT4;
jbe@427 4398 "j" INT4;
jbe@427 4399 "m" INT4;
jbe@427 4400 "n" INT4;
jbe@427 4401 "battle_row" "battle"%ROWTYPE;
jbe@427 4402 "rank_ary" INT4[];
jbe@427 4403 "rank_v" INT4;
jbe@427 4404 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 4405 BEGIN
jbe@333 4406 PERFORM "require_transaction_isolation"();
jbe@155 4407 SELECT * INTO "issue_row"
jbe@331 4408 FROM "issue" WHERE "id" = "issue_id_p";
jbe@155 4409 SELECT * INTO "policy_row"
jbe@155 4410 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@126 4411 SELECT count(1) INTO "dimension_v"
jbe@126 4412 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@428 4413 -- create "matrix_a" with absolute number of votes in pairwise
jbe@170 4414 -- comparison:
jbe@427 4415 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4416 "i" := 1;
jbe@170 4417 "j" := 2;
jbe@170 4418 FOR "battle_row" IN
jbe@170 4419 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@170 4420 ORDER BY
jbe@411 4421 "winning_initiative_id" NULLS FIRST,
jbe@411 4422 "losing_initiative_id" NULLS FIRST
jbe@170 4423 LOOP
jbe@427 4424 "matrix_a"["i"]["j"] := "battle_row"."count";
jbe@170 4425 IF "j" = "dimension_v" THEN
jbe@170 4426 "i" := "i" + 1;
jbe@170 4427 "j" := 1;
jbe@170 4428 ELSE
jbe@170 4429 "j" := "j" + 1;
jbe@170 4430 IF "j" = "i" THEN
jbe@170 4431 "j" := "j" + 1;
jbe@170 4432 END IF;
jbe@170 4433 END IF;
jbe@170 4434 END LOOP;
jbe@170 4435 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@170 4436 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@170 4437 END IF;
jbe@428 4438 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
jbe@427 4439 -- and "secondary_link_strength" functions:
jbe@427 4440 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4441 "i" := 1;
jbe@170 4442 LOOP
jbe@170 4443 "j" := 1;
jbe@0 4444 LOOP
jbe@170 4445 IF "i" != "j" THEN
jbe@427 4446 "matrix_d"["i"]["j"] := (
jbe@426 4447 "defeat_strength"(
jbe@427 4448 "matrix_a"["i"]["j"],
jbe@427 4449 "matrix_a"["j"]["i"],
jbe@426 4450 "policy_row"."defeat_strength"
jbe@426 4451 ),
jbe@426 4452 "secondary_link_strength"(
jbe@426 4453 "i",
jbe@426 4454 "j",
jbe@426 4455 "policy_row"."tie_breaking"
jbe@426 4456 )
jbe@426 4457 )::"link_strength";
jbe@0 4458 END IF;
jbe@170 4459 EXIT WHEN "j" = "dimension_v";
jbe@170 4460 "j" := "j" + 1;
jbe@0 4461 END LOOP;
jbe@170 4462 EXIT WHEN "i" = "dimension_v";
jbe@170 4463 "i" := "i" + 1;
jbe@170 4464 END LOOP;
jbe@428 4465 -- find best paths:
jbe@427 4466 "matrix_p" := "find_best_paths"("matrix_d");
jbe@428 4467 -- create partial order:
jbe@427 4468 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4469 "i" := 1;
jbe@170 4470 LOOP
jbe@427 4471 "j" := "i" + 1;
jbe@170 4472 LOOP
jbe@170 4473 IF "i" != "j" THEN
jbe@427 4474 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
jbe@427 4475 "matrix_b"["i"]["j"] := TRUE;
jbe@427 4476 "matrix_b"["j"]["i"] := FALSE;
jbe@427 4477 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
jbe@427 4478 "matrix_b"["i"]["j"] := FALSE;
jbe@427 4479 "matrix_b"["j"]["i"] := TRUE;
jbe@427 4480 END IF;
jbe@170 4481 END IF;
jbe@170 4482 EXIT WHEN "j" = "dimension_v";
jbe@170 4483 "j" := "j" + 1;
jbe@170 4484 END LOOP;
jbe@427 4485 EXIT WHEN "i" = "dimension_v" - 1;
jbe@170 4486 "i" := "i" + 1;
jbe@170 4487 END LOOP;
jbe@428 4488 -- tie-breaking by forbidding shared weakest links in beat-paths
jbe@428 4489 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
jbe@428 4490 -- is performed later by initiative id):
jbe@427 4491 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
jbe@427 4492 "m" := 1;
jbe@427 4493 LOOP
jbe@427 4494 "n" := "m" + 1;
jbe@427 4495 LOOP
jbe@428 4496 -- only process those candidates m and n, which are tied:
jbe@427 4497 IF "matrix_b"["m"]["n"] ISNULL THEN
jbe@428 4498 -- start with beat-paths prior tie-breaking:
jbe@427 4499 "matrix_t" := "matrix_p";
jbe@428 4500 -- start with all links allowed:
jbe@427 4501 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
jbe@427 4502 LOOP
jbe@428 4503 -- determine (and forbid) that link that is the weakest link
jbe@428 4504 -- in both the best path from candidate m to candidate n and
jbe@428 4505 -- from candidate n to candidate m:
jbe@427 4506 "i" := 1;
jbe@427 4507 <<forbid_one_link>>
jbe@427 4508 LOOP
jbe@427 4509 "j" := 1;
jbe@427 4510 LOOP
jbe@427 4511 IF "i" != "j" THEN
jbe@427 4512 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
jbe@427 4513 "matrix_f"["i"]["j"] := TRUE;
jbe@427 4514 -- exit for performance reasons,
jbe@428 4515 -- as exactly one link will be found:
jbe@427 4516 EXIT forbid_one_link;
jbe@427 4517 END IF;
jbe@427 4518 END IF;
jbe@427 4519 EXIT WHEN "j" = "dimension_v";
jbe@427 4520 "j" := "j" + 1;
jbe@427 4521 END LOOP;
jbe@427 4522 IF "i" = "dimension_v" THEN
jbe@428 4523 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
jbe@427 4524 END IF;
jbe@427 4525 "i" := "i" + 1;
jbe@427 4526 END LOOP;
jbe@428 4527 -- calculate best beat-paths while ignoring forbidden links:
jbe@427 4528 "i" := 1;
jbe@427 4529 LOOP
jbe@427 4530 "j" := 1;
jbe@427 4531 LOOP
jbe@427 4532 IF "i" != "j" THEN
jbe@427 4533 "matrix_t"["i"]["j"] := CASE
jbe@427 4534 WHEN "matrix_f"["i"]["j"]
jbe@431 4535 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
jbe@427 4536 ELSE "matrix_d"["i"]["j"] END;
jbe@427 4537 END IF;
jbe@427 4538 EXIT WHEN "j" = "dimension_v";
jbe@427 4539 "j" := "j" + 1;
jbe@427 4540 END LOOP;
jbe@427 4541 EXIT WHEN "i" = "dimension_v";
jbe@427 4542 "i" := "i" + 1;
jbe@427 4543 END LOOP;
jbe@427 4544 "matrix_t" := "find_best_paths"("matrix_t");
jbe@428 4545 -- extend partial order, if tie-breaking was successful:
jbe@427 4546 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
jbe@427 4547 "matrix_b"["m"]["n"] := TRUE;
jbe@427 4548 "matrix_b"["n"]["m"] := FALSE;
jbe@427 4549 EXIT;
jbe@427 4550 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
jbe@427 4551 "matrix_b"["m"]["n"] := FALSE;
jbe@427 4552 "matrix_b"["n"]["m"] := TRUE;
jbe@427 4553 EXIT;
jbe@427 4554 END IF;
jbe@427 4555 END LOOP;
jbe@427 4556 END IF;
jbe@427 4557 EXIT WHEN "n" = "dimension_v";
jbe@427 4558 "n" := "n" + 1;
jbe@427 4559 END LOOP;
jbe@427 4560 EXIT WHEN "m" = "dimension_v" - 1;
jbe@427 4561 "m" := "m" + 1;
jbe@427 4562 END LOOP;
jbe@427 4563 END IF;
jbe@428 4564 -- store a unique ranking in "rank_ary":
jbe@170 4565 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@170 4566 "rank_v" := 1;
jbe@170 4567 LOOP
jbe@0 4568 "i" := 1;
jbe@428 4569 <<assign_next_rank>>
jbe@0 4570 LOOP
jbe@170 4571 IF "rank_ary"["i"] ISNULL THEN
jbe@170 4572 "j" := 1;
jbe@170 4573 LOOP
jbe@170 4574 IF
jbe@170 4575 "i" != "j" AND
jbe@170 4576 "rank_ary"["j"] ISNULL AND
jbe@427 4577 ( "matrix_b"["j"]["i"] OR
jbe@411 4578 -- tie-breaking by "id"
jbe@427 4579 ( "matrix_b"["j"]["i"] ISNULL AND
jbe@411 4580 "j" < "i" ) )
jbe@170 4581 THEN
jbe@170 4582 -- someone else is better
jbe@170 4583 EXIT;
jbe@170 4584 END IF;
jbe@428 4585 IF "j" = "dimension_v" THEN
jbe@170 4586 -- noone is better
jbe@411 4587 "rank_ary"["i"] := "rank_v";
jbe@428 4588 EXIT assign_next_rank;
jbe@170 4589 END IF;
jbe@428 4590 "j" := "j" + 1;
jbe@170 4591 END LOOP;
jbe@170 4592 END IF;
jbe@0 4593 "i" := "i" + 1;
jbe@411 4594 IF "i" > "dimension_v" THEN
jbe@411 4595 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
jbe@411 4596 END IF;
jbe@0 4597 END LOOP;
jbe@411 4598 EXIT WHEN "rank_v" = "dimension_v";
jbe@170 4599 "rank_v" := "rank_v" + 1;
jbe@170 4600 END LOOP;
jbe@170 4601 -- write preliminary results:
jbe@411 4602 "i" := 2; -- omit status quo with "i" = 1
jbe@170 4603 FOR "initiative_id_v" IN
jbe@170 4604 SELECT "id" FROM "initiative"
jbe@170 4605 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@170 4606 ORDER BY "id"
jbe@170 4607 LOOP
jbe@170 4608 UPDATE "initiative" SET
jbe@170 4609 "direct_majority" =
jbe@170 4610 CASE WHEN "policy_row"."direct_majority_strict" THEN
jbe@170 4611 "positive_votes" * "policy_row"."direct_majority_den" >
jbe@170 4612 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4613 ELSE
jbe@170 4614 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@170 4615 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4616 END
jbe@170 4617 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@170 4618 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4619 "policy_row"."direct_majority_non_negative",
jbe@170 4620 "indirect_majority" =
jbe@170 4621 CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4622 "positive_votes" * "policy_row"."indirect_majority_den" >
jbe@170 4623 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4624 ELSE
jbe@170 4625 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@170 4626 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4627 END
jbe@170 4628 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@170 4629 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4630 "policy_row"."indirect_majority_non_negative",
jbe@171 4631 "schulze_rank" = "rank_ary"["i"],
jbe@411 4632 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
jbe@411 4633 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
jbe@411 4634 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
jbe@429 4635 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
jbe@429 4636 THEN NULL
jbe@429 4637 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
jbe@216 4638 "eligible" = FALSE,
jbe@250 4639 "winner" = FALSE,
jbe@250 4640 "rank" = NULL -- NOTE: in cases of manual reset of issue state
jbe@170 4641 WHERE "id" = "initiative_id_v";
jbe@170 4642 "i" := "i" + 1;
jbe@170 4643 END LOOP;
jbe@411 4644 IF "i" != "dimension_v" + 1 THEN
jbe@170 4645 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 4646 END IF;
jbe@170 4647 -- take indirect majorities into account:
jbe@170 4648 LOOP
jbe@170 4649 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@139 4650 FROM (
jbe@170 4651 SELECT "new_initiative"."id" AS "initiative_id"
jbe@170 4652 FROM "initiative" "old_initiative"
jbe@170 4653 JOIN "initiative" "new_initiative"
jbe@170 4654 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@170 4655 AND "new_initiative"."indirect_majority" = FALSE
jbe@139 4656 JOIN "battle" "battle_win"
jbe@139 4657 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4658 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@170 4659 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@139 4660 JOIN "battle" "battle_lose"
jbe@139 4661 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4662 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@170 4663 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@170 4664 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@170 4665 AND "old_initiative"."indirect_majority" = TRUE
jbe@170 4666 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4667 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@170 4668 "policy_row"."indirect_majority_num" *
jbe@170 4669 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4670 ELSE
jbe@170 4671 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@170 4672 "policy_row"."indirect_majority_num" *
jbe@170 4673 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4674 END
jbe@170 4675 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@170 4676 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@170 4677 "policy_row"."indirect_majority_non_negative"
jbe@139 4678 ) AS "subquery"
jbe@139 4679 WHERE "id" = "subquery"."initiative_id";
jbe@170 4680 EXIT WHEN NOT FOUND;
jbe@170 4681 END LOOP;
jbe@170 4682 -- set "multistage_majority" for remaining matching initiatives:
jbe@216 4683 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@170 4684 FROM (
jbe@170 4685 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@170 4686 FROM "initiative" "losing_initiative"
jbe@170 4687 JOIN "initiative" "winning_initiative"
jbe@170 4688 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@170 4689 AND "winning_initiative"."admitted"
jbe@170 4690 JOIN "battle" "battle_win"
jbe@170 4691 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4692 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@170 4693 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@170 4694 JOIN "battle" "battle_lose"
jbe@170 4695 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4696 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@170 4697 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@170 4698 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@170 4699 AND "losing_initiative"."admitted"
jbe@170 4700 AND "winning_initiative"."schulze_rank" <
jbe@170 4701 "losing_initiative"."schulze_rank"
jbe@170 4702 AND "battle_win"."count" > "battle_lose"."count"
jbe@170 4703 AND (
jbe@170 4704 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@170 4705 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@170 4706 ) AS "subquery"
jbe@170 4707 WHERE "id" = "subquery"."initiative_id";
jbe@170 4708 -- mark eligible initiatives:
jbe@170 4709 UPDATE "initiative" SET "eligible" = TRUE
jbe@171 4710 WHERE "issue_id" = "issue_id_p"
jbe@171 4711 AND "initiative"."direct_majority"
jbe@171 4712 AND "initiative"."indirect_majority"
jbe@171 4713 AND "initiative"."better_than_status_quo"
jbe@171 4714 AND (
jbe@171 4715 "policy_row"."no_multistage_majority" = FALSE OR
jbe@429 4716 "initiative"."multistage_majority" = FALSE )
jbe@429 4717 AND (
jbe@429 4718 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@429 4719 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
jbe@170 4720 -- mark final winner:
jbe@170 4721 UPDATE "initiative" SET "winner" = TRUE
jbe@170 4722 FROM (
jbe@170 4723 SELECT "id" AS "initiative_id"
jbe@170 4724 FROM "initiative"
jbe@170 4725 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@217 4726 ORDER BY
jbe@217 4727 "schulze_rank",
jbe@217 4728 "id"
jbe@170 4729 LIMIT 1
jbe@170 4730 ) AS "subquery"
jbe@170 4731 WHERE "id" = "subquery"."initiative_id";
jbe@173 4732 -- write (final) ranks:
jbe@173 4733 "rank_v" := 1;
jbe@173 4734 FOR "initiative_id_v" IN
jbe@173 4735 SELECT "id"
jbe@173 4736 FROM "initiative"
jbe@173 4737 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@174 4738 ORDER BY
jbe@174 4739 "winner" DESC,
jbe@217 4740 "eligible" DESC,
jbe@174 4741 "schulze_rank",
jbe@174 4742 "id"
jbe@173 4743 LOOP
jbe@173 4744 UPDATE "initiative" SET "rank" = "rank_v"
jbe@173 4745 WHERE "id" = "initiative_id_v";
jbe@173 4746 "rank_v" := "rank_v" + 1;
jbe@173 4747 END LOOP;
jbe@170 4748 -- set schulze rank of status quo and mark issue as finished:
jbe@111 4749 UPDATE "issue" SET
jbe@411 4750 "status_quo_schulze_rank" = "rank_ary"[1],
jbe@111 4751 "state" =
jbe@139 4752 CASE WHEN EXISTS (
jbe@139 4753 SELECT NULL FROM "initiative"
jbe@139 4754 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@139 4755 ) THEN
jbe@139 4756 'finished_with_winner'::"issue_state"
jbe@139 4757 ELSE
jbe@121 4758 'finished_without_winner'::"issue_state"
jbe@111 4759 END,
jbe@331 4760 "closed" = "phase_finished",
jbe@331 4761 "phase_finished" = NULL
jbe@0 4762 WHERE "id" = "issue_id_p";
jbe@0 4763 RETURN;
jbe@0 4764 END;
jbe@0 4765 $$;
jbe@0 4766
jbe@0 4767 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 4768 ( "issue"."id"%TYPE )
jbe@0 4769 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 4770
jbe@0 4771
jbe@0 4772
jbe@0 4773 -----------------------------
jbe@0 4774 -- Automatic state changes --
jbe@0 4775 -----------------------------
jbe@0 4776
jbe@0 4777
jbe@331 4778 CREATE TYPE "check_issue_persistence" AS (
jbe@331 4779 "state" "issue_state",
jbe@331 4780 "phase_finished" BOOLEAN,
jbe@331 4781 "issue_revoked" BOOLEAN,
jbe@331 4782 "snapshot_created" BOOLEAN,
jbe@331 4783 "harmonic_weights_set" BOOLEAN,
jbe@331 4784 "closed_voting" BOOLEAN );
jbe@331 4785
jbe@336 4786 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 4787
jbe@336 4788
jbe@0 4789 CREATE FUNCTION "check_issue"
jbe@331 4790 ( "issue_id_p" "issue"."id"%TYPE,
jbe@331 4791 "persist" "check_issue_persistence" )
jbe@331 4792 RETURNS "check_issue_persistence"
jbe@0 4793 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4794 DECLARE
jbe@336 4795 "issue_row" "issue"%ROWTYPE;
jbe@336 4796 "policy_row" "policy"%ROWTYPE;
jbe@336 4797 "initiative_row" "initiative"%ROWTYPE;
jbe@336 4798 "state_v" "issue_state";
jbe@0 4799 BEGIN
jbe@333 4800 PERFORM "require_transaction_isolation"();
jbe@331 4801 IF "persist" ISNULL THEN
jbe@331 4802 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@331 4803 FOR UPDATE;
jbe@331 4804 IF "issue_row"."closed" NOTNULL THEN
jbe@331 4805 RETURN NULL;
jbe@0 4806 END IF;
jbe@331 4807 "persist"."state" := "issue_row"."state";
jbe@331 4808 IF
jbe@331 4809 ( "issue_row"."state" = 'admission' AND now() >=
jbe@447 4810 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
jbe@331 4811 ( "issue_row"."state" = 'discussion' AND now() >=
jbe@331 4812 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
jbe@331 4813 ( "issue_row"."state" = 'verification' AND now() >=
jbe@331 4814 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
jbe@331 4815 ( "issue_row"."state" = 'voting' AND now() >=
jbe@331 4816 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
jbe@331 4817 THEN
jbe@331 4818 "persist"."phase_finished" := TRUE;
jbe@331 4819 ELSE
jbe@331 4820 "persist"."phase_finished" := FALSE;
jbe@0 4821 END IF;
jbe@0 4822 IF
jbe@24 4823 NOT EXISTS (
jbe@24 4824 -- all initiatives are revoked
jbe@24 4825 SELECT NULL FROM "initiative"
jbe@24 4826 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 4827 ) AND (
jbe@111 4828 -- and issue has not been accepted yet
jbe@331 4829 "persist"."state" = 'admission' OR
jbe@331 4830 -- or verification time has elapsed
jbe@331 4831 ( "persist"."state" = 'verification' AND
jbe@331 4832 "persist"."phase_finished" ) OR
jbe@331 4833 -- or no initiatives have been revoked lately
jbe@24 4834 NOT EXISTS (
jbe@24 4835 SELECT NULL FROM "initiative"
jbe@24 4836 WHERE "issue_id" = "issue_id_p"
jbe@24 4837 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 4838 )
jbe@24 4839 )
jbe@24 4840 THEN
jbe@331 4841 "persist"."issue_revoked" := TRUE;
jbe@331 4842 ELSE
jbe@331 4843 "persist"."issue_revoked" := FALSE;
jbe@24 4844 END IF;
jbe@331 4845 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
jbe@331 4846 UPDATE "issue" SET "phase_finished" = now()
jbe@331 4847 WHERE "id" = "issue_row"."id";
jbe@331 4848 RETURN "persist";
jbe@331 4849 ELSIF
jbe@331 4850 "persist"."state" IN ('admission', 'discussion', 'verification')
jbe@3 4851 THEN
jbe@331 4852 RETURN "persist";
jbe@331 4853 ELSE
jbe@331 4854 RETURN NULL;
jbe@322 4855 END IF;
jbe@0 4856 END IF;
jbe@331 4857 IF
jbe@331 4858 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 4859 coalesce("persist"."snapshot_created", FALSE) = FALSE
jbe@331 4860 THEN
jbe@331 4861 PERFORM "create_snapshot"("issue_id_p");
jbe@331 4862 "persist"."snapshot_created" = TRUE;
jbe@331 4863 IF "persist"."phase_finished" THEN
jbe@331 4864 IF "persist"."state" = 'admission' THEN
jbe@331 4865 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@331 4866 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 4867 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@331 4868 ELSIF "persist"."state" = 'verification' THEN
jbe@331 4869 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@336 4870 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@336 4871 SELECT * INTO "policy_row" FROM "policy"
jbe@336 4872 WHERE "id" = "issue_row"."policy_id";
jbe@336 4873 FOR "initiative_row" IN
jbe@336 4874 SELECT * FROM "initiative"
jbe@336 4875 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@336 4876 FOR UPDATE
jbe@336 4877 LOOP
jbe@336 4878 IF
jbe@336 4879 "initiative_row"."polling" OR (
jbe@336 4880 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@336 4881 "initiative_row"."satisfied_supporter_count" *
jbe@336 4882 "policy_row"."initiative_quorum_den" >=
jbe@336 4883 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@336 4884 )
jbe@336 4885 THEN
jbe@336 4886 UPDATE "initiative" SET "admitted" = TRUE
jbe@336 4887 WHERE "id" = "initiative_row"."id";
jbe@336 4888 ELSE
jbe@336 4889 UPDATE "initiative" SET "admitted" = FALSE
jbe@336 4890 WHERE "id" = "initiative_row"."id";
jbe@336 4891 END IF;
jbe@336 4892 END LOOP;
jbe@331 4893 END IF;
jbe@331 4894 END IF;
jbe@331 4895 RETURN "persist";
jbe@331 4896 END IF;
jbe@331 4897 IF
jbe@331 4898 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 4899 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
jbe@331 4900 THEN
jbe@331 4901 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@331 4902 "persist"."harmonic_weights_set" = TRUE;
jbe@332 4903 IF
jbe@332 4904 "persist"."phase_finished" OR
jbe@332 4905 "persist"."issue_revoked" OR
jbe@332 4906 "persist"."state" = 'admission'
jbe@332 4907 THEN
jbe@331 4908 RETURN "persist";
jbe@331 4909 ELSE
jbe@331 4910 RETURN NULL;
jbe@331 4911 END IF;
jbe@331 4912 END IF;
jbe@331 4913 IF "persist"."issue_revoked" THEN
jbe@331 4914 IF "persist"."state" = 'admission' THEN
jbe@331 4915 "state_v" := 'canceled_revoked_before_accepted';
jbe@331 4916 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 4917 "state_v" := 'canceled_after_revocation_during_discussion';
jbe@331 4918 ELSIF "persist"."state" = 'verification' THEN
jbe@331 4919 "state_v" := 'canceled_after_revocation_during_verification';
jbe@331 4920 END IF;
jbe@331 4921 UPDATE "issue" SET
jbe@331 4922 "state" = "state_v",
jbe@331 4923 "closed" = "phase_finished",
jbe@331 4924 "phase_finished" = NULL
jbe@332 4925 WHERE "id" = "issue_id_p";
jbe@331 4926 RETURN NULL;
jbe@331 4927 END IF;
jbe@331 4928 IF "persist"."state" = 'admission' THEN
jbe@336 4929 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 4930 FOR UPDATE;
jbe@336 4931 SELECT * INTO "policy_row"
jbe@336 4932 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@447 4933 IF
jbe@447 4934 ( now() >=
jbe@447 4935 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
jbe@447 4936 EXISTS (
jbe@447 4937 SELECT NULL FROM "initiative"
jbe@447 4938 WHERE "issue_id" = "issue_id_p"
jbe@447 4939 AND "supporter_count" > 0
jbe@447 4940 AND "supporter_count" * "policy_row"."issue_quorum_den"
jbe@447 4941 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
jbe@447 4942 )
jbe@447 4943 THEN
jbe@336 4944 UPDATE "issue" SET
jbe@336 4945 "state" = 'discussion',
jbe@336 4946 "accepted" = coalesce("phase_finished", now()),
jbe@336 4947 "phase_finished" = NULL
jbe@336 4948 WHERE "id" = "issue_id_p";
jbe@336 4949 ELSIF "issue_row"."phase_finished" NOTNULL THEN
jbe@336 4950 UPDATE "issue" SET
jbe@336 4951 "state" = 'canceled_issue_not_accepted',
jbe@336 4952 "closed" = "phase_finished",
jbe@336 4953 "phase_finished" = NULL
jbe@336 4954 WHERE "id" = "issue_id_p";
jbe@336 4955 END IF;
jbe@331 4956 RETURN NULL;
jbe@331 4957 END IF;
jbe@332 4958 IF "persist"."phase_finished" THEN
jbe@443 4959 IF "persist"."state" = 'discussion' THEN
jbe@332 4960 UPDATE "issue" SET
jbe@332 4961 "state" = 'verification',
jbe@332 4962 "half_frozen" = "phase_finished",
jbe@332 4963 "phase_finished" = NULL
jbe@332 4964 WHERE "id" = "issue_id_p";
jbe@332 4965 RETURN NULL;
jbe@332 4966 END IF;
jbe@332 4967 IF "persist"."state" = 'verification' THEN
jbe@336 4968 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 4969 FOR UPDATE;
jbe@336 4970 SELECT * INTO "policy_row" FROM "policy"
jbe@336 4971 WHERE "id" = "issue_row"."policy_id";
jbe@336 4972 IF EXISTS (
jbe@336 4973 SELECT NULL FROM "initiative"
jbe@336 4974 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@336 4975 ) THEN
jbe@336 4976 UPDATE "issue" SET
jbe@343 4977 "state" = 'voting',
jbe@343 4978 "fully_frozen" = "phase_finished",
jbe@336 4979 "phase_finished" = NULL
jbe@336 4980 WHERE "id" = "issue_id_p";
jbe@336 4981 ELSE
jbe@336 4982 UPDATE "issue" SET
jbe@343 4983 "state" = 'canceled_no_initiative_admitted',
jbe@343 4984 "fully_frozen" = "phase_finished",
jbe@343 4985 "closed" = "phase_finished",
jbe@343 4986 "phase_finished" = NULL
jbe@336 4987 WHERE "id" = "issue_id_p";
jbe@336 4988 -- NOTE: The following DELETE statements have effect only when
jbe@336 4989 -- issue state has been manipulated
jbe@336 4990 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 4991 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 4992 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@336 4993 END IF;
jbe@332 4994 RETURN NULL;
jbe@332 4995 END IF;
jbe@332 4996 IF "persist"."state" = 'voting' THEN
jbe@332 4997 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
jbe@332 4998 PERFORM "close_voting"("issue_id_p");
jbe@332 4999 "persist"."closed_voting" = TRUE;
jbe@332 5000 RETURN "persist";
jbe@332 5001 END IF;
jbe@332 5002 PERFORM "calculate_ranks"("issue_id_p");
jbe@332 5003 RETURN NULL;
jbe@332 5004 END IF;
jbe@331 5005 END IF;
jbe@331 5006 RAISE WARNING 'should not happen';
jbe@331 5007 RETURN NULL;
jbe@0 5008 END;
jbe@0 5009 $$;
jbe@0 5010
jbe@0 5011 COMMENT ON FUNCTION "check_issue"
jbe@331 5012 ( "issue"."id"%TYPE,
jbe@331 5013 "check_issue_persistence" )
jbe@336 5014 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 5015
jbe@0 5016
jbe@0 5017 CREATE FUNCTION "check_everything"()
jbe@0 5018 RETURNS VOID
jbe@0 5019 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5020 DECLARE
jbe@0 5021 "issue_id_v" "issue"."id"%TYPE;
jbe@331 5022 "persist_v" "check_issue_persistence";
jbe@0 5023 BEGIN
jbe@333 5024 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
jbe@235 5025 DELETE FROM "expired_session";
jbe@184 5026 PERFORM "check_activity"();
jbe@4 5027 PERFORM "calculate_member_counts"();
jbe@4 5028 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@331 5029 "persist_v" := NULL;
jbe@331 5030 LOOP
jbe@331 5031 "persist_v" := "check_issue"("issue_id_v", "persist_v");
jbe@331 5032 EXIT WHEN "persist_v" ISNULL;
jbe@331 5033 END LOOP;
jbe@0 5034 END LOOP;
jbe@0 5035 RETURN;
jbe@0 5036 END;
jbe@0 5037 $$;
jbe@0 5038
jbe@336 5039 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.';
jbe@0 5040
jbe@0 5041
jbe@0 5042
jbe@59 5043 ----------------------
jbe@59 5044 -- Deletion of data --
jbe@59 5045 ----------------------
jbe@59 5046
jbe@59 5047
jbe@59 5048 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 5049 RETURNS VOID
jbe@59 5050 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 5051 BEGIN
jbe@385 5052 IF EXISTS (
jbe@385 5053 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
jbe@385 5054 ) THEN
jbe@385 5055 -- override protection triggers:
jbe@385 5056 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 5057 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@385 5058 -- clean data:
jbe@59 5059 DELETE FROM "delegating_voter"
jbe@59 5060 WHERE "issue_id" = "issue_id_p";
jbe@59 5061 DELETE FROM "direct_voter"
jbe@59 5062 WHERE "issue_id" = "issue_id_p";
jbe@59 5063 DELETE FROM "delegating_interest_snapshot"
jbe@59 5064 WHERE "issue_id" = "issue_id_p";
jbe@59 5065 DELETE FROM "direct_interest_snapshot"
jbe@59 5066 WHERE "issue_id" = "issue_id_p";
jbe@59 5067 DELETE FROM "delegating_population_snapshot"
jbe@59 5068 WHERE "issue_id" = "issue_id_p";
jbe@59 5069 DELETE FROM "direct_population_snapshot"
jbe@59 5070 WHERE "issue_id" = "issue_id_p";
jbe@113 5071 DELETE FROM "non_voter"
jbe@94 5072 WHERE "issue_id" = "issue_id_p";
jbe@59 5073 DELETE FROM "delegation"
jbe@59 5074 WHERE "issue_id" = "issue_id_p";
jbe@59 5075 DELETE FROM "supporter"
jbe@329 5076 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 5077 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 5078 AND "supporter"."initiative_id" = "initiative_id";
jbe@385 5079 -- mark issue as cleaned:
jbe@385 5080 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
jbe@385 5081 -- finish overriding protection triggers (avoids garbage):
jbe@385 5082 DELETE FROM "temporary_transaction_data"
jbe@385 5083 WHERE "key" = 'override_protection_triggers';
jbe@59 5084 END IF;
jbe@59 5085 RETURN;
jbe@59 5086 END;
jbe@59 5087 $$;
jbe@59 5088
jbe@59 5089 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 5090
jbe@8 5091
jbe@54 5092 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 5093 RETURNS VOID
jbe@8 5094 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 5095 BEGIN
jbe@9 5096 UPDATE "member" SET
jbe@57 5097 "last_login" = NULL,
jbe@387 5098 "last_delegation_check" = NULL,
jbe@45 5099 "login" = NULL,
jbe@11 5100 "password" = NULL,
jbe@441 5101 "authority" = NULL,
jbe@441 5102 "authority_uid" = NULL,
jbe@441 5103 "authority_login" = NULL,
jbe@101 5104 "locked" = TRUE,
jbe@54 5105 "active" = FALSE,
jbe@11 5106 "notify_email" = NULL,
jbe@11 5107 "notify_email_unconfirmed" = NULL,
jbe@11 5108 "notify_email_secret" = NULL,
jbe@11 5109 "notify_email_secret_expiry" = NULL,
jbe@57 5110 "notify_email_lock_expiry" = NULL,
jbe@522 5111 "disable_notifications" = TRUE,
jbe@522 5112 "notification_counter" = DEFAULT,
jbe@522 5113 "notification_sample_size" = 0,
jbe@499 5114 "notification_dow" = NULL,
jbe@499 5115 "notification_hour" = NULL,
jbe@387 5116 "login_recovery_expiry" = NULL,
jbe@11 5117 "password_reset_secret" = NULL,
jbe@11 5118 "password_reset_secret_expiry" = NULL,
jbe@11 5119 "organizational_unit" = NULL,
jbe@11 5120 "internal_posts" = NULL,
jbe@11 5121 "realname" = NULL,
jbe@11 5122 "birthday" = NULL,
jbe@11 5123 "address" = NULL,
jbe@11 5124 "email" = NULL,
jbe@11 5125 "xmpp_address" = NULL,
jbe@11 5126 "website" = NULL,
jbe@11 5127 "phone" = NULL,
jbe@11 5128 "mobile_phone" = NULL,
jbe@11 5129 "profession" = NULL,
jbe@11 5130 "external_memberships" = NULL,
jbe@11 5131 "external_posts" = NULL,
jbe@45 5132 "statement" = NULL
jbe@45 5133 WHERE "id" = "member_id_p";
jbe@11 5134 -- "text_search_data" is updated by triggers
jbe@45 5135 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@45 5136 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@45 5137 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@45 5138 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 5139 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 5140 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@235 5141 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@45 5142 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@45 5143 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@113 5144 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@45 5145 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@45 5146 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@54 5147 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
jbe@54 5148 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 5149 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 5150 DELETE FROM "direct_voter" USING "issue"
jbe@57 5151 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 5152 AND "issue"."closed" ISNULL
jbe@57 5153 AND "member_id" = "member_id_p";
jbe@45 5154 RETURN;
jbe@45 5155 END;
jbe@45 5156 $$;
jbe@45 5157
jbe@57 5158 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 5159
jbe@45 5160
jbe@45 5161 CREATE FUNCTION "delete_private_data"()
jbe@45 5162 RETURNS VOID
jbe@45 5163 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 5164 BEGIN
jbe@385 5165 DELETE FROM "temporary_transaction_data";
jbe@226 5166 DELETE FROM "member" WHERE "activated" ISNULL;
jbe@50 5167 UPDATE "member" SET
jbe@206 5168 "invite_code" = NULL,
jbe@232 5169 "invite_code_expiry" = NULL,
jbe@228 5170 "admin_comment" = NULL,
jbe@57 5171 "last_login" = NULL,
jbe@387 5172 "last_delegation_check" = NULL,
jbe@50 5173 "login" = NULL,
jbe@50 5174 "password" = NULL,
jbe@441 5175 "authority" = NULL,
jbe@441 5176 "authority_uid" = NULL,
jbe@441 5177 "authority_login" = NULL,
jbe@238 5178 "lang" = NULL,
jbe@50 5179 "notify_email" = NULL,
jbe@50 5180 "notify_email_unconfirmed" = NULL,
jbe@50 5181 "notify_email_secret" = NULL,
jbe@50 5182 "notify_email_secret_expiry" = NULL,
jbe@57 5183 "notify_email_lock_expiry" = NULL,
jbe@522 5184 "disable_notifications" = TRUE,
jbe@522 5185 "notification_counter" = DEFAULT,
jbe@522 5186 "notification_sample_size" = 0,
jbe@499 5187 "notification_dow" = NULL,
jbe@499 5188 "notification_hour" = NULL,
jbe@387 5189 "login_recovery_expiry" = NULL,
jbe@50 5190 "password_reset_secret" = NULL,
jbe@50 5191 "password_reset_secret_expiry" = NULL,
jbe@50 5192 "organizational_unit" = NULL,
jbe@50 5193 "internal_posts" = NULL,
jbe@50 5194 "realname" = NULL,
jbe@50 5195 "birthday" = NULL,
jbe@50 5196 "address" = NULL,
jbe@50 5197 "email" = NULL,
jbe@50 5198 "xmpp_address" = NULL,
jbe@50 5199 "website" = NULL,
jbe@50 5200 "phone" = NULL,
jbe@50 5201 "mobile_phone" = NULL,
jbe@50 5202 "profession" = NULL,
jbe@50 5203 "external_memberships" = NULL,
jbe@50 5204 "external_posts" = NULL,
jbe@238 5205 "formatting_engine" = NULL,
jbe@50 5206 "statement" = NULL;
jbe@50 5207 -- "text_search_data" is updated by triggers
jbe@50 5208 DELETE FROM "setting";
jbe@50 5209 DELETE FROM "setting_map";
jbe@50 5210 DELETE FROM "member_relation_setting";
jbe@50 5211 DELETE FROM "member_image";
jbe@50 5212 DELETE FROM "contact";
jbe@113 5213 DELETE FROM "ignored_member";
jbe@235 5214 DELETE FROM "session";
jbe@50 5215 DELETE FROM "area_setting";
jbe@50 5216 DELETE FROM "issue_setting";
jbe@113 5217 DELETE FROM "ignored_initiative";
jbe@50 5218 DELETE FROM "initiative_setting";
jbe@50 5219 DELETE FROM "suggestion_setting";
jbe@113 5220 DELETE FROM "non_voter";
jbe@8 5221 DELETE FROM "direct_voter" USING "issue"
jbe@8 5222 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 5223 AND "issue"."closed" ISNULL;
jbe@8 5224 RETURN;
jbe@8 5225 END;
jbe@8 5226 $$;
jbe@8 5227
jbe@273 5228 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 5229
jbe@8 5230
jbe@8 5231
jbe@0 5232 COMMIT;

Impressum / About Us