liquid_feedback_core

annotate core.sql @ 489:5abcd0043fff

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

Impressum / About Us