liquid_feedback_core

annotate core.sql @ 414:719ad5c5c940

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

Impressum / About Us