liquid_feedback_core

annotate core.sql @ 424:7fbf614ca8cb

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

Impressum / About Us