liquid_feedback_core

annotate core.sql @ 527:eaa4836e04ee

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

Impressum / About Us