liquid_feedback_core

annotate core.sql @ 360:47965760b1b8

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

Impressum / About Us