liquid_feedback_core

annotate core.sql @ 302:548cec6b7a79

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

Impressum / About Us