liquid_feedback_core

annotate core.sql @ 389:582d270d2653

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

Impressum / About Us