liquid_feedback_core

annotate core.sql @ 519:003b4cc8e9ef

Merged experimental work on alternative mechanism to the first (issue) quorum
author jbe
date Tue May 03 20:35:30 2016 +0200 (2016-05-03)
parents e4f619e87664 fae00a5c1c71
children 2a2f76da1177
rev   line source
jbe@0 1
jbe@92 2 -- Execute the following command manually for PostgreSQL prior version 9.0:
jbe@92 3 -- CREATE LANGUAGE plpgsql;
jbe@0 4
jbe@0 5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
jbe@0 6
jbe@0 7 BEGIN;
jbe@0 8
jbe@5 9 CREATE VIEW "liquid_feedback_version" AS
jbe@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@457 2009 CREATE VIEW "matching_admission_rule_condition" AS
jbe@457 2010 SELECT DISTINCT ON ("issue_id", "admission_rule_condition"."admission_rule_id")
jbe@457 2011 "issue"."id" AS "issue_id",
jbe@457 2012 "admission_rule_condition".*
jbe@457 2013 FROM "admission_rule_condition"
jbe@457 2014 JOIN "area" ON "admission_rule_condition"."unit_id" = "area"."unit_id"
jbe@457 2015 JOIN "issue" ON "area"."id" = "issue"."area_id"
jbe@457 2016 WHERE (
jbe@457 2017 "admission_rule_condition"."policy_id" ISNULL OR
jbe@457 2018 "admission_rule_condition"."policy_id" = "issue"."policy_id"
jbe@457 2019 ) AND (
jbe@457 2020 "admission_rule_condition"."area_id" ISNULL OR
jbe@457 2021 "admission_rule_condition"."area_id" = "area"."id"
jbe@457 2022 )
jbe@457 2023 ORDER BY
jbe@457 2024 "issue_id",
jbe@457 2025 "admission_rule_condition"."admission_rule_id",
jbe@457 2026 "admission_rule_condition"."policy_id" ISNULL,
jbe@457 2027 "admission_rule_condition"."area_id" ISNULL;
jbe@457 2028
jbe@457 2029 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 2030
jbe@457 2031
jbe@457 2032 CREATE VIEW "applicable_admission_rule" AS
jbe@457 2033 SELECT * FROM "admission_rule"
jbe@457 2034 WHERE NOT EXISTS (
jbe@457 2035 SELECT NULL FROM "issue"
jbe@457 2036 JOIN "matching_admission_rule_condition" AS "condition"
jbe@457 2037 ON "issue"."id" = "condition"."issue_id"
jbe@457 2038 WHERE "condition"."admission_rule_id" = "admission_rule"."id"
jbe@457 2039 AND "issue"."accepted" > now() - "condition"."holdoff_time"
jbe@457 2040 );
jbe@457 2041
jbe@457 2042 COMMENT ON VIEW "applicable_admission_rule" IS 'Filters "admission_rule"s which are not blocked by a recently admitted issue';
jbe@457 2043
jbe@457 2044
jbe@457 2045 CREATE VIEW "issue_for_admission" AS
jbe@457 2046 SELECT
jbe@457 2047 "issue".*,
jbe@457 2048 max("initiative"."supporter_count") AS "max_supporter_count"
jbe@457 2049 FROM "issue"
jbe@457 2050 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@457 2051 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@457 2052 JOIN "admission_rule_condition"
jbe@457 2053 ON "admission_rule_condition"."unit_id" = "area"."unit_id"
jbe@457 2054 AND (
jbe@457 2055 "admission_rule_condition"."policy_id" ISNULL OR
jbe@457 2056 "admission_rule_condition"."policy_id" = "issue"."policy_id"
jbe@457 2057 )
jbe@457 2058 AND (
jbe@457 2059 "admission_rule_condition"."area_id" ISNULL OR
jbe@457 2060 "admission_rule_condition"."area_id" = "area"."id"
jbe@457 2061 )
jbe@457 2062 JOIN "applicable_admission_rule"
jbe@457 2063 ON "admission_rule_condition"."admission_rule_id" = "applicable_admission_rule"."id"
jbe@457 2064 WHERE "issue"."state" = 'admission'::"issue_state"
jbe@457 2065 GROUP BY "issue"."id"
jbe@457 2066 ORDER BY "max_supporter_count" DESC, "issue"."id";
jbe@457 2067
jbe@457 2068 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 2069
jbe@457 2070
jbe@97 2071 CREATE VIEW "unit_delegation" AS
jbe@97 2072 SELECT
jbe@97 2073 "unit"."id" AS "unit_id",
jbe@97 2074 "delegation"."id",
jbe@97 2075 "delegation"."truster_id",
jbe@97 2076 "delegation"."trustee_id",
jbe@97 2077 "delegation"."scope"
jbe@97 2078 FROM "unit"
jbe@97 2079 JOIN "delegation"
jbe@97 2080 ON "delegation"."unit_id" = "unit"."id"
jbe@97 2081 JOIN "member"
jbe@97 2082 ON "delegation"."truster_id" = "member"."id"
jbe@97 2083 JOIN "privilege"
jbe@97 2084 ON "delegation"."unit_id" = "privilege"."unit_id"
jbe@97 2085 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2086 WHERE "member"."active" AND "privilege"."voting_right";
jbe@97 2087
jbe@97 2088 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
jbe@5 2089
jbe@5 2090
jbe@5 2091 CREATE VIEW "area_delegation" AS
jbe@70 2092 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@70 2093 "area"."id" AS "area_id",
jbe@70 2094 "delegation"."id",
jbe@70 2095 "delegation"."truster_id",
jbe@70 2096 "delegation"."trustee_id",
jbe@70 2097 "delegation"."scope"
jbe@97 2098 FROM "area"
jbe@97 2099 JOIN "delegation"
jbe@97 2100 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 2101 OR "delegation"."area_id" = "area"."id"
jbe@97 2102 JOIN "member"
jbe@97 2103 ON "delegation"."truster_id" = "member"."id"
jbe@97 2104 JOIN "privilege"
jbe@97 2105 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 2106 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2107 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 2108 ORDER BY
jbe@70 2109 "area"."id",
jbe@70 2110 "delegation"."truster_id",
jbe@70 2111 "delegation"."scope" DESC;
jbe@70 2112
jbe@97 2113 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
jbe@5 2114
jbe@5 2115
jbe@5 2116 CREATE VIEW "issue_delegation" AS
jbe@70 2117 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@70 2118 "issue"."id" AS "issue_id",
jbe@70 2119 "delegation"."id",
jbe@70 2120 "delegation"."truster_id",
jbe@70 2121 "delegation"."trustee_id",
jbe@70 2122 "delegation"."scope"
jbe@97 2123 FROM "issue"
jbe@97 2124 JOIN "area"
jbe@97 2125 ON "area"."id" = "issue"."area_id"
jbe@97 2126 JOIN "delegation"
jbe@97 2127 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 2128 OR "delegation"."area_id" = "area"."id"
jbe@97 2129 OR "delegation"."issue_id" = "issue"."id"
jbe@97 2130 JOIN "member"
jbe@97 2131 ON "delegation"."truster_id" = "member"."id"
jbe@97 2132 JOIN "privilege"
jbe@97 2133 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 2134 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 2135 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 2136 ORDER BY
jbe@70 2137 "issue"."id",
jbe@70 2138 "delegation"."truster_id",
jbe@70 2139 "delegation"."scope" DESC;
jbe@70 2140
jbe@97 2141 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
jbe@5 2142
jbe@5 2143
jbe@5 2144 CREATE FUNCTION "membership_weight_with_skipping"
jbe@5 2145 ( "area_id_p" "area"."id"%TYPE,
jbe@5 2146 "member_id_p" "member"."id"%TYPE,
jbe@5 2147 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
jbe@5 2148 RETURNS INT4
jbe@5 2149 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2150 DECLARE
jbe@5 2151 "sum_v" INT4;
jbe@5 2152 "delegation_row" "area_delegation"%ROWTYPE;
jbe@5 2153 BEGIN
jbe@5 2154 "sum_v" := 1;
jbe@5 2155 FOR "delegation_row" IN
jbe@5 2156 SELECT "area_delegation".*
jbe@5 2157 FROM "area_delegation" LEFT JOIN "membership"
jbe@5 2158 ON "membership"."area_id" = "area_id_p"
jbe@5 2159 AND "membership"."member_id" = "area_delegation"."truster_id"
jbe@5 2160 WHERE "area_delegation"."area_id" = "area_id_p"
jbe@5 2161 AND "area_delegation"."trustee_id" = "member_id_p"
jbe@5 2162 AND "membership"."member_id" ISNULL
jbe@5 2163 LOOP
jbe@5 2164 IF NOT
jbe@5 2165 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
jbe@5 2166 THEN
jbe@5 2167 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
jbe@5 2168 "area_id_p",
jbe@5 2169 "delegation_row"."truster_id",
jbe@5 2170 "skip_member_ids_p" || "delegation_row"."truster_id"
jbe@5 2171 );
jbe@5 2172 END IF;
jbe@5 2173 END LOOP;
jbe@5 2174 RETURN "sum_v";
jbe@5 2175 END;
jbe@5 2176 $$;
jbe@5 2177
jbe@8 2178 COMMENT ON FUNCTION "membership_weight_with_skipping"
jbe@8 2179 ( "area"."id"%TYPE,
jbe@8 2180 "member"."id"%TYPE,
jbe@8 2181 INT4[] )
jbe@8 2182 IS 'Helper function for "membership_weight" function';
jbe@8 2183
jbe@8 2184
jbe@5 2185 CREATE FUNCTION "membership_weight"
jbe@5 2186 ( "area_id_p" "area"."id"%TYPE,
jbe@5 2187 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
jbe@5 2188 RETURNS INT4
jbe@5 2189 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2190 BEGIN
jbe@5 2191 RETURN "membership_weight_with_skipping"(
jbe@5 2192 "area_id_p",
jbe@5 2193 "member_id_p",
jbe@5 2194 ARRAY["member_id_p"]
jbe@5 2195 );
jbe@5 2196 END;
jbe@5 2197 $$;
jbe@5 2198
jbe@8 2199 COMMENT ON FUNCTION "membership_weight"
jbe@8 2200 ( "area"."id"%TYPE,
jbe@8 2201 "member"."id"%TYPE )
jbe@8 2202 IS 'Calculates the potential voting weight of a member in a given area';
jbe@8 2203
jbe@5 2204
jbe@4 2205 CREATE VIEW "member_count_view" AS
jbe@5 2206 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 2207
jbe@4 2208 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 2209
jbe@4 2210
jbe@97 2211 CREATE VIEW "unit_member_count" AS
jbe@97 2212 SELECT
jbe@97 2213 "unit"."id" AS "unit_id",
jbe@248 2214 count("member"."id") AS "member_count"
jbe@97 2215 FROM "unit"
jbe@97 2216 LEFT JOIN "privilege"
jbe@97 2217 ON "privilege"."unit_id" = "unit"."id"
jbe@97 2218 AND "privilege"."voting_right"
jbe@97 2219 LEFT JOIN "member"
jbe@97 2220 ON "member"."id" = "privilege"."member_id"
jbe@97 2221 AND "member"."active"
jbe@97 2222 GROUP BY "unit"."id";
jbe@97 2223
jbe@97 2224 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@97 2225
jbe@97 2226
jbe@4 2227 CREATE VIEW "area_member_count" AS
jbe@5 2228 SELECT
jbe@5 2229 "area"."id" AS "area_id",
jbe@5 2230 count("member"."id") AS "direct_member_count",
jbe@5 2231 coalesce(
jbe@5 2232 sum(
jbe@5 2233 CASE WHEN "member"."id" NOTNULL THEN
jbe@5 2234 "membership_weight"("area"."id", "member"."id")
jbe@5 2235 ELSE 0 END
jbe@5 2236 )
jbe@169 2237 ) AS "member_weight"
jbe@4 2238 FROM "area"
jbe@4 2239 LEFT JOIN "membership"
jbe@4 2240 ON "area"."id" = "membership"."area_id"
jbe@97 2241 LEFT JOIN "privilege"
jbe@97 2242 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 2243 AND "privilege"."member_id" = "membership"."member_id"
jbe@97 2244 AND "privilege"."voting_right"
jbe@4 2245 LEFT JOIN "member"
jbe@97 2246 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
jbe@4 2247 AND "member"."active"
jbe@4 2248 GROUP BY "area"."id";
jbe@4 2249
jbe@169 2250 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
jbe@4 2251
jbe@4 2252
jbe@9 2253 CREATE VIEW "opening_draft" AS
jbe@9 2254 SELECT "draft".* FROM (
jbe@9 2255 SELECT
jbe@9 2256 "initiative"."id" AS "initiative_id",
jbe@9 2257 min("draft"."id") AS "draft_id"
jbe@9 2258 FROM "initiative" JOIN "draft"
jbe@9 2259 ON "initiative"."id" = "draft"."initiative_id"
jbe@9 2260 GROUP BY "initiative"."id"
jbe@9 2261 ) AS "subquery"
jbe@9 2262 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@9 2263
jbe@9 2264 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 2265
jbe@9 2266
jbe@0 2267 CREATE VIEW "current_draft" AS
jbe@0 2268 SELECT "draft".* FROM (
jbe@0 2269 SELECT
jbe@0 2270 "initiative"."id" AS "initiative_id",
jbe@0 2271 max("draft"."id") AS "draft_id"
jbe@0 2272 FROM "initiative" JOIN "draft"
jbe@0 2273 ON "initiative"."id" = "draft"."initiative_id"
jbe@0 2274 GROUP BY "initiative"."id"
jbe@0 2275 ) AS "subquery"
jbe@0 2276 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@0 2277
jbe@0 2278 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 2279
jbe@0 2280
jbe@0 2281 CREATE VIEW "critical_opinion" AS
jbe@0 2282 SELECT * FROM "opinion"
jbe@0 2283 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 2284 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 2285
jbe@0 2286 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 2287
jbe@0 2288
jbe@392 2289 CREATE VIEW "issue_supporter_in_admission_state" AS
jbe@466 2290 SELECT DISTINCT -- TODO: DISTINCT needed?
jbe@410 2291 "area"."unit_id",
jbe@392 2292 "issue"."area_id",
jbe@392 2293 "issue"."id" AS "issue_id",
jbe@392 2294 "supporter"."member_id",
jbe@392 2295 "direct_interest_snapshot"."weight"
jbe@392 2296 FROM "issue"
jbe@410 2297 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@392 2298 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
jbe@392 2299 JOIN "direct_interest_snapshot"
jbe@392 2300 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@392 2301 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
jbe@392 2302 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
jbe@392 2303 WHERE "issue"."state" = 'admission'::"issue_state";
jbe@392 2304
jbe@392 2305 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 2306
jbe@392 2307
jbe@352 2308 CREATE VIEW "initiative_suggestion_order_calculation" AS
jbe@352 2309 SELECT
jbe@352 2310 "initiative"."id" AS "initiative_id",
jbe@352 2311 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
jbe@352 2312 FROM "initiative" JOIN "issue"
jbe@352 2313 ON "initiative"."issue_id" = "issue"."id"
jbe@352 2314 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
jbe@352 2315 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
jbe@352 2316
jbe@352 2317 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
jbe@352 2318
jbe@360 2319 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 2320
jbe@352 2321
jbe@352 2322 CREATE VIEW "individual_suggestion_ranking" AS
jbe@352 2323 SELECT
jbe@352 2324 "opinion"."initiative_id",
jbe@352 2325 "opinion"."member_id",
jbe@352 2326 "direct_interest_snapshot"."weight",
jbe@352 2327 CASE WHEN
jbe@352 2328 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 2329 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
jbe@352 2330 THEN 1 ELSE
jbe@352 2331 CASE WHEN
jbe@352 2332 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
jbe@352 2333 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
jbe@352 2334 THEN 2 ELSE
jbe@352 2335 CASE WHEN
jbe@352 2336 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
jbe@352 2337 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
jbe@352 2338 THEN 3 ELSE 4 END
jbe@352 2339 END
jbe@352 2340 END AS "preference",
jbe@352 2341 "opinion"."suggestion_id"
jbe@352 2342 FROM "opinion"
jbe@352 2343 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
jbe@352 2344 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@352 2345 JOIN "direct_interest_snapshot"
jbe@352 2346 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@352 2347 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
jbe@352 2348 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
jbe@352 2349
jbe@352 2350 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 2351
jbe@352 2352
jbe@126 2353 CREATE VIEW "battle_participant" AS
jbe@126 2354 SELECT "initiative"."id", "initiative"."issue_id"
jbe@126 2355 FROM "issue" JOIN "initiative"
jbe@126 2356 ON "issue"."id" = "initiative"."issue_id"
jbe@126 2357 WHERE "initiative"."admitted"
jbe@126 2358 UNION ALL
jbe@126 2359 SELECT NULL, "id" AS "issue_id"
jbe@126 2360 FROM "issue";
jbe@126 2361
jbe@126 2362 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 2363
jbe@126 2364
jbe@61 2365 CREATE VIEW "battle_view" AS
jbe@0 2366 SELECT
jbe@0 2367 "issue"."id" AS "issue_id",
jbe@10 2368 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 2369 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 2370 sum(
jbe@0 2371 CASE WHEN
jbe@0 2372 coalesce("better_vote"."grade", 0) >
jbe@0 2373 coalesce("worse_vote"."grade", 0)
jbe@0 2374 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 2375 ) AS "count"
jbe@0 2376 FROM "issue"
jbe@0 2377 LEFT JOIN "direct_voter"
jbe@0 2378 ON "issue"."id" = "direct_voter"."issue_id"
jbe@126 2379 JOIN "battle_participant" AS "winning_initiative"
jbe@10 2380 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@126 2381 JOIN "battle_participant" AS "losing_initiative"
jbe@10 2382 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@0 2383 LEFT JOIN "vote" AS "better_vote"
jbe@10 2384 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 2385 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 2386 LEFT JOIN "vote" AS "worse_vote"
jbe@10 2387 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 2388 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@328 2389 WHERE "issue"."state" = 'voting'
jbe@328 2390 AND "issue"."phase_finished" NOTNULL
jbe@126 2391 AND (
jbe@126 2392 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@126 2393 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@126 2394 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@0 2395 GROUP BY
jbe@0 2396 "issue"."id",
jbe@10 2397 "winning_initiative"."id",
jbe@10 2398 "losing_initiative"."id";
jbe@0 2399
jbe@126 2400 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 2401
jbe@1 2402
jbe@235 2403 CREATE VIEW "expired_session" AS
jbe@235 2404 SELECT * FROM "session" WHERE now() > "expiry";
jbe@235 2405
jbe@235 2406 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@235 2407 DELETE FROM "session" WHERE "ident" = OLD."ident";
jbe@235 2408
jbe@235 2409 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@235 2410 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 2411
jbe@235 2412
jbe@0 2413 CREATE VIEW "open_issue" AS
jbe@0 2414 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 2415
jbe@0 2416 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 2417
jbe@0 2418
jbe@9 2419 CREATE VIEW "member_contingent" AS
jbe@9 2420 SELECT
jbe@9 2421 "member"."id" AS "member_id",
jbe@293 2422 "contingent"."polling",
jbe@9 2423 "contingent"."time_frame",
jbe@9 2424 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 2425 (
jbe@9 2426 SELECT count(1) FROM "draft"
jbe@293 2427 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@9 2428 WHERE "draft"."author_id" = "member"."id"
jbe@293 2429 AND "initiative"."polling" = "contingent"."polling"
jbe@9 2430 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 2431 ) + (
jbe@9 2432 SELECT count(1) FROM "suggestion"
jbe@293 2433 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
jbe@9 2434 WHERE "suggestion"."author_id" = "member"."id"
jbe@293 2435 AND "contingent"."polling" = FALSE
jbe@9 2436 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 2437 )
jbe@9 2438 ELSE NULL END AS "text_entry_count",
jbe@9 2439 "contingent"."text_entry_limit",
jbe@9 2440 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@293 2441 SELECT count(1) FROM "opening_draft" AS "draft"
jbe@293 2442 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@293 2443 WHERE "draft"."author_id" = "member"."id"
jbe@293 2444 AND "initiative"."polling" = "contingent"."polling"
jbe@293 2445 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 2446 ) ELSE NULL END AS "initiative_count",
jbe@9 2447 "contingent"."initiative_limit"
jbe@9 2448 FROM "member" CROSS JOIN "contingent";
jbe@9 2449
jbe@9 2450 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 2451
jbe@9 2452 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 2453 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 2454
jbe@9 2455
jbe@9 2456 CREATE VIEW "member_contingent_left" AS
jbe@9 2457 SELECT
jbe@9 2458 "member_id",
jbe@293 2459 "polling",
jbe@9 2460 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 2461 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@293 2462 FROM "member_contingent" GROUP BY "member_id", "polling";
jbe@9 2463
jbe@9 2464 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 2465
jbe@9 2466
jbe@499 2467 CREATE VIEW "event_for_notification" AS
jbe@113 2468 SELECT
jbe@499 2469 "member"."id" AS "recipient_id",
jbe@113 2470 "event".*
jbe@113 2471 FROM "member" CROSS JOIN "event"
jbe@499 2472 JOIN "issue" ON "issue"."id" = "event"."issue_id"
jbe@499 2473 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@499 2474 LEFT JOIN "privilege" ON
jbe@499 2475 "privilege"."member_id" = "member"."id" AND
jbe@499 2476 "privilege"."unit_id" = "area"."unit_id" AND
jbe@499 2477 "privilege"."voting_right" = TRUE
jbe@499 2478 LEFT JOIN "subscription" ON
jbe@499 2479 "subscription"."member_id" = "member"."id" AND
jbe@499 2480 "subscription"."unit_id" = "area"."unit_id"
jbe@499 2481 LEFT JOIN "ignored_area" ON
jbe@499 2482 "ignored_area"."member_id" = "member"."id" AND
jbe@499 2483 "ignored_area"."area_id" = "issue"."area_id"
jbe@499 2484 LEFT JOIN "interest" ON
jbe@499 2485 "interest"."member_id" = "member"."id" AND
jbe@499 2486 "interest"."issue_id" = "event"."issue_id"
jbe@499 2487 LEFT JOIN "supporter" ON
jbe@499 2488 "supporter"."member_id" = "member"."id" AND
jbe@499 2489 "supporter"."initiative_id" = "event"."initiative_id"
jbe@499 2490 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
jbe@499 2491 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
jbe@499 2492 AND (
jbe@499 2493 "event"."event" = 'issue_state_changed'::"event_type" OR
jbe@499 2494 ( "event"."event" = 'initiative_revoked'::"event_type" AND
jbe@499 2495 "supporter"."member_id" NOTNULL ) );
jbe@499 2496
jbe@508 2497 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
jbe@508 2498
jbe@508 2499 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
jbe@222 2500
jbe@222 2501
jbe@473 2502 CREATE VIEW "updated_initiative" AS
jbe@113 2503 SELECT
jbe@499 2504 "supporter"."member_id" AS "recipient_id",
jbe@477 2505 FALSE AS "featured",
jbe@499 2506 "supporter"."initiative_id"
jbe@499 2507 FROM "supporter"
jbe@499 2508 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
jbe@473 2509 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@507 2510 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 2511 "sent"."member_id" = "supporter"."member_id" AND
jbe@499 2512 "sent"."initiative_id" = "supporter"."initiative_id"
jbe@499 2513 LEFT JOIN "ignored_initiative" ON
jbe@499 2514 "ignored_initiative"."member_id" = "supporter"."member_id" AND
jbe@499 2515 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
jbe@480 2516 WHERE "issue"."state" IN ('admission', 'discussion')
jbe@503 2517 AND "initiative"."revoked" ISNULL
jbe@499 2518 AND "ignored_initiative"."member_id" ISNULL
jbe@473 2519 AND (
jbe@473 2520 EXISTS (
jbe@473 2521 SELECT NULL FROM "draft"
jbe@499 2522 LEFT JOIN "ignored_member" ON
jbe@499 2523 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 2524 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 2525 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
jbe@473 2526 AND "draft"."id" > "supporter"."draft_id"
jbe@499 2527 AND "ignored_member"."member_id" ISNULL
jbe@473 2528 ) OR EXISTS (
jbe@473 2529 SELECT NULL FROM "suggestion"
jbe@487 2530 LEFT JOIN "opinion" ON
jbe@487 2531 "opinion"."member_id" = "supporter"."member_id" AND
jbe@487 2532 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 2533 LEFT JOIN "ignored_member" ON
jbe@499 2534 "ignored_member"."member_id" = "supporter"."member_id" AND
jbe@499 2535 "ignored_member"."other_member_id" = "suggestion"."author_id"
jbe@499 2536 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@487 2537 AND "opinion"."member_id" ISNULL
jbe@499 2538 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 2539 AND "ignored_member"."member_id" ISNULL
jbe@473 2540 )
jbe@473 2541 );
jbe@473 2542
jbe@508 2543 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
jbe@508 2544
jbe@508 2545
jbe@474 2546 CREATE FUNCTION "featured_initiative"
jbe@499 2547 ( "recipient_id_p" "member"."id"%TYPE,
jbe@499 2548 "area_id_p" "area"."id"%TYPE )
jbe@499 2549 RETURNS SETOF "initiative"."id"%TYPE
jbe@474 2550 LANGUAGE 'plpgsql' STABLE AS $$
jbe@474 2551 DECLARE
jbe@499 2552 "counter_v" "member"."notification_counter"%TYPE;
jbe@499 2553 "sample_size_v" "member"."notification_sample_size"%TYPE;
jbe@499 2554 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
jbe@499 2555 "match_v" BOOLEAN;
jbe@474 2556 "member_id_v" "member"."id"%TYPE;
jbe@474 2557 "seed_v" TEXT;
jbe@499 2558 "initiative_id_v" "initiative"."id"%TYPE;
jbe@474 2559 BEGIN
jbe@499 2560 SELECT "notification_counter", "notification_sample_size"
jbe@499 2561 INTO "counter_v", "sample_size_v"
jbe@499 2562 FROM "member" WHERE "id" = "recipient_id_p";
jbe@474 2563 "initiative_id_ary" := '{}';
jbe@474 2564 LOOP
jbe@474 2565 "match_v" := FALSE;
jbe@474 2566 FOR "member_id_v", "seed_v" IN
jbe@474 2567 SELECT * FROM (
jbe@474 2568 SELECT DISTINCT
jbe@474 2569 "supporter"."member_id",
jbe@499 2570 md5(
jbe@499 2571 "recipient_id_p" || '-' ||
jbe@499 2572 "counter_v" || '-' ||
jbe@499 2573 "area_id_p" || '-' ||
jbe@499 2574 "supporter"."member_id"
jbe@499 2575 ) AS "seed"
jbe@474 2576 FROM "supporter"
jbe@474 2577 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
jbe@474 2578 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 2579 WHERE "supporter"."member_id" != "recipient_id_p"
jbe@474 2580 AND "issue"."area_id" = "area_id_p"
jbe@474 2581 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@474 2582 ) AS "subquery"
jbe@474 2583 ORDER BY "seed"
jbe@474 2584 LOOP
jbe@499 2585 SELECT "initiative"."id" INTO "initiative_id_v"
jbe@476 2586 FROM "initiative"
jbe@474 2587 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@499 2588 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@474 2589 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
jbe@474 2590 LEFT JOIN "supporter" AS "self_support" ON
jbe@474 2591 "self_support"."initiative_id" = "initiative"."id" AND
jbe@499 2592 "self_support"."member_id" = "recipient_id_p"
jbe@499 2593 LEFT JOIN "privilege" ON
jbe@499 2594 "privilege"."member_id" = "recipient_id_p" AND
jbe@499 2595 "privilege"."unit_id" = "area"."unit_id" AND
jbe@499 2596 "privilege"."voting_right" = TRUE
jbe@499 2597 LEFT JOIN "subscription" ON
jbe@499 2598 "subscription"."member_id" = "recipient_id_p" AND
jbe@499 2599 "subscription"."unit_id" = "area"."unit_id"
jbe@499 2600 LEFT JOIN "ignored_initiative" ON
jbe@499 2601 "ignored_initiative"."member_id" = "recipient_id_p" AND
jbe@499 2602 "ignored_initiative"."initiative_id" = "initiative"."id"
jbe@474 2603 WHERE "supporter"."member_id" = "member_id_v"
jbe@474 2604 AND "issue"."area_id" = "area_id_p"
jbe@474 2605 AND "issue"."state" IN ('admission', 'discussion', 'verification')
jbe@503 2606 AND "initiative"."revoked" ISNULL
jbe@474 2607 AND "self_support"."member_id" ISNULL
jbe@476 2608 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
jbe@499 2609 AND (
jbe@499 2610 "privilege"."member_id" NOTNULL OR
jbe@499 2611 "subscription"."member_id" NOTNULL )
jbe@499 2612 AND "ignored_initiative"."member_id" ISNULL
jbe@499 2613 AND NOT EXISTS (
jbe@499 2614 SELECT NULL FROM "draft"
jbe@499 2615 JOIN "ignored_member" ON
jbe@499 2616 "ignored_member"."member_id" = "recipient_id_p" AND
jbe@499 2617 "ignored_member"."other_member_id" = "draft"."author_id"
jbe@499 2618 WHERE "draft"."initiative_id" = "initiative"."id"
jbe@499 2619 )
jbe@474 2620 ORDER BY md5("seed_v" || '-' || "initiative"."id")
jbe@476 2621 LIMIT 1;
jbe@476 2622 IF FOUND THEN
jbe@476 2623 "match_v" := TRUE;
jbe@499 2624 RETURN NEXT "initiative_id_v";
jbe@499 2625 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
jbe@476 2626 RETURN;
jbe@474 2627 END IF;
jbe@499 2628 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
jbe@476 2629 END IF;
jbe@474 2630 END LOOP;
jbe@474 2631 EXIT WHEN NOT "match_v";
jbe@474 2632 END LOOP;
jbe@474 2633 RETURN;
jbe@474 2634 END;
jbe@474 2635 $$;
jbe@474 2636
jbe@508 2637 COMMENT ON FUNCTION "featured_initiative"
jbe@508 2638 ( "recipient_id_p" "member"."id"%TYPE,
jbe@508 2639 "area_id_p" "area"."id"%TYPE )
jbe@508 2640 IS 'Helper function for view "updated_or_featured_initiative"';
jbe@508 2641
jbe@508 2642
jbe@474 2643 CREATE VIEW "updated_or_featured_initiative" AS
jbe@474 2644 SELECT
jbe@499 2645 "subquery".*,
jbe@477 2646 NOT EXISTS (
jbe@477 2647 SELECT NULL FROM "initiative" AS "better_initiative"
jbe@499 2648 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
jbe@484 2649 AND
jbe@502 2650 ( COALESCE("better_initiative"."supporter_count", -1),
jbe@484 2651 -"better_initiative"."id" ) >
jbe@502 2652 ( COALESCE("initiative"."supporter_count", -1),
jbe@485 2653 -"initiative"."id" )
jbe@499 2654 ) AS "leading"
jbe@499 2655 FROM (
jbe@499 2656 SELECT * FROM "updated_initiative"
jbe@499 2657 UNION ALL
jbe@499 2658 SELECT
jbe@499 2659 "member"."id" AS "recipient_id",
jbe@499 2660 TRUE AS "featured",
jbe@499 2661 "featured_initiative_id" AS "initiative_id"
jbe@499 2662 FROM "member" CROSS JOIN "area"
jbe@499 2663 CROSS JOIN LATERAL
jbe@499 2664 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
jbe@499 2665 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
jbe@499 2666 ) AS "subquery"
jbe@499 2667 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
jbe@474 2668
jbe@508 2669 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 2670
jbe@508 2671 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 2672 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 2673 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 2674 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 2675
jbe@508 2676
jbe@474 2677 CREATE VIEW "leading_complement_initiative" AS
jbe@477 2678 SELECT * FROM (
jbe@499 2679 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
jbe@499 2680 "uf_initiative"."recipient_id",
jbe@477 2681 FALSE AS "featured",
jbe@499 2682 "uf_initiative"."initiative_id",
jbe@499 2683 TRUE AS "leading"
jbe@489 2684 FROM "updated_or_featured_initiative" AS "uf_initiative"
jbe@499 2685 JOIN "initiative" AS "uf_initiative_full" ON
jbe@499 2686 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
jbe@489 2687 JOIN "initiative" ON
jbe@499 2688 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
jbe@503 2689 WHERE "initiative"."revoked" ISNULL
jbe@477 2690 ORDER BY
jbe@499 2691 "uf_initiative"."recipient_id",
jbe@477 2692 "initiative"."issue_id",
jbe@502 2693 "initiative"."supporter_count" DESC,
jbe@477 2694 "initiative"."id"
jbe@477 2695 ) AS "subquery"
jbe@477 2696 WHERE NOT EXISTS (
jbe@477 2697 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
jbe@499 2698 WHERE "other"."recipient_id" = "subquery"."recipient_id"
jbe@499 2699 AND "other"."initiative_id" = "subquery"."initiative_id"
jbe@477 2700 );
jbe@474 2701
jbe@508 2702 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 2703 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
jbe@508 2704 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 2705 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
jbe@508 2706
jbe@508 2707
jbe@490 2708 CREATE VIEW "unfiltered_initiative_for_notification" AS
jbe@499 2709 SELECT
jbe@499 2710 "subquery".*,
jbe@499 2711 "supporter"."member_id" NOTNULL AS "supported",
jbe@499 2712 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 2713 EXISTS (
jbe@499 2714 SELECT NULL FROM "draft"
jbe@499 2715 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 2716 AND "draft"."id" > "supporter"."draft_id"
jbe@499 2717 )
jbe@222 2718 ELSE
jbe@499 2719 EXISTS (
jbe@499 2720 SELECT NULL FROM "draft"
jbe@499 2721 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
jbe@499 2722 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
jbe@499 2723 )
jbe@499 2724 END AS "new_draft",
jbe@499 2725 CASE WHEN "supporter"."member_id" NOTNULL THEN
jbe@499 2726 ( SELECT count(1) FROM "suggestion"
jbe@499 2727 LEFT JOIN "opinion" ON
jbe@499 2728 "opinion"."member_id" = "supporter"."member_id" AND
jbe@499 2729 "opinion"."suggestion_id" = "suggestion"."id"
jbe@499 2730 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 2731 AND "opinion"."member_id" ISNULL
jbe@499 2732 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 2733 )
jbe@499 2734 ELSE
jbe@499 2735 ( SELECT count(1) FROM "suggestion"
jbe@499 2736 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
jbe@499 2737 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
jbe@499 2738 )
jbe@499 2739 END AS "new_suggestion_count"
jbe@499 2740 FROM (
jbe@499 2741 SELECT * FROM "updated_or_featured_initiative"
jbe@499 2742 UNION ALL
jbe@499 2743 SELECT * FROM "leading_complement_initiative"
jbe@499 2744 ) AS "subquery"
jbe@499 2745 LEFT JOIN "supporter" ON
jbe@499 2746 "supporter"."member_id" = "subquery"."recipient_id" AND
jbe@499 2747 "supporter"."initiative_id" = "subquery"."initiative_id"
jbe@507 2748 LEFT JOIN "notification_initiative_sent" AS "sent" ON
jbe@499 2749 "sent"."member_id" = "subquery"."recipient_id" AND
jbe@499 2750 "sent"."initiative_id" = "subquery"."initiative_id";
jbe@474 2751
jbe@508 2752 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 2753
jbe@508 2754 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 2755 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 2756 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 2757
jbe@508 2758
jbe@490 2759 CREATE VIEW "initiative_for_notification" AS
jbe@499 2760 SELECT "unfiltered1".*
jbe@499 2761 FROM "unfiltered_initiative_for_notification" "unfiltered1"
jbe@499 2762 JOIN "initiative" AS "initiative1" ON
jbe@499 2763 "initiative1"."id" = "unfiltered1"."initiative_id"
jbe@499 2764 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
jbe@490 2765 WHERE EXISTS (
jbe@490 2766 SELECT NULL
jbe@499 2767 FROM "unfiltered_initiative_for_notification" "unfiltered2"
jbe@499 2768 JOIN "initiative" AS "initiative2" ON
jbe@499 2769 "initiative2"."id" = "unfiltered2"."initiative_id"
jbe@499 2770 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
jbe@499 2771 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
jbe@490 2772 AND "issue1"."area_id" = "issue2"."area_id"
jbe@499 2773 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
jbe@490 2774 );
jbe@490 2775
jbe@508 2776 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
jbe@508 2777
jbe@508 2778 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
jbe@508 2779 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 2780 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
jbe@508 2781 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
jbe@508 2782 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
jbe@508 2783 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 2784 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 2785
jbe@508 2786
jbe@504 2787 CREATE VIEW "scheduled_notification_to_send" AS
jbe@505 2788 SELECT * FROM (
jbe@505 2789 SELECT
jbe@505 2790 "id" AS "recipient_id",
jbe@505 2791 now() - CASE WHEN "notification_dow" ISNULL THEN
jbe@505 2792 ( "notification_sent"::DATE + CASE
jbe@505 2793 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 2794 THEN 0 ELSE 1 END
jbe@505 2795 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@222 2796 ELSE
jbe@505 2797 ( "notification_sent"::DATE +
jbe@505 2798 ( 7 + "notification_dow" -
jbe@505 2799 EXTRACT(DOW FROM
jbe@505 2800 ( "notification_sent"::DATE + CASE
jbe@505 2801 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 2802 THEN 0 ELSE 1 END
jbe@505 2803 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 2804 )::INTEGER
jbe@505 2805 ) % 7 +
jbe@505 2806 CASE
jbe@505 2807 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@505 2808 THEN 0 ELSE 1
jbe@505 2809 END
jbe@505 2810 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@505 2811 END AS "pending"
jbe@505 2812 FROM (
jbe@505 2813 SELECT
jbe@505 2814 "id",
jbe@505 2815 COALESCE("notification_sent", "activated") AS "notification_sent",
jbe@505 2816 "notification_dow",
jbe@505 2817 "notification_hour"
jbe@505 2818 FROM "member"
jbe@505 2819 WHERE "disable_notifications" = FALSE
jbe@505 2820 AND "notification_hour" NOTNULL
jbe@505 2821 ) AS "subquery1"
jbe@505 2822 ) AS "subquery2"
jbe@505 2823 WHERE "pending" > '0'::INTERVAL;
jbe@504 2824
jbe@508 2825 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
jbe@508 2826
jbe@508 2827 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
jbe@508 2828 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
jbe@508 2829
jbe@508 2830
jbe@497 2831 CREATE VIEW "newsletter_to_send" AS
jbe@497 2832 SELECT
jbe@499 2833 "member"."id" AS "recipient_id",
jbe@514 2834 "newsletter"."id" AS "newsletter_id",
jbe@514 2835 "newsletter"."published"
jbe@497 2836 FROM "newsletter" CROSS JOIN "member"
jbe@497 2837 LEFT JOIN "privilege" ON
jbe@497 2838 "privilege"."member_id" = "member"."id" AND
jbe@497 2839 "privilege"."unit_id" = "newsletter"."unit_id" AND
jbe@497 2840 "privilege"."voting_right" = TRUE
jbe@497 2841 LEFT JOIN "subscription" ON
jbe@497 2842 "subscription"."member_id" = "member"."id" AND
jbe@497 2843 "subscription"."unit_id" = "newsletter"."unit_id"
jbe@498 2844 WHERE "newsletter"."published" <= now()
jbe@497 2845 AND "newsletter"."sent" ISNULL
jbe@497 2846 AND "member"."locked" = FALSE
jbe@113 2847 AND (
jbe@497 2848 "member"."disable_notifications" = FALSE OR
jbe@497 2849 "newsletter"."include_all_members" = TRUE )
jbe@497 2850 AND (
jbe@497 2851 "newsletter"."unit_id" ISNULL OR
jbe@497 2852 "privilege"."member_id" NOTNULL OR
jbe@497 2853 "subscription"."member_id" NOTNULL );
jbe@497 2854
jbe@508 2855 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
jbe@508 2856
jbe@514 2857 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
jbe@113 2858
jbe@113 2859
jbe@0 2860
jbe@242 2861 ------------------------------------------------------
jbe@242 2862 -- Row set returning function for delegation chains --
jbe@242 2863 ------------------------------------------------------
jbe@5 2864
jbe@5 2865
jbe@5 2866 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 2867 ('first', 'intermediate', 'last', 'repetition');
jbe@5 2868
jbe@5 2869 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 2870
jbe@5 2871
jbe@5 2872 CREATE TYPE "delegation_chain_row" AS (
jbe@5 2873 "index" INT4,
jbe@5 2874 "member_id" INT4,
jbe@97 2875 "member_valid" BOOLEAN,
jbe@5 2876 "participation" BOOLEAN,
jbe@5 2877 "overridden" BOOLEAN,
jbe@5 2878 "scope_in" "delegation_scope",
jbe@5 2879 "scope_out" "delegation_scope",
jbe@86 2880 "disabled_out" BOOLEAN,
jbe@5 2881 "loop" "delegation_chain_loop_tag" );
jbe@5 2882
jbe@243 2883 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
jbe@5 2884
jbe@5 2885 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 2886 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 2887 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 2888 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 2889 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 2890 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 2891 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 2892
jbe@5 2893
jbe@242 2894 CREATE FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2895 ( "member_id_p" "member"."id"%TYPE,
jbe@242 2896 "issue_id_p" "issue"."id"%TYPE )
jbe@242 2897 RETURNS SETOF "delegation_chain_row"
jbe@242 2898 LANGUAGE 'plpgsql' STABLE AS $$
jbe@242 2899 DECLARE
jbe@242 2900 "output_row" "delegation_chain_row";
jbe@242 2901 "direct_voter_row" "direct_voter"%ROWTYPE;
jbe@242 2902 "delegating_voter_row" "delegating_voter"%ROWTYPE;
jbe@242 2903 BEGIN
jbe@242 2904 "output_row"."index" := 0;
jbe@242 2905 "output_row"."member_id" := "member_id_p";
jbe@242 2906 "output_row"."member_valid" := TRUE;
jbe@242 2907 "output_row"."participation" := FALSE;
jbe@242 2908 "output_row"."overridden" := FALSE;
jbe@242 2909 "output_row"."disabled_out" := FALSE;
jbe@242 2910 LOOP
jbe@242 2911 SELECT INTO "direct_voter_row" * FROM "direct_voter"
jbe@242 2912 WHERE "issue_id" = "issue_id_p"
jbe@242 2913 AND "member_id" = "output_row"."member_id";
jbe@242 2914 IF "direct_voter_row"."member_id" NOTNULL THEN
jbe@242 2915 "output_row"."participation" := TRUE;
jbe@242 2916 "output_row"."scope_out" := NULL;
jbe@242 2917 "output_row"."disabled_out" := NULL;
jbe@242 2918 RETURN NEXT "output_row";
jbe@242 2919 RETURN;
jbe@242 2920 END IF;
jbe@242 2921 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
jbe@242 2922 WHERE "issue_id" = "issue_id_p"
jbe@242 2923 AND "member_id" = "output_row"."member_id";
jbe@242 2924 IF "delegating_voter_row"."member_id" ISNULL THEN
jbe@242 2925 RETURN;
jbe@242 2926 END IF;
jbe@242 2927 "output_row"."scope_out" := "delegating_voter_row"."scope";
jbe@242 2928 RETURN NEXT "output_row";
jbe@242 2929 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
jbe@242 2930 "output_row"."scope_in" := "output_row"."scope_out";
jbe@242 2931 END LOOP;
jbe@242 2932 END;
jbe@242 2933 $$;
jbe@242 2934
jbe@242 2935 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2936 ( "member"."id"%TYPE,
jbe@242 2937 "member"."id"%TYPE )
jbe@242 2938 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
jbe@242 2939
jbe@242 2940
jbe@5 2941 CREATE FUNCTION "delegation_chain"
jbe@5 2942 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2943 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2944 "area_id_p" "area"."id"%TYPE,
jbe@5 2945 "issue_id_p" "issue"."id"%TYPE,
jbe@255 2946 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 2947 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@5 2948 RETURNS SETOF "delegation_chain_row"
jbe@5 2949 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2950 DECLARE
jbe@97 2951 "scope_v" "delegation_scope";
jbe@97 2952 "unit_id_v" "unit"."id"%TYPE;
jbe@97 2953 "area_id_v" "area"."id"%TYPE;
jbe@241 2954 "issue_row" "issue"%ROWTYPE;
jbe@5 2955 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 2956 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 2957 "output_row" "delegation_chain_row";
jbe@5 2958 "output_rows" "delegation_chain_row"[];
jbe@255 2959 "simulate_v" BOOLEAN;
jbe@255 2960 "simulate_here_v" BOOLEAN;
jbe@5 2961 "delegation_row" "delegation"%ROWTYPE;
jbe@5 2962 "row_count" INT4;
jbe@5 2963 "i" INT4;
jbe@5 2964 "loop_v" BOOLEAN;
jbe@5 2965 BEGIN
jbe@255 2966 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
jbe@255 2967 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
jbe@255 2968 END IF;
jbe@255 2969 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
jbe@255 2970 "simulate_v" := TRUE;
jbe@255 2971 ELSE
jbe@255 2972 "simulate_v" := FALSE;
jbe@255 2973 END IF;
jbe@97 2974 IF
jbe@97 2975 "unit_id_p" NOTNULL AND
jbe@97 2976 "area_id_p" ISNULL AND
jbe@97 2977 "issue_id_p" ISNULL
jbe@97 2978 THEN
jbe@97 2979 "scope_v" := 'unit';
jbe@97 2980 "unit_id_v" := "unit_id_p";
jbe@97 2981 ELSIF
jbe@97 2982 "unit_id_p" ISNULL AND
jbe@97 2983 "area_id_p" NOTNULL AND
jbe@97 2984 "issue_id_p" ISNULL
jbe@97 2985 THEN
jbe@97 2986 "scope_v" := 'area';
jbe@97 2987 "area_id_v" := "area_id_p";
jbe@97 2988 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2989 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2990 ELSIF
jbe@97 2991 "unit_id_p" ISNULL AND
jbe@97 2992 "area_id_p" ISNULL AND
jbe@97 2993 "issue_id_p" NOTNULL
jbe@97 2994 THEN
jbe@242 2995 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@242 2996 IF "issue_row"."id" ISNULL THEN
jbe@242 2997 RETURN;
jbe@242 2998 END IF;
jbe@242 2999 IF "issue_row"."closed" NOTNULL THEN
jbe@255 3000 IF "simulate_v" THEN
jbe@242 3001 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@242 3002 END IF;
jbe@242 3003 FOR "output_row" IN
jbe@242 3004 SELECT * FROM
jbe@242 3005 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@242 3006 LOOP
jbe@242 3007 RETURN NEXT "output_row";
jbe@242 3008 END LOOP;
jbe@242 3009 RETURN;
jbe@242 3010 END IF;
jbe@97 3011 "scope_v" := 'issue';
jbe@97 3012 SELECT "area_id" INTO "area_id_v"
jbe@97 3013 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 3014 SELECT "unit_id" INTO "unit_id_v"
jbe@97 3015 FROM "area" WHERE "id" = "area_id_v";
jbe@97 3016 ELSE
jbe@97 3017 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 3018 END IF;
jbe@5 3019 "visited_member_ids" := '{}';
jbe@5 3020 "loop_member_id_v" := NULL;
jbe@5 3021 "output_rows" := '{}';
jbe@5 3022 "output_row"."index" := 0;
jbe@5 3023 "output_row"."member_id" := "member_id_p";
jbe@97 3024 "output_row"."member_valid" := TRUE;
jbe@5 3025 "output_row"."participation" := FALSE;
jbe@5 3026 "output_row"."overridden" := FALSE;
jbe@86 3027 "output_row"."disabled_out" := FALSE;
jbe@5 3028 "output_row"."scope_out" := NULL;
jbe@5 3029 LOOP
jbe@5 3030 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 3031 "loop_member_id_v" := "output_row"."member_id";
jbe@5 3032 ELSE
jbe@5 3033 "visited_member_ids" :=
jbe@5 3034 "visited_member_ids" || "output_row"."member_id";
jbe@5 3035 END IF;
jbe@241 3036 IF "output_row"."participation" ISNULL THEN
jbe@241 3037 "output_row"."overridden" := NULL;
jbe@241 3038 ELSIF "output_row"."participation" THEN
jbe@5 3039 "output_row"."overridden" := TRUE;
jbe@5 3040 END IF;
jbe@5 3041 "output_row"."scope_in" := "output_row"."scope_out";
jbe@255 3042 "output_row"."member_valid" := EXISTS (
jbe@97 3043 SELECT NULL FROM "member" JOIN "privilege"
jbe@97 3044 ON "privilege"."member_id" = "member"."id"
jbe@97 3045 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 3046 WHERE "id" = "output_row"."member_id"
jbe@97 3047 AND "member"."active" AND "privilege"."voting_right"
jbe@255 3048 );
jbe@255 3049 "simulate_here_v" := (
jbe@255 3050 "simulate_v" AND
jbe@255 3051 "output_row"."member_id" = "member_id_p"
jbe@255 3052 );
jbe@255 3053 "delegation_row" := ROW(NULL);
jbe@255 3054 IF "output_row"."member_valid" OR "simulate_here_v" THEN
jbe@97 3055 IF "scope_v" = 'unit' THEN
jbe@255 3056 IF NOT "simulate_here_v" THEN
jbe@255 3057 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3058 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3059 AND "unit_id" = "unit_id_v";
jbe@255 3060 END IF;
jbe@97 3061 ELSIF "scope_v" = 'area' THEN
jbe@5 3062 "output_row"."participation" := EXISTS (
jbe@5 3063 SELECT NULL FROM "membership"
jbe@5 3064 WHERE "area_id" = "area_id_p"
jbe@5 3065 AND "member_id" = "output_row"."member_id"
jbe@5 3066 );
jbe@255 3067 IF "simulate_here_v" THEN
jbe@255 3068 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 3069 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3070 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3071 AND "unit_id" = "unit_id_v";
jbe@255 3072 END IF;
jbe@255 3073 ELSE
jbe@255 3074 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3075 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3076 AND (
jbe@255 3077 "unit_id" = "unit_id_v" OR
jbe@255 3078 "area_id" = "area_id_v"
jbe@255 3079 )
jbe@255 3080 ORDER BY "scope" DESC;
jbe@255 3081 END IF;
jbe@97 3082 ELSIF "scope_v" = 'issue' THEN
jbe@241 3083 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@241 3084 "output_row"."participation" := EXISTS (
jbe@241 3085 SELECT NULL FROM "interest"
jbe@241 3086 WHERE "issue_id" = "issue_id_p"
jbe@241 3087 AND "member_id" = "output_row"."member_id"
jbe@241 3088 );
jbe@241 3089 ELSE
jbe@241 3090 IF "output_row"."member_id" = "member_id_p" THEN
jbe@241 3091 "output_row"."participation" := EXISTS (
jbe@241 3092 SELECT NULL FROM "direct_voter"
jbe@241 3093 WHERE "issue_id" = "issue_id_p"
jbe@241 3094 AND "member_id" = "output_row"."member_id"
jbe@241 3095 );
jbe@241 3096 ELSE
jbe@241 3097 "output_row"."participation" := NULL;
jbe@241 3098 END IF;
jbe@241 3099 END IF;
jbe@255 3100 IF "simulate_here_v" THEN
jbe@255 3101 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 3102 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3103 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3104 AND (
jbe@255 3105 "unit_id" = "unit_id_v" OR
jbe@255 3106 "area_id" = "area_id_v"
jbe@255 3107 )
jbe@255 3108 ORDER BY "scope" DESC;
jbe@255 3109 END IF;
jbe@255 3110 ELSE
jbe@255 3111 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 3112 WHERE "truster_id" = "output_row"."member_id"
jbe@255 3113 AND (
jbe@255 3114 "unit_id" = "unit_id_v" OR
jbe@255 3115 "area_id" = "area_id_v" OR
jbe@255 3116 "issue_id" = "issue_id_p"
jbe@255 3117 )
jbe@255 3118 ORDER BY "scope" DESC;
jbe@255 3119 END IF;
jbe@5 3120 END IF;
jbe@5 3121 ELSE
jbe@5 3122 "output_row"."participation" := FALSE;
jbe@5 3123 END IF;
jbe@255 3124 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
jbe@97 3125 "output_row"."scope_out" := "scope_v";
jbe@5 3126 "output_rows" := "output_rows" || "output_row";
jbe@5 3127 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 3128 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 3129 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 3130 "output_rows" := "output_rows" || "output_row";
jbe@5 3131 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 3132 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 3133 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 3134 "output_row"."disabled_out" := TRUE;
jbe@86 3135 "output_rows" := "output_rows" || "output_row";
jbe@86 3136 EXIT;
jbe@5 3137 ELSE
jbe@5 3138 "output_row"."scope_out" := NULL;
jbe@5 3139 "output_rows" := "output_rows" || "output_row";
jbe@5 3140 EXIT;
jbe@5 3141 END IF;
jbe@5 3142 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 3143 "output_row"."index" := "output_row"."index" + 1;
jbe@5 3144 END LOOP;
jbe@5 3145 "row_count" := array_upper("output_rows", 1);
jbe@5 3146 "i" := 1;
jbe@5 3147 "loop_v" := FALSE;
jbe@5 3148 LOOP
jbe@5 3149 "output_row" := "output_rows"["i"];
jbe@98 3150 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 3151 IF "loop_v" THEN
jbe@5 3152 IF "i" + 1 = "row_count" THEN
jbe@5 3153 "output_row"."loop" := 'last';
jbe@5 3154 ELSIF "i" = "row_count" THEN
jbe@5 3155 "output_row"."loop" := 'repetition';
jbe@5 3156 ELSE
jbe@5 3157 "output_row"."loop" := 'intermediate';
jbe@5 3158 END IF;
jbe@5 3159 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 3160 "output_row"."loop" := 'first';
jbe@5 3161 "loop_v" := TRUE;
jbe@5 3162 END IF;
jbe@97 3163 IF "scope_v" = 'unit' THEN
jbe@5 3164 "output_row"."participation" := NULL;
jbe@5 3165 END IF;
jbe@5 3166 RETURN NEXT "output_row";
jbe@5 3167 "i" := "i" + 1;
jbe@5 3168 END LOOP;
jbe@5 3169 RETURN;
jbe@5 3170 END;
jbe@5 3171 $$;
jbe@5 3172
jbe@5 3173 COMMENT ON FUNCTION "delegation_chain"
jbe@5 3174 ( "member"."id"%TYPE,
jbe@97 3175 "unit"."id"%TYPE,
jbe@5 3176 "area"."id"%TYPE,
jbe@5 3177 "issue"."id"%TYPE,
jbe@255 3178 "member"."id"%TYPE,
jbe@255 3179 BOOLEAN )
jbe@242 3180 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
jbe@242 3181
jbe@242 3182
jbe@242 3183
jbe@242 3184 ---------------------------------------------------------
jbe@242 3185 -- Single row returning function for delegation chains --
jbe@242 3186 ---------------------------------------------------------
jbe@242 3187
jbe@242 3188
jbe@242 3189 CREATE TYPE "delegation_info_loop_type" AS ENUM
jbe@242 3190 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
jbe@240 3191
jbe@243 3192 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 3193
jbe@243 3194
jbe@240 3195 CREATE TYPE "delegation_info_type" AS (
jbe@242 3196 "own_participation" BOOLEAN,
jbe@242 3197 "own_delegation_scope" "delegation_scope",
jbe@242 3198 "first_trustee_id" INT4,
jbe@240 3199 "first_trustee_participation" BOOLEAN,
jbe@242 3200 "first_trustee_ellipsis" BOOLEAN,
jbe@242 3201 "other_trustee_id" INT4,
jbe@240 3202 "other_trustee_participation" BOOLEAN,
jbe@242 3203 "other_trustee_ellipsis" BOOLEAN,
jbe@253 3204 "delegation_loop" "delegation_info_loop_type",
jbe@253 3205 "participating_member_id" INT4 );
jbe@240 3206
jbe@243 3207 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 3208
jbe@243 3209 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
jbe@243 3210 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
jbe@243 3211 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
jbe@243 3212 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
jbe@243 3213 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
jbe@243 3214 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
jbe@243 3215 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 3216 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
jbe@243 3217 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 3218 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
jbe@243 3219
jbe@243 3220
jbe@240 3221 CREATE FUNCTION "delegation_info"
jbe@242 3222 ( "member_id_p" "member"."id"%TYPE,
jbe@242 3223 "unit_id_p" "unit"."id"%TYPE,
jbe@242 3224 "area_id_p" "area"."id"%TYPE,
jbe@242 3225 "issue_id_p" "issue"."id"%TYPE,
jbe@255 3226 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 3227 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@240 3228 RETURNS "delegation_info_type"
jbe@240 3229 LANGUAGE 'plpgsql' STABLE AS $$
jbe@240 3230 DECLARE
jbe@242 3231 "current_row" "delegation_chain_row";
jbe@242 3232 "result" "delegation_info_type";
jbe@240 3233 BEGIN
jbe@242 3234 "result"."own_participation" := FALSE;
jbe@242 3235 FOR "current_row" IN
jbe@242 3236 SELECT * FROM "delegation_chain"(
jbe@242 3237 "member_id_p",
jbe@242 3238 "unit_id_p", "area_id_p", "issue_id_p",
jbe@255 3239 "simulate_trustee_id_p", "simulate_default_p")
jbe@242 3240 LOOP
jbe@253 3241 IF
jbe@253 3242 "result"."participating_member_id" ISNULL AND
jbe@253 3243 "current_row"."participation"
jbe@253 3244 THEN
jbe@253 3245 "result"."participating_member_id" := "current_row"."member_id";
jbe@253 3246 END IF;
jbe@242 3247 IF "current_row"."member_id" = "member_id_p" THEN
jbe@242 3248 "result"."own_participation" := "current_row"."participation";
jbe@242 3249 "result"."own_delegation_scope" := "current_row"."scope_out";
jbe@242 3250 IF "current_row"."loop" = 'first' THEN
jbe@242 3251 "result"."delegation_loop" := 'own';
jbe@242 3252 END IF;
jbe@242 3253 ELSIF
jbe@242 3254 "current_row"."member_valid" AND
jbe@242 3255 ( "current_row"."loop" ISNULL OR
jbe@242 3256 "current_row"."loop" != 'repetition' )
jbe@242 3257 THEN
jbe@242 3258 IF "result"."first_trustee_id" ISNULL THEN
jbe@242 3259 "result"."first_trustee_id" := "current_row"."member_id";
jbe@242 3260 "result"."first_trustee_participation" := "current_row"."participation";
jbe@242 3261 "result"."first_trustee_ellipsis" := FALSE;
jbe@242 3262 IF "current_row"."loop" = 'first' THEN
jbe@242 3263 "result"."delegation_loop" := 'first';
jbe@242 3264 END IF;
jbe@242 3265 ELSIF "result"."other_trustee_id" ISNULL THEN
jbe@247 3266 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
jbe@242 3267 "result"."other_trustee_id" := "current_row"."member_id";
jbe@242 3268 "result"."other_trustee_participation" := TRUE;
jbe@242 3269 "result"."other_trustee_ellipsis" := FALSE;
jbe@242 3270 IF "current_row"."loop" = 'first' THEN
jbe@242 3271 "result"."delegation_loop" := 'other';
jbe@240 3272 END IF;
jbe@240 3273 ELSE
jbe@242 3274 "result"."first_trustee_ellipsis" := TRUE;
jbe@242 3275 IF "current_row"."loop" = 'first' THEN
jbe@242 3276 "result"."delegation_loop" := 'first_ellipsis';
jbe@242 3277 END IF;
jbe@242 3278 END IF;
jbe@242 3279 ELSE
jbe@242 3280 "result"."other_trustee_ellipsis" := TRUE;
jbe@242 3281 IF "current_row"."loop" = 'first' THEN
jbe@242 3282 "result"."delegation_loop" := 'other_ellipsis';
jbe@240 3283 END IF;
jbe@240 3284 END IF;
jbe@240 3285 END IF;
jbe@242 3286 END LOOP;
jbe@240 3287 RETURN "result";
jbe@240 3288 END;
jbe@240 3289 $$;
jbe@240 3290
jbe@243 3291 COMMENT ON FUNCTION "delegation_info"
jbe@243 3292 ( "member"."id"%TYPE,
jbe@243 3293 "unit"."id"%TYPE,
jbe@243 3294 "area"."id"%TYPE,
jbe@243 3295 "issue"."id"%TYPE,
jbe@255 3296 "member"."id"%TYPE,
jbe@255 3297 BOOLEAN )
jbe@243 3298 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
jbe@243 3299
jbe@240 3300
jbe@240 3301
jbe@333 3302 ---------------------------
jbe@333 3303 -- Transaction isolation --
jbe@333 3304 ---------------------------
jbe@333 3305
jbe@344 3306
jbe@333 3307 CREATE FUNCTION "require_transaction_isolation"()
jbe@333 3308 RETURNS VOID
jbe@333 3309 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 3310 BEGIN
jbe@333 3311 IF
jbe@333 3312 current_setting('transaction_isolation') NOT IN
jbe@333 3313 ('repeatable read', 'serializable')
jbe@333 3314 THEN
jbe@463 3315 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
jbe@463 3316 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
jbe@333 3317 END IF;
jbe@333 3318 RETURN;
jbe@333 3319 END;
jbe@333 3320 $$;
jbe@333 3321
jbe@344 3322 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
jbe@344 3323
jbe@333 3324
jbe@333 3325 CREATE FUNCTION "dont_require_transaction_isolation"()
jbe@333 3326 RETURNS VOID
jbe@333 3327 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 3328 BEGIN
jbe@333 3329 IF
jbe@333 3330 current_setting('transaction_isolation') IN
jbe@333 3331 ('repeatable read', 'serializable')
jbe@333 3332 THEN
jbe@333 3333 RAISE WARNING 'Unneccessary transaction isolation level: %',
jbe@333 3334 current_setting('transaction_isolation');
jbe@333 3335 END IF;
jbe@333 3336 RETURN;
jbe@333 3337 END;
jbe@333 3338 $$;
jbe@333 3339
jbe@344 3340 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
jbe@344 3341
jbe@333 3342
jbe@333 3343
jbe@491 3344 -------------------------
jbe@491 3345 -- Notification system --
jbe@491 3346 -------------------------
jbe@491 3347
jbe@491 3348 CREATE FUNCTION "get_initiatives_for_notification"
jbe@501 3349 ( "recipient_id_p" "member"."id"%TYPE )
jbe@491 3350 RETURNS SETOF "initiative_for_notification"
jbe@491 3351 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@491 3352 DECLARE
jbe@491 3353 "result_row" "initiative_for_notification"%ROWTYPE;
jbe@491 3354 "last_draft_id_v" "draft"."id"%TYPE;
jbe@491 3355 "last_suggestion_id_v" "suggestion"."id"%TYPE;
jbe@491 3356 BEGIN
jbe@491 3357 PERFORM "require_transaction_isolation"();
jbe@501 3358 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
jbe@491 3359 FOR "result_row" IN
jbe@491 3360 SELECT * FROM "initiative_for_notification"
jbe@501 3361 WHERE "recipient_id" = "recipient_id_p"
jbe@491 3362 LOOP
jbe@491 3363 SELECT "id" INTO "last_draft_id_v" FROM "draft"
jbe@499 3364 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
jbe@491 3365 ORDER BY "id" DESC LIMIT 1;
jbe@491 3366 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
jbe@499 3367 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
jbe@491 3368 ORDER BY "id" DESC LIMIT 1;
jbe@517 3369 /* compatibility with PostgreSQL 9.1 */
jbe@517 3370 DELETE FROM "notification_initiative_sent"
jbe@517 3371 WHERE "member_id" = "recipient_id_p"
jbe@517 3372 AND "initiative_id" = "result_row"."initiative_id";
jbe@517 3373 INSERT INTO "notification_initiative_sent"
jbe@517 3374 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@517 3375 VALUES (
jbe@517 3376 "recipient_id_p",
jbe@517 3377 "result_row"."initiative_id",
jbe@517 3378 "last_draft_id_v",
jbe@517 3379 "last_suggestion_id_v" );
jbe@517 3380 /* TODO: use alternative code below, requires PostgreSQL 9.5 or higher
jbe@507 3381 INSERT INTO "notification_initiative_sent"
jbe@491 3382 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@491 3383 VALUES (
jbe@501 3384 "recipient_id_p",
jbe@499 3385 "result_row"."initiative_id",
jbe@493 3386 "last_draft_id_v",
jbe@493 3387 "last_suggestion_id_v" )
jbe@491 3388 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
jbe@517 3389 "last_draft_id" = "last_draft_id_v",
jbe@517 3390 "last_suggestion_id" = "last_suggestion_id_v";
jbe@517 3391 */
jbe@491 3392 RETURN NEXT "result_row";
jbe@491 3393 END LOOP;
jbe@507 3394 DELETE FROM "notification_initiative_sent"
jbe@491 3395 USING "initiative", "issue"
jbe@507 3396 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
jbe@507 3397 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
jbe@491 3398 AND "issue"."id" = "initiative"."issue_id"
jbe@491 3399 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
jbe@505 3400 UPDATE "member" SET
jbe@506 3401 "notification_counter" = "notification_counter" + 1,
jbe@505 3402 "notification_sent" = now()
jbe@501 3403 WHERE "id" = "recipient_id_p";
jbe@491 3404 RETURN;
jbe@491 3405 END;
jbe@491 3406 $$;
jbe@491 3407
jbe@511 3408 COMMENT ON FUNCTION "get_initiatives_for_notification"
jbe@511 3409 ( "member"."id"%TYPE )
jbe@511 3410 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 3411
jbe@491 3412
jbe@491 3413
jbe@103 3414 ------------------------------------------------------------------------
jbe@103 3415 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 3416 ------------------------------------------------------------------------
jbe@103 3417
jbe@333 3418
jbe@184 3419 CREATE FUNCTION "check_activity"()
jbe@103 3420 RETURNS VOID
jbe@103 3421 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 3422 DECLARE
jbe@104 3423 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 3424 BEGIN
jbe@333 3425 PERFORM "dont_require_transaction_isolation"();
jbe@104 3426 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@104 3427 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 3428 UPDATE "member" SET "active" = FALSE
jbe@104 3429 WHERE "active" = TRUE
jbe@184 3430 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
jbe@104 3431 END IF;
jbe@103 3432 RETURN;
jbe@103 3433 END;
jbe@103 3434 $$;
jbe@103 3435
jbe@184 3436 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
jbe@103 3437
jbe@4 3438
jbe@4 3439 CREATE FUNCTION "calculate_member_counts"()
jbe@4 3440 RETURNS VOID
jbe@4 3441 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 3442 BEGIN
jbe@333 3443 PERFORM "require_transaction_isolation"();
jbe@4 3444 DELETE FROM "member_count";
jbe@5 3445 INSERT INTO "member_count" ("total_count")
jbe@5 3446 SELECT "total_count" FROM "member_count_view";
jbe@97 3447 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 3448 FROM "unit_member_count" AS "view"
jbe@97 3449 WHERE "view"."unit_id" = "unit"."id";
jbe@5 3450 UPDATE "area" SET
jbe@5 3451 "direct_member_count" = "view"."direct_member_count",
jbe@169 3452 "member_weight" = "view"."member_weight"
jbe@5 3453 FROM "area_member_count" AS "view"
jbe@5 3454 WHERE "view"."area_id" = "area"."id";
jbe@4 3455 RETURN;
jbe@4 3456 END;
jbe@4 3457 $$;
jbe@4 3458
jbe@4 3459 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 3460
jbe@4 3461
jbe@4 3462
jbe@327 3463 ------------------------------------
jbe@327 3464 -- Calculation of harmonic weight --
jbe@327 3465 ------------------------------------
jbe@310 3466
jbe@312 3467
jbe@310 3468 CREATE VIEW "remaining_harmonic_supporter_weight" AS
jbe@310 3469 SELECT
jbe@310 3470 "direct_interest_snapshot"."issue_id",
jbe@310 3471 "direct_interest_snapshot"."event",
jbe@310 3472 "direct_interest_snapshot"."member_id",
jbe@310 3473 "direct_interest_snapshot"."weight" AS "weight_num",
jbe@310 3474 count("initiative"."id") AS "weight_den"
jbe@312 3475 FROM "issue"
jbe@312 3476 JOIN "direct_interest_snapshot"
jbe@312 3477 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
jbe@312 3478 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
jbe@327 3479 JOIN "initiative"
jbe@327 3480 ON "issue"."id" = "initiative"."issue_id"
jbe@327 3481 AND "initiative"."harmonic_weight" ISNULL
jbe@310 3482 JOIN "direct_supporter_snapshot"
jbe@327 3483 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 3484 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
jbe@310 3485 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 3486 AND (
jbe@321 3487 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 3488 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 3489 )
jbe@310 3490 GROUP BY
jbe@310 3491 "direct_interest_snapshot"."issue_id",
jbe@310 3492 "direct_interest_snapshot"."event",
jbe@310 3493 "direct_interest_snapshot"."member_id",
jbe@310 3494 "direct_interest_snapshot"."weight";
jbe@310 3495
jbe@310 3496 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 3497
jbe@310 3498
jbe@310 3499 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
jbe@310 3500 SELECT
jbe@310 3501 "initiative"."issue_id",
jbe@310 3502 "initiative"."id" AS "initiative_id",
jbe@320 3503 "initiative"."admitted",
jbe@310 3504 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
jbe@310 3505 "remaining_harmonic_supporter_weight"."weight_den"
jbe@310 3506 FROM "remaining_harmonic_supporter_weight"
jbe@327 3507 JOIN "initiative"
jbe@327 3508 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
jbe@327 3509 AND "initiative"."harmonic_weight" ISNULL
jbe@310 3510 JOIN "direct_supporter_snapshot"
jbe@327 3511 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 3512 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
jbe@310 3513 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 3514 AND (
jbe@321 3515 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 3516 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 3517 )
jbe@310 3518 GROUP BY
jbe@310 3519 "initiative"."issue_id",
jbe@310 3520 "initiative"."id",
jbe@320 3521 "initiative"."admitted",
jbe@310 3522 "remaining_harmonic_supporter_weight"."weight_den";
jbe@310 3523
jbe@310 3524 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 3525
jbe@310 3526
jbe@349 3527 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
jbe@349 3528 SELECT
jbe@349 3529 "issue_id",
jbe@349 3530 "id" AS "initiative_id",
jbe@349 3531 "admitted",
jbe@349 3532 0 AS "weight_num",
jbe@349 3533 1 AS "weight_den"
jbe@349 3534 FROM "initiative"
jbe@349 3535 WHERE "harmonic_weight" ISNULL;
jbe@349 3536
jbe@349 3537 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 3538
jbe@349 3539
jbe@310 3540 CREATE FUNCTION "set_harmonic_initiative_weights"
jbe@310 3541 ( "issue_id_p" "issue"."id"%TYPE )
jbe@310 3542 RETURNS VOID
jbe@310 3543 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@310 3544 DECLARE
jbe@310 3545 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
jbe@310 3546 "i" INT4;
jbe@310 3547 "count_v" INT4;
jbe@310 3548 "summand_v" FLOAT;
jbe@310 3549 "id_ary" INT4[];
jbe@310 3550 "weight_ary" FLOAT[];
jbe@310 3551 "min_weight_v" FLOAT;
jbe@310 3552 BEGIN
jbe@333 3553 PERFORM "require_transaction_isolation"();
jbe@312 3554 UPDATE "initiative" SET "harmonic_weight" = NULL
jbe@312 3555 WHERE "issue_id" = "issue_id_p";
jbe@310 3556 LOOP
jbe@310 3557 "min_weight_v" := NULL;
jbe@310 3558 "i" := 0;
jbe@310 3559 "count_v" := 0;
jbe@310 3560 FOR "weight_row" IN
jbe@310 3561 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
jbe@310 3562 WHERE "issue_id" = "issue_id_p"
jbe@320 3563 AND (
jbe@320 3564 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@320 3565 SELECT NULL FROM "initiative"
jbe@320 3566 WHERE "issue_id" = "issue_id_p"
jbe@320 3567 AND "harmonic_weight" ISNULL
jbe@320 3568 AND coalesce("admitted", FALSE) = FALSE
jbe@320 3569 )
jbe@320 3570 )
jbe@349 3571 UNION ALL -- needed for corner cases
jbe@349 3572 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
jbe@349 3573 WHERE "issue_id" = "issue_id_p"
jbe@349 3574 AND (
jbe@349 3575 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@349 3576 SELECT NULL FROM "initiative"
jbe@349 3577 WHERE "issue_id" = "issue_id_p"
jbe@349 3578 AND "harmonic_weight" ISNULL
jbe@349 3579 AND coalesce("admitted", FALSE) = FALSE
jbe@349 3580 )
jbe@349 3581 )
jbe@310 3582 ORDER BY "initiative_id" DESC, "weight_den" DESC
jbe@320 3583 -- NOTE: non-admitted initiatives placed first (at last positions),
jbe@320 3584 -- latest initiatives treated worse in case of tie
jbe@310 3585 LOOP
jbe@310 3586 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
jbe@310 3587 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
jbe@310 3588 "i" := "i" + 1;
jbe@310 3589 "count_v" := "i";
jbe@310 3590 "id_ary"["i"] := "weight_row"."initiative_id";
jbe@310 3591 "weight_ary"["i"] := "summand_v";
jbe@310 3592 ELSE
jbe@310 3593 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
jbe@310 3594 END IF;
jbe@310 3595 END LOOP;
jbe@310 3596 EXIT WHEN "count_v" = 0;
jbe@310 3597 "i" := 1;
jbe@310 3598 LOOP
jbe@313 3599 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
jbe@310 3600 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
jbe@310 3601 "min_weight_v" := "weight_ary"["i"];
jbe@310 3602 END IF;
jbe@310 3603 "i" := "i" + 1;
jbe@310 3604 EXIT WHEN "i" > "count_v";
jbe@310 3605 END LOOP;
jbe@310 3606 "i" := 1;
jbe@310 3607 LOOP
jbe@310 3608 IF "weight_ary"["i"] = "min_weight_v" THEN
jbe@310 3609 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
jbe@310 3610 WHERE "id" = "id_ary"["i"];
jbe@310 3611 EXIT;
jbe@310 3612 END IF;
jbe@310 3613 "i" := "i" + 1;
jbe@310 3614 END LOOP;
jbe@310 3615 END LOOP;
jbe@316 3616 UPDATE "initiative" SET "harmonic_weight" = 0
jbe@316 3617 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
jbe@310 3618 END;
jbe@310 3619 $$;
jbe@310 3620
jbe@310 3621 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
jbe@310 3622 ( "issue"."id"%TYPE )
jbe@310 3623 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
jbe@310 3624
jbe@310 3625
jbe@312 3626
jbe@0 3627 ------------------------------
jbe@0 3628 -- Calculation of snapshots --
jbe@0 3629 ------------------------------
jbe@0 3630
jbe@312 3631
jbe@0 3632 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3633 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3634 "member_id_p" "member"."id"%TYPE,
jbe@0 3635 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3636 RETURNS "direct_population_snapshot"."weight"%TYPE
jbe@0 3637 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3638 DECLARE
jbe@0 3639 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3640 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3641 "weight_v" INT4;
jbe@8 3642 "sub_weight_v" INT4;
jbe@0 3643 BEGIN
jbe@336 3644 PERFORM "require_transaction_isolation"();
jbe@0 3645 "weight_v" := 0;
jbe@0 3646 FOR "issue_delegation_row" IN
jbe@0 3647 SELECT * FROM "issue_delegation"
jbe@0 3648 WHERE "trustee_id" = "member_id_p"
jbe@0 3649 AND "issue_id" = "issue_id_p"
jbe@0 3650 LOOP
jbe@0 3651 IF NOT EXISTS (
jbe@0 3652 SELECT NULL FROM "direct_population_snapshot"
jbe@0 3653 WHERE "issue_id" = "issue_id_p"
jbe@0 3654 AND "event" = 'periodic'
jbe@0 3655 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3656 ) AND NOT EXISTS (
jbe@0 3657 SELECT NULL FROM "delegating_population_snapshot"
jbe@0 3658 WHERE "issue_id" = "issue_id_p"
jbe@0 3659 AND "event" = 'periodic'
jbe@0 3660 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3661 ) THEN
jbe@0 3662 "delegate_member_ids_v" :=
jbe@0 3663 "member_id_p" || "delegate_member_ids_p";
jbe@10 3664 INSERT INTO "delegating_population_snapshot" (
jbe@10 3665 "issue_id",
jbe@10 3666 "event",
jbe@10 3667 "member_id",
jbe@10 3668 "scope",
jbe@10 3669 "delegate_member_ids"
jbe@10 3670 ) VALUES (
jbe@0 3671 "issue_id_p",
jbe@0 3672 'periodic',
jbe@0 3673 "issue_delegation_row"."truster_id",
jbe@10 3674 "issue_delegation_row"."scope",
jbe@0 3675 "delegate_member_ids_v"
jbe@0 3676 );
jbe@8 3677 "sub_weight_v" := 1 +
jbe@0 3678 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3679 "issue_id_p",
jbe@0 3680 "issue_delegation_row"."truster_id",
jbe@0 3681 "delegate_member_ids_v"
jbe@0 3682 );
jbe@8 3683 UPDATE "delegating_population_snapshot"
jbe@8 3684 SET "weight" = "sub_weight_v"
jbe@8 3685 WHERE "issue_id" = "issue_id_p"
jbe@8 3686 AND "event" = 'periodic'
jbe@8 3687 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3688 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3689 END IF;
jbe@0 3690 END LOOP;
jbe@0 3691 RETURN "weight_v";
jbe@0 3692 END;
jbe@0 3693 $$;
jbe@0 3694
jbe@0 3695 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3696 ( "issue"."id"%TYPE,
jbe@0 3697 "member"."id"%TYPE,
jbe@0 3698 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3699 IS 'Helper function for "create_population_snapshot" function';
jbe@0 3700
jbe@0 3701
jbe@0 3702 CREATE FUNCTION "create_population_snapshot"
jbe@0 3703 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3704 RETURNS VOID
jbe@0 3705 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3706 DECLARE
jbe@0 3707 "member_id_v" "member"."id"%TYPE;
jbe@0 3708 BEGIN
jbe@336 3709 PERFORM "require_transaction_isolation"();
jbe@0 3710 DELETE FROM "direct_population_snapshot"
jbe@0 3711 WHERE "issue_id" = "issue_id_p"
jbe@0 3712 AND "event" = 'periodic';
jbe@0 3713 DELETE FROM "delegating_population_snapshot"
jbe@0 3714 WHERE "issue_id" = "issue_id_p"
jbe@0 3715 AND "event" = 'periodic';
jbe@0 3716 INSERT INTO "direct_population_snapshot"
jbe@54 3717 ("issue_id", "event", "member_id")
jbe@54 3718 SELECT
jbe@54 3719 "issue_id_p" AS "issue_id",
jbe@54 3720 'periodic'::"snapshot_event" AS "event",
jbe@54 3721 "member"."id" AS "member_id"
jbe@54 3722 FROM "issue"
jbe@54 3723 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@54 3724 JOIN "membership" ON "area"."id" = "membership"."area_id"
jbe@54 3725 JOIN "member" ON "membership"."member_id" = "member"."id"
jbe@97 3726 JOIN "privilege"
jbe@97 3727 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3728 AND "privilege"."member_id" = "member"."id"
jbe@54 3729 WHERE "issue"."id" = "issue_id_p"
jbe@97 3730 AND "member"."active" AND "privilege"."voting_right"
jbe@54 3731 UNION
jbe@54 3732 SELECT
jbe@54 3733 "issue_id_p" AS "issue_id",
jbe@54 3734 'periodic'::"snapshot_event" AS "event",
jbe@54 3735 "member"."id" AS "member_id"
jbe@97 3736 FROM "issue"
jbe@97 3737 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3738 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3739 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3740 JOIN "privilege"
jbe@97 3741 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3742 AND "privilege"."member_id" = "member"."id"
jbe@97 3743 WHERE "issue"."id" = "issue_id_p"
jbe@97 3744 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3745 FOR "member_id_v" IN
jbe@0 3746 SELECT "member_id" FROM "direct_population_snapshot"
jbe@0 3747 WHERE "issue_id" = "issue_id_p"
jbe@0 3748 AND "event" = 'periodic'
jbe@0 3749 LOOP
jbe@0 3750 UPDATE "direct_population_snapshot" SET
jbe@0 3751 "weight" = 1 +
jbe@0 3752 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3753 "issue_id_p",
jbe@0 3754 "member_id_v",
jbe@0 3755 '{}'
jbe@0 3756 )
jbe@0 3757 WHERE "issue_id" = "issue_id_p"
jbe@0 3758 AND "event" = 'periodic'
jbe@0 3759 AND "member_id" = "member_id_v";
jbe@0 3760 END LOOP;
jbe@0 3761 RETURN;
jbe@0 3762 END;
jbe@0 3763 $$;
jbe@0 3764
jbe@0 3765 COMMENT ON FUNCTION "create_population_snapshot"
jbe@67 3766 ( "issue"."id"%TYPE )
jbe@0 3767 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 3768
jbe@0 3769
jbe@0 3770 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3771 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3772 "member_id_p" "member"."id"%TYPE,
jbe@0 3773 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3774 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 3775 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3776 DECLARE
jbe@0 3777 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3778 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3779 "weight_v" INT4;
jbe@8 3780 "sub_weight_v" INT4;
jbe@0 3781 BEGIN
jbe@336 3782 PERFORM "require_transaction_isolation"();
jbe@0 3783 "weight_v" := 0;
jbe@0 3784 FOR "issue_delegation_row" IN
jbe@0 3785 SELECT * FROM "issue_delegation"
jbe@0 3786 WHERE "trustee_id" = "member_id_p"
jbe@0 3787 AND "issue_id" = "issue_id_p"
jbe@0 3788 LOOP
jbe@0 3789 IF NOT EXISTS (
jbe@0 3790 SELECT NULL FROM "direct_interest_snapshot"
jbe@0 3791 WHERE "issue_id" = "issue_id_p"
jbe@0 3792 AND "event" = 'periodic'
jbe@0 3793 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3794 ) AND NOT EXISTS (
jbe@0 3795 SELECT NULL FROM "delegating_interest_snapshot"
jbe@0 3796 WHERE "issue_id" = "issue_id_p"
jbe@0 3797 AND "event" = 'periodic'
jbe@0 3798 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3799 ) THEN
jbe@0 3800 "delegate_member_ids_v" :=
jbe@0 3801 "member_id_p" || "delegate_member_ids_p";
jbe@10 3802 INSERT INTO "delegating_interest_snapshot" (
jbe@10 3803 "issue_id",
jbe@10 3804 "event",
jbe@10 3805 "member_id",
jbe@10 3806 "scope",
jbe@10 3807 "delegate_member_ids"
jbe@10 3808 ) VALUES (
jbe@0 3809 "issue_id_p",
jbe@0 3810 'periodic',
jbe@0 3811 "issue_delegation_row"."truster_id",
jbe@10 3812 "issue_delegation_row"."scope",
jbe@0 3813 "delegate_member_ids_v"
jbe@0 3814 );
jbe@8 3815 "sub_weight_v" := 1 +
jbe@0 3816 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3817 "issue_id_p",
jbe@0 3818 "issue_delegation_row"."truster_id",
jbe@0 3819 "delegate_member_ids_v"
jbe@0 3820 );
jbe@8 3821 UPDATE "delegating_interest_snapshot"
jbe@8 3822 SET "weight" = "sub_weight_v"
jbe@8 3823 WHERE "issue_id" = "issue_id_p"
jbe@8 3824 AND "event" = 'periodic'
jbe@8 3825 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3826 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3827 END IF;
jbe@0 3828 END LOOP;
jbe@0 3829 RETURN "weight_v";
jbe@0 3830 END;
jbe@0 3831 $$;
jbe@0 3832
jbe@0 3833 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3834 ( "issue"."id"%TYPE,
jbe@0 3835 "member"."id"%TYPE,
jbe@0 3836 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3837 IS 'Helper function for "create_interest_snapshot" function';
jbe@0 3838
jbe@0 3839
jbe@0 3840 CREATE FUNCTION "create_interest_snapshot"
jbe@0 3841 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3842 RETURNS VOID
jbe@0 3843 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3844 DECLARE
jbe@0 3845 "member_id_v" "member"."id"%TYPE;
jbe@0 3846 BEGIN
jbe@336 3847 PERFORM "require_transaction_isolation"();
jbe@0 3848 DELETE FROM "direct_interest_snapshot"
jbe@0 3849 WHERE "issue_id" = "issue_id_p"
jbe@0 3850 AND "event" = 'periodic';
jbe@0 3851 DELETE FROM "delegating_interest_snapshot"
jbe@0 3852 WHERE "issue_id" = "issue_id_p"
jbe@0 3853 AND "event" = 'periodic';
jbe@0 3854 DELETE FROM "direct_supporter_snapshot"
jbe@325 3855 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 3856 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 3857 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 3858 AND "direct_supporter_snapshot"."event" = 'periodic';
jbe@0 3859 INSERT INTO "direct_interest_snapshot"
jbe@144 3860 ("issue_id", "event", "member_id")
jbe@0 3861 SELECT
jbe@0 3862 "issue_id_p" AS "issue_id",
jbe@0 3863 'periodic' AS "event",
jbe@144 3864 "member"."id" AS "member_id"
jbe@97 3865 FROM "issue"
jbe@97 3866 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3867 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3868 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3869 JOIN "privilege"
jbe@97 3870 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3871 AND "privilege"."member_id" = "member"."id"
jbe@97 3872 WHERE "issue"."id" = "issue_id_p"
jbe@97 3873 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3874 FOR "member_id_v" IN
jbe@0 3875 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@0 3876 WHERE "issue_id" = "issue_id_p"
jbe@0 3877 AND "event" = 'periodic'
jbe@0 3878 LOOP
jbe@0 3879 UPDATE "direct_interest_snapshot" SET
jbe@0 3880 "weight" = 1 +
jbe@0 3881 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3882 "issue_id_p",
jbe@0 3883 "member_id_v",
jbe@0 3884 '{}'
jbe@0 3885 )
jbe@0 3886 WHERE "issue_id" = "issue_id_p"
jbe@0 3887 AND "event" = 'periodic'
jbe@0 3888 AND "member_id" = "member_id_v";
jbe@0 3889 END LOOP;
jbe@0 3890 INSERT INTO "direct_supporter_snapshot"
jbe@0 3891 ( "issue_id", "initiative_id", "event", "member_id",
jbe@204 3892 "draft_id", "informed", "satisfied" )
jbe@0 3893 SELECT
jbe@96 3894 "issue_id_p" AS "issue_id",
jbe@96 3895 "initiative"."id" AS "initiative_id",
jbe@96 3896 'periodic' AS "event",
jbe@96 3897 "supporter"."member_id" AS "member_id",
jbe@204 3898 "supporter"."draft_id" AS "draft_id",
jbe@0 3899 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@0 3900 NOT EXISTS (
jbe@0 3901 SELECT NULL FROM "critical_opinion"
jbe@0 3902 WHERE "initiative_id" = "initiative"."id"
jbe@96 3903 AND "member_id" = "supporter"."member_id"
jbe@0 3904 ) AS "satisfied"
jbe@96 3905 FROM "initiative"
jbe@96 3906 JOIN "supporter"
jbe@0 3907 ON "supporter"."initiative_id" = "initiative"."id"
jbe@0 3908 JOIN "current_draft"
jbe@0 3909 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@0 3910 JOIN "direct_interest_snapshot"
jbe@96 3911 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@0 3912 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@3 3913 AND "event" = 'periodic'
jbe@96 3914 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@0 3915 RETURN;
jbe@0 3916 END;
jbe@0 3917 $$;
jbe@0 3918
jbe@0 3919 COMMENT ON FUNCTION "create_interest_snapshot"
jbe@0 3920 ( "issue"."id"%TYPE )
jbe@0 3921 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 3922
jbe@0 3923
jbe@0 3924 CREATE FUNCTION "create_snapshot"
jbe@0 3925 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3926 RETURNS VOID
jbe@0 3927 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3928 DECLARE
jbe@0 3929 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3930 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@0 3931 BEGIN
jbe@333 3932 PERFORM "require_transaction_isolation"();
jbe@0 3933 PERFORM "create_population_snapshot"("issue_id_p");
jbe@0 3934 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@0 3935 UPDATE "issue" SET
jbe@331 3936 "snapshot" = coalesce("phase_finished", now()),
jbe@8 3937 "latest_snapshot_event" = 'periodic',
jbe@0 3938 "population" = (
jbe@0 3939 SELECT coalesce(sum("weight"), 0)
jbe@0 3940 FROM "direct_population_snapshot"
jbe@0 3941 WHERE "issue_id" = "issue_id_p"
jbe@0 3942 AND "event" = 'periodic'
jbe@0 3943 )
jbe@0 3944 WHERE "id" = "issue_id_p";
jbe@0 3945 FOR "initiative_id_v" IN
jbe@0 3946 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@0 3947 LOOP
jbe@0 3948 UPDATE "initiative" SET
jbe@0 3949 "supporter_count" = (
jbe@0 3950 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3951 FROM "direct_interest_snapshot" AS "di"
jbe@0 3952 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3953 ON "di"."member_id" = "ds"."member_id"
jbe@0 3954 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3955 AND "di"."event" = 'periodic'
jbe@0 3956 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3957 AND "ds"."event" = 'periodic'
jbe@0 3958 ),
jbe@0 3959 "informed_supporter_count" = (
jbe@0 3960 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3961 FROM "direct_interest_snapshot" AS "di"
jbe@0 3962 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3963 ON "di"."member_id" = "ds"."member_id"
jbe@0 3964 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3965 AND "di"."event" = 'periodic'
jbe@0 3966 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3967 AND "ds"."event" = 'periodic'
jbe@0 3968 AND "ds"."informed"
jbe@0 3969 ),
jbe@0 3970 "satisfied_supporter_count" = (
jbe@0 3971 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3972 FROM "direct_interest_snapshot" AS "di"
jbe@0 3973 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3974 ON "di"."member_id" = "ds"."member_id"
jbe@0 3975 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3976 AND "di"."event" = 'periodic'
jbe@0 3977 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3978 AND "ds"."event" = 'periodic'
jbe@0 3979 AND "ds"."satisfied"
jbe@0 3980 ),
jbe@0 3981 "satisfied_informed_supporter_count" = (
jbe@0 3982 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3983 FROM "direct_interest_snapshot" AS "di"
jbe@0 3984 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3985 ON "di"."member_id" = "ds"."member_id"
jbe@0 3986 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3987 AND "di"."event" = 'periodic'
jbe@0 3988 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3989 AND "ds"."event" = 'periodic'
jbe@0 3990 AND "ds"."informed"
jbe@0 3991 AND "ds"."satisfied"
jbe@0 3992 )
jbe@0 3993 WHERE "id" = "initiative_id_v";
jbe@0 3994 FOR "suggestion_id_v" IN
jbe@0 3995 SELECT "id" FROM "suggestion"
jbe@0 3996 WHERE "initiative_id" = "initiative_id_v"
jbe@0 3997 LOOP
jbe@0 3998 UPDATE "suggestion" SET
jbe@0 3999 "minus2_unfulfilled_count" = (
jbe@0 4000 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4001 FROM "issue" CROSS JOIN "opinion"
jbe@36 4002 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4003 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4004 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4005 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4006 WHERE "issue"."id" = "issue_id_p"
jbe@36 4007 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4008 AND "opinion"."degree" = -2
jbe@0 4009 AND "opinion"."fulfilled" = FALSE
jbe@0 4010 ),
jbe@0 4011 "minus2_fulfilled_count" = (
jbe@0 4012 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4013 FROM "issue" CROSS JOIN "opinion"
jbe@36 4014 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4015 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4016 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4017 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4018 WHERE "issue"."id" = "issue_id_p"
jbe@36 4019 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4020 AND "opinion"."degree" = -2
jbe@0 4021 AND "opinion"."fulfilled" = TRUE
jbe@0 4022 ),
jbe@0 4023 "minus1_unfulfilled_count" = (
jbe@0 4024 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4025 FROM "issue" CROSS JOIN "opinion"
jbe@36 4026 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4027 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4028 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4029 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4030 WHERE "issue"."id" = "issue_id_p"
jbe@36 4031 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4032 AND "opinion"."degree" = -1
jbe@0 4033 AND "opinion"."fulfilled" = FALSE
jbe@0 4034 ),
jbe@0 4035 "minus1_fulfilled_count" = (
jbe@0 4036 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4037 FROM "issue" CROSS JOIN "opinion"
jbe@36 4038 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4039 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4040 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4041 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4042 WHERE "issue"."id" = "issue_id_p"
jbe@36 4043 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4044 AND "opinion"."degree" = -1
jbe@0 4045 AND "opinion"."fulfilled" = TRUE
jbe@0 4046 ),
jbe@0 4047 "plus1_unfulfilled_count" = (
jbe@0 4048 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4049 FROM "issue" CROSS JOIN "opinion"
jbe@36 4050 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4051 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4052 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4053 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4054 WHERE "issue"."id" = "issue_id_p"
jbe@36 4055 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4056 AND "opinion"."degree" = 1
jbe@0 4057 AND "opinion"."fulfilled" = FALSE
jbe@0 4058 ),
jbe@0 4059 "plus1_fulfilled_count" = (
jbe@0 4060 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4061 FROM "issue" CROSS JOIN "opinion"
jbe@36 4062 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4063 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4064 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4065 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4066 WHERE "issue"."id" = "issue_id_p"
jbe@36 4067 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4068 AND "opinion"."degree" = 1
jbe@0 4069 AND "opinion"."fulfilled" = TRUE
jbe@0 4070 ),
jbe@0 4071 "plus2_unfulfilled_count" = (
jbe@0 4072 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4073 FROM "issue" CROSS JOIN "opinion"
jbe@36 4074 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4075 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4076 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4077 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4078 WHERE "issue"."id" = "issue_id_p"
jbe@36 4079 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4080 AND "opinion"."degree" = 2
jbe@0 4081 AND "opinion"."fulfilled" = FALSE
jbe@0 4082 ),
jbe@0 4083 "plus2_fulfilled_count" = (
jbe@0 4084 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 4085 FROM "issue" CROSS JOIN "opinion"
jbe@36 4086 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 4087 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 4088 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 4089 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 4090 WHERE "issue"."id" = "issue_id_p"
jbe@36 4091 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 4092 AND "opinion"."degree" = 2
jbe@0 4093 AND "opinion"."fulfilled" = TRUE
jbe@0 4094 )
jbe@0 4095 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@0 4096 END LOOP;
jbe@0 4097 END LOOP;
jbe@0 4098 RETURN;
jbe@0 4099 END;
jbe@0 4100 $$;
jbe@0 4101
jbe@0 4102 COMMENT ON FUNCTION "create_snapshot"
jbe@0 4103 ( "issue"."id"%TYPE )
jbe@0 4104 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 4105
jbe@0 4106
jbe@0 4107 CREATE FUNCTION "set_snapshot_event"
jbe@0 4108 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 4109 "event_p" "snapshot_event" )
jbe@0 4110 RETURNS VOID
jbe@0 4111 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@21 4112 DECLARE
jbe@21 4113 "event_v" "issue"."latest_snapshot_event"%TYPE;
jbe@0 4114 BEGIN
jbe@333 4115 PERFORM "require_transaction_isolation"();
jbe@21 4116 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
jbe@21 4117 WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@8 4118 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
jbe@8 4119 WHERE "id" = "issue_id_p";
jbe@3 4120 UPDATE "direct_population_snapshot" SET "event" = "event_p"
jbe@21 4121 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4122 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
jbe@21 4123 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4124 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
jbe@21 4125 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4126 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
jbe@21 4127 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 4128 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
jbe@325 4129 FROM "initiative" -- NOTE: due to missing index on issue_id
jbe@325 4130 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 4131 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 4132 AND "direct_supporter_snapshot"."event" = "event_v";
jbe@0 4133 RETURN;
jbe@0 4134 END;
jbe@0 4135 $$;
jbe@0 4136
jbe@0 4137 COMMENT ON FUNCTION "set_snapshot_event"
jbe@0 4138 ( "issue"."id"%TYPE,
jbe@0 4139 "snapshot_event" )
jbe@0 4140 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
jbe@0 4141
jbe@0 4142
jbe@0 4143
jbe@0 4144 -----------------------
jbe@0 4145 -- Counting of votes --
jbe@0 4146 -----------------------
jbe@0 4147
jbe@0 4148
jbe@5 4149 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 4150 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 4151 "member_id_p" "member"."id"%TYPE,
jbe@0 4152 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 4153 RETURNS "direct_voter"."weight"%TYPE
jbe@0 4154 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4155 DECLARE
jbe@0 4156 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 4157 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 4158 "weight_v" INT4;
jbe@8 4159 "sub_weight_v" INT4;
jbe@0 4160 BEGIN
jbe@336 4161 PERFORM "require_transaction_isolation"();
jbe@0 4162 "weight_v" := 0;
jbe@0 4163 FOR "issue_delegation_row" IN
jbe@0 4164 SELECT * FROM "issue_delegation"
jbe@0 4165 WHERE "trustee_id" = "member_id_p"
jbe@0 4166 AND "issue_id" = "issue_id_p"
jbe@0 4167 LOOP
jbe@0 4168 IF NOT EXISTS (
jbe@0 4169 SELECT NULL FROM "direct_voter"
jbe@0 4170 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4171 AND "issue_id" = "issue_id_p"
jbe@0 4172 ) AND NOT EXISTS (
jbe@0 4173 SELECT NULL FROM "delegating_voter"
jbe@0 4174 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 4175 AND "issue_id" = "issue_id_p"
jbe@0 4176 ) THEN
jbe@0 4177 "delegate_member_ids_v" :=
jbe@0 4178 "member_id_p" || "delegate_member_ids_p";
jbe@10 4179 INSERT INTO "delegating_voter" (
jbe@10 4180 "issue_id",
jbe@10 4181 "member_id",
jbe@10 4182 "scope",
jbe@10 4183 "delegate_member_ids"
jbe@10 4184 ) VALUES (
jbe@5 4185 "issue_id_p",
jbe@5 4186 "issue_delegation_row"."truster_id",
jbe@10 4187 "issue_delegation_row"."scope",
jbe@5 4188 "delegate_member_ids_v"
jbe@5 4189 );
jbe@8 4190 "sub_weight_v" := 1 +
jbe@8 4191 "weight_of_added_vote_delegations"(
jbe@8 4192 "issue_id_p",
jbe@8 4193 "issue_delegation_row"."truster_id",
jbe@8 4194 "delegate_member_ids_v"
jbe@8 4195 );
jbe@8 4196 UPDATE "delegating_voter"
jbe@8 4197 SET "weight" = "sub_weight_v"
jbe@8 4198 WHERE "issue_id" = "issue_id_p"
jbe@8 4199 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 4200 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 4201 END IF;
jbe@0 4202 END LOOP;
jbe@0 4203 RETURN "weight_v";
jbe@0 4204 END;
jbe@0 4205 $$;
jbe@0 4206
jbe@5 4207 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 4208 ( "issue"."id"%TYPE,
jbe@0 4209 "member"."id"%TYPE,
jbe@0 4210 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 4211 IS 'Helper function for "add_vote_delegations" function';
jbe@0 4212
jbe@0 4213
jbe@0 4214 CREATE FUNCTION "add_vote_delegations"
jbe@0 4215 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4216 RETURNS VOID
jbe@0 4217 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4218 DECLARE
jbe@0 4219 "member_id_v" "member"."id"%TYPE;
jbe@0 4220 BEGIN
jbe@336 4221 PERFORM "require_transaction_isolation"();
jbe@0 4222 FOR "member_id_v" IN
jbe@0 4223 SELECT "member_id" FROM "direct_voter"
jbe@0 4224 WHERE "issue_id" = "issue_id_p"
jbe@0 4225 LOOP
jbe@0 4226 UPDATE "direct_voter" SET
jbe@5 4227 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 4228 "issue_id_p",
jbe@0 4229 "member_id_v",
jbe@0 4230 '{}'
jbe@0 4231 )
jbe@0 4232 WHERE "member_id" = "member_id_v"
jbe@0 4233 AND "issue_id" = "issue_id_p";
jbe@0 4234 END LOOP;
jbe@0 4235 RETURN;
jbe@0 4236 END;
jbe@0 4237 $$;
jbe@0 4238
jbe@0 4239 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 4240 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4241 IS 'Helper function for "close_voting" function';
jbe@0 4242
jbe@0 4243
jbe@0 4244 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 4245 RETURNS VOID
jbe@0 4246 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4247 DECLARE
jbe@97 4248 "area_id_v" "area"."id"%TYPE;
jbe@97 4249 "unit_id_v" "unit"."id"%TYPE;
jbe@0 4250 "member_id_v" "member"."id"%TYPE;
jbe@0 4251 BEGIN
jbe@333 4252 PERFORM "require_transaction_isolation"();
jbe@129 4253 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 4254 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@383 4255 -- override protection triggers:
jbe@385 4256 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 4257 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@285 4258 -- delete timestamp of voting comment:
jbe@285 4259 UPDATE "direct_voter" SET "comment_changed" = NULL
jbe@285 4260 WHERE "issue_id" = "issue_id_p";
jbe@169 4261 -- delete delegating votes (in cases of manual reset of issue state):
jbe@0 4262 DELETE FROM "delegating_voter"
jbe@0 4263 WHERE "issue_id" = "issue_id_p";
jbe@169 4264 -- delete votes from non-privileged voters:
jbe@97 4265 DELETE FROM "direct_voter"
jbe@97 4266 USING (
jbe@97 4267 SELECT
jbe@97 4268 "direct_voter"."member_id"
jbe@97 4269 FROM "direct_voter"
jbe@97 4270 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@97 4271 LEFT JOIN "privilege"
jbe@97 4272 ON "privilege"."unit_id" = "unit_id_v"
jbe@97 4273 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 4274 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 4275 "member"."active" = FALSE OR
jbe@97 4276 "privilege"."voting_right" ISNULL OR
jbe@97 4277 "privilege"."voting_right" = FALSE
jbe@97 4278 )
jbe@97 4279 ) AS "subquery"
jbe@97 4280 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 4281 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@169 4282 -- consider delegations:
jbe@0 4283 UPDATE "direct_voter" SET "weight" = 1
jbe@0 4284 WHERE "issue_id" = "issue_id_p";
jbe@0 4285 PERFORM "add_vote_delegations"("issue_id_p");
jbe@414 4286 -- mark first preferences:
jbe@414 4287 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
jbe@414 4288 FROM (
jbe@414 4289 SELECT
jbe@414 4290 "vote"."initiative_id",
jbe@414 4291 "vote"."member_id",
jbe@414 4292 CASE WHEN "vote"."grade" > 0 THEN
jbe@414 4293 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
jbe@414 4294 ELSE NULL
jbe@414 4295 END AS "first_preference"
jbe@415 4296 FROM "vote"
jbe@415 4297 JOIN "initiative" -- NOTE: due to missing index on issue_id
jbe@415 4298 ON "vote"."issue_id" = "initiative"."issue_id"
jbe@415 4299 JOIN "vote" AS "agg"
jbe@415 4300 ON "initiative"."id" = "agg"."initiative_id"
jbe@415 4301 AND "vote"."member_id" = "agg"."member_id"
jbe@433 4302 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
jbe@414 4303 ) AS "subquery"
jbe@414 4304 WHERE "vote"."issue_id" = "issue_id_p"
jbe@414 4305 AND "vote"."initiative_id" = "subquery"."initiative_id"
jbe@414 4306 AND "vote"."member_id" = "subquery"."member_id";
jbe@385 4307 -- finish overriding protection triggers (avoids garbage):
jbe@385 4308 DELETE FROM "temporary_transaction_data"
jbe@385 4309 WHERE "key" = 'override_protection_triggers';
jbe@137 4310 -- materialize battle_view:
jbe@61 4311 -- NOTE: "closed" column of issue must be set at this point
jbe@61 4312 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 4313 INSERT INTO "battle" (
jbe@61 4314 "issue_id",
jbe@61 4315 "winning_initiative_id", "losing_initiative_id",
jbe@61 4316 "count"
jbe@61 4317 ) SELECT
jbe@61 4318 "issue_id",
jbe@61 4319 "winning_initiative_id", "losing_initiative_id",
jbe@61 4320 "count"
jbe@61 4321 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@331 4322 -- set voter count:
jbe@331 4323 UPDATE "issue" SET
jbe@331 4324 "voter_count" = (
jbe@331 4325 SELECT coalesce(sum("weight"), 0)
jbe@331 4326 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@331 4327 )
jbe@331 4328 WHERE "id" = "issue_id_p";
jbe@437 4329 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@437 4330 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
jbe@437 4331 UPDATE "initiative" SET
jbe@437 4332 "first_preference_votes" = 0,
jbe@437 4333 "positive_votes" = "battle_win"."count",
jbe@437 4334 "negative_votes" = "battle_lose"."count"
jbe@437 4335 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@437 4336 WHERE
jbe@437 4337 "battle_win"."issue_id" = "issue_id_p" AND
jbe@437 4338 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@437 4339 "battle_win"."losing_initiative_id" ISNULL AND
jbe@437 4340 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@437 4341 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@437 4342 "battle_lose"."winning_initiative_id" ISNULL;
jbe@414 4343 -- calculate "first_preference_votes":
jbe@437 4344 -- NOTE: will only set values not equal to zero
jbe@437 4345 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
jbe@414 4346 FROM (
jbe@414 4347 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
jbe@414 4348 FROM "vote" JOIN "direct_voter"
jbe@414 4349 ON "vote"."issue_id" = "direct_voter"."issue_id"
jbe@414 4350 AND "vote"."member_id" = "direct_voter"."member_id"
jbe@414 4351 WHERE "vote"."first_preference"
jbe@414 4352 GROUP BY "vote"."initiative_id"
jbe@414 4353 ) AS "subquery"
jbe@414 4354 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@414 4355 AND "initiative"."admitted"
jbe@414 4356 AND "initiative"."id" = "subquery"."initiative_id";
jbe@0 4357 END;
jbe@0 4358 $$;
jbe@0 4359
jbe@0 4360 COMMENT ON FUNCTION "close_voting"
jbe@0 4361 ( "issue"."id"%TYPE )
jbe@0 4362 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 4363
jbe@0 4364
jbe@30 4365 CREATE FUNCTION "defeat_strength"
jbe@424 4366 ( "positive_votes_p" INT4,
jbe@424 4367 "negative_votes_p" INT4,
jbe@424 4368 "defeat_strength_p" "defeat_strength" )
jbe@30 4369 RETURNS INT8
jbe@30 4370 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 4371 BEGIN
jbe@424 4372 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
jbe@424 4373 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 4374 RETURN "positive_votes_p";
jbe@424 4375 ELSE
jbe@424 4376 RETURN 0;
jbe@424 4377 END IF;
jbe@30 4378 ELSE
jbe@424 4379 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 4380 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@424 4381 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@424 4382 RETURN 0;
jbe@424 4383 ELSE
jbe@424 4384 RETURN -1;
jbe@424 4385 END IF;
jbe@30 4386 END IF;
jbe@30 4387 END;
jbe@30 4388 $$;
jbe@30 4389
jbe@425 4390 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 4391
jbe@30 4392
jbe@423 4393 CREATE FUNCTION "secondary_link_strength"
jbe@426 4394 ( "initiative1_ord_p" INT4,
jbe@426 4395 "initiative2_ord_p" INT4,
jbe@424 4396 "tie_breaking_p" "tie_breaking" )
jbe@423 4397 RETURNS INT8
jbe@423 4398 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@423 4399 BEGIN
jbe@426 4400 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
jbe@423 4401 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
jbe@423 4402 END IF;
jbe@423 4403 RETURN (
jbe@426 4404 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
jbe@426 4405 0
jbe@424 4406 ELSE
jbe@426 4407 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
jbe@426 4408 1::INT8 << 62
jbe@426 4409 ELSE 0 END
jbe@426 4410 +
jbe@426 4411 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
jbe@426 4412 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
jbe@426 4413 ELSE
jbe@426 4414 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
jbe@426 4415 END
jbe@424 4416 END
jbe@423 4417 );
jbe@423 4418 END;
jbe@423 4419 $$;
jbe@423 4420
jbe@424 4421 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 4422
jbe@423 4423
jbe@426 4424 CREATE TYPE "link_strength" AS (
jbe@426 4425 "primary" INT8,
jbe@426 4426 "secondary" INT8 );
jbe@426 4427
jbe@428 4428 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 4429
jbe@427 4430
jbe@427 4431 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
jbe@427 4432 RETURNS "link_strength"[][]
jbe@427 4433 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@427 4434 DECLARE
jbe@427 4435 "dimension_v" INT4;
jbe@427 4436 "matrix_p" "link_strength"[][];
jbe@427 4437 "i" INT4;
jbe@427 4438 "j" INT4;
jbe@427 4439 "k" INT4;
jbe@427 4440 BEGIN
jbe@427 4441 "dimension_v" := array_upper("matrix_d", 1);
jbe@427 4442 "matrix_p" := "matrix_d";
jbe@427 4443 "i" := 1;
jbe@427 4444 LOOP
jbe@427 4445 "j" := 1;
jbe@427 4446 LOOP
jbe@427 4447 IF "i" != "j" THEN
jbe@427 4448 "k" := 1;
jbe@427 4449 LOOP
jbe@427 4450 IF "i" != "k" AND "j" != "k" THEN
jbe@427 4451 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
jbe@427 4452 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
jbe@427 4453 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
jbe@427 4454 END IF;
jbe@427 4455 ELSE
jbe@427 4456 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
jbe@427 4457 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
jbe@427 4458 END IF;
jbe@427 4459 END IF;
jbe@427 4460 END IF;
jbe@427 4461 EXIT WHEN "k" = "dimension_v";
jbe@427 4462 "k" := "k" + 1;
jbe@427 4463 END LOOP;
jbe@427 4464 END IF;
jbe@427 4465 EXIT WHEN "j" = "dimension_v";
jbe@427 4466 "j" := "j" + 1;
jbe@427 4467 END LOOP;
jbe@427 4468 EXIT WHEN "i" = "dimension_v";
jbe@427 4469 "i" := "i" + 1;
jbe@427 4470 END LOOP;
jbe@427 4471 RETURN "matrix_p";
jbe@427 4472 END;
jbe@427 4473 $$;
jbe@427 4474
jbe@428 4475 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
jbe@426 4476
jbe@426 4477
jbe@0 4478 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 4479 RETURNS VOID
jbe@0 4480 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4481 DECLARE
jbe@427 4482 "issue_row" "issue"%ROWTYPE;
jbe@427 4483 "policy_row" "policy"%ROWTYPE;
jbe@427 4484 "dimension_v" INT4;
jbe@427 4485 "matrix_a" INT4[][]; -- absolute votes
jbe@427 4486 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
jbe@427 4487 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
jbe@427 4488 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
jbe@427 4489 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
jbe@427 4490 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
jbe@427 4491 "i" INT4;
jbe@427 4492 "j" INT4;
jbe@427 4493 "m" INT4;
jbe@427 4494 "n" INT4;
jbe@427 4495 "battle_row" "battle"%ROWTYPE;
jbe@427 4496 "rank_ary" INT4[];
jbe@427 4497 "rank_v" INT4;
jbe@427 4498 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 4499 BEGIN
jbe@333 4500 PERFORM "require_transaction_isolation"();
jbe@155 4501 SELECT * INTO "issue_row"
jbe@331 4502 FROM "issue" WHERE "id" = "issue_id_p";
jbe@155 4503 SELECT * INTO "policy_row"
jbe@155 4504 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@126 4505 SELECT count(1) INTO "dimension_v"
jbe@126 4506 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@428 4507 -- create "matrix_a" with absolute number of votes in pairwise
jbe@170 4508 -- comparison:
jbe@427 4509 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4510 "i" := 1;
jbe@170 4511 "j" := 2;
jbe@170 4512 FOR "battle_row" IN
jbe@170 4513 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@170 4514 ORDER BY
jbe@411 4515 "winning_initiative_id" NULLS FIRST,
jbe@411 4516 "losing_initiative_id" NULLS FIRST
jbe@170 4517 LOOP
jbe@427 4518 "matrix_a"["i"]["j"] := "battle_row"."count";
jbe@170 4519 IF "j" = "dimension_v" THEN
jbe@170 4520 "i" := "i" + 1;
jbe@170 4521 "j" := 1;
jbe@170 4522 ELSE
jbe@170 4523 "j" := "j" + 1;
jbe@170 4524 IF "j" = "i" THEN
jbe@170 4525 "j" := "j" + 1;
jbe@170 4526 END IF;
jbe@170 4527 END IF;
jbe@170 4528 END LOOP;
jbe@170 4529 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@170 4530 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@170 4531 END IF;
jbe@428 4532 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
jbe@427 4533 -- and "secondary_link_strength" functions:
jbe@427 4534 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4535 "i" := 1;
jbe@170 4536 LOOP
jbe@170 4537 "j" := 1;
jbe@0 4538 LOOP
jbe@170 4539 IF "i" != "j" THEN
jbe@427 4540 "matrix_d"["i"]["j"] := (
jbe@426 4541 "defeat_strength"(
jbe@427 4542 "matrix_a"["i"]["j"],
jbe@427 4543 "matrix_a"["j"]["i"],
jbe@426 4544 "policy_row"."defeat_strength"
jbe@426 4545 ),
jbe@426 4546 "secondary_link_strength"(
jbe@426 4547 "i",
jbe@426 4548 "j",
jbe@426 4549 "policy_row"."tie_breaking"
jbe@426 4550 )
jbe@426 4551 )::"link_strength";
jbe@0 4552 END IF;
jbe@170 4553 EXIT WHEN "j" = "dimension_v";
jbe@170 4554 "j" := "j" + 1;
jbe@0 4555 END LOOP;
jbe@170 4556 EXIT WHEN "i" = "dimension_v";
jbe@170 4557 "i" := "i" + 1;
jbe@170 4558 END LOOP;
jbe@428 4559 -- find best paths:
jbe@427 4560 "matrix_p" := "find_best_paths"("matrix_d");
jbe@428 4561 -- create partial order:
jbe@427 4562 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4563 "i" := 1;
jbe@170 4564 LOOP
jbe@427 4565 "j" := "i" + 1;
jbe@170 4566 LOOP
jbe@170 4567 IF "i" != "j" THEN
jbe@427 4568 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
jbe@427 4569 "matrix_b"["i"]["j"] := TRUE;
jbe@427 4570 "matrix_b"["j"]["i"] := FALSE;
jbe@427 4571 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
jbe@427 4572 "matrix_b"["i"]["j"] := FALSE;
jbe@427 4573 "matrix_b"["j"]["i"] := TRUE;
jbe@427 4574 END IF;
jbe@170 4575 END IF;
jbe@170 4576 EXIT WHEN "j" = "dimension_v";
jbe@170 4577 "j" := "j" + 1;
jbe@170 4578 END LOOP;
jbe@427 4579 EXIT WHEN "i" = "dimension_v" - 1;
jbe@170 4580 "i" := "i" + 1;
jbe@170 4581 END LOOP;
jbe@428 4582 -- tie-breaking by forbidding shared weakest links in beat-paths
jbe@428 4583 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
jbe@428 4584 -- is performed later by initiative id):
jbe@427 4585 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
jbe@427 4586 "m" := 1;
jbe@427 4587 LOOP
jbe@427 4588 "n" := "m" + 1;
jbe@427 4589 LOOP
jbe@428 4590 -- only process those candidates m and n, which are tied:
jbe@427 4591 IF "matrix_b"["m"]["n"] ISNULL THEN
jbe@428 4592 -- start with beat-paths prior tie-breaking:
jbe@427 4593 "matrix_t" := "matrix_p";
jbe@428 4594 -- start with all links allowed:
jbe@427 4595 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
jbe@427 4596 LOOP
jbe@428 4597 -- determine (and forbid) that link that is the weakest link
jbe@428 4598 -- in both the best path from candidate m to candidate n and
jbe@428 4599 -- from candidate n to candidate m:
jbe@427 4600 "i" := 1;
jbe@427 4601 <<forbid_one_link>>
jbe@427 4602 LOOP
jbe@427 4603 "j" := 1;
jbe@427 4604 LOOP
jbe@427 4605 IF "i" != "j" THEN
jbe@427 4606 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
jbe@427 4607 "matrix_f"["i"]["j"] := TRUE;
jbe@427 4608 -- exit for performance reasons,
jbe@428 4609 -- as exactly one link will be found:
jbe@427 4610 EXIT forbid_one_link;
jbe@427 4611 END IF;
jbe@427 4612 END IF;
jbe@427 4613 EXIT WHEN "j" = "dimension_v";
jbe@427 4614 "j" := "j" + 1;
jbe@427 4615 END LOOP;
jbe@427 4616 IF "i" = "dimension_v" THEN
jbe@428 4617 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
jbe@427 4618 END IF;
jbe@427 4619 "i" := "i" + 1;
jbe@427 4620 END LOOP;
jbe@428 4621 -- calculate best beat-paths while ignoring forbidden links:
jbe@427 4622 "i" := 1;
jbe@427 4623 LOOP
jbe@427 4624 "j" := 1;
jbe@427 4625 LOOP
jbe@427 4626 IF "i" != "j" THEN
jbe@427 4627 "matrix_t"["i"]["j"] := CASE
jbe@427 4628 WHEN "matrix_f"["i"]["j"]
jbe@431 4629 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
jbe@427 4630 ELSE "matrix_d"["i"]["j"] END;
jbe@427 4631 END IF;
jbe@427 4632 EXIT WHEN "j" = "dimension_v";
jbe@427 4633 "j" := "j" + 1;
jbe@427 4634 END LOOP;
jbe@427 4635 EXIT WHEN "i" = "dimension_v";
jbe@427 4636 "i" := "i" + 1;
jbe@427 4637 END LOOP;
jbe@427 4638 "matrix_t" := "find_best_paths"("matrix_t");
jbe@428 4639 -- extend partial order, if tie-breaking was successful:
jbe@427 4640 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
jbe@427 4641 "matrix_b"["m"]["n"] := TRUE;
jbe@427 4642 "matrix_b"["n"]["m"] := FALSE;
jbe@427 4643 EXIT;
jbe@427 4644 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
jbe@427 4645 "matrix_b"["m"]["n"] := FALSE;
jbe@427 4646 "matrix_b"["n"]["m"] := TRUE;
jbe@427 4647 EXIT;
jbe@427 4648 END IF;
jbe@427 4649 END LOOP;
jbe@427 4650 END IF;
jbe@427 4651 EXIT WHEN "n" = "dimension_v";
jbe@427 4652 "n" := "n" + 1;
jbe@427 4653 END LOOP;
jbe@427 4654 EXIT WHEN "m" = "dimension_v" - 1;
jbe@427 4655 "m" := "m" + 1;
jbe@427 4656 END LOOP;
jbe@427 4657 END IF;
jbe@428 4658 -- store a unique ranking in "rank_ary":
jbe@170 4659 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@170 4660 "rank_v" := 1;
jbe@170 4661 LOOP
jbe@0 4662 "i" := 1;
jbe@428 4663 <<assign_next_rank>>
jbe@0 4664 LOOP
jbe@170 4665 IF "rank_ary"["i"] ISNULL THEN
jbe@170 4666 "j" := 1;
jbe@170 4667 LOOP
jbe@170 4668 IF
jbe@170 4669 "i" != "j" AND
jbe@170 4670 "rank_ary"["j"] ISNULL AND
jbe@427 4671 ( "matrix_b"["j"]["i"] OR
jbe@411 4672 -- tie-breaking by "id"
jbe@427 4673 ( "matrix_b"["j"]["i"] ISNULL AND
jbe@411 4674 "j" < "i" ) )
jbe@170 4675 THEN
jbe@170 4676 -- someone else is better
jbe@170 4677 EXIT;
jbe@170 4678 END IF;
jbe@428 4679 IF "j" = "dimension_v" THEN
jbe@170 4680 -- noone is better
jbe@411 4681 "rank_ary"["i"] := "rank_v";
jbe@428 4682 EXIT assign_next_rank;
jbe@170 4683 END IF;
jbe@428 4684 "j" := "j" + 1;
jbe@170 4685 END LOOP;
jbe@170 4686 END IF;
jbe@0 4687 "i" := "i" + 1;
jbe@411 4688 IF "i" > "dimension_v" THEN
jbe@411 4689 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
jbe@411 4690 END IF;
jbe@0 4691 END LOOP;
jbe@411 4692 EXIT WHEN "rank_v" = "dimension_v";
jbe@170 4693 "rank_v" := "rank_v" + 1;
jbe@170 4694 END LOOP;
jbe@170 4695 -- write preliminary results:
jbe@411 4696 "i" := 2; -- omit status quo with "i" = 1
jbe@170 4697 FOR "initiative_id_v" IN
jbe@170 4698 SELECT "id" FROM "initiative"
jbe@170 4699 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@170 4700 ORDER BY "id"
jbe@170 4701 LOOP
jbe@170 4702 UPDATE "initiative" SET
jbe@170 4703 "direct_majority" =
jbe@170 4704 CASE WHEN "policy_row"."direct_majority_strict" THEN
jbe@170 4705 "positive_votes" * "policy_row"."direct_majority_den" >
jbe@170 4706 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4707 ELSE
jbe@170 4708 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@170 4709 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4710 END
jbe@170 4711 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@170 4712 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4713 "policy_row"."direct_majority_non_negative",
jbe@170 4714 "indirect_majority" =
jbe@170 4715 CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4716 "positive_votes" * "policy_row"."indirect_majority_den" >
jbe@170 4717 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4718 ELSE
jbe@170 4719 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@170 4720 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4721 END
jbe@170 4722 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@170 4723 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4724 "policy_row"."indirect_majority_non_negative",
jbe@171 4725 "schulze_rank" = "rank_ary"["i"],
jbe@411 4726 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
jbe@411 4727 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
jbe@411 4728 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
jbe@429 4729 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
jbe@429 4730 THEN NULL
jbe@429 4731 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
jbe@216 4732 "eligible" = FALSE,
jbe@250 4733 "winner" = FALSE,
jbe@250 4734 "rank" = NULL -- NOTE: in cases of manual reset of issue state
jbe@170 4735 WHERE "id" = "initiative_id_v";
jbe@170 4736 "i" := "i" + 1;
jbe@170 4737 END LOOP;
jbe@411 4738 IF "i" != "dimension_v" + 1 THEN
jbe@170 4739 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 4740 END IF;
jbe@170 4741 -- take indirect majorities into account:
jbe@170 4742 LOOP
jbe@170 4743 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@139 4744 FROM (
jbe@170 4745 SELECT "new_initiative"."id" AS "initiative_id"
jbe@170 4746 FROM "initiative" "old_initiative"
jbe@170 4747 JOIN "initiative" "new_initiative"
jbe@170 4748 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@170 4749 AND "new_initiative"."indirect_majority" = FALSE
jbe@139 4750 JOIN "battle" "battle_win"
jbe@139 4751 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4752 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@170 4753 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@139 4754 JOIN "battle" "battle_lose"
jbe@139 4755 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4756 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@170 4757 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@170 4758 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@170 4759 AND "old_initiative"."indirect_majority" = TRUE
jbe@170 4760 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4761 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@170 4762 "policy_row"."indirect_majority_num" *
jbe@170 4763 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4764 ELSE
jbe@170 4765 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@170 4766 "policy_row"."indirect_majority_num" *
jbe@170 4767 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4768 END
jbe@170 4769 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@170 4770 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@170 4771 "policy_row"."indirect_majority_non_negative"
jbe@139 4772 ) AS "subquery"
jbe@139 4773 WHERE "id" = "subquery"."initiative_id";
jbe@170 4774 EXIT WHEN NOT FOUND;
jbe@170 4775 END LOOP;
jbe@170 4776 -- set "multistage_majority" for remaining matching initiatives:
jbe@216 4777 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@170 4778 FROM (
jbe@170 4779 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@170 4780 FROM "initiative" "losing_initiative"
jbe@170 4781 JOIN "initiative" "winning_initiative"
jbe@170 4782 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@170 4783 AND "winning_initiative"."admitted"
jbe@170 4784 JOIN "battle" "battle_win"
jbe@170 4785 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4786 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@170 4787 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@170 4788 JOIN "battle" "battle_lose"
jbe@170 4789 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4790 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@170 4791 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@170 4792 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@170 4793 AND "losing_initiative"."admitted"
jbe@170 4794 AND "winning_initiative"."schulze_rank" <
jbe@170 4795 "losing_initiative"."schulze_rank"
jbe@170 4796 AND "battle_win"."count" > "battle_lose"."count"
jbe@170 4797 AND (
jbe@170 4798 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@170 4799 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@170 4800 ) AS "subquery"
jbe@170 4801 WHERE "id" = "subquery"."initiative_id";
jbe@170 4802 -- mark eligible initiatives:
jbe@170 4803 UPDATE "initiative" SET "eligible" = TRUE
jbe@171 4804 WHERE "issue_id" = "issue_id_p"
jbe@171 4805 AND "initiative"."direct_majority"
jbe@171 4806 AND "initiative"."indirect_majority"
jbe@171 4807 AND "initiative"."better_than_status_quo"
jbe@171 4808 AND (
jbe@171 4809 "policy_row"."no_multistage_majority" = FALSE OR
jbe@429 4810 "initiative"."multistage_majority" = FALSE )
jbe@429 4811 AND (
jbe@429 4812 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@429 4813 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
jbe@170 4814 -- mark final winner:
jbe@170 4815 UPDATE "initiative" SET "winner" = TRUE
jbe@170 4816 FROM (
jbe@170 4817 SELECT "id" AS "initiative_id"
jbe@170 4818 FROM "initiative"
jbe@170 4819 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@217 4820 ORDER BY
jbe@217 4821 "schulze_rank",
jbe@217 4822 "id"
jbe@170 4823 LIMIT 1
jbe@170 4824 ) AS "subquery"
jbe@170 4825 WHERE "id" = "subquery"."initiative_id";
jbe@173 4826 -- write (final) ranks:
jbe@173 4827 "rank_v" := 1;
jbe@173 4828 FOR "initiative_id_v" IN
jbe@173 4829 SELECT "id"
jbe@173 4830 FROM "initiative"
jbe@173 4831 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@174 4832 ORDER BY
jbe@174 4833 "winner" DESC,
jbe@217 4834 "eligible" DESC,
jbe@174 4835 "schulze_rank",
jbe@174 4836 "id"
jbe@173 4837 LOOP
jbe@173 4838 UPDATE "initiative" SET "rank" = "rank_v"
jbe@173 4839 WHERE "id" = "initiative_id_v";
jbe@173 4840 "rank_v" := "rank_v" + 1;
jbe@173 4841 END LOOP;
jbe@170 4842 -- set schulze rank of status quo and mark issue as finished:
jbe@111 4843 UPDATE "issue" SET
jbe@411 4844 "status_quo_schulze_rank" = "rank_ary"[1],
jbe@111 4845 "state" =
jbe@139 4846 CASE WHEN EXISTS (
jbe@139 4847 SELECT NULL FROM "initiative"
jbe@139 4848 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@139 4849 ) THEN
jbe@139 4850 'finished_with_winner'::"issue_state"
jbe@139 4851 ELSE
jbe@121 4852 'finished_without_winner'::"issue_state"
jbe@111 4853 END,
jbe@331 4854 "closed" = "phase_finished",
jbe@331 4855 "phase_finished" = NULL
jbe@0 4856 WHERE "id" = "issue_id_p";
jbe@0 4857 RETURN;
jbe@0 4858 END;
jbe@0 4859 $$;
jbe@0 4860
jbe@0 4861 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 4862 ( "issue"."id"%TYPE )
jbe@0 4863 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 4864
jbe@0 4865
jbe@0 4866
jbe@0 4867 -----------------------------
jbe@0 4868 -- Automatic state changes --
jbe@0 4869 -----------------------------
jbe@0 4870
jbe@0 4871
jbe@331 4872 CREATE TYPE "check_issue_persistence" AS (
jbe@331 4873 "state" "issue_state",
jbe@331 4874 "phase_finished" BOOLEAN,
jbe@331 4875 "issue_revoked" BOOLEAN,
jbe@331 4876 "snapshot_created" BOOLEAN,
jbe@331 4877 "harmonic_weights_set" BOOLEAN,
jbe@331 4878 "closed_voting" BOOLEAN );
jbe@331 4879
jbe@336 4880 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 4881
jbe@336 4882
jbe@0 4883 CREATE FUNCTION "check_issue"
jbe@331 4884 ( "issue_id_p" "issue"."id"%TYPE,
jbe@331 4885 "persist" "check_issue_persistence" )
jbe@331 4886 RETURNS "check_issue_persistence"
jbe@0 4887 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4888 DECLARE
jbe@336 4889 "issue_row" "issue"%ROWTYPE;
jbe@336 4890 "policy_row" "policy"%ROWTYPE;
jbe@336 4891 "initiative_row" "initiative"%ROWTYPE;
jbe@336 4892 "state_v" "issue_state";
jbe@0 4893 BEGIN
jbe@333 4894 PERFORM "require_transaction_isolation"();
jbe@331 4895 IF "persist" ISNULL THEN
jbe@331 4896 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@331 4897 FOR UPDATE;
jbe@331 4898 IF "issue_row"."closed" NOTNULL THEN
jbe@331 4899 RETURN NULL;
jbe@0 4900 END IF;
jbe@331 4901 "persist"."state" := "issue_row"."state";
jbe@331 4902 IF
jbe@331 4903 ( "issue_row"."state" = 'admission' AND now() >=
jbe@447 4904 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
jbe@331 4905 ( "issue_row"."state" = 'discussion' AND now() >=
jbe@331 4906 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
jbe@331 4907 ( "issue_row"."state" = 'verification' AND now() >=
jbe@331 4908 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
jbe@331 4909 ( "issue_row"."state" = 'voting' AND now() >=
jbe@331 4910 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
jbe@331 4911 THEN
jbe@331 4912 "persist"."phase_finished" := TRUE;
jbe@331 4913 ELSE
jbe@331 4914 "persist"."phase_finished" := FALSE;
jbe@0 4915 END IF;
jbe@0 4916 IF
jbe@24 4917 NOT EXISTS (
jbe@24 4918 -- all initiatives are revoked
jbe@24 4919 SELECT NULL FROM "initiative"
jbe@24 4920 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 4921 ) AND (
jbe@111 4922 -- and issue has not been accepted yet
jbe@331 4923 "persist"."state" = 'admission' OR
jbe@331 4924 -- or verification time has elapsed
jbe@331 4925 ( "persist"."state" = 'verification' AND
jbe@331 4926 "persist"."phase_finished" ) OR
jbe@331 4927 -- or no initiatives have been revoked lately
jbe@24 4928 NOT EXISTS (
jbe@24 4929 SELECT NULL FROM "initiative"
jbe@24 4930 WHERE "issue_id" = "issue_id_p"
jbe@24 4931 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 4932 )
jbe@24 4933 )
jbe@24 4934 THEN
jbe@331 4935 "persist"."issue_revoked" := TRUE;
jbe@331 4936 ELSE
jbe@331 4937 "persist"."issue_revoked" := FALSE;
jbe@24 4938 END IF;
jbe@331 4939 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
jbe@331 4940 UPDATE "issue" SET "phase_finished" = now()
jbe@331 4941 WHERE "id" = "issue_row"."id";
jbe@331 4942 RETURN "persist";
jbe@331 4943 ELSIF
jbe@331 4944 "persist"."state" IN ('admission', 'discussion', 'verification')
jbe@3 4945 THEN
jbe@331 4946 RETURN "persist";
jbe@331 4947 ELSE
jbe@331 4948 RETURN NULL;
jbe@322 4949 END IF;
jbe@0 4950 END IF;
jbe@331 4951 IF
jbe@331 4952 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 4953 coalesce("persist"."snapshot_created", FALSE) = FALSE
jbe@331 4954 THEN
jbe@331 4955 PERFORM "create_snapshot"("issue_id_p");
jbe@331 4956 "persist"."snapshot_created" = TRUE;
jbe@331 4957 IF "persist"."phase_finished" THEN
jbe@331 4958 IF "persist"."state" = 'admission' THEN
jbe@331 4959 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@331 4960 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 4961 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@331 4962 ELSIF "persist"."state" = 'verification' THEN
jbe@331 4963 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@336 4964 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@336 4965 SELECT * INTO "policy_row" FROM "policy"
jbe@336 4966 WHERE "id" = "issue_row"."policy_id";
jbe@336 4967 FOR "initiative_row" IN
jbe@336 4968 SELECT * FROM "initiative"
jbe@336 4969 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@336 4970 FOR UPDATE
jbe@336 4971 LOOP
jbe@336 4972 IF
jbe@336 4973 "initiative_row"."polling" OR (
jbe@336 4974 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@336 4975 "initiative_row"."satisfied_supporter_count" *
jbe@336 4976 "policy_row"."initiative_quorum_den" >=
jbe@336 4977 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@336 4978 )
jbe@336 4979 THEN
jbe@336 4980 UPDATE "initiative" SET "admitted" = TRUE
jbe@336 4981 WHERE "id" = "initiative_row"."id";
jbe@336 4982 ELSE
jbe@336 4983 UPDATE "initiative" SET "admitted" = FALSE
jbe@336 4984 WHERE "id" = "initiative_row"."id";
jbe@336 4985 END IF;
jbe@336 4986 END LOOP;
jbe@331 4987 END IF;
jbe@331 4988 END IF;
jbe@331 4989 RETURN "persist";
jbe@331 4990 END IF;
jbe@331 4991 IF
jbe@331 4992 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 4993 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
jbe@331 4994 THEN
jbe@331 4995 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@331 4996 "persist"."harmonic_weights_set" = TRUE;
jbe@332 4997 IF
jbe@332 4998 "persist"."phase_finished" OR
jbe@332 4999 "persist"."issue_revoked" OR
jbe@332 5000 "persist"."state" = 'admission'
jbe@332 5001 THEN
jbe@331 5002 RETURN "persist";
jbe@331 5003 ELSE
jbe@331 5004 RETURN NULL;
jbe@331 5005 END IF;
jbe@331 5006 END IF;
jbe@331 5007 IF "persist"."issue_revoked" THEN
jbe@331 5008 IF "persist"."state" = 'admission' THEN
jbe@331 5009 "state_v" := 'canceled_revoked_before_accepted';
jbe@331 5010 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 5011 "state_v" := 'canceled_after_revocation_during_discussion';
jbe@331 5012 ELSIF "persist"."state" = 'verification' THEN
jbe@331 5013 "state_v" := 'canceled_after_revocation_during_verification';
jbe@331 5014 END IF;
jbe@331 5015 UPDATE "issue" SET
jbe@331 5016 "state" = "state_v",
jbe@331 5017 "closed" = "phase_finished",
jbe@331 5018 "phase_finished" = NULL
jbe@332 5019 WHERE "id" = "issue_id_p";
jbe@331 5020 RETURN NULL;
jbe@331 5021 END IF;
jbe@331 5022 IF "persist"."state" = 'admission' THEN
jbe@336 5023 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 5024 FOR UPDATE;
jbe@336 5025 SELECT * INTO "policy_row"
jbe@336 5026 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@447 5027 IF
jbe@447 5028 ( now() >=
jbe@458 5029 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
jbe@457 5030 -- TODO: implement new mechanism for issue admission
jbe@458 5031 EXISTS (
jbe@458 5032 SELECT NULL FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@458 5033 AND "supporter_count" >= "policy_row"."issue_quorum"
jbe@458 5034 )
jbe@447 5035 THEN
jbe@336 5036 UPDATE "issue" SET
jbe@336 5037 "state" = 'discussion',
jbe@336 5038 "accepted" = coalesce("phase_finished", now()),
jbe@336 5039 "phase_finished" = NULL
jbe@336 5040 WHERE "id" = "issue_id_p";
jbe@336 5041 ELSIF "issue_row"."phase_finished" NOTNULL THEN
jbe@336 5042 UPDATE "issue" SET
jbe@336 5043 "state" = 'canceled_issue_not_accepted',
jbe@336 5044 "closed" = "phase_finished",
jbe@336 5045 "phase_finished" = NULL
jbe@336 5046 WHERE "id" = "issue_id_p";
jbe@336 5047 END IF;
jbe@331 5048 RETURN NULL;
jbe@331 5049 END IF;
jbe@332 5050 IF "persist"."phase_finished" THEN
jbe@443 5051 IF "persist"."state" = 'discussion' THEN
jbe@332 5052 UPDATE "issue" SET
jbe@332 5053 "state" = 'verification',
jbe@332 5054 "half_frozen" = "phase_finished",
jbe@332 5055 "phase_finished" = NULL
jbe@332 5056 WHERE "id" = "issue_id_p";
jbe@332 5057 RETURN NULL;
jbe@332 5058 END IF;
jbe@332 5059 IF "persist"."state" = 'verification' THEN
jbe@336 5060 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 5061 FOR UPDATE;
jbe@336 5062 SELECT * INTO "policy_row" FROM "policy"
jbe@336 5063 WHERE "id" = "issue_row"."policy_id";
jbe@336 5064 IF EXISTS (
jbe@336 5065 SELECT NULL FROM "initiative"
jbe@336 5066 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@336 5067 ) THEN
jbe@336 5068 UPDATE "issue" SET
jbe@343 5069 "state" = 'voting',
jbe@343 5070 "fully_frozen" = "phase_finished",
jbe@336 5071 "phase_finished" = NULL
jbe@336 5072 WHERE "id" = "issue_id_p";
jbe@336 5073 ELSE
jbe@336 5074 UPDATE "issue" SET
jbe@343 5075 "state" = 'canceled_no_initiative_admitted',
jbe@343 5076 "fully_frozen" = "phase_finished",
jbe@343 5077 "closed" = "phase_finished",
jbe@343 5078 "phase_finished" = NULL
jbe@336 5079 WHERE "id" = "issue_id_p";
jbe@336 5080 -- NOTE: The following DELETE statements have effect only when
jbe@336 5081 -- issue state has been manipulated
jbe@336 5082 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 5083 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 5084 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@336 5085 END IF;
jbe@332 5086 RETURN NULL;
jbe@332 5087 END IF;
jbe@332 5088 IF "persist"."state" = 'voting' THEN
jbe@332 5089 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
jbe@332 5090 PERFORM "close_voting"("issue_id_p");
jbe@332 5091 "persist"."closed_voting" = TRUE;
jbe@332 5092 RETURN "persist";
jbe@332 5093 END IF;
jbe@332 5094 PERFORM "calculate_ranks"("issue_id_p");
jbe@332 5095 RETURN NULL;
jbe@332 5096 END IF;
jbe@331 5097 END IF;
jbe@331 5098 RAISE WARNING 'should not happen';
jbe@331 5099 RETURN NULL;
jbe@0 5100 END;
jbe@0 5101 $$;
jbe@0 5102
jbe@0 5103 COMMENT ON FUNCTION "check_issue"
jbe@331 5104 ( "issue"."id"%TYPE,
jbe@331 5105 "check_issue_persistence" )
jbe@336 5106 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 5107
jbe@0 5108
jbe@0 5109 CREATE FUNCTION "check_everything"()
jbe@0 5110 RETURNS VOID
jbe@0 5111 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 5112 DECLARE
jbe@0 5113 "issue_id_v" "issue"."id"%TYPE;
jbe@331 5114 "persist_v" "check_issue_persistence";
jbe@0 5115 BEGIN
jbe@333 5116 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
jbe@235 5117 DELETE FROM "expired_session";
jbe@184 5118 PERFORM "check_activity"();
jbe@4 5119 PERFORM "calculate_member_counts"();
jbe@4 5120 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@331 5121 "persist_v" := NULL;
jbe@331 5122 LOOP
jbe@331 5123 "persist_v" := "check_issue"("issue_id_v", "persist_v");
jbe@331 5124 EXIT WHEN "persist_v" ISNULL;
jbe@331 5125 END LOOP;
jbe@0 5126 END LOOP;
jbe@0 5127 RETURN;
jbe@0 5128 END;
jbe@0 5129 $$;
jbe@0 5130
jbe@336 5131 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 5132
jbe@0 5133
jbe@0 5134
jbe@59 5135 ----------------------
jbe@59 5136 -- Deletion of data --
jbe@59 5137 ----------------------
jbe@59 5138
jbe@59 5139
jbe@59 5140 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 5141 RETURNS VOID
jbe@59 5142 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 5143 BEGIN
jbe@385 5144 IF EXISTS (
jbe@385 5145 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
jbe@385 5146 ) THEN
jbe@385 5147 -- override protection triggers:
jbe@385 5148 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 5149 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@385 5150 -- clean data:
jbe@59 5151 DELETE FROM "delegating_voter"
jbe@59 5152 WHERE "issue_id" = "issue_id_p";
jbe@59 5153 DELETE FROM "direct_voter"
jbe@59 5154 WHERE "issue_id" = "issue_id_p";
jbe@59 5155 DELETE FROM "delegating_interest_snapshot"
jbe@59 5156 WHERE "issue_id" = "issue_id_p";
jbe@59 5157 DELETE FROM "direct_interest_snapshot"
jbe@59 5158 WHERE "issue_id" = "issue_id_p";
jbe@59 5159 DELETE FROM "delegating_population_snapshot"
jbe@59 5160 WHERE "issue_id" = "issue_id_p";
jbe@59 5161 DELETE FROM "direct_population_snapshot"
jbe@59 5162 WHERE "issue_id" = "issue_id_p";
jbe@113 5163 DELETE FROM "non_voter"
jbe@94 5164 WHERE "issue_id" = "issue_id_p";
jbe@59 5165 DELETE FROM "delegation"
jbe@59 5166 WHERE "issue_id" = "issue_id_p";
jbe@59 5167 DELETE FROM "supporter"
jbe@329 5168 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 5169 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 5170 AND "supporter"."initiative_id" = "initiative_id";
jbe@385 5171 -- mark issue as cleaned:
jbe@385 5172 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
jbe@385 5173 -- finish overriding protection triggers (avoids garbage):
jbe@385 5174 DELETE FROM "temporary_transaction_data"
jbe@385 5175 WHERE "key" = 'override_protection_triggers';
jbe@59 5176 END IF;
jbe@59 5177 RETURN;
jbe@59 5178 END;
jbe@59 5179 $$;
jbe@59 5180
jbe@59 5181 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 5182
jbe@8 5183
jbe@54 5184 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 5185 RETURNS VOID
jbe@8 5186 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 5187 BEGIN
jbe@9 5188 UPDATE "member" SET
jbe@57 5189 "last_login" = NULL,
jbe@387 5190 "last_delegation_check" = NULL,
jbe@45 5191 "login" = NULL,
jbe@11 5192 "password" = NULL,
jbe@441 5193 "authority" = NULL,
jbe@441 5194 "authority_uid" = NULL,
jbe@441 5195 "authority_login" = NULL,
jbe@101 5196 "locked" = TRUE,
jbe@54 5197 "active" = FALSE,
jbe@11 5198 "notify_email" = NULL,
jbe@11 5199 "notify_email_unconfirmed" = NULL,
jbe@11 5200 "notify_email_secret" = NULL,
jbe@11 5201 "notify_email_secret_expiry" = NULL,
jbe@57 5202 "notify_email_lock_expiry" = NULL,
jbe@499 5203 "disable_notifications" = NULL,
jbe@499 5204 "notification_counter" = NULL,
jbe@499 5205 "notification_sample_size" = NULL,
jbe@499 5206 "notification_dow" = NULL,
jbe@499 5207 "notification_hour" = NULL,
jbe@387 5208 "login_recovery_expiry" = NULL,
jbe@11 5209 "password_reset_secret" = NULL,
jbe@11 5210 "password_reset_secret_expiry" = NULL,
jbe@11 5211 "organizational_unit" = NULL,
jbe@11 5212 "internal_posts" = NULL,
jbe@11 5213 "realname" = NULL,
jbe@11 5214 "birthday" = NULL,
jbe@11 5215 "address" = NULL,
jbe@11 5216 "email" = NULL,
jbe@11 5217 "xmpp_address" = NULL,
jbe@11 5218 "website" = NULL,
jbe@11 5219 "phone" = NULL,
jbe@11 5220 "mobile_phone" = NULL,
jbe@11 5221 "profession" = NULL,
jbe@11 5222 "external_memberships" = NULL,
jbe@11 5223 "external_posts" = NULL,
jbe@45 5224 "statement" = NULL
jbe@45 5225 WHERE "id" = "member_id_p";
jbe@11 5226 -- "text_search_data" is updated by triggers
jbe@45 5227 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@45 5228 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@45 5229 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@45 5230 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 5231 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 5232 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@235 5233 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@45 5234 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@45 5235 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@113 5236 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@45 5237 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@45 5238 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@54 5239 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
jbe@54 5240 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 5241 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 5242 DELETE FROM "direct_voter" USING "issue"
jbe@57 5243 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 5244 AND "issue"."closed" ISNULL
jbe@57 5245 AND "member_id" = "member_id_p";
jbe@45 5246 RETURN;
jbe@45 5247 END;
jbe@45 5248 $$;
jbe@45 5249
jbe@57 5250 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 5251
jbe@45 5252
jbe@45 5253 CREATE FUNCTION "delete_private_data"()
jbe@45 5254 RETURNS VOID
jbe@45 5255 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 5256 BEGIN
jbe@385 5257 DELETE FROM "temporary_transaction_data";
jbe@226 5258 DELETE FROM "member" WHERE "activated" ISNULL;
jbe@50 5259 UPDATE "member" SET
jbe@206 5260 "invite_code" = NULL,
jbe@232 5261 "invite_code_expiry" = NULL,
jbe@228 5262 "admin_comment" = NULL,
jbe@57 5263 "last_login" = NULL,
jbe@387 5264 "last_delegation_check" = NULL,
jbe@50 5265 "login" = NULL,
jbe@50 5266 "password" = NULL,
jbe@441 5267 "authority" = NULL,
jbe@441 5268 "authority_uid" = NULL,
jbe@441 5269 "authority_login" = NULL,
jbe@238 5270 "lang" = NULL,
jbe@50 5271 "notify_email" = NULL,
jbe@50 5272 "notify_email_unconfirmed" = NULL,
jbe@50 5273 "notify_email_secret" = NULL,
jbe@50 5274 "notify_email_secret_expiry" = NULL,
jbe@57 5275 "notify_email_lock_expiry" = NULL,
jbe@499 5276 "disable_notifications" = NULL,
jbe@499 5277 "notification_counter" = NULL,
jbe@499 5278 "notification_sample_size" = NULL,
jbe@499 5279 "notification_dow" = NULL,
jbe@499 5280 "notification_hour" = NULL,
jbe@387 5281 "login_recovery_expiry" = NULL,
jbe@50 5282 "password_reset_secret" = NULL,
jbe@50 5283 "password_reset_secret_expiry" = NULL,
jbe@50 5284 "organizational_unit" = NULL,
jbe@50 5285 "internal_posts" = NULL,
jbe@50 5286 "realname" = NULL,
jbe@50 5287 "birthday" = NULL,
jbe@50 5288 "address" = NULL,
jbe@50 5289 "email" = NULL,
jbe@50 5290 "xmpp_address" = NULL,
jbe@50 5291 "website" = NULL,
jbe@50 5292 "phone" = NULL,
jbe@50 5293 "mobile_phone" = NULL,
jbe@50 5294 "profession" = NULL,
jbe@50 5295 "external_memberships" = NULL,
jbe@50 5296 "external_posts" = NULL,
jbe@238 5297 "formatting_engine" = NULL,
jbe@50 5298 "statement" = NULL;
jbe@50 5299 -- "text_search_data" is updated by triggers
jbe@50 5300 DELETE FROM "setting";
jbe@50 5301 DELETE FROM "setting_map";
jbe@50 5302 DELETE FROM "member_relation_setting";
jbe@50 5303 DELETE FROM "member_image";
jbe@50 5304 DELETE FROM "contact";
jbe@113 5305 DELETE FROM "ignored_member";
jbe@235 5306 DELETE FROM "session";
jbe@50 5307 DELETE FROM "area_setting";
jbe@50 5308 DELETE FROM "issue_setting";
jbe@113 5309 DELETE FROM "ignored_initiative";
jbe@50 5310 DELETE FROM "initiative_setting";
jbe@50 5311 DELETE FROM "suggestion_setting";
jbe@113 5312 DELETE FROM "non_voter";
jbe@8 5313 DELETE FROM "direct_voter" USING "issue"
jbe@8 5314 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 5315 AND "issue"."closed" ISNULL;
jbe@8 5316 RETURN;
jbe@8 5317 END;
jbe@8 5318 $$;
jbe@8 5319
jbe@273 5320 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 5321
jbe@8 5322
jbe@8 5323
jbe@0 5324 COMMIT;

Impressum / About Us