liquid_feedback_core

annotate core.sql @ 332:f17ee916711a

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

Impressum / About Us