liquid_feedback_core

annotate core.sql @ 444:d14513809147

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

Impressum / About Us