liquid_feedback_core

annotate core.sql @ 395:d93428e4edad

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

Impressum / About Us