liquid_feedback_core

annotate core.sql @ 311:4dd3339453b8

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

Impressum / About Us