liquid_feedback_core

annotate core.sql @ 408:f7b4457cf1a6

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

Impressum / About Us