liquid_feedback_core

annotate core.sql @ 398:806561cce3b1

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

Impressum / About Us