liquid_feedback_core

annotate core.sql @ 487:14bca0b56925

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

Impressum / About Us