liquid_feedback_core

annotate core.sql @ 328:16803f8dfcf0

Stub (no implementation yet) for "phase_finished" field, allowing calculations to take more time without database locking
author jbe
date Sun Feb 10 23:23:17 2013 +0100 (2013-02-10)
parents ae0da58a9858
children b9e625add823
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@32 1581 "issue_id_v" "issue"."id"%TYPE;
jbe@32 1582 "issue_row" "issue"%ROWTYPE;
jbe@20 1583 BEGIN
jbe@290 1584 IF TG_RELID = 'direct_voter'::regclass AND TG_OP = 'UPDATE' THEN
jbe@290 1585 IF
jbe@290 1586 OLD."issue_id" = NEW."issue_id" AND
jbe@290 1587 OLD."member_id" = NEW."member_id" AND
jbe@290 1588 OLD."weight" = NEW."weight"
jbe@290 1589 THEN
jbe@290 1590 RETURN NULL; -- allows changing of voter comment
jbe@290 1591 END IF;
jbe@290 1592 END IF;
jbe@32 1593 IF TG_OP = 'DELETE' THEN
jbe@32 1594 "issue_id_v" := OLD."issue_id";
jbe@32 1595 ELSE
jbe@32 1596 "issue_id_v" := NEW."issue_id";
jbe@32 1597 END IF;
jbe@20 1598 SELECT INTO "issue_row" * FROM "issue"
jbe@32 1599 WHERE "id" = "issue_id_v" FOR SHARE;
jbe@20 1600 IF "issue_row"."closed" NOTNULL THEN
jbe@20 1601 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.';
jbe@20 1602 END IF;
jbe@20 1603 RETURN NULL;
jbe@20 1604 END;
jbe@20 1605 $$;
jbe@20 1606
jbe@20 1607 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1608 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@20 1609 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1610 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1611
jbe@20 1612 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1613 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@20 1614 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1615 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1616
jbe@20 1617 CREATE TRIGGER "forbid_changes_on_closed_issue"
jbe@20 1618 AFTER INSERT OR UPDATE OR DELETE ON "vote"
jbe@20 1619 FOR EACH ROW EXECUTE PROCEDURE
jbe@20 1620 "forbid_changes_on_closed_issue_trigger"();
jbe@20 1621
jbe@20 1622 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 1623 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 1624 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 1625 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 1626
jbe@20 1627
jbe@20 1628
jbe@0 1629 --------------------------------------------------------------------
jbe@0 1630 -- Auto-retrieval of fields only needed for referential integrity --
jbe@0 1631 --------------------------------------------------------------------
jbe@0 1632
jbe@20 1633
jbe@0 1634 CREATE FUNCTION "autofill_issue_id_trigger"()
jbe@0 1635 RETURNS TRIGGER
jbe@0 1636 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1637 BEGIN
jbe@0 1638 IF NEW."issue_id" ISNULL THEN
jbe@0 1639 SELECT "issue_id" INTO NEW."issue_id"
jbe@0 1640 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1641 END IF;
jbe@0 1642 RETURN NEW;
jbe@0 1643 END;
jbe@0 1644 $$;
jbe@0 1645
jbe@0 1646 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
jbe@0 1647 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1648
jbe@0 1649 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
jbe@0 1650 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
jbe@0 1651
jbe@0 1652 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
jbe@0 1653 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1654 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
jbe@0 1655
jbe@0 1656
jbe@0 1657 CREATE FUNCTION "autofill_initiative_id_trigger"()
jbe@0 1658 RETURNS TRIGGER
jbe@0 1659 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1660 BEGIN
jbe@0 1661 IF NEW."initiative_id" ISNULL THEN
jbe@0 1662 SELECT "initiative_id" INTO NEW."initiative_id"
jbe@0 1663 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1664 END IF;
jbe@0 1665 RETURN NEW;
jbe@0 1666 END;
jbe@0 1667 $$;
jbe@0 1668
jbe@0 1669 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
jbe@0 1670 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
jbe@0 1671
jbe@0 1672 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
jbe@0 1673 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
jbe@0 1674
jbe@0 1675
jbe@0 1676
jbe@4 1677 -----------------------------------------------------
jbe@4 1678 -- Automatic calculation of certain default values --
jbe@4 1679 -----------------------------------------------------
jbe@0 1680
jbe@22 1681
jbe@22 1682 CREATE FUNCTION "copy_timings_trigger"()
jbe@22 1683 RETURNS TRIGGER
jbe@22 1684 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@22 1685 DECLARE
jbe@22 1686 "policy_row" "policy"%ROWTYPE;
jbe@22 1687 BEGIN
jbe@22 1688 SELECT * INTO "policy_row" FROM "policy"
jbe@22 1689 WHERE "id" = NEW."policy_id";
jbe@22 1690 IF NEW."admission_time" ISNULL THEN
jbe@22 1691 NEW."admission_time" := "policy_row"."admission_time";
jbe@22 1692 END IF;
jbe@22 1693 IF NEW."discussion_time" ISNULL THEN
jbe@22 1694 NEW."discussion_time" := "policy_row"."discussion_time";
jbe@22 1695 END IF;
jbe@22 1696 IF NEW."verification_time" ISNULL THEN
jbe@22 1697 NEW."verification_time" := "policy_row"."verification_time";
jbe@22 1698 END IF;
jbe@22 1699 IF NEW."voting_time" ISNULL THEN
jbe@22 1700 NEW."voting_time" := "policy_row"."voting_time";
jbe@22 1701 END IF;
jbe@22 1702 RETURN NEW;
jbe@22 1703 END;
jbe@22 1704 $$;
jbe@22 1705
jbe@22 1706 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
jbe@22 1707 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
jbe@22 1708
jbe@22 1709 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
jbe@22 1710 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
jbe@22 1711
jbe@22 1712
jbe@160 1713 CREATE FUNCTION "default_for_draft_id_trigger"()
jbe@2 1714 RETURNS TRIGGER
jbe@2 1715 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@2 1716 BEGIN
jbe@2 1717 IF NEW."draft_id" ISNULL THEN
jbe@2 1718 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
jbe@2 1719 WHERE "initiative_id" = NEW."initiative_id";
jbe@2 1720 END IF;
jbe@2 1721 RETURN NEW;
jbe@2 1722 END;
jbe@2 1723 $$;
jbe@2 1724
jbe@160 1725 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
jbe@160 1726 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@2 1727 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
jbe@160 1728 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
jbe@160 1729
jbe@160 1730 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
jbe@160 1731 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 1732 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 1733
jbe@2 1734
jbe@0 1735
jbe@0 1736 ----------------------------------------
jbe@0 1737 -- Automatic creation of dependencies --
jbe@0 1738 ----------------------------------------
jbe@0 1739
jbe@22 1740
jbe@0 1741 CREATE FUNCTION "autocreate_interest_trigger"()
jbe@0 1742 RETURNS TRIGGER
jbe@0 1743 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1744 BEGIN
jbe@0 1745 IF NOT EXISTS (
jbe@0 1746 SELECT NULL FROM "initiative" JOIN "interest"
jbe@0 1747 ON "initiative"."issue_id" = "interest"."issue_id"
jbe@0 1748 WHERE "initiative"."id" = NEW."initiative_id"
jbe@0 1749 AND "interest"."member_id" = NEW."member_id"
jbe@0 1750 ) THEN
jbe@0 1751 BEGIN
jbe@0 1752 INSERT INTO "interest" ("issue_id", "member_id")
jbe@0 1753 SELECT "issue_id", NEW."member_id"
jbe@0 1754 FROM "initiative" WHERE "id" = NEW."initiative_id";
jbe@0 1755 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1756 END IF;
jbe@0 1757 RETURN NEW;
jbe@0 1758 END;
jbe@0 1759 $$;
jbe@0 1760
jbe@0 1761 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
jbe@0 1762 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
jbe@0 1763
jbe@0 1764 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
jbe@0 1765 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 1766
jbe@0 1767
jbe@0 1768 CREATE FUNCTION "autocreate_supporter_trigger"()
jbe@0 1769 RETURNS TRIGGER
jbe@0 1770 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 1771 BEGIN
jbe@0 1772 IF NOT EXISTS (
jbe@0 1773 SELECT NULL FROM "suggestion" JOIN "supporter"
jbe@0 1774 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
jbe@0 1775 WHERE "suggestion"."id" = NEW."suggestion_id"
jbe@0 1776 AND "supporter"."member_id" = NEW."member_id"
jbe@0 1777 ) THEN
jbe@0 1778 BEGIN
jbe@0 1779 INSERT INTO "supporter" ("initiative_id", "member_id")
jbe@0 1780 SELECT "initiative_id", NEW."member_id"
jbe@0 1781 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
jbe@0 1782 EXCEPTION WHEN unique_violation THEN END;
jbe@0 1783 END IF;
jbe@0 1784 RETURN NEW;
jbe@0 1785 END;
jbe@0 1786 $$;
jbe@0 1787
jbe@0 1788 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
jbe@0 1789 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
jbe@0 1790
jbe@0 1791 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
jbe@0 1792 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 1793
jbe@0 1794
jbe@0 1795
jbe@0 1796 ------------------------------------------
jbe@0 1797 -- Views and helper functions for views --
jbe@0 1798 ------------------------------------------
jbe@0 1799
jbe@5 1800
jbe@97 1801 CREATE VIEW "unit_delegation" AS
jbe@97 1802 SELECT
jbe@97 1803 "unit"."id" AS "unit_id",
jbe@97 1804 "delegation"."id",
jbe@97 1805 "delegation"."truster_id",
jbe@97 1806 "delegation"."trustee_id",
jbe@97 1807 "delegation"."scope"
jbe@97 1808 FROM "unit"
jbe@97 1809 JOIN "delegation"
jbe@97 1810 ON "delegation"."unit_id" = "unit"."id"
jbe@97 1811 JOIN "member"
jbe@97 1812 ON "delegation"."truster_id" = "member"."id"
jbe@97 1813 JOIN "privilege"
jbe@97 1814 ON "delegation"."unit_id" = "privilege"."unit_id"
jbe@97 1815 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1816 WHERE "member"."active" AND "privilege"."voting_right";
jbe@97 1817
jbe@97 1818 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
jbe@5 1819
jbe@5 1820
jbe@5 1821 CREATE VIEW "area_delegation" AS
jbe@70 1822 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
jbe@70 1823 "area"."id" AS "area_id",
jbe@70 1824 "delegation"."id",
jbe@70 1825 "delegation"."truster_id",
jbe@70 1826 "delegation"."trustee_id",
jbe@70 1827 "delegation"."scope"
jbe@97 1828 FROM "area"
jbe@97 1829 JOIN "delegation"
jbe@97 1830 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 1831 OR "delegation"."area_id" = "area"."id"
jbe@97 1832 JOIN "member"
jbe@97 1833 ON "delegation"."truster_id" = "member"."id"
jbe@97 1834 JOIN "privilege"
jbe@97 1835 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 1836 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1837 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 1838 ORDER BY
jbe@70 1839 "area"."id",
jbe@70 1840 "delegation"."truster_id",
jbe@70 1841 "delegation"."scope" DESC;
jbe@70 1842
jbe@97 1843 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
jbe@5 1844
jbe@5 1845
jbe@5 1846 CREATE VIEW "issue_delegation" AS
jbe@70 1847 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@70 1848 "issue"."id" AS "issue_id",
jbe@70 1849 "delegation"."id",
jbe@70 1850 "delegation"."truster_id",
jbe@70 1851 "delegation"."trustee_id",
jbe@70 1852 "delegation"."scope"
jbe@97 1853 FROM "issue"
jbe@97 1854 JOIN "area"
jbe@97 1855 ON "area"."id" = "issue"."area_id"
jbe@97 1856 JOIN "delegation"
jbe@97 1857 ON "delegation"."unit_id" = "area"."unit_id"
jbe@97 1858 OR "delegation"."area_id" = "area"."id"
jbe@97 1859 OR "delegation"."issue_id" = "issue"."id"
jbe@97 1860 JOIN "member"
jbe@97 1861 ON "delegation"."truster_id" = "member"."id"
jbe@97 1862 JOIN "privilege"
jbe@97 1863 ON "area"."unit_id" = "privilege"."unit_id"
jbe@97 1864 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@97 1865 WHERE "member"."active" AND "privilege"."voting_right"
jbe@70 1866 ORDER BY
jbe@70 1867 "issue"."id",
jbe@70 1868 "delegation"."truster_id",
jbe@70 1869 "delegation"."scope" DESC;
jbe@70 1870
jbe@97 1871 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
jbe@5 1872
jbe@5 1873
jbe@5 1874 CREATE FUNCTION "membership_weight_with_skipping"
jbe@5 1875 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1876 "member_id_p" "member"."id"%TYPE,
jbe@5 1877 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
jbe@5 1878 RETURNS INT4
jbe@5 1879 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1880 DECLARE
jbe@5 1881 "sum_v" INT4;
jbe@5 1882 "delegation_row" "area_delegation"%ROWTYPE;
jbe@5 1883 BEGIN
jbe@5 1884 "sum_v" := 1;
jbe@5 1885 FOR "delegation_row" IN
jbe@5 1886 SELECT "area_delegation".*
jbe@5 1887 FROM "area_delegation" LEFT JOIN "membership"
jbe@5 1888 ON "membership"."area_id" = "area_id_p"
jbe@5 1889 AND "membership"."member_id" = "area_delegation"."truster_id"
jbe@5 1890 WHERE "area_delegation"."area_id" = "area_id_p"
jbe@5 1891 AND "area_delegation"."trustee_id" = "member_id_p"
jbe@5 1892 AND "membership"."member_id" ISNULL
jbe@5 1893 LOOP
jbe@5 1894 IF NOT
jbe@5 1895 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
jbe@5 1896 THEN
jbe@5 1897 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
jbe@5 1898 "area_id_p",
jbe@5 1899 "delegation_row"."truster_id",
jbe@5 1900 "skip_member_ids_p" || "delegation_row"."truster_id"
jbe@5 1901 );
jbe@5 1902 END IF;
jbe@5 1903 END LOOP;
jbe@5 1904 RETURN "sum_v";
jbe@5 1905 END;
jbe@5 1906 $$;
jbe@5 1907
jbe@8 1908 COMMENT ON FUNCTION "membership_weight_with_skipping"
jbe@8 1909 ( "area"."id"%TYPE,
jbe@8 1910 "member"."id"%TYPE,
jbe@8 1911 INT4[] )
jbe@8 1912 IS 'Helper function for "membership_weight" function';
jbe@8 1913
jbe@8 1914
jbe@5 1915 CREATE FUNCTION "membership_weight"
jbe@5 1916 ( "area_id_p" "area"."id"%TYPE,
jbe@5 1917 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
jbe@5 1918 RETURNS INT4
jbe@5 1919 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 1920 BEGIN
jbe@5 1921 RETURN "membership_weight_with_skipping"(
jbe@5 1922 "area_id_p",
jbe@5 1923 "member_id_p",
jbe@5 1924 ARRAY["member_id_p"]
jbe@5 1925 );
jbe@5 1926 END;
jbe@5 1927 $$;
jbe@5 1928
jbe@8 1929 COMMENT ON FUNCTION "membership_weight"
jbe@8 1930 ( "area"."id"%TYPE,
jbe@8 1931 "member"."id"%TYPE )
jbe@8 1932 IS 'Calculates the potential voting weight of a member in a given area';
jbe@8 1933
jbe@5 1934
jbe@4 1935 CREATE VIEW "member_count_view" AS
jbe@5 1936 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
jbe@4 1937
jbe@4 1938 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
jbe@4 1939
jbe@4 1940
jbe@97 1941 CREATE VIEW "unit_member_count" AS
jbe@97 1942 SELECT
jbe@97 1943 "unit"."id" AS "unit_id",
jbe@248 1944 count("member"."id") AS "member_count"
jbe@97 1945 FROM "unit"
jbe@97 1946 LEFT JOIN "privilege"
jbe@97 1947 ON "privilege"."unit_id" = "unit"."id"
jbe@97 1948 AND "privilege"."voting_right"
jbe@97 1949 LEFT JOIN "member"
jbe@97 1950 ON "member"."id" = "privilege"."member_id"
jbe@97 1951 AND "member"."active"
jbe@97 1952 GROUP BY "unit"."id";
jbe@97 1953
jbe@97 1954 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@97 1955
jbe@97 1956
jbe@4 1957 CREATE VIEW "area_member_count" AS
jbe@5 1958 SELECT
jbe@5 1959 "area"."id" AS "area_id",
jbe@5 1960 count("member"."id") AS "direct_member_count",
jbe@5 1961 coalesce(
jbe@5 1962 sum(
jbe@5 1963 CASE WHEN "member"."id" NOTNULL THEN
jbe@5 1964 "membership_weight"("area"."id", "member"."id")
jbe@5 1965 ELSE 0 END
jbe@5 1966 )
jbe@169 1967 ) AS "member_weight"
jbe@4 1968 FROM "area"
jbe@4 1969 LEFT JOIN "membership"
jbe@4 1970 ON "area"."id" = "membership"."area_id"
jbe@97 1971 LEFT JOIN "privilege"
jbe@97 1972 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 1973 AND "privilege"."member_id" = "membership"."member_id"
jbe@97 1974 AND "privilege"."voting_right"
jbe@4 1975 LEFT JOIN "member"
jbe@97 1976 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
jbe@4 1977 AND "member"."active"
jbe@4 1978 GROUP BY "area"."id";
jbe@4 1979
jbe@169 1980 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
jbe@4 1981
jbe@4 1982
jbe@9 1983 CREATE VIEW "opening_draft" AS
jbe@9 1984 SELECT "draft".* FROM (
jbe@9 1985 SELECT
jbe@9 1986 "initiative"."id" AS "initiative_id",
jbe@9 1987 min("draft"."id") AS "draft_id"
jbe@9 1988 FROM "initiative" JOIN "draft"
jbe@9 1989 ON "initiative"."id" = "draft"."initiative_id"
jbe@9 1990 GROUP BY "initiative"."id"
jbe@9 1991 ) AS "subquery"
jbe@9 1992 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@9 1993
jbe@9 1994 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
jbe@9 1995
jbe@9 1996
jbe@0 1997 CREATE VIEW "current_draft" AS
jbe@0 1998 SELECT "draft".* FROM (
jbe@0 1999 SELECT
jbe@0 2000 "initiative"."id" AS "initiative_id",
jbe@0 2001 max("draft"."id") AS "draft_id"
jbe@0 2002 FROM "initiative" JOIN "draft"
jbe@0 2003 ON "initiative"."id" = "draft"."initiative_id"
jbe@0 2004 GROUP BY "initiative"."id"
jbe@0 2005 ) AS "subquery"
jbe@0 2006 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
jbe@0 2007
jbe@0 2008 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
jbe@0 2009
jbe@0 2010
jbe@0 2011 CREATE VIEW "critical_opinion" AS
jbe@0 2012 SELECT * FROM "opinion"
jbe@0 2013 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
jbe@0 2014 OR ("degree" = -2 AND "fulfilled" = TRUE);
jbe@0 2015
jbe@0 2016 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
jbe@0 2017
jbe@0 2018
jbe@126 2019 CREATE VIEW "battle_participant" AS
jbe@126 2020 SELECT "initiative"."id", "initiative"."issue_id"
jbe@126 2021 FROM "issue" JOIN "initiative"
jbe@126 2022 ON "issue"."id" = "initiative"."issue_id"
jbe@126 2023 WHERE "initiative"."admitted"
jbe@126 2024 UNION ALL
jbe@126 2025 SELECT NULL, "id" AS "issue_id"
jbe@126 2026 FROM "issue";
jbe@126 2027
jbe@126 2028 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 2029
jbe@126 2030
jbe@61 2031 CREATE VIEW "battle_view" AS
jbe@0 2032 SELECT
jbe@0 2033 "issue"."id" AS "issue_id",
jbe@10 2034 "winning_initiative"."id" AS "winning_initiative_id",
jbe@10 2035 "losing_initiative"."id" AS "losing_initiative_id",
jbe@0 2036 sum(
jbe@0 2037 CASE WHEN
jbe@0 2038 coalesce("better_vote"."grade", 0) >
jbe@0 2039 coalesce("worse_vote"."grade", 0)
jbe@0 2040 THEN "direct_voter"."weight" ELSE 0 END
jbe@0 2041 ) AS "count"
jbe@0 2042 FROM "issue"
jbe@0 2043 LEFT JOIN "direct_voter"
jbe@0 2044 ON "issue"."id" = "direct_voter"."issue_id"
jbe@126 2045 JOIN "battle_participant" AS "winning_initiative"
jbe@10 2046 ON "issue"."id" = "winning_initiative"."issue_id"
jbe@126 2047 JOIN "battle_participant" AS "losing_initiative"
jbe@10 2048 ON "issue"."id" = "losing_initiative"."issue_id"
jbe@0 2049 LEFT JOIN "vote" AS "better_vote"
jbe@10 2050 ON "direct_voter"."member_id" = "better_vote"."member_id"
jbe@10 2051 AND "winning_initiative"."id" = "better_vote"."initiative_id"
jbe@0 2052 LEFT JOIN "vote" AS "worse_vote"
jbe@10 2053 ON "direct_voter"."member_id" = "worse_vote"."member_id"
jbe@10 2054 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
jbe@328 2055 WHERE "issue"."state" = 'voting'
jbe@328 2056 AND "issue"."phase_finished" NOTNULL
jbe@61 2057 AND "issue"."cleaned" ISNULL
jbe@126 2058 AND (
jbe@126 2059 "winning_initiative"."id" != "losing_initiative"."id" OR
jbe@126 2060 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
jbe@126 2061 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
jbe@0 2062 GROUP BY
jbe@0 2063 "issue"."id",
jbe@10 2064 "winning_initiative"."id",
jbe@10 2065 "losing_initiative"."id";
jbe@0 2066
jbe@126 2067 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 2068
jbe@1 2069
jbe@235 2070 CREATE VIEW "expired_session" AS
jbe@235 2071 SELECT * FROM "session" WHERE now() > "expiry";
jbe@235 2072
jbe@235 2073 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@235 2074 DELETE FROM "session" WHERE "ident" = OLD."ident";
jbe@235 2075
jbe@235 2076 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@235 2077 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 2078
jbe@235 2079
jbe@0 2080 CREATE VIEW "open_issue" AS
jbe@0 2081 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@0 2082
jbe@0 2083 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@0 2084
jbe@0 2085
jbe@9 2086 CREATE VIEW "member_contingent" AS
jbe@9 2087 SELECT
jbe@9 2088 "member"."id" AS "member_id",
jbe@293 2089 "contingent"."polling",
jbe@9 2090 "contingent"."time_frame",
jbe@9 2091 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
jbe@9 2092 (
jbe@9 2093 SELECT count(1) FROM "draft"
jbe@293 2094 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@9 2095 WHERE "draft"."author_id" = "member"."id"
jbe@293 2096 AND "initiative"."polling" = "contingent"."polling"
jbe@9 2097 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 2098 ) + (
jbe@9 2099 SELECT count(1) FROM "suggestion"
jbe@293 2100 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
jbe@9 2101 WHERE "suggestion"."author_id" = "member"."id"
jbe@293 2102 AND "contingent"."polling" = FALSE
jbe@9 2103 AND "suggestion"."created" > now() - "contingent"."time_frame"
jbe@9 2104 )
jbe@9 2105 ELSE NULL END AS "text_entry_count",
jbe@9 2106 "contingent"."text_entry_limit",
jbe@9 2107 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
jbe@293 2108 SELECT count(1) FROM "opening_draft" AS "draft"
jbe@293 2109 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
jbe@293 2110 WHERE "draft"."author_id" = "member"."id"
jbe@293 2111 AND "initiative"."polling" = "contingent"."polling"
jbe@293 2112 AND "draft"."created" > now() - "contingent"."time_frame"
jbe@9 2113 ) ELSE NULL END AS "initiative_count",
jbe@9 2114 "contingent"."initiative_limit"
jbe@9 2115 FROM "member" CROSS JOIN "contingent";
jbe@9 2116
jbe@9 2117 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 2118
jbe@9 2119 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
jbe@9 2120 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
jbe@9 2121
jbe@9 2122
jbe@9 2123 CREATE VIEW "member_contingent_left" AS
jbe@9 2124 SELECT
jbe@9 2125 "member_id",
jbe@293 2126 "polling",
jbe@9 2127 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
jbe@9 2128 max("initiative_limit" - "initiative_count") AS "initiatives_left"
jbe@293 2129 FROM "member_contingent" GROUP BY "member_id", "polling";
jbe@9 2130
jbe@9 2131 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 2132
jbe@9 2133
jbe@113 2134 CREATE VIEW "event_seen_by_member" AS
jbe@113 2135 SELECT
jbe@113 2136 "member"."id" AS "seen_by_member_id",
jbe@113 2137 CASE WHEN "event"."state" IN (
jbe@113 2138 'voting',
jbe@113 2139 'finished_without_winner',
jbe@113 2140 'finished_with_winner'
jbe@113 2141 ) THEN
jbe@113 2142 'voting'::"notify_level"
jbe@113 2143 ELSE
jbe@113 2144 CASE WHEN "event"."state" IN (
jbe@113 2145 'verification',
jbe@113 2146 'canceled_after_revocation_during_verification',
jbe@113 2147 'canceled_no_initiative_admitted'
jbe@113 2148 ) THEN
jbe@113 2149 'verification'::"notify_level"
jbe@113 2150 ELSE
jbe@113 2151 CASE WHEN "event"."state" IN (
jbe@113 2152 'discussion',
jbe@113 2153 'canceled_after_revocation_during_discussion'
jbe@113 2154 ) THEN
jbe@113 2155 'discussion'::"notify_level"
jbe@113 2156 ELSE
jbe@113 2157 'all'::"notify_level"
jbe@113 2158 END
jbe@113 2159 END
jbe@113 2160 END AS "notify_level",
jbe@113 2161 "event".*
jbe@113 2162 FROM "member" CROSS JOIN "event"
jbe@113 2163 LEFT JOIN "issue"
jbe@113 2164 ON "event"."issue_id" = "issue"."id"
jbe@113 2165 LEFT JOIN "membership"
jbe@113 2166 ON "member"."id" = "membership"."member_id"
jbe@113 2167 AND "issue"."area_id" = "membership"."area_id"
jbe@113 2168 LEFT JOIN "interest"
jbe@113 2169 ON "member"."id" = "interest"."member_id"
jbe@113 2170 AND "event"."issue_id" = "interest"."issue_id"
jbe@113 2171 LEFT JOIN "supporter"
jbe@113 2172 ON "member"."id" = "supporter"."member_id"
jbe@113 2173 AND "event"."initiative_id" = "supporter"."initiative_id"
jbe@113 2174 LEFT JOIN "ignored_member"
jbe@113 2175 ON "member"."id" = "ignored_member"."member_id"
jbe@113 2176 AND "event"."member_id" = "ignored_member"."other_member_id"
jbe@113 2177 LEFT JOIN "ignored_initiative"
jbe@113 2178 ON "member"."id" = "ignored_initiative"."member_id"
jbe@113 2179 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
jbe@113 2180 WHERE (
jbe@113 2181 "supporter"."member_id" NOTNULL OR
jbe@113 2182 "interest"."member_id" NOTNULL OR
jbe@113 2183 ( "membership"."member_id" NOTNULL AND
jbe@113 2184 "event"."event" IN (
jbe@113 2185 'issue_state_changed',
jbe@113 2186 'initiative_created_in_new_issue',
jbe@113 2187 'initiative_created_in_existing_issue',
jbe@113 2188 'initiative_revoked' ) ) )
jbe@113 2189 AND "ignored_member"."member_id" ISNULL
jbe@113 2190 AND "ignored_initiative"."member_id" ISNULL;
jbe@113 2191
jbe@222 2192 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 2193
jbe@222 2194
jbe@222 2195 CREATE VIEW "selected_event_seen_by_member" AS
jbe@113 2196 SELECT
jbe@113 2197 "member"."id" AS "seen_by_member_id",
jbe@222 2198 CASE WHEN "event"."state" IN (
jbe@222 2199 'voting',
jbe@222 2200 'finished_without_winner',
jbe@222 2201 'finished_with_winner'
jbe@222 2202 ) THEN
jbe@222 2203 'voting'::"notify_level"
jbe@222 2204 ELSE
jbe@222 2205 CASE WHEN "event"."state" IN (
jbe@222 2206 'verification',
jbe@222 2207 'canceled_after_revocation_during_verification',
jbe@222 2208 'canceled_no_initiative_admitted'
jbe@222 2209 ) THEN
jbe@222 2210 'verification'::"notify_level"
jbe@222 2211 ELSE
jbe@222 2212 CASE WHEN "event"."state" IN (
jbe@222 2213 'discussion',
jbe@222 2214 'canceled_after_revocation_during_discussion'
jbe@222 2215 ) THEN
jbe@222 2216 'discussion'::"notify_level"
jbe@222 2217 ELSE
jbe@222 2218 'all'::"notify_level"
jbe@222 2219 END
jbe@222 2220 END
jbe@222 2221 END AS "notify_level",
jbe@113 2222 "event".*
jbe@113 2223 FROM "member" CROSS JOIN "event"
jbe@113 2224 LEFT JOIN "issue"
jbe@113 2225 ON "event"."issue_id" = "issue"."id"
jbe@113 2226 LEFT JOIN "membership"
jbe@113 2227 ON "member"."id" = "membership"."member_id"
jbe@113 2228 AND "issue"."area_id" = "membership"."area_id"
jbe@113 2229 LEFT JOIN "interest"
jbe@113 2230 ON "member"."id" = "interest"."member_id"
jbe@113 2231 AND "event"."issue_id" = "interest"."issue_id"
jbe@113 2232 LEFT JOIN "supporter"
jbe@113 2233 ON "member"."id" = "supporter"."member_id"
jbe@113 2234 AND "event"."initiative_id" = "supporter"."initiative_id"
jbe@113 2235 LEFT JOIN "ignored_member"
jbe@113 2236 ON "member"."id" = "ignored_member"."member_id"
jbe@113 2237 AND "event"."member_id" = "ignored_member"."other_member_id"
jbe@113 2238 LEFT JOIN "ignored_initiative"
jbe@113 2239 ON "member"."id" = "ignored_initiative"."member_id"
jbe@113 2240 AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
jbe@113 2241 WHERE (
jbe@113 2242 ( "member"."notify_level" >= 'all' ) OR
jbe@113 2243 ( "member"."notify_level" >= 'voting' AND
jbe@113 2244 "event"."state" IN (
jbe@113 2245 'voting',
jbe@113 2246 'finished_without_winner',
jbe@113 2247 'finished_with_winner' ) ) OR
jbe@113 2248 ( "member"."notify_level" >= 'verification' AND
jbe@113 2249 "event"."state" IN (
jbe@113 2250 'verification',
jbe@113 2251 'canceled_after_revocation_during_verification',
jbe@113 2252 'canceled_no_initiative_admitted' ) ) OR
jbe@113 2253 ( "member"."notify_level" >= 'discussion' AND
jbe@113 2254 "event"."state" IN (
jbe@113 2255 'discussion',
jbe@113 2256 'canceled_after_revocation_during_discussion' ) ) )
jbe@113 2257 AND (
jbe@113 2258 "supporter"."member_id" NOTNULL OR
jbe@113 2259 "interest"."member_id" NOTNULL OR
jbe@113 2260 ( "membership"."member_id" NOTNULL AND
jbe@113 2261 "event"."event" IN (
jbe@113 2262 'issue_state_changed',
jbe@113 2263 'initiative_created_in_new_issue',
jbe@113 2264 'initiative_created_in_existing_issue',
jbe@113 2265 'initiative_revoked' ) ) )
jbe@113 2266 AND "ignored_member"."member_id" ISNULL
jbe@113 2267 AND "ignored_initiative"."member_id" ISNULL;
jbe@113 2268
jbe@222 2269 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 2270
jbe@113 2271
jbe@16 2272 CREATE TYPE "timeline_event" AS ENUM (
jbe@16 2273 'issue_created',
jbe@16 2274 'issue_canceled',
jbe@16 2275 'issue_accepted',
jbe@16 2276 'issue_half_frozen',
jbe@16 2277 'issue_finished_without_voting',
jbe@16 2278 'issue_voting_started',
jbe@16 2279 'issue_finished_after_voting',
jbe@16 2280 'initiative_created',
jbe@16 2281 'initiative_revoked',
jbe@16 2282 'draft_created',
jbe@16 2283 'suggestion_created');
jbe@16 2284
jbe@112 2285 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
jbe@16 2286
jbe@16 2287
jbe@16 2288 CREATE VIEW "timeline_issue" AS
jbe@16 2289 SELECT
jbe@16 2290 "created" AS "occurrence",
jbe@16 2291 'issue_created'::"timeline_event" AS "event",
jbe@16 2292 "id" AS "issue_id"
jbe@16 2293 FROM "issue"
jbe@16 2294 UNION ALL
jbe@16 2295 SELECT
jbe@16 2296 "closed" AS "occurrence",
jbe@16 2297 'issue_canceled'::"timeline_event" AS "event",
jbe@16 2298 "id" AS "issue_id"
jbe@16 2299 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL
jbe@16 2300 UNION ALL
jbe@16 2301 SELECT
jbe@16 2302 "accepted" AS "occurrence",
jbe@16 2303 'issue_accepted'::"timeline_event" AS "event",
jbe@16 2304 "id" AS "issue_id"
jbe@16 2305 FROM "issue" WHERE "accepted" NOTNULL
jbe@16 2306 UNION ALL
jbe@16 2307 SELECT
jbe@16 2308 "half_frozen" AS "occurrence",
jbe@16 2309 'issue_half_frozen'::"timeline_event" AS "event",
jbe@16 2310 "id" AS "issue_id"
jbe@16 2311 FROM "issue" WHERE "half_frozen" NOTNULL
jbe@16 2312 UNION ALL
jbe@16 2313 SELECT
jbe@16 2314 "fully_frozen" AS "occurrence",
jbe@16 2315 'issue_voting_started'::"timeline_event" AS "event",
jbe@16 2316 "id" AS "issue_id"
jbe@16 2317 FROM "issue"
jbe@17 2318 WHERE "fully_frozen" NOTNULL
jbe@17 2319 AND ("closed" ISNULL OR "closed" != "fully_frozen")
jbe@16 2320 UNION ALL
jbe@16 2321 SELECT
jbe@16 2322 "closed" AS "occurrence",
jbe@16 2323 CASE WHEN "fully_frozen" = "closed" THEN
jbe@16 2324 'issue_finished_without_voting'::"timeline_event"
jbe@16 2325 ELSE
jbe@16 2326 'issue_finished_after_voting'::"timeline_event"
jbe@16 2327 END AS "event",
jbe@16 2328 "id" AS "issue_id"
jbe@16 2329 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL;
jbe@16 2330
jbe@112 2331 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2332
jbe@16 2333
jbe@16 2334 CREATE VIEW "timeline_initiative" AS
jbe@16 2335 SELECT
jbe@16 2336 "created" AS "occurrence",
jbe@16 2337 'initiative_created'::"timeline_event" AS "event",
jbe@16 2338 "id" AS "initiative_id"
jbe@16 2339 FROM "initiative"
jbe@16 2340 UNION ALL
jbe@16 2341 SELECT
jbe@16 2342 "revoked" AS "occurrence",
jbe@16 2343 'initiative_revoked'::"timeline_event" AS "event",
jbe@16 2344 "id" AS "initiative_id"
jbe@16 2345 FROM "initiative" WHERE "revoked" NOTNULL;
jbe@16 2346
jbe@112 2347 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2348
jbe@16 2349
jbe@16 2350 CREATE VIEW "timeline_draft" AS
jbe@16 2351 SELECT
jbe@16 2352 "created" AS "occurrence",
jbe@16 2353 'draft_created'::"timeline_event" AS "event",
jbe@16 2354 "id" AS "draft_id"
jbe@16 2355 FROM "draft";
jbe@16 2356
jbe@112 2357 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2358
jbe@16 2359
jbe@16 2360 CREATE VIEW "timeline_suggestion" AS
jbe@16 2361 SELECT
jbe@16 2362 "created" AS "occurrence",
jbe@16 2363 'suggestion_created'::"timeline_event" AS "event",
jbe@16 2364 "id" AS "suggestion_id"
jbe@16 2365 FROM "suggestion";
jbe@16 2366
jbe@112 2367 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
jbe@16 2368
jbe@16 2369
jbe@16 2370 CREATE VIEW "timeline" AS
jbe@16 2371 SELECT
jbe@16 2372 "occurrence",
jbe@16 2373 "event",
jbe@16 2374 "issue_id",
jbe@16 2375 NULL AS "initiative_id",
jbe@16 2376 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture?
jbe@16 2377 NULL::INT8 AS "suggestion_id"
jbe@16 2378 FROM "timeline_issue"
jbe@16 2379 UNION ALL
jbe@16 2380 SELECT
jbe@16 2381 "occurrence",
jbe@16 2382 "event",
jbe@16 2383 NULL AS "issue_id",
jbe@16 2384 "initiative_id",
jbe@16 2385 NULL AS "draft_id",
jbe@16 2386 NULL AS "suggestion_id"
jbe@16 2387 FROM "timeline_initiative"
jbe@16 2388 UNION ALL
jbe@16 2389 SELECT
jbe@16 2390 "occurrence",
jbe@16 2391 "event",
jbe@16 2392 NULL AS "issue_id",
jbe@16 2393 NULL AS "initiative_id",
jbe@16 2394 "draft_id",
jbe@16 2395 NULL AS "suggestion_id"
jbe@16 2396 FROM "timeline_draft"
jbe@16 2397 UNION ALL
jbe@16 2398 SELECT
jbe@16 2399 "occurrence",
jbe@16 2400 "event",
jbe@16 2401 NULL AS "issue_id",
jbe@16 2402 NULL AS "initiative_id",
jbe@16 2403 NULL AS "draft_id",
jbe@16 2404 "suggestion_id"
jbe@16 2405 FROM "timeline_suggestion";
jbe@16 2406
jbe@112 2407 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
jbe@16 2408
jbe@16 2409
jbe@0 2410
jbe@242 2411 ------------------------------------------------------
jbe@242 2412 -- Row set returning function for delegation chains --
jbe@242 2413 ------------------------------------------------------
jbe@5 2414
jbe@5 2415
jbe@5 2416 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 2417 ('first', 'intermediate', 'last', 'repetition');
jbe@5 2418
jbe@5 2419 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 2420
jbe@5 2421
jbe@5 2422 CREATE TYPE "delegation_chain_row" AS (
jbe@5 2423 "index" INT4,
jbe@5 2424 "member_id" INT4,
jbe@97 2425 "member_valid" BOOLEAN,
jbe@5 2426 "participation" BOOLEAN,
jbe@5 2427 "overridden" BOOLEAN,
jbe@5 2428 "scope_in" "delegation_scope",
jbe@5 2429 "scope_out" "delegation_scope",
jbe@86 2430 "disabled_out" BOOLEAN,
jbe@5 2431 "loop" "delegation_chain_loop_tag" );
jbe@5 2432
jbe@243 2433 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
jbe@5 2434
jbe@5 2435 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 2436 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 2437 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 2438 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 2439 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 2440 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 2441 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 2442
jbe@5 2443
jbe@242 2444 CREATE FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2445 ( "member_id_p" "member"."id"%TYPE,
jbe@242 2446 "issue_id_p" "issue"."id"%TYPE )
jbe@242 2447 RETURNS SETOF "delegation_chain_row"
jbe@242 2448 LANGUAGE 'plpgsql' STABLE AS $$
jbe@242 2449 DECLARE
jbe@242 2450 "output_row" "delegation_chain_row";
jbe@242 2451 "direct_voter_row" "direct_voter"%ROWTYPE;
jbe@242 2452 "delegating_voter_row" "delegating_voter"%ROWTYPE;
jbe@242 2453 BEGIN
jbe@242 2454 "output_row"."index" := 0;
jbe@242 2455 "output_row"."member_id" := "member_id_p";
jbe@242 2456 "output_row"."member_valid" := TRUE;
jbe@242 2457 "output_row"."participation" := FALSE;
jbe@242 2458 "output_row"."overridden" := FALSE;
jbe@242 2459 "output_row"."disabled_out" := FALSE;
jbe@242 2460 LOOP
jbe@242 2461 SELECT INTO "direct_voter_row" * FROM "direct_voter"
jbe@242 2462 WHERE "issue_id" = "issue_id_p"
jbe@242 2463 AND "member_id" = "output_row"."member_id";
jbe@242 2464 IF "direct_voter_row"."member_id" NOTNULL THEN
jbe@242 2465 "output_row"."participation" := TRUE;
jbe@242 2466 "output_row"."scope_out" := NULL;
jbe@242 2467 "output_row"."disabled_out" := NULL;
jbe@242 2468 RETURN NEXT "output_row";
jbe@242 2469 RETURN;
jbe@242 2470 END IF;
jbe@242 2471 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
jbe@242 2472 WHERE "issue_id" = "issue_id_p"
jbe@242 2473 AND "member_id" = "output_row"."member_id";
jbe@242 2474 IF "delegating_voter_row"."member_id" ISNULL THEN
jbe@242 2475 RETURN;
jbe@242 2476 END IF;
jbe@242 2477 "output_row"."scope_out" := "delegating_voter_row"."scope";
jbe@242 2478 RETURN NEXT "output_row";
jbe@242 2479 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
jbe@242 2480 "output_row"."scope_in" := "output_row"."scope_out";
jbe@242 2481 END LOOP;
jbe@242 2482 END;
jbe@242 2483 $$;
jbe@242 2484
jbe@242 2485 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2486 ( "member"."id"%TYPE,
jbe@242 2487 "member"."id"%TYPE )
jbe@242 2488 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
jbe@242 2489
jbe@242 2490
jbe@5 2491 CREATE FUNCTION "delegation_chain"
jbe@5 2492 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2493 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2494 "area_id_p" "area"."id"%TYPE,
jbe@5 2495 "issue_id_p" "issue"."id"%TYPE,
jbe@255 2496 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 2497 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@5 2498 RETURNS SETOF "delegation_chain_row"
jbe@5 2499 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2500 DECLARE
jbe@97 2501 "scope_v" "delegation_scope";
jbe@97 2502 "unit_id_v" "unit"."id"%TYPE;
jbe@97 2503 "area_id_v" "area"."id"%TYPE;
jbe@241 2504 "issue_row" "issue"%ROWTYPE;
jbe@5 2505 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 2506 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 2507 "output_row" "delegation_chain_row";
jbe@5 2508 "output_rows" "delegation_chain_row"[];
jbe@255 2509 "simulate_v" BOOLEAN;
jbe@255 2510 "simulate_here_v" BOOLEAN;
jbe@5 2511 "delegation_row" "delegation"%ROWTYPE;
jbe@5 2512 "row_count" INT4;
jbe@5 2513 "i" INT4;
jbe@5 2514 "loop_v" BOOLEAN;
jbe@5 2515 BEGIN
jbe@255 2516 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
jbe@255 2517 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
jbe@255 2518 END IF;
jbe@255 2519 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
jbe@255 2520 "simulate_v" := TRUE;
jbe@255 2521 ELSE
jbe@255 2522 "simulate_v" := FALSE;
jbe@255 2523 END IF;
jbe@97 2524 IF
jbe@97 2525 "unit_id_p" NOTNULL AND
jbe@97 2526 "area_id_p" ISNULL AND
jbe@97 2527 "issue_id_p" ISNULL
jbe@97 2528 THEN
jbe@97 2529 "scope_v" := 'unit';
jbe@97 2530 "unit_id_v" := "unit_id_p";
jbe@97 2531 ELSIF
jbe@97 2532 "unit_id_p" ISNULL AND
jbe@97 2533 "area_id_p" NOTNULL AND
jbe@97 2534 "issue_id_p" ISNULL
jbe@97 2535 THEN
jbe@97 2536 "scope_v" := 'area';
jbe@97 2537 "area_id_v" := "area_id_p";
jbe@97 2538 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2539 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2540 ELSIF
jbe@97 2541 "unit_id_p" ISNULL AND
jbe@97 2542 "area_id_p" ISNULL AND
jbe@97 2543 "issue_id_p" NOTNULL
jbe@97 2544 THEN
jbe@242 2545 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@242 2546 IF "issue_row"."id" ISNULL THEN
jbe@242 2547 RETURN;
jbe@242 2548 END IF;
jbe@242 2549 IF "issue_row"."closed" NOTNULL THEN
jbe@255 2550 IF "simulate_v" THEN
jbe@242 2551 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@242 2552 END IF;
jbe@242 2553 FOR "output_row" IN
jbe@242 2554 SELECT * FROM
jbe@242 2555 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@242 2556 LOOP
jbe@242 2557 RETURN NEXT "output_row";
jbe@242 2558 END LOOP;
jbe@242 2559 RETURN;
jbe@242 2560 END IF;
jbe@97 2561 "scope_v" := 'issue';
jbe@97 2562 SELECT "area_id" INTO "area_id_v"
jbe@97 2563 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 2564 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2565 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2566 ELSE
jbe@97 2567 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 2568 END IF;
jbe@5 2569 "visited_member_ids" := '{}';
jbe@5 2570 "loop_member_id_v" := NULL;
jbe@5 2571 "output_rows" := '{}';
jbe@5 2572 "output_row"."index" := 0;
jbe@5 2573 "output_row"."member_id" := "member_id_p";
jbe@97 2574 "output_row"."member_valid" := TRUE;
jbe@5 2575 "output_row"."participation" := FALSE;
jbe@5 2576 "output_row"."overridden" := FALSE;
jbe@86 2577 "output_row"."disabled_out" := FALSE;
jbe@5 2578 "output_row"."scope_out" := NULL;
jbe@5 2579 LOOP
jbe@5 2580 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 2581 "loop_member_id_v" := "output_row"."member_id";
jbe@5 2582 ELSE
jbe@5 2583 "visited_member_ids" :=
jbe@5 2584 "visited_member_ids" || "output_row"."member_id";
jbe@5 2585 END IF;
jbe@241 2586 IF "output_row"."participation" ISNULL THEN
jbe@241 2587 "output_row"."overridden" := NULL;
jbe@241 2588 ELSIF "output_row"."participation" THEN
jbe@5 2589 "output_row"."overridden" := TRUE;
jbe@5 2590 END IF;
jbe@5 2591 "output_row"."scope_in" := "output_row"."scope_out";
jbe@255 2592 "output_row"."member_valid" := EXISTS (
jbe@97 2593 SELECT NULL FROM "member" JOIN "privilege"
jbe@97 2594 ON "privilege"."member_id" = "member"."id"
jbe@97 2595 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 2596 WHERE "id" = "output_row"."member_id"
jbe@97 2597 AND "member"."active" AND "privilege"."voting_right"
jbe@255 2598 );
jbe@255 2599 "simulate_here_v" := (
jbe@255 2600 "simulate_v" AND
jbe@255 2601 "output_row"."member_id" = "member_id_p"
jbe@255 2602 );
jbe@255 2603 "delegation_row" := ROW(NULL);
jbe@255 2604 IF "output_row"."member_valid" OR "simulate_here_v" THEN
jbe@97 2605 IF "scope_v" = 'unit' THEN
jbe@255 2606 IF NOT "simulate_here_v" THEN
jbe@255 2607 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2608 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2609 AND "unit_id" = "unit_id_v";
jbe@255 2610 END IF;
jbe@97 2611 ELSIF "scope_v" = 'area' THEN
jbe@5 2612 "output_row"."participation" := EXISTS (
jbe@5 2613 SELECT NULL FROM "membership"
jbe@5 2614 WHERE "area_id" = "area_id_p"
jbe@5 2615 AND "member_id" = "output_row"."member_id"
jbe@5 2616 );
jbe@255 2617 IF "simulate_here_v" THEN
jbe@255 2618 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 2619 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2620 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2621 AND "unit_id" = "unit_id_v";
jbe@255 2622 END IF;
jbe@255 2623 ELSE
jbe@255 2624 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2625 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2626 AND (
jbe@255 2627 "unit_id" = "unit_id_v" OR
jbe@255 2628 "area_id" = "area_id_v"
jbe@255 2629 )
jbe@255 2630 ORDER BY "scope" DESC;
jbe@255 2631 END IF;
jbe@97 2632 ELSIF "scope_v" = 'issue' THEN
jbe@241 2633 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@241 2634 "output_row"."participation" := EXISTS (
jbe@241 2635 SELECT NULL FROM "interest"
jbe@241 2636 WHERE "issue_id" = "issue_id_p"
jbe@241 2637 AND "member_id" = "output_row"."member_id"
jbe@241 2638 );
jbe@241 2639 ELSE
jbe@241 2640 IF "output_row"."member_id" = "member_id_p" THEN
jbe@241 2641 "output_row"."participation" := EXISTS (
jbe@241 2642 SELECT NULL FROM "direct_voter"
jbe@241 2643 WHERE "issue_id" = "issue_id_p"
jbe@241 2644 AND "member_id" = "output_row"."member_id"
jbe@241 2645 );
jbe@241 2646 ELSE
jbe@241 2647 "output_row"."participation" := NULL;
jbe@241 2648 END IF;
jbe@241 2649 END IF;
jbe@255 2650 IF "simulate_here_v" THEN
jbe@255 2651 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 2652 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2653 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2654 AND (
jbe@255 2655 "unit_id" = "unit_id_v" OR
jbe@255 2656 "area_id" = "area_id_v"
jbe@255 2657 )
jbe@255 2658 ORDER BY "scope" DESC;
jbe@255 2659 END IF;
jbe@255 2660 ELSE
jbe@255 2661 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2662 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2663 AND (
jbe@255 2664 "unit_id" = "unit_id_v" OR
jbe@255 2665 "area_id" = "area_id_v" OR
jbe@255 2666 "issue_id" = "issue_id_p"
jbe@255 2667 )
jbe@255 2668 ORDER BY "scope" DESC;
jbe@255 2669 END IF;
jbe@5 2670 END IF;
jbe@5 2671 ELSE
jbe@5 2672 "output_row"."participation" := FALSE;
jbe@5 2673 END IF;
jbe@255 2674 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
jbe@97 2675 "output_row"."scope_out" := "scope_v";
jbe@5 2676 "output_rows" := "output_rows" || "output_row";
jbe@5 2677 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 2678 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 2679 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 2680 "output_rows" := "output_rows" || "output_row";
jbe@5 2681 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 2682 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 2683 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 2684 "output_row"."disabled_out" := TRUE;
jbe@86 2685 "output_rows" := "output_rows" || "output_row";
jbe@86 2686 EXIT;
jbe@5 2687 ELSE
jbe@5 2688 "output_row"."scope_out" := NULL;
jbe@5 2689 "output_rows" := "output_rows" || "output_row";
jbe@5 2690 EXIT;
jbe@5 2691 END IF;
jbe@5 2692 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 2693 "output_row"."index" := "output_row"."index" + 1;
jbe@5 2694 END LOOP;
jbe@5 2695 "row_count" := array_upper("output_rows", 1);
jbe@5 2696 "i" := 1;
jbe@5 2697 "loop_v" := FALSE;
jbe@5 2698 LOOP
jbe@5 2699 "output_row" := "output_rows"["i"];
jbe@98 2700 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 2701 IF "loop_v" THEN
jbe@5 2702 IF "i" + 1 = "row_count" THEN
jbe@5 2703 "output_row"."loop" := 'last';
jbe@5 2704 ELSIF "i" = "row_count" THEN
jbe@5 2705 "output_row"."loop" := 'repetition';
jbe@5 2706 ELSE
jbe@5 2707 "output_row"."loop" := 'intermediate';
jbe@5 2708 END IF;
jbe@5 2709 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 2710 "output_row"."loop" := 'first';
jbe@5 2711 "loop_v" := TRUE;
jbe@5 2712 END IF;
jbe@97 2713 IF "scope_v" = 'unit' THEN
jbe@5 2714 "output_row"."participation" := NULL;
jbe@5 2715 END IF;
jbe@5 2716 RETURN NEXT "output_row";
jbe@5 2717 "i" := "i" + 1;
jbe@5 2718 END LOOP;
jbe@5 2719 RETURN;
jbe@5 2720 END;
jbe@5 2721 $$;
jbe@5 2722
jbe@5 2723 COMMENT ON FUNCTION "delegation_chain"
jbe@5 2724 ( "member"."id"%TYPE,
jbe@97 2725 "unit"."id"%TYPE,
jbe@5 2726 "area"."id"%TYPE,
jbe@5 2727 "issue"."id"%TYPE,
jbe@255 2728 "member"."id"%TYPE,
jbe@255 2729 BOOLEAN )
jbe@242 2730 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
jbe@242 2731
jbe@242 2732
jbe@242 2733
jbe@242 2734 ---------------------------------------------------------
jbe@242 2735 -- Single row returning function for delegation chains --
jbe@242 2736 ---------------------------------------------------------
jbe@242 2737
jbe@242 2738
jbe@242 2739 CREATE TYPE "delegation_info_loop_type" AS ENUM
jbe@242 2740 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
jbe@240 2741
jbe@243 2742 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 2743
jbe@243 2744
jbe@240 2745 CREATE TYPE "delegation_info_type" AS (
jbe@242 2746 "own_participation" BOOLEAN,
jbe@242 2747 "own_delegation_scope" "delegation_scope",
jbe@242 2748 "first_trustee_id" INT4,
jbe@240 2749 "first_trustee_participation" BOOLEAN,
jbe@242 2750 "first_trustee_ellipsis" BOOLEAN,
jbe@242 2751 "other_trustee_id" INT4,
jbe@240 2752 "other_trustee_participation" BOOLEAN,
jbe@242 2753 "other_trustee_ellipsis" BOOLEAN,
jbe@253 2754 "delegation_loop" "delegation_info_loop_type",
jbe@253 2755 "participating_member_id" INT4 );
jbe@240 2756
jbe@243 2757 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 2758
jbe@243 2759 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
jbe@243 2760 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
jbe@243 2761 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
jbe@243 2762 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
jbe@243 2763 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
jbe@243 2764 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
jbe@243 2765 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 2766 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
jbe@243 2767 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 2768 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
jbe@243 2769
jbe@243 2770
jbe@240 2771 CREATE FUNCTION "delegation_info"
jbe@242 2772 ( "member_id_p" "member"."id"%TYPE,
jbe@242 2773 "unit_id_p" "unit"."id"%TYPE,
jbe@242 2774 "area_id_p" "area"."id"%TYPE,
jbe@242 2775 "issue_id_p" "issue"."id"%TYPE,
jbe@255 2776 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 2777 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@240 2778 RETURNS "delegation_info_type"
jbe@240 2779 LANGUAGE 'plpgsql' STABLE AS $$
jbe@240 2780 DECLARE
jbe@242 2781 "current_row" "delegation_chain_row";
jbe@242 2782 "result" "delegation_info_type";
jbe@240 2783 BEGIN
jbe@242 2784 "result"."own_participation" := FALSE;
jbe@242 2785 FOR "current_row" IN
jbe@242 2786 SELECT * FROM "delegation_chain"(
jbe@242 2787 "member_id_p",
jbe@242 2788 "unit_id_p", "area_id_p", "issue_id_p",
jbe@255 2789 "simulate_trustee_id_p", "simulate_default_p")
jbe@242 2790 LOOP
jbe@253 2791 IF
jbe@253 2792 "result"."participating_member_id" ISNULL AND
jbe@253 2793 "current_row"."participation"
jbe@253 2794 THEN
jbe@253 2795 "result"."participating_member_id" := "current_row"."member_id";
jbe@253 2796 END IF;
jbe@242 2797 IF "current_row"."member_id" = "member_id_p" THEN
jbe@242 2798 "result"."own_participation" := "current_row"."participation";
jbe@242 2799 "result"."own_delegation_scope" := "current_row"."scope_out";
jbe@242 2800 IF "current_row"."loop" = 'first' THEN
jbe@242 2801 "result"."delegation_loop" := 'own';
jbe@242 2802 END IF;
jbe@242 2803 ELSIF
jbe@242 2804 "current_row"."member_valid" AND
jbe@242 2805 ( "current_row"."loop" ISNULL OR
jbe@242 2806 "current_row"."loop" != 'repetition' )
jbe@242 2807 THEN
jbe@242 2808 IF "result"."first_trustee_id" ISNULL THEN
jbe@242 2809 "result"."first_trustee_id" := "current_row"."member_id";
jbe@242 2810 "result"."first_trustee_participation" := "current_row"."participation";
jbe@242 2811 "result"."first_trustee_ellipsis" := FALSE;
jbe@242 2812 IF "current_row"."loop" = 'first' THEN
jbe@242 2813 "result"."delegation_loop" := 'first';
jbe@242 2814 END IF;
jbe@242 2815 ELSIF "result"."other_trustee_id" ISNULL THEN
jbe@247 2816 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
jbe@242 2817 "result"."other_trustee_id" := "current_row"."member_id";
jbe@242 2818 "result"."other_trustee_participation" := TRUE;
jbe@242 2819 "result"."other_trustee_ellipsis" := FALSE;
jbe@242 2820 IF "current_row"."loop" = 'first' THEN
jbe@242 2821 "result"."delegation_loop" := 'other';
jbe@240 2822 END IF;
jbe@240 2823 ELSE
jbe@242 2824 "result"."first_trustee_ellipsis" := TRUE;
jbe@242 2825 IF "current_row"."loop" = 'first' THEN
jbe@242 2826 "result"."delegation_loop" := 'first_ellipsis';
jbe@242 2827 END IF;
jbe@242 2828 END IF;
jbe@242 2829 ELSE
jbe@242 2830 "result"."other_trustee_ellipsis" := TRUE;
jbe@242 2831 IF "current_row"."loop" = 'first' THEN
jbe@242 2832 "result"."delegation_loop" := 'other_ellipsis';
jbe@240 2833 END IF;
jbe@240 2834 END IF;
jbe@240 2835 END IF;
jbe@242 2836 END LOOP;
jbe@240 2837 RETURN "result";
jbe@240 2838 END;
jbe@240 2839 $$;
jbe@240 2840
jbe@243 2841 COMMENT ON FUNCTION "delegation_info"
jbe@243 2842 ( "member"."id"%TYPE,
jbe@243 2843 "unit"."id"%TYPE,
jbe@243 2844 "area"."id"%TYPE,
jbe@243 2845 "issue"."id"%TYPE,
jbe@255 2846 "member"."id"%TYPE,
jbe@255 2847 BOOLEAN )
jbe@243 2848 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
jbe@243 2849
jbe@240 2850
jbe@240 2851
jbe@0 2852 ------------------------------------------------
jbe@0 2853 -- Locking for snapshots and voting procedure --
jbe@0 2854 ------------------------------------------------
jbe@0 2855
jbe@67 2856
jbe@67 2857 CREATE FUNCTION "share_row_lock_issue_trigger"()
jbe@67 2858 RETURNS TRIGGER
jbe@67 2859 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@67 2860 BEGIN
jbe@67 2861 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
jbe@67 2862 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@67 2863 END IF;
jbe@67 2864 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@67 2865 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@67 2866 RETURN NEW;
jbe@67 2867 ELSE
jbe@67 2868 RETURN OLD;
jbe@67 2869 END IF;
jbe@67 2870 END;
jbe@67 2871 $$;
jbe@67 2872
jbe@67 2873 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables';
jbe@67 2874
jbe@67 2875
jbe@67 2876 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"()
jbe@67 2877 RETURNS TRIGGER
jbe@0 2878 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 2879 BEGIN
jbe@67 2880 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN
jbe@67 2881 PERFORM NULL FROM "issue"
jbe@67 2882 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@67 2883 WHERE "initiative"."id" = OLD."initiative_id"
jbe@67 2884 FOR SHARE OF "issue";
jbe@67 2885 END IF;
jbe@67 2886 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@67 2887 PERFORM NULL FROM "issue"
jbe@67 2888 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@67 2889 WHERE "initiative"."id" = NEW."initiative_id"
jbe@67 2890 FOR SHARE OF "issue";
jbe@67 2891 RETURN NEW;
jbe@67 2892 ELSE
jbe@67 2893 RETURN OLD;
jbe@67 2894 END IF;
jbe@67 2895 END;
jbe@67 2896 $$;
jbe@67 2897
jbe@67 2898 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"';
jbe@67 2899
jbe@67 2900
jbe@67 2901 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2902 BEFORE INSERT OR UPDATE OR DELETE ON "initiative"
jbe@67 2903 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2904 "share_row_lock_issue_trigger"();
jbe@67 2905
jbe@67 2906 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2907 BEFORE INSERT OR UPDATE OR DELETE ON "interest"
jbe@67 2908 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2909 "share_row_lock_issue_trigger"();
jbe@67 2910
jbe@67 2911 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2912 BEFORE INSERT OR UPDATE OR DELETE ON "supporter"
jbe@67 2913 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2914 "share_row_lock_issue_trigger"();
jbe@67 2915
jbe@67 2916 CREATE TRIGGER "share_row_lock_issue_via_initiative"
jbe@67 2917 BEFORE INSERT OR UPDATE OR DELETE ON "opinion"
jbe@67 2918 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2919 "share_row_lock_issue_via_initiative_trigger"();
jbe@67 2920
jbe@67 2921 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2922 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter"
jbe@67 2923 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2924 "share_row_lock_issue_trigger"();
jbe@67 2925
jbe@67 2926 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2927 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter"
jbe@67 2928 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2929 "share_row_lock_issue_trigger"();
jbe@67 2930
jbe@67 2931 CREATE TRIGGER "share_row_lock_issue"
jbe@67 2932 BEFORE INSERT OR UPDATE OR DELETE ON "vote"
jbe@67 2933 FOR EACH ROW EXECUTE PROCEDURE
jbe@67 2934 "share_row_lock_issue_trigger"();
jbe@67 2935
jbe@67 2936 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function';
jbe@67 2937 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function';
jbe@67 2938 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function';
jbe@67 2939 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function';
jbe@67 2940 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function';
jbe@67 2941 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function';
jbe@67 2942 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function';
jbe@67 2943
jbe@67 2944
jbe@67 2945 CREATE FUNCTION "lock_issue"
jbe@67 2946 ( "issue_id_p" "issue"."id"%TYPE )
jbe@67 2947 RETURNS VOID
jbe@67 2948 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@67 2949 BEGIN
jbe@296 2950 -- The following locking order is used:
jbe@296 2951 -- 1st) row-level lock on the issue
jbe@296 2952 -- 2nd) table-level locks in order of occurrence in the core.sql file
jbe@67 2953 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@67 2954 -- NOTE: The row-level exclusive lock in combination with the
jbe@67 2955 -- share_row_lock_issue(_via_initiative)_trigger functions (which
jbe@67 2956 -- acquire a row-level share lock on the issue) ensure that no data
jbe@67 2957 -- is changed, which could affect calculation of snapshots or
jbe@67 2958 -- counting of votes. Table "delegation" must be table-level-locked,
jbe@67 2959 -- as it also contains issue- and global-scope delegations.
jbe@300 2960 PERFORM NULL FROM "member" WHERE "active" FOR SHARE;
jbe@298 2961 -- NOTE: As we later cause implicit row-level share locks on many
jbe@300 2962 -- active members, we lock them before locking any other table
jbe@300 2963 -- to avoid deadlocks
jbe@300 2964 LOCK TABLE "member" IN SHARE MODE;
jbe@296 2965 LOCK TABLE "privilege" IN SHARE MODE;
jbe@296 2966 LOCK TABLE "membership" IN SHARE MODE;
jbe@296 2967 LOCK TABLE "policy" IN SHARE MODE;
jbe@67 2968 LOCK TABLE "delegation" IN SHARE MODE;
jbe@0 2969 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 2970 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
jbe@0 2971 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 2972 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE;
jbe@0 2973 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE;
jbe@0 2974 RETURN;
jbe@0 2975 END;
jbe@0 2976 $$;
jbe@0 2977
jbe@67 2978 COMMENT ON FUNCTION "lock_issue"
jbe@67 2979 ( "issue"."id"%TYPE )
jbe@67 2980 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.';
jbe@0 2981
jbe@0 2982
jbe@0 2983
jbe@103 2984 ------------------------------------------------------------------------
jbe@103 2985 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 2986 ------------------------------------------------------------------------
jbe@103 2987
jbe@184 2988 CREATE FUNCTION "check_activity"()
jbe@103 2989 RETURNS VOID
jbe@103 2990 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 2991 DECLARE
jbe@104 2992 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 2993 BEGIN
jbe@104 2994 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@103 2995 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
jbe@104 2996 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 2997 UPDATE "member" SET "active" = FALSE
jbe@104 2998 WHERE "active" = TRUE
jbe@184 2999 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
jbe@104 3000 END IF;
jbe@103 3001 RETURN;
jbe@103 3002 END;
jbe@103 3003 $$;
jbe@103 3004
jbe@184 3005 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
jbe@103 3006
jbe@4 3007
jbe@4 3008 CREATE FUNCTION "calculate_member_counts"()
jbe@4 3009 RETURNS VOID
jbe@4 3010 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 3011 BEGIN
jbe@67 3012 LOCK TABLE "member" IN SHARE MODE;
jbe@67 3013 LOCK TABLE "member_count" IN EXCLUSIVE MODE;
jbe@97 3014 LOCK TABLE "unit" IN EXCLUSIVE MODE;
jbe@67 3015 LOCK TABLE "area" IN EXCLUSIVE MODE;
jbe@97 3016 LOCK TABLE "privilege" IN SHARE MODE;
jbe@67 3017 LOCK TABLE "membership" IN SHARE MODE;
jbe@4 3018 DELETE FROM "member_count";
jbe@5 3019 INSERT INTO "member_count" ("total_count")
jbe@5 3020 SELECT "total_count" FROM "member_count_view";
jbe@97 3021 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 3022 FROM "unit_member_count" AS "view"
jbe@97 3023 WHERE "view"."unit_id" = "unit"."id";
jbe@5 3024 UPDATE "area" SET
jbe@5 3025 "direct_member_count" = "view"."direct_member_count",
jbe@169 3026 "member_weight" = "view"."member_weight"
jbe@5 3027 FROM "area_member_count" AS "view"
jbe@5 3028 WHERE "view"."area_id" = "area"."id";
jbe@4 3029 RETURN;
jbe@4 3030 END;
jbe@4 3031 $$;
jbe@4 3032
jbe@4 3033 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 3034
jbe@4 3035
jbe@4 3036
jbe@327 3037 ------------------------------------
jbe@327 3038 -- Calculation of harmonic weight --
jbe@327 3039 ------------------------------------
jbe@310 3040
jbe@312 3041
jbe@310 3042 CREATE VIEW "remaining_harmonic_supporter_weight" AS
jbe@310 3043 SELECT
jbe@310 3044 "direct_interest_snapshot"."issue_id",
jbe@310 3045 "direct_interest_snapshot"."event",
jbe@310 3046 "direct_interest_snapshot"."member_id",
jbe@310 3047 "direct_interest_snapshot"."weight" AS "weight_num",
jbe@310 3048 count("initiative"."id") AS "weight_den"
jbe@312 3049 FROM "issue"
jbe@312 3050 JOIN "direct_interest_snapshot"
jbe@312 3051 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
jbe@312 3052 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
jbe@327 3053 JOIN "initiative"
jbe@327 3054 ON "issue"."id" = "initiative"."issue_id"
jbe@327 3055 AND "initiative"."harmonic_weight" ISNULL
jbe@310 3056 JOIN "direct_supporter_snapshot"
jbe@327 3057 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 3058 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
jbe@310 3059 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 3060 AND (
jbe@321 3061 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 3062 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 3063 )
jbe@310 3064 GROUP BY
jbe@310 3065 "direct_interest_snapshot"."issue_id",
jbe@310 3066 "direct_interest_snapshot"."event",
jbe@310 3067 "direct_interest_snapshot"."member_id",
jbe@310 3068 "direct_interest_snapshot"."weight";
jbe@310 3069
jbe@310 3070 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 3071
jbe@310 3072
jbe@310 3073 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
jbe@310 3074 SELECT
jbe@310 3075 "initiative"."issue_id",
jbe@310 3076 "initiative"."id" AS "initiative_id",
jbe@320 3077 "initiative"."admitted",
jbe@310 3078 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
jbe@310 3079 "remaining_harmonic_supporter_weight"."weight_den"
jbe@310 3080 FROM "remaining_harmonic_supporter_weight"
jbe@327 3081 JOIN "initiative"
jbe@327 3082 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
jbe@327 3083 AND "initiative"."harmonic_weight" ISNULL
jbe@310 3084 JOIN "direct_supporter_snapshot"
jbe@327 3085 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 3086 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
jbe@310 3087 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 3088 AND (
jbe@321 3089 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 3090 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 3091 )
jbe@310 3092 GROUP BY
jbe@310 3093 "initiative"."issue_id",
jbe@310 3094 "initiative"."id",
jbe@320 3095 "initiative"."admitted",
jbe@310 3096 "remaining_harmonic_supporter_weight"."weight_den";
jbe@310 3097
jbe@310 3098 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 3099
jbe@310 3100
jbe@310 3101 CREATE FUNCTION "set_harmonic_initiative_weights"
jbe@310 3102 ( "issue_id_p" "issue"."id"%TYPE )
jbe@310 3103 RETURNS VOID
jbe@310 3104 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@310 3105 DECLARE
jbe@310 3106 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
jbe@310 3107 "i" INT4;
jbe@310 3108 "count_v" INT4;
jbe@310 3109 "summand_v" FLOAT;
jbe@310 3110 "id_ary" INT4[];
jbe@310 3111 "weight_ary" FLOAT[];
jbe@310 3112 "min_weight_v" FLOAT;
jbe@310 3113 BEGIN
jbe@312 3114 UPDATE "initiative" SET "harmonic_weight" = NULL
jbe@312 3115 WHERE "issue_id" = "issue_id_p";
jbe@310 3116 LOOP
jbe@310 3117 "min_weight_v" := NULL;
jbe@310 3118 "i" := 0;
jbe@310 3119 "count_v" := 0;
jbe@310 3120 FOR "weight_row" IN
jbe@310 3121 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
jbe@310 3122 WHERE "issue_id" = "issue_id_p"
jbe@320 3123 AND (
jbe@320 3124 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@320 3125 SELECT NULL FROM "initiative"
jbe@320 3126 WHERE "issue_id" = "issue_id_p"
jbe@320 3127 AND "harmonic_weight" ISNULL
jbe@320 3128 AND coalesce("admitted", FALSE) = FALSE
jbe@320 3129 )
jbe@320 3130 )
jbe@310 3131 ORDER BY "initiative_id" DESC, "weight_den" DESC
jbe@320 3132 -- NOTE: non-admitted initiatives placed first (at last positions),
jbe@320 3133 -- latest initiatives treated worse in case of tie
jbe@310 3134 LOOP
jbe@310 3135 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
jbe@310 3136 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
jbe@310 3137 "i" := "i" + 1;
jbe@310 3138 "count_v" := "i";
jbe@310 3139 "id_ary"["i"] := "weight_row"."initiative_id";
jbe@310 3140 "weight_ary"["i"] := "summand_v";
jbe@310 3141 ELSE
jbe@310 3142 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
jbe@310 3143 END IF;
jbe@310 3144 END LOOP;
jbe@310 3145 EXIT WHEN "count_v" = 0;
jbe@310 3146 "i" := 1;
jbe@310 3147 LOOP
jbe@313 3148 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
jbe@310 3149 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
jbe@310 3150 "min_weight_v" := "weight_ary"["i"];
jbe@310 3151 END IF;
jbe@310 3152 "i" := "i" + 1;
jbe@310 3153 EXIT WHEN "i" > "count_v";
jbe@310 3154 END LOOP;
jbe@310 3155 "i" := 1;
jbe@310 3156 LOOP
jbe@310 3157 IF "weight_ary"["i"] = "min_weight_v" THEN
jbe@310 3158 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
jbe@310 3159 WHERE "id" = "id_ary"["i"];
jbe@310 3160 EXIT;
jbe@310 3161 END IF;
jbe@310 3162 "i" := "i" + 1;
jbe@310 3163 END LOOP;
jbe@310 3164 END LOOP;
jbe@316 3165 UPDATE "initiative" SET "harmonic_weight" = 0
jbe@316 3166 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
jbe@310 3167 END;
jbe@310 3168 $$;
jbe@310 3169
jbe@310 3170 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
jbe@310 3171 ( "issue"."id"%TYPE )
jbe@310 3172 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
jbe@310 3173
jbe@310 3174
jbe@312 3175
jbe@0 3176 ------------------------------
jbe@0 3177 -- Calculation of snapshots --
jbe@0 3178 ------------------------------
jbe@0 3179
jbe@312 3180
jbe@0 3181 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3182 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3183 "member_id_p" "member"."id"%TYPE,
jbe@0 3184 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3185 RETURNS "direct_population_snapshot"."weight"%TYPE
jbe@0 3186 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3187 DECLARE
jbe@0 3188 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3189 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3190 "weight_v" INT4;
jbe@8 3191 "sub_weight_v" INT4;
jbe@0 3192 BEGIN
jbe@0 3193 "weight_v" := 0;
jbe@0 3194 FOR "issue_delegation_row" IN
jbe@0 3195 SELECT * FROM "issue_delegation"
jbe@0 3196 WHERE "trustee_id" = "member_id_p"
jbe@0 3197 AND "issue_id" = "issue_id_p"
jbe@0 3198 LOOP
jbe@0 3199 IF NOT EXISTS (
jbe@0 3200 SELECT NULL FROM "direct_population_snapshot"
jbe@0 3201 WHERE "issue_id" = "issue_id_p"
jbe@0 3202 AND "event" = 'periodic'
jbe@0 3203 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3204 ) AND NOT EXISTS (
jbe@0 3205 SELECT NULL FROM "delegating_population_snapshot"
jbe@0 3206 WHERE "issue_id" = "issue_id_p"
jbe@0 3207 AND "event" = 'periodic'
jbe@0 3208 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3209 ) THEN
jbe@0 3210 "delegate_member_ids_v" :=
jbe@0 3211 "member_id_p" || "delegate_member_ids_p";
jbe@10 3212 INSERT INTO "delegating_population_snapshot" (
jbe@10 3213 "issue_id",
jbe@10 3214 "event",
jbe@10 3215 "member_id",
jbe@10 3216 "scope",
jbe@10 3217 "delegate_member_ids"
jbe@10 3218 ) VALUES (
jbe@0 3219 "issue_id_p",
jbe@0 3220 'periodic',
jbe@0 3221 "issue_delegation_row"."truster_id",
jbe@10 3222 "issue_delegation_row"."scope",
jbe@0 3223 "delegate_member_ids_v"
jbe@0 3224 );
jbe@8 3225 "sub_weight_v" := 1 +
jbe@0 3226 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3227 "issue_id_p",
jbe@0 3228 "issue_delegation_row"."truster_id",
jbe@0 3229 "delegate_member_ids_v"
jbe@0 3230 );
jbe@8 3231 UPDATE "delegating_population_snapshot"
jbe@8 3232 SET "weight" = "sub_weight_v"
jbe@8 3233 WHERE "issue_id" = "issue_id_p"
jbe@8 3234 AND "event" = 'periodic'
jbe@8 3235 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3236 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3237 END IF;
jbe@0 3238 END LOOP;
jbe@0 3239 RETURN "weight_v";
jbe@0 3240 END;
jbe@0 3241 $$;
jbe@0 3242
jbe@0 3243 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3244 ( "issue"."id"%TYPE,
jbe@0 3245 "member"."id"%TYPE,
jbe@0 3246 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3247 IS 'Helper function for "create_population_snapshot" function';
jbe@0 3248
jbe@0 3249
jbe@0 3250 CREATE FUNCTION "create_population_snapshot"
jbe@0 3251 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3252 RETURNS VOID
jbe@0 3253 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3254 DECLARE
jbe@0 3255 "member_id_v" "member"."id"%TYPE;
jbe@0 3256 BEGIN
jbe@0 3257 DELETE FROM "direct_population_snapshot"
jbe@0 3258 WHERE "issue_id" = "issue_id_p"
jbe@0 3259 AND "event" = 'periodic';
jbe@0 3260 DELETE FROM "delegating_population_snapshot"
jbe@0 3261 WHERE "issue_id" = "issue_id_p"
jbe@0 3262 AND "event" = 'periodic';
jbe@0 3263 INSERT INTO "direct_population_snapshot"
jbe@54 3264 ("issue_id", "event", "member_id")
jbe@54 3265 SELECT
jbe@54 3266 "issue_id_p" AS "issue_id",
jbe@54 3267 'periodic'::"snapshot_event" AS "event",
jbe@54 3268 "member"."id" AS "member_id"
jbe@54 3269 FROM "issue"
jbe@54 3270 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@54 3271 JOIN "membership" ON "area"."id" = "membership"."area_id"
jbe@54 3272 JOIN "member" ON "membership"."member_id" = "member"."id"
jbe@97 3273 JOIN "privilege"
jbe@97 3274 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3275 AND "privilege"."member_id" = "member"."id"
jbe@54 3276 WHERE "issue"."id" = "issue_id_p"
jbe@97 3277 AND "member"."active" AND "privilege"."voting_right"
jbe@54 3278 UNION
jbe@54 3279 SELECT
jbe@54 3280 "issue_id_p" AS "issue_id",
jbe@54 3281 'periodic'::"snapshot_event" AS "event",
jbe@54 3282 "member"."id" AS "member_id"
jbe@97 3283 FROM "issue"
jbe@97 3284 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3285 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3286 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3287 JOIN "privilege"
jbe@97 3288 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3289 AND "privilege"."member_id" = "member"."id"
jbe@97 3290 WHERE "issue"."id" = "issue_id_p"
jbe@97 3291 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3292 FOR "member_id_v" IN
jbe@0 3293 SELECT "member_id" FROM "direct_population_snapshot"
jbe@0 3294 WHERE "issue_id" = "issue_id_p"
jbe@0 3295 AND "event" = 'periodic'
jbe@0 3296 LOOP
jbe@0 3297 UPDATE "direct_population_snapshot" SET
jbe@0 3298 "weight" = 1 +
jbe@0 3299 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3300 "issue_id_p",
jbe@0 3301 "member_id_v",
jbe@0 3302 '{}'
jbe@0 3303 )
jbe@0 3304 WHERE "issue_id" = "issue_id_p"
jbe@0 3305 AND "event" = 'periodic'
jbe@0 3306 AND "member_id" = "member_id_v";
jbe@0 3307 END LOOP;
jbe@0 3308 RETURN;
jbe@0 3309 END;
jbe@0 3310 $$;
jbe@0 3311
jbe@0 3312 COMMENT ON FUNCTION "create_population_snapshot"
jbe@67 3313 ( "issue"."id"%TYPE )
jbe@0 3314 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 3315
jbe@0 3316
jbe@0 3317 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3318 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3319 "member_id_p" "member"."id"%TYPE,
jbe@0 3320 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3321 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 3322 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3323 DECLARE
jbe@0 3324 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3325 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3326 "weight_v" INT4;
jbe@8 3327 "sub_weight_v" INT4;
jbe@0 3328 BEGIN
jbe@0 3329 "weight_v" := 0;
jbe@0 3330 FOR "issue_delegation_row" IN
jbe@0 3331 SELECT * FROM "issue_delegation"
jbe@0 3332 WHERE "trustee_id" = "member_id_p"
jbe@0 3333 AND "issue_id" = "issue_id_p"
jbe@0 3334 LOOP
jbe@0 3335 IF NOT EXISTS (
jbe@0 3336 SELECT NULL FROM "direct_interest_snapshot"
jbe@0 3337 WHERE "issue_id" = "issue_id_p"
jbe@0 3338 AND "event" = 'periodic'
jbe@0 3339 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3340 ) AND NOT EXISTS (
jbe@0 3341 SELECT NULL FROM "delegating_interest_snapshot"
jbe@0 3342 WHERE "issue_id" = "issue_id_p"
jbe@0 3343 AND "event" = 'periodic'
jbe@0 3344 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3345 ) THEN
jbe@0 3346 "delegate_member_ids_v" :=
jbe@0 3347 "member_id_p" || "delegate_member_ids_p";
jbe@10 3348 INSERT INTO "delegating_interest_snapshot" (
jbe@10 3349 "issue_id",
jbe@10 3350 "event",
jbe@10 3351 "member_id",
jbe@10 3352 "scope",
jbe@10 3353 "delegate_member_ids"
jbe@10 3354 ) VALUES (
jbe@0 3355 "issue_id_p",
jbe@0 3356 'periodic',
jbe@0 3357 "issue_delegation_row"."truster_id",
jbe@10 3358 "issue_delegation_row"."scope",
jbe@0 3359 "delegate_member_ids_v"
jbe@0 3360 );
jbe@8 3361 "sub_weight_v" := 1 +
jbe@0 3362 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3363 "issue_id_p",
jbe@0 3364 "issue_delegation_row"."truster_id",
jbe@0 3365 "delegate_member_ids_v"
jbe@0 3366 );
jbe@8 3367 UPDATE "delegating_interest_snapshot"
jbe@8 3368 SET "weight" = "sub_weight_v"
jbe@8 3369 WHERE "issue_id" = "issue_id_p"
jbe@8 3370 AND "event" = 'periodic'
jbe@8 3371 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3372 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3373 END IF;
jbe@0 3374 END LOOP;
jbe@0 3375 RETURN "weight_v";
jbe@0 3376 END;
jbe@0 3377 $$;
jbe@0 3378
jbe@0 3379 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3380 ( "issue"."id"%TYPE,
jbe@0 3381 "member"."id"%TYPE,
jbe@0 3382 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3383 IS 'Helper function for "create_interest_snapshot" function';
jbe@0 3384
jbe@0 3385
jbe@0 3386 CREATE FUNCTION "create_interest_snapshot"
jbe@0 3387 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3388 RETURNS VOID
jbe@0 3389 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3390 DECLARE
jbe@0 3391 "member_id_v" "member"."id"%TYPE;
jbe@0 3392 BEGIN
jbe@0 3393 DELETE FROM "direct_interest_snapshot"
jbe@0 3394 WHERE "issue_id" = "issue_id_p"
jbe@0 3395 AND "event" = 'periodic';
jbe@0 3396 DELETE FROM "delegating_interest_snapshot"
jbe@0 3397 WHERE "issue_id" = "issue_id_p"
jbe@0 3398 AND "event" = 'periodic';
jbe@0 3399 DELETE FROM "direct_supporter_snapshot"
jbe@325 3400 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 3401 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 3402 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 3403 AND "direct_supporter_snapshot"."event" = 'periodic';
jbe@0 3404 INSERT INTO "direct_interest_snapshot"
jbe@144 3405 ("issue_id", "event", "member_id")
jbe@0 3406 SELECT
jbe@0 3407 "issue_id_p" AS "issue_id",
jbe@0 3408 'periodic' AS "event",
jbe@144 3409 "member"."id" AS "member_id"
jbe@97 3410 FROM "issue"
jbe@97 3411 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3412 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3413 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3414 JOIN "privilege"
jbe@97 3415 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3416 AND "privilege"."member_id" = "member"."id"
jbe@97 3417 WHERE "issue"."id" = "issue_id_p"
jbe@97 3418 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3419 FOR "member_id_v" IN
jbe@0 3420 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@0 3421 WHERE "issue_id" = "issue_id_p"
jbe@0 3422 AND "event" = 'periodic'
jbe@0 3423 LOOP
jbe@0 3424 UPDATE "direct_interest_snapshot" SET
jbe@0 3425 "weight" = 1 +
jbe@0 3426 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3427 "issue_id_p",
jbe@0 3428 "member_id_v",
jbe@0 3429 '{}'
jbe@0 3430 )
jbe@0 3431 WHERE "issue_id" = "issue_id_p"
jbe@0 3432 AND "event" = 'periodic'
jbe@0 3433 AND "member_id" = "member_id_v";
jbe@0 3434 END LOOP;
jbe@0 3435 INSERT INTO "direct_supporter_snapshot"
jbe@0 3436 ( "issue_id", "initiative_id", "event", "member_id",
jbe@204 3437 "draft_id", "informed", "satisfied" )
jbe@0 3438 SELECT
jbe@96 3439 "issue_id_p" AS "issue_id",
jbe@96 3440 "initiative"."id" AS "initiative_id",
jbe@96 3441 'periodic' AS "event",
jbe@96 3442 "supporter"."member_id" AS "member_id",
jbe@204 3443 "supporter"."draft_id" AS "draft_id",
jbe@0 3444 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@0 3445 NOT EXISTS (
jbe@0 3446 SELECT NULL FROM "critical_opinion"
jbe@0 3447 WHERE "initiative_id" = "initiative"."id"
jbe@96 3448 AND "member_id" = "supporter"."member_id"
jbe@0 3449 ) AS "satisfied"
jbe@96 3450 FROM "initiative"
jbe@96 3451 JOIN "supporter"
jbe@0 3452 ON "supporter"."initiative_id" = "initiative"."id"
jbe@0 3453 JOIN "current_draft"
jbe@0 3454 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@0 3455 JOIN "direct_interest_snapshot"
jbe@96 3456 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@0 3457 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@3 3458 AND "event" = 'periodic'
jbe@96 3459 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@0 3460 RETURN;
jbe@0 3461 END;
jbe@0 3462 $$;
jbe@0 3463
jbe@0 3464 COMMENT ON FUNCTION "create_interest_snapshot"
jbe@0 3465 ( "issue"."id"%TYPE )
jbe@0 3466 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 3467
jbe@0 3468
jbe@0 3469 CREATE FUNCTION "create_snapshot"
jbe@0 3470 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3471 RETURNS VOID
jbe@0 3472 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3473 DECLARE
jbe@0 3474 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3475 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@0 3476 BEGIN
jbe@67 3477 PERFORM "lock_issue"("issue_id_p");
jbe@0 3478 PERFORM "create_population_snapshot"("issue_id_p");
jbe@0 3479 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@0 3480 UPDATE "issue" SET
jbe@8 3481 "snapshot" = now(),
jbe@8 3482 "latest_snapshot_event" = 'periodic',
jbe@0 3483 "population" = (
jbe@0 3484 SELECT coalesce(sum("weight"), 0)
jbe@0 3485 FROM "direct_population_snapshot"
jbe@0 3486 WHERE "issue_id" = "issue_id_p"
jbe@0 3487 AND "event" = 'periodic'
jbe@0 3488 )
jbe@0 3489 WHERE "id" = "issue_id_p";
jbe@0 3490 FOR "initiative_id_v" IN
jbe@0 3491 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@0 3492 LOOP
jbe@0 3493 UPDATE "initiative" SET
jbe@0 3494 "supporter_count" = (
jbe@0 3495 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3496 FROM "direct_interest_snapshot" AS "di"
jbe@0 3497 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3498 ON "di"."member_id" = "ds"."member_id"
jbe@0 3499 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3500 AND "di"."event" = 'periodic'
jbe@0 3501 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3502 AND "ds"."event" = 'periodic'
jbe@0 3503 ),
jbe@0 3504 "informed_supporter_count" = (
jbe@0 3505 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3506 FROM "direct_interest_snapshot" AS "di"
jbe@0 3507 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3508 ON "di"."member_id" = "ds"."member_id"
jbe@0 3509 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3510 AND "di"."event" = 'periodic'
jbe@0 3511 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3512 AND "ds"."event" = 'periodic'
jbe@0 3513 AND "ds"."informed"
jbe@0 3514 ),
jbe@0 3515 "satisfied_supporter_count" = (
jbe@0 3516 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3517 FROM "direct_interest_snapshot" AS "di"
jbe@0 3518 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3519 ON "di"."member_id" = "ds"."member_id"
jbe@0 3520 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3521 AND "di"."event" = 'periodic'
jbe@0 3522 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3523 AND "ds"."event" = 'periodic'
jbe@0 3524 AND "ds"."satisfied"
jbe@0 3525 ),
jbe@0 3526 "satisfied_informed_supporter_count" = (
jbe@0 3527 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3528 FROM "direct_interest_snapshot" AS "di"
jbe@0 3529 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3530 ON "di"."member_id" = "ds"."member_id"
jbe@0 3531 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3532 AND "di"."event" = 'periodic'
jbe@0 3533 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3534 AND "ds"."event" = 'periodic'
jbe@0 3535 AND "ds"."informed"
jbe@0 3536 AND "ds"."satisfied"
jbe@0 3537 )
jbe@0 3538 WHERE "id" = "initiative_id_v";
jbe@0 3539 FOR "suggestion_id_v" IN
jbe@0 3540 SELECT "id" FROM "suggestion"
jbe@0 3541 WHERE "initiative_id" = "initiative_id_v"
jbe@0 3542 LOOP
jbe@0 3543 UPDATE "suggestion" SET
jbe@0 3544 "minus2_unfulfilled_count" = (
jbe@0 3545 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3546 FROM "issue" CROSS JOIN "opinion"
jbe@36 3547 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3548 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3549 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3550 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3551 WHERE "issue"."id" = "issue_id_p"
jbe@36 3552 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3553 AND "opinion"."degree" = -2
jbe@0 3554 AND "opinion"."fulfilled" = FALSE
jbe@0 3555 ),
jbe@0 3556 "minus2_fulfilled_count" = (
jbe@0 3557 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3558 FROM "issue" CROSS JOIN "opinion"
jbe@36 3559 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3560 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3561 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3562 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3563 WHERE "issue"."id" = "issue_id_p"
jbe@36 3564 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3565 AND "opinion"."degree" = -2
jbe@0 3566 AND "opinion"."fulfilled" = TRUE
jbe@0 3567 ),
jbe@0 3568 "minus1_unfulfilled_count" = (
jbe@0 3569 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3570 FROM "issue" CROSS JOIN "opinion"
jbe@36 3571 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3572 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3573 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3574 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3575 WHERE "issue"."id" = "issue_id_p"
jbe@36 3576 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3577 AND "opinion"."degree" = -1
jbe@0 3578 AND "opinion"."fulfilled" = FALSE
jbe@0 3579 ),
jbe@0 3580 "minus1_fulfilled_count" = (
jbe@0 3581 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3582 FROM "issue" CROSS JOIN "opinion"
jbe@36 3583 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3584 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3585 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3586 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3587 WHERE "issue"."id" = "issue_id_p"
jbe@36 3588 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3589 AND "opinion"."degree" = -1
jbe@0 3590 AND "opinion"."fulfilled" = TRUE
jbe@0 3591 ),
jbe@0 3592 "plus1_unfulfilled_count" = (
jbe@0 3593 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3594 FROM "issue" CROSS JOIN "opinion"
jbe@36 3595 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3596 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3597 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3598 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3599 WHERE "issue"."id" = "issue_id_p"
jbe@36 3600 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3601 AND "opinion"."degree" = 1
jbe@0 3602 AND "opinion"."fulfilled" = FALSE
jbe@0 3603 ),
jbe@0 3604 "plus1_fulfilled_count" = (
jbe@0 3605 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3606 FROM "issue" CROSS JOIN "opinion"
jbe@36 3607 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3608 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3609 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3610 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3611 WHERE "issue"."id" = "issue_id_p"
jbe@36 3612 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3613 AND "opinion"."degree" = 1
jbe@0 3614 AND "opinion"."fulfilled" = TRUE
jbe@0 3615 ),
jbe@0 3616 "plus2_unfulfilled_count" = (
jbe@0 3617 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3618 FROM "issue" CROSS JOIN "opinion"
jbe@36 3619 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3620 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3621 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3622 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3623 WHERE "issue"."id" = "issue_id_p"
jbe@36 3624 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3625 AND "opinion"."degree" = 2
jbe@0 3626 AND "opinion"."fulfilled" = FALSE
jbe@0 3627 ),
jbe@0 3628 "plus2_fulfilled_count" = (
jbe@0 3629 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3630 FROM "issue" CROSS JOIN "opinion"
jbe@36 3631 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3632 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3633 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3634 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3635 WHERE "issue"."id" = "issue_id_p"
jbe@36 3636 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3637 AND "opinion"."degree" = 2
jbe@0 3638 AND "opinion"."fulfilled" = TRUE
jbe@0 3639 )
jbe@0 3640 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@0 3641 END LOOP;
jbe@0 3642 END LOOP;
jbe@0 3643 RETURN;
jbe@0 3644 END;
jbe@0 3645 $$;
jbe@0 3646
jbe@0 3647 COMMENT ON FUNCTION "create_snapshot"
jbe@0 3648 ( "issue"."id"%TYPE )
jbe@0 3649 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 3650
jbe@0 3651
jbe@0 3652 CREATE FUNCTION "set_snapshot_event"
jbe@0 3653 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3654 "event_p" "snapshot_event" )
jbe@0 3655 RETURNS VOID
jbe@0 3656 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@21 3657 DECLARE
jbe@21 3658 "event_v" "issue"."latest_snapshot_event"%TYPE;
jbe@0 3659 BEGIN
jbe@21 3660 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
jbe@21 3661 WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@8 3662 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
jbe@8 3663 WHERE "id" = "issue_id_p";
jbe@3 3664 UPDATE "direct_population_snapshot" SET "event" = "event_p"
jbe@21 3665 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3666 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
jbe@21 3667 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3668 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
jbe@21 3669 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3670 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
jbe@21 3671 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3672 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
jbe@325 3673 FROM "initiative" -- NOTE: due to missing index on issue_id
jbe@325 3674 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 3675 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 3676 AND "direct_supporter_snapshot"."event" = "event_v";
jbe@0 3677 RETURN;
jbe@0 3678 END;
jbe@0 3679 $$;
jbe@0 3680
jbe@0 3681 COMMENT ON FUNCTION "set_snapshot_event"
jbe@0 3682 ( "issue"."id"%TYPE,
jbe@0 3683 "snapshot_event" )
jbe@0 3684 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
jbe@0 3685
jbe@0 3686
jbe@0 3687
jbe@0 3688 ---------------------
jbe@0 3689 -- Freezing issues --
jbe@0 3690 ---------------------
jbe@0 3691
jbe@0 3692 CREATE FUNCTION "freeze_after_snapshot"
jbe@0 3693 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3694 RETURNS VOID
jbe@0 3695 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3696 DECLARE
jbe@0 3697 "issue_row" "issue"%ROWTYPE;
jbe@0 3698 "policy_row" "policy"%ROWTYPE;
jbe@0 3699 "initiative_row" "initiative"%ROWTYPE;
jbe@0 3700 BEGIN
jbe@0 3701 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@0 3702 SELECT * INTO "policy_row"
jbe@0 3703 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@21 3704 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@0 3705 FOR "initiative_row" IN
jbe@15 3706 SELECT * FROM "initiative"
jbe@15 3707 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@0 3708 LOOP
jbe@0 3709 IF
jbe@261 3710 "initiative_row"."polling" OR (
jbe@261 3711 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@261 3712 "initiative_row"."satisfied_supporter_count" *
jbe@261 3713 "policy_row"."initiative_quorum_den" >=
jbe@261 3714 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@261 3715 )
jbe@0 3716 THEN
jbe@0 3717 UPDATE "initiative" SET "admitted" = TRUE
jbe@0 3718 WHERE "id" = "initiative_row"."id";
jbe@0 3719 ELSE
jbe@0 3720 UPDATE "initiative" SET "admitted" = FALSE
jbe@0 3721 WHERE "id" = "initiative_row"."id";
jbe@0 3722 END IF;
jbe@0 3723 END LOOP;
jbe@113 3724 IF EXISTS (
jbe@9 3725 SELECT NULL FROM "initiative"
jbe@9 3726 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@9 3727 ) THEN
jbe@113 3728 UPDATE "issue" SET
jbe@113 3729 "state" = 'voting',
jbe@113 3730 "accepted" = coalesce("accepted", now()),
jbe@113 3731 "half_frozen" = coalesce("half_frozen", now()),
jbe@113 3732 "fully_frozen" = now()
jbe@113 3733 WHERE "id" = "issue_id_p";
jbe@113 3734 ELSE
jbe@113 3735 UPDATE "issue" SET
jbe@121 3736 "state" = 'canceled_no_initiative_admitted',
jbe@121 3737 "accepted" = coalesce("accepted", now()),
jbe@121 3738 "half_frozen" = coalesce("half_frozen", now()),
jbe@121 3739 "fully_frozen" = now(),
jbe@121 3740 "closed" = now(),
jbe@121 3741 "ranks_available" = TRUE
jbe@113 3742 WHERE "id" = "issue_id_p";
jbe@113 3743 -- NOTE: The following DELETE statements have effect only when
jbe@113 3744 -- issue state has been manipulated
jbe@113 3745 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@113 3746 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@113 3747 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@9 3748 END IF;
jbe@0 3749 RETURN;
jbe@0 3750 END;
jbe@0 3751 $$;
jbe@0 3752
jbe@0 3753 COMMENT ON FUNCTION "freeze_after_snapshot"
jbe@0 3754 ( "issue"."id"%TYPE )
jbe@9 3755 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.';
jbe@0 3756
jbe@0 3757
jbe@0 3758 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3759 RETURNS VOID
jbe@0 3760 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3761 DECLARE
jbe@0 3762 "issue_row" "issue"%ROWTYPE;
jbe@0 3763 BEGIN
jbe@0 3764 PERFORM "create_snapshot"("issue_id_p");
jbe@0 3765 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@322 3766 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@0 3767 RETURN;
jbe@0 3768 END;
jbe@0 3769 $$;
jbe@0 3770
jbe@55 3771 COMMENT ON FUNCTION "manual_freeze"
jbe@0 3772 ( "issue"."id"%TYPE )
jbe@3 3773 IS 'Freeze an issue manually (fully) and start voting';
jbe@0 3774
jbe@0 3775
jbe@0 3776
jbe@0 3777 -----------------------
jbe@0 3778 -- Counting of votes --
jbe@0 3779 -----------------------
jbe@0 3780
jbe@0 3781
jbe@5 3782 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 3783 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3784 "member_id_p" "member"."id"%TYPE,
jbe@0 3785 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3786 RETURNS "direct_voter"."weight"%TYPE
jbe@0 3787 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3788 DECLARE
jbe@0 3789 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3790 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 3791 "weight_v" INT4;
jbe@8 3792 "sub_weight_v" INT4;
jbe@0 3793 BEGIN
jbe@0 3794 "weight_v" := 0;
jbe@0 3795 FOR "issue_delegation_row" IN
jbe@0 3796 SELECT * FROM "issue_delegation"
jbe@0 3797 WHERE "trustee_id" = "member_id_p"
jbe@0 3798 AND "issue_id" = "issue_id_p"
jbe@0 3799 LOOP
jbe@0 3800 IF NOT EXISTS (
jbe@0 3801 SELECT NULL FROM "direct_voter"
jbe@0 3802 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3803 AND "issue_id" = "issue_id_p"
jbe@0 3804 ) AND NOT EXISTS (
jbe@0 3805 SELECT NULL FROM "delegating_voter"
jbe@0 3806 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3807 AND "issue_id" = "issue_id_p"
jbe@0 3808 ) THEN
jbe@0 3809 "delegate_member_ids_v" :=
jbe@0 3810 "member_id_p" || "delegate_member_ids_p";
jbe@10 3811 INSERT INTO "delegating_voter" (
jbe@10 3812 "issue_id",
jbe@10 3813 "member_id",
jbe@10 3814 "scope",
jbe@10 3815 "delegate_member_ids"
jbe@10 3816 ) VALUES (
jbe@5 3817 "issue_id_p",
jbe@5 3818 "issue_delegation_row"."truster_id",
jbe@10 3819 "issue_delegation_row"."scope",
jbe@5 3820 "delegate_member_ids_v"
jbe@5 3821 );
jbe@8 3822 "sub_weight_v" := 1 +
jbe@8 3823 "weight_of_added_vote_delegations"(
jbe@8 3824 "issue_id_p",
jbe@8 3825 "issue_delegation_row"."truster_id",
jbe@8 3826 "delegate_member_ids_v"
jbe@8 3827 );
jbe@8 3828 UPDATE "delegating_voter"
jbe@8 3829 SET "weight" = "sub_weight_v"
jbe@8 3830 WHERE "issue_id" = "issue_id_p"
jbe@8 3831 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3832 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3833 END IF;
jbe@0 3834 END LOOP;
jbe@0 3835 RETURN "weight_v";
jbe@0 3836 END;
jbe@0 3837 $$;
jbe@0 3838
jbe@5 3839 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 3840 ( "issue"."id"%TYPE,
jbe@0 3841 "member"."id"%TYPE,
jbe@0 3842 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3843 IS 'Helper function for "add_vote_delegations" function';
jbe@0 3844
jbe@0 3845
jbe@0 3846 CREATE FUNCTION "add_vote_delegations"
jbe@0 3847 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3848 RETURNS VOID
jbe@0 3849 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3850 DECLARE
jbe@0 3851 "member_id_v" "member"."id"%TYPE;
jbe@0 3852 BEGIN
jbe@0 3853 FOR "member_id_v" IN
jbe@0 3854 SELECT "member_id" FROM "direct_voter"
jbe@0 3855 WHERE "issue_id" = "issue_id_p"
jbe@0 3856 LOOP
jbe@0 3857 UPDATE "direct_voter" SET
jbe@5 3858 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 3859 "issue_id_p",
jbe@0 3860 "member_id_v",
jbe@0 3861 '{}'
jbe@0 3862 )
jbe@0 3863 WHERE "member_id" = "member_id_v"
jbe@0 3864 AND "issue_id" = "issue_id_p";
jbe@0 3865 END LOOP;
jbe@0 3866 RETURN;
jbe@0 3867 END;
jbe@0 3868 $$;
jbe@0 3869
jbe@0 3870 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 3871 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3872 IS 'Helper function for "close_voting" function';
jbe@0 3873
jbe@0 3874
jbe@0 3875 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3876 RETURNS VOID
jbe@0 3877 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3878 DECLARE
jbe@97 3879 "area_id_v" "area"."id"%TYPE;
jbe@97 3880 "unit_id_v" "unit"."id"%TYPE;
jbe@0 3881 "member_id_v" "member"."id"%TYPE;
jbe@0 3882 BEGIN
jbe@67 3883 PERFORM "lock_issue"("issue_id_p");
jbe@129 3884 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 3885 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@285 3886 -- delete timestamp of voting comment:
jbe@285 3887 UPDATE "direct_voter" SET "comment_changed" = NULL
jbe@285 3888 WHERE "issue_id" = "issue_id_p";
jbe@169 3889 -- delete delegating votes (in cases of manual reset of issue state):
jbe@0 3890 DELETE FROM "delegating_voter"
jbe@0 3891 WHERE "issue_id" = "issue_id_p";
jbe@169 3892 -- delete votes from non-privileged voters:
jbe@97 3893 DELETE FROM "direct_voter"
jbe@97 3894 USING (
jbe@97 3895 SELECT
jbe@97 3896 "direct_voter"."member_id"
jbe@97 3897 FROM "direct_voter"
jbe@97 3898 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@97 3899 LEFT JOIN "privilege"
jbe@97 3900 ON "privilege"."unit_id" = "unit_id_v"
jbe@97 3901 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 3902 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 3903 "member"."active" = FALSE OR
jbe@97 3904 "privilege"."voting_right" ISNULL OR
jbe@97 3905 "privilege"."voting_right" = FALSE
jbe@97 3906 )
jbe@97 3907 ) AS "subquery"
jbe@97 3908 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 3909 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@169 3910 -- consider delegations:
jbe@0 3911 UPDATE "direct_voter" SET "weight" = 1
jbe@0 3912 WHERE "issue_id" = "issue_id_p";
jbe@0 3913 PERFORM "add_vote_delegations"("issue_id_p");
jbe@137 3914 -- set voter count and mark issue as being calculated:
jbe@4 3915 UPDATE "issue" SET
jbe@111 3916 "state" = 'calculation',
jbe@61 3917 "closed" = now(),
jbe@4 3918 "voter_count" = (
jbe@4 3919 SELECT coalesce(sum("weight"), 0)
jbe@4 3920 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@6 3921 )
jbe@6 3922 WHERE "id" = "issue_id_p";
jbe@137 3923 -- materialize battle_view:
jbe@61 3924 -- NOTE: "closed" column of issue must be set at this point
jbe@61 3925 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 3926 INSERT INTO "battle" (
jbe@61 3927 "issue_id",
jbe@61 3928 "winning_initiative_id", "losing_initiative_id",
jbe@61 3929 "count"
jbe@61 3930 ) SELECT
jbe@61 3931 "issue_id",
jbe@61 3932 "winning_initiative_id", "losing_initiative_id",
jbe@61 3933 "count"
jbe@61 3934 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@155 3935 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@155 3936 UPDATE "initiative" SET
jbe@155 3937 "positive_votes" = "battle_win"."count",
jbe@155 3938 "negative_votes" = "battle_lose"."count"
jbe@155 3939 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@155 3940 WHERE
jbe@155 3941 "battle_win"."issue_id" = "issue_id_p" AND
jbe@155 3942 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@155 3943 "battle_win"."losing_initiative_id" ISNULL AND
jbe@155 3944 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@155 3945 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@155 3946 "battle_lose"."winning_initiative_id" ISNULL;
jbe@0 3947 END;
jbe@0 3948 $$;
jbe@0 3949
jbe@0 3950 COMMENT ON FUNCTION "close_voting"
jbe@0 3951 ( "issue"."id"%TYPE )
jbe@0 3952 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 3953
jbe@0 3954
jbe@30 3955 CREATE FUNCTION "defeat_strength"
jbe@30 3956 ( "positive_votes_p" INT4, "negative_votes_p" INT4 )
jbe@30 3957 RETURNS INT8
jbe@30 3958 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 3959 BEGIN
jbe@30 3960 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@30 3961 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@30 3962 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@30 3963 RETURN 0;
jbe@30 3964 ELSE
jbe@30 3965 RETURN -1;
jbe@30 3966 END IF;
jbe@30 3967 END;
jbe@30 3968 $$;
jbe@30 3969
jbe@30 3970 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 3971
jbe@30 3972
jbe@0 3973 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3974 RETURNS VOID
jbe@0 3975 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3976 DECLARE
jbe@155 3977 "issue_row" "issue"%ROWTYPE;
jbe@155 3978 "policy_row" "policy"%ROWTYPE;
jbe@134 3979 "dimension_v" INTEGER;
jbe@134 3980 "vote_matrix" INT4[][]; -- absolute votes
jbe@134 3981 "matrix" INT8[][]; -- defeat strength / best paths
jbe@134 3982 "i" INTEGER;
jbe@134 3983 "j" INTEGER;
jbe@134 3984 "k" INTEGER;
jbe@134 3985 "battle_row" "battle"%ROWTYPE;
jbe@134 3986 "rank_ary" INT4[];
jbe@134 3987 "rank_v" INT4;
jbe@134 3988 "done_v" INTEGER;
jbe@134 3989 "winners_ary" INTEGER[];
jbe@134 3990 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3991 BEGIN
jbe@155 3992 SELECT * INTO "issue_row"
jbe@155 3993 FROM "issue" WHERE "id" = "issue_id_p"
jbe@155 3994 FOR UPDATE;
jbe@155 3995 SELECT * INTO "policy_row"
jbe@155 3996 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@126 3997 SELECT count(1) INTO "dimension_v"
jbe@126 3998 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@170 3999 -- Create "vote_matrix" with absolute number of votes in pairwise
jbe@170 4000 -- comparison:
jbe@170 4001 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4002 "i" := 1;
jbe@170 4003 "j" := 2;
jbe@170 4004 FOR "battle_row" IN
jbe@170 4005 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@170 4006 ORDER BY
jbe@170 4007 "winning_initiative_id" NULLS LAST,
jbe@170 4008 "losing_initiative_id" NULLS LAST
jbe@170 4009 LOOP
jbe@170 4010 "vote_matrix"["i"]["j"] := "battle_row"."count";
jbe@170 4011 IF "j" = "dimension_v" THEN
jbe@170 4012 "i" := "i" + 1;
jbe@170 4013 "j" := 1;
jbe@170 4014 ELSE
jbe@170 4015 "j" := "j" + 1;
jbe@170 4016 IF "j" = "i" THEN
jbe@170 4017 "j" := "j" + 1;
jbe@170 4018 END IF;
jbe@170 4019 END IF;
jbe@170 4020 END LOOP;
jbe@170 4021 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@170 4022 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@170 4023 END IF;
jbe@170 4024 -- Store defeat strengths in "matrix" using "defeat_strength"
jbe@170 4025 -- function:
jbe@170 4026 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4027 "i" := 1;
jbe@170 4028 LOOP
jbe@170 4029 "j" := 1;
jbe@0 4030 LOOP
jbe@170 4031 IF "i" != "j" THEN
jbe@170 4032 "matrix"["i"]["j"] := "defeat_strength"(
jbe@170 4033 "vote_matrix"["i"]["j"],
jbe@170 4034 "vote_matrix"["j"]["i"]
jbe@170 4035 );
jbe@0 4036 END IF;
jbe@170 4037 EXIT WHEN "j" = "dimension_v";
jbe@170 4038 "j" := "j" + 1;
jbe@0 4039 END LOOP;
jbe@170 4040 EXIT WHEN "i" = "dimension_v";
jbe@170 4041 "i" := "i" + 1;
jbe@170 4042 END LOOP;
jbe@170 4043 -- Find best paths:
jbe@170 4044 "i" := 1;
jbe@170 4045 LOOP
jbe@170 4046 "j" := 1;
jbe@170 4047 LOOP
jbe@170 4048 IF "i" != "j" THEN
jbe@170 4049 "k" := 1;
jbe@170 4050 LOOP
jbe@170 4051 IF "i" != "k" AND "j" != "k" THEN
jbe@170 4052 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
jbe@170 4053 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
jbe@170 4054 "matrix"["j"]["k"] := "matrix"["j"]["i"];
jbe@170 4055 END IF;
jbe@170 4056 ELSE
jbe@170 4057 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
jbe@170 4058 "matrix"["j"]["k"] := "matrix"["i"]["k"];
jbe@170 4059 END IF;
jbe@170 4060 END IF;
jbe@170 4061 END IF;
jbe@170 4062 EXIT WHEN "k" = "dimension_v";
jbe@170 4063 "k" := "k" + 1;
jbe@170 4064 END LOOP;
jbe@170 4065 END IF;
jbe@170 4066 EXIT WHEN "j" = "dimension_v";
jbe@170 4067 "j" := "j" + 1;
jbe@170 4068 END LOOP;
jbe@170 4069 EXIT WHEN "i" = "dimension_v";
jbe@170 4070 "i" := "i" + 1;
jbe@170 4071 END LOOP;
jbe@170 4072 -- Determine order of winners:
jbe@170 4073 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@170 4074 "rank_v" := 1;
jbe@170 4075 "done_v" := 0;
jbe@170 4076 LOOP
jbe@170 4077 "winners_ary" := '{}';
jbe@0 4078 "i" := 1;
jbe@0 4079 LOOP
jbe@170 4080 IF "rank_ary"["i"] ISNULL THEN
jbe@170 4081 "j" := 1;
jbe@170 4082 LOOP
jbe@170 4083 IF
jbe@170 4084 "i" != "j" AND
jbe@170 4085 "rank_ary"["j"] ISNULL AND
jbe@170 4086 "matrix"["j"]["i"] > "matrix"["i"]["j"]
jbe@170 4087 THEN
jbe@170 4088 -- someone else is better
jbe@170 4089 EXIT;
jbe@170 4090 END IF;
jbe@170 4091 IF "j" = "dimension_v" THEN
jbe@170 4092 -- noone is better
jbe@170 4093 "winners_ary" := "winners_ary" || "i";
jbe@170 4094 EXIT;
jbe@170 4095 END IF;
jbe@170 4096 "j" := "j" + 1;
jbe@170 4097 END LOOP;
jbe@170 4098 END IF;
jbe@30 4099 EXIT WHEN "i" = "dimension_v";
jbe@0 4100 "i" := "i" + 1;
jbe@0 4101 END LOOP;
jbe@0 4102 "i" := 1;
jbe@0 4103 LOOP
jbe@170 4104 "rank_ary"["winners_ary"["i"]] := "rank_v";
jbe@170 4105 "done_v" := "done_v" + 1;
jbe@170 4106 EXIT WHEN "i" = array_upper("winners_ary", 1);
jbe@0 4107 "i" := "i" + 1;
jbe@0 4108 END LOOP;
jbe@170 4109 EXIT WHEN "done_v" = "dimension_v";
jbe@170 4110 "rank_v" := "rank_v" + 1;
jbe@170 4111 END LOOP;
jbe@170 4112 -- write preliminary results:
jbe@170 4113 "i" := 1;
jbe@170 4114 FOR "initiative_id_v" IN
jbe@170 4115 SELECT "id" FROM "initiative"
jbe@170 4116 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@170 4117 ORDER BY "id"
jbe@170 4118 LOOP
jbe@170 4119 UPDATE "initiative" SET
jbe@170 4120 "direct_majority" =
jbe@170 4121 CASE WHEN "policy_row"."direct_majority_strict" THEN
jbe@170 4122 "positive_votes" * "policy_row"."direct_majority_den" >
jbe@170 4123 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4124 ELSE
jbe@170 4125 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@170 4126 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4127 END
jbe@170 4128 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@170 4129 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4130 "policy_row"."direct_majority_non_negative",
jbe@170 4131 "indirect_majority" =
jbe@170 4132 CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4133 "positive_votes" * "policy_row"."indirect_majority_den" >
jbe@170 4134 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4135 ELSE
jbe@170 4136 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@170 4137 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4138 END
jbe@170 4139 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@170 4140 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4141 "policy_row"."indirect_majority_non_negative",
jbe@171 4142 "schulze_rank" = "rank_ary"["i"],
jbe@170 4143 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
jbe@170 4144 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"],
jbe@170 4145 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
jbe@172 4146 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0,
jbe@216 4147 "eligible" = FALSE,
jbe@250 4148 "winner" = FALSE,
jbe@250 4149 "rank" = NULL -- NOTE: in cases of manual reset of issue state
jbe@170 4150 WHERE "id" = "initiative_id_v";
jbe@170 4151 "i" := "i" + 1;
jbe@170 4152 END LOOP;
jbe@170 4153 IF "i" != "dimension_v" THEN
jbe@170 4154 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 4155 END IF;
jbe@170 4156 -- take indirect majorities into account:
jbe@170 4157 LOOP
jbe@170 4158 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@139 4159 FROM (
jbe@170 4160 SELECT "new_initiative"."id" AS "initiative_id"
jbe@170 4161 FROM "initiative" "old_initiative"
jbe@170 4162 JOIN "initiative" "new_initiative"
jbe@170 4163 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@170 4164 AND "new_initiative"."indirect_majority" = FALSE
jbe@139 4165 JOIN "battle" "battle_win"
jbe@139 4166 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4167 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@170 4168 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@139 4169 JOIN "battle" "battle_lose"
jbe@139 4170 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4171 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@170 4172 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@170 4173 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@170 4174 AND "old_initiative"."indirect_majority" = TRUE
jbe@170 4175 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4176 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@170 4177 "policy_row"."indirect_majority_num" *
jbe@170 4178 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4179 ELSE
jbe@170 4180 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@170 4181 "policy_row"."indirect_majority_num" *
jbe@170 4182 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4183 END
jbe@170 4184 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@170 4185 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@170 4186 "policy_row"."indirect_majority_non_negative"
jbe@139 4187 ) AS "subquery"
jbe@139 4188 WHERE "id" = "subquery"."initiative_id";
jbe@170 4189 EXIT WHEN NOT FOUND;
jbe@170 4190 END LOOP;
jbe@170 4191 -- set "multistage_majority" for remaining matching initiatives:
jbe@216 4192 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@170 4193 FROM (
jbe@170 4194 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@170 4195 FROM "initiative" "losing_initiative"
jbe@170 4196 JOIN "initiative" "winning_initiative"
jbe@170 4197 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@170 4198 AND "winning_initiative"."admitted"
jbe@170 4199 JOIN "battle" "battle_win"
jbe@170 4200 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4201 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@170 4202 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@170 4203 JOIN "battle" "battle_lose"
jbe@170 4204 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4205 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@170 4206 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@170 4207 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@170 4208 AND "losing_initiative"."admitted"
jbe@170 4209 AND "winning_initiative"."schulze_rank" <
jbe@170 4210 "losing_initiative"."schulze_rank"
jbe@170 4211 AND "battle_win"."count" > "battle_lose"."count"
jbe@170 4212 AND (
jbe@170 4213 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@170 4214 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@170 4215 ) AS "subquery"
jbe@170 4216 WHERE "id" = "subquery"."initiative_id";
jbe@170 4217 -- mark eligible initiatives:
jbe@170 4218 UPDATE "initiative" SET "eligible" = TRUE
jbe@171 4219 WHERE "issue_id" = "issue_id_p"
jbe@171 4220 AND "initiative"."direct_majority"
jbe@171 4221 AND "initiative"."indirect_majority"
jbe@171 4222 AND "initiative"."better_than_status_quo"
jbe@171 4223 AND (
jbe@171 4224 "policy_row"."no_multistage_majority" = FALSE OR
jbe@171 4225 "initiative"."multistage_majority" = FALSE )
jbe@171 4226 AND (
jbe@171 4227 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@171 4228 "initiative"."reverse_beat_path" = FALSE );
jbe@170 4229 -- mark final winner:
jbe@170 4230 UPDATE "initiative" SET "winner" = TRUE
jbe@170 4231 FROM (
jbe@170 4232 SELECT "id" AS "initiative_id"
jbe@170 4233 FROM "initiative"
jbe@170 4234 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@217 4235 ORDER BY
jbe@217 4236 "schulze_rank",
jbe@217 4237 "id"
jbe@170 4238 LIMIT 1
jbe@170 4239 ) AS "subquery"
jbe@170 4240 WHERE "id" = "subquery"."initiative_id";
jbe@173 4241 -- write (final) ranks:
jbe@173 4242 "rank_v" := 1;
jbe@173 4243 FOR "initiative_id_v" IN
jbe@173 4244 SELECT "id"
jbe@173 4245 FROM "initiative"
jbe@173 4246 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@174 4247 ORDER BY
jbe@174 4248 "winner" DESC,
jbe@217 4249 "eligible" DESC,
jbe@174 4250 "schulze_rank",
jbe@174 4251 "id"
jbe@173 4252 LOOP
jbe@173 4253 UPDATE "initiative" SET "rank" = "rank_v"
jbe@173 4254 WHERE "id" = "initiative_id_v";
jbe@173 4255 "rank_v" := "rank_v" + 1;
jbe@173 4256 END LOOP;
jbe@170 4257 -- set schulze rank of status quo and mark issue as finished:
jbe@111 4258 UPDATE "issue" SET
jbe@170 4259 "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
jbe@111 4260 "state" =
jbe@139 4261 CASE WHEN EXISTS (
jbe@139 4262 SELECT NULL FROM "initiative"
jbe@139 4263 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@139 4264 ) THEN
jbe@139 4265 'finished_with_winner'::"issue_state"
jbe@139 4266 ELSE
jbe@121 4267 'finished_without_winner'::"issue_state"
jbe@111 4268 END,
jbe@111 4269 "ranks_available" = TRUE
jbe@0 4270 WHERE "id" = "issue_id_p";
jbe@0 4271 RETURN;
jbe@0 4272 END;
jbe@0 4273 $$;
jbe@0 4274
jbe@0 4275 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 4276 ( "issue"."id"%TYPE )
jbe@0 4277 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 4278
jbe@0 4279
jbe@0 4280
jbe@0 4281 -----------------------------
jbe@0 4282 -- Automatic state changes --
jbe@0 4283 -----------------------------
jbe@0 4284
jbe@0 4285
jbe@0 4286 CREATE FUNCTION "check_issue"
jbe@0 4287 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 4288 RETURNS VOID
jbe@0 4289 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4290 DECLARE
jbe@322 4291 "issue_row" "issue"%ROWTYPE;
jbe@322 4292 "policy_row" "policy"%ROWTYPE;
jbe@322 4293 "new_snapshot_v" BOOLEAN;
jbe@0 4294 BEGIN
jbe@67 4295 PERFORM "lock_issue"("issue_id_p");
jbe@0 4296 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 4297 -- only process open issues:
jbe@0 4298 IF "issue_row"."closed" ISNULL THEN
jbe@0 4299 SELECT * INTO "policy_row" FROM "policy"
jbe@0 4300 WHERE "id" = "issue_row"."policy_id";
jbe@24 4301 -- create a snapshot, unless issue is already fully frozen:
jbe@3 4302 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@0 4303 PERFORM "create_snapshot"("issue_id_p");
jbe@322 4304 "new_snapshot_v" := TRUE;
jbe@0 4305 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@322 4306 ELSE
jbe@322 4307 "new_snapshot_v" := FALSE;
jbe@0 4308 END IF;
jbe@24 4309 -- eventually close or accept issues, which have not been accepted:
jbe@0 4310 IF "issue_row"."accepted" ISNULL THEN
jbe@0 4311 IF EXISTS (
jbe@0 4312 SELECT NULL FROM "initiative"
jbe@0 4313 WHERE "issue_id" = "issue_id_p"
jbe@0 4314 AND "supporter_count" > 0
jbe@0 4315 AND "supporter_count" * "policy_row"."issue_quorum_den"
jbe@0 4316 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
jbe@0 4317 ) THEN
jbe@24 4318 -- accept issues, if supporter count is high enough
jbe@3 4319 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@111 4320 -- NOTE: "issue_row" used later
jbe@111 4321 "issue_row"."state" := 'discussion';
jbe@111 4322 "issue_row"."accepted" := now();
jbe@111 4323 UPDATE "issue" SET
jbe@111 4324 "state" = "issue_row"."state",
jbe@111 4325 "accepted" = "issue_row"."accepted"
jbe@0 4326 WHERE "id" = "issue_row"."id";
jbe@0 4327 ELSIF
jbe@22 4328 now() >= "issue_row"."created" + "issue_row"."admission_time"
jbe@0 4329 THEN
jbe@24 4330 -- close issues, if admission time has expired
jbe@0 4331 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@111 4332 UPDATE "issue" SET
jbe@111 4333 "state" = 'canceled_issue_not_accepted',
jbe@111 4334 "closed" = now()
jbe@0 4335 WHERE "id" = "issue_row"."id";
jbe@0 4336 END IF;
jbe@0 4337 END IF;
jbe@24 4338 -- eventually half freeze issues:
jbe@0 4339 IF
jbe@24 4340 -- NOTE: issue can't be closed at this point, if it has been accepted
jbe@0 4341 "issue_row"."accepted" NOTNULL AND
jbe@3 4342 "issue_row"."half_frozen" ISNULL
jbe@0 4343 THEN
jbe@0 4344 IF
jbe@144 4345 now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
jbe@0 4346 THEN
jbe@21 4347 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@111 4348 -- NOTE: "issue_row" used later
jbe@111 4349 "issue_row"."state" := 'verification';
jbe@111 4350 "issue_row"."half_frozen" := now();
jbe@111 4351 UPDATE "issue" SET
jbe@111 4352 "state" = "issue_row"."state",
jbe@111 4353 "half_frozen" = "issue_row"."half_frozen"
jbe@3 4354 WHERE "id" = "issue_row"."id";
jbe@0 4355 END IF;
jbe@0 4356 END IF;
jbe@24 4357 -- close issues after some time, if all initiatives have been revoked:
jbe@24 4358 IF
jbe@24 4359 "issue_row"."closed" ISNULL AND
jbe@24 4360 NOT EXISTS (
jbe@24 4361 -- all initiatives are revoked
jbe@24 4362 SELECT NULL FROM "initiative"
jbe@24 4363 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 4364 ) AND (
jbe@111 4365 -- and issue has not been accepted yet
jbe@111 4366 "issue_row"."accepted" ISNULL OR
jbe@24 4367 NOT EXISTS (
jbe@111 4368 -- or no initiatives have been revoked lately
jbe@24 4369 SELECT NULL FROM "initiative"
jbe@24 4370 WHERE "issue_id" = "issue_id_p"
jbe@24 4371 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 4372 ) OR (
jbe@24 4373 -- or verification time has elapsed
jbe@24 4374 "issue_row"."half_frozen" NOTNULL AND
jbe@24 4375 "issue_row"."fully_frozen" ISNULL AND
jbe@24 4376 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@24 4377 )
jbe@24 4378 )
jbe@24 4379 THEN
jbe@111 4380 -- NOTE: "issue_row" used later
jbe@113 4381 IF "issue_row"."accepted" ISNULL THEN
jbe@113 4382 "issue_row"."state" := 'canceled_revoked_before_accepted';
jbe@113 4383 ELSIF "issue_row"."half_frozen" ISNULL THEN
jbe@113 4384 "issue_row"."state" := 'canceled_after_revocation_during_discussion';
jbe@113 4385 ELSE
jbe@113 4386 "issue_row"."state" := 'canceled_after_revocation_during_verification';
jbe@113 4387 END IF;
jbe@111 4388 "issue_row"."closed" := now();
jbe@111 4389 UPDATE "issue" SET
jbe@111 4390 "state" = "issue_row"."state",
jbe@111 4391 "closed" = "issue_row"."closed"
jbe@24 4392 WHERE "id" = "issue_row"."id";
jbe@24 4393 END IF;
jbe@24 4394 -- fully freeze issue after verification time:
jbe@0 4395 IF
jbe@3 4396 "issue_row"."half_frozen" NOTNULL AND
jbe@3 4397 "issue_row"."fully_frozen" ISNULL AND
jbe@24 4398 "issue_row"."closed" ISNULL AND
jbe@22 4399 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
jbe@3 4400 THEN
jbe@3 4401 PERFORM "freeze_after_snapshot"("issue_id_p");
jbe@24 4402 -- NOTE: "issue" might change, thus "issue_row" has to be updated below
jbe@3 4403 END IF;
jbe@9 4404 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@24 4405 -- close issue by calling close_voting(...) after voting time:
jbe@3 4406 IF
jbe@9 4407 "issue_row"."closed" ISNULL AND
jbe@3 4408 "issue_row"."fully_frozen" NOTNULL AND
jbe@22 4409 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
jbe@0 4410 THEN
jbe@0 4411 PERFORM "close_voting"("issue_id_p");
jbe@111 4412 -- calculate ranks will not consume much time and can be done now
jbe@111 4413 PERFORM "calculate_ranks"("issue_id_p");
jbe@0 4414 END IF;
jbe@322 4415 -- if a new shapshot has been created, then recalculate harmonic weights:
jbe@322 4416 IF "new_snapshot_v" THEN
jbe@322 4417 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@322 4418 END IF;
jbe@0 4419 END IF;
jbe@0 4420 RETURN;
jbe@0 4421 END;
jbe@0 4422 $$;
jbe@0 4423
jbe@0 4424 COMMENT ON FUNCTION "check_issue"
jbe@0 4425 ( "issue"."id"%TYPE )
jbe@0 4426 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 4427
jbe@0 4428
jbe@0 4429 CREATE FUNCTION "check_everything"()
jbe@0 4430 RETURNS VOID
jbe@0 4431 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4432 DECLARE
jbe@0 4433 "issue_id_v" "issue"."id"%TYPE;
jbe@0 4434 BEGIN
jbe@235 4435 DELETE FROM "expired_session";
jbe@184 4436 PERFORM "check_activity"();
jbe@4 4437 PERFORM "calculate_member_counts"();
jbe@4 4438 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@0 4439 PERFORM "check_issue"("issue_id_v");
jbe@0 4440 END LOOP;
jbe@4 4441 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
jbe@0 4442 PERFORM "calculate_ranks"("issue_id_v");
jbe@0 4443 END LOOP;
jbe@0 4444 RETURN;
jbe@0 4445 END;
jbe@0 4446 $$;
jbe@0 4447
jbe@103 4448 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 4449
jbe@0 4450
jbe@0 4451
jbe@59 4452 ----------------------
jbe@59 4453 -- Deletion of data --
jbe@59 4454 ----------------------
jbe@59 4455
jbe@59 4456
jbe@59 4457 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 4458 RETURNS VOID
jbe@59 4459 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 4460 DECLARE
jbe@59 4461 "issue_row" "issue"%ROWTYPE;
jbe@59 4462 BEGIN
jbe@59 4463 SELECT * INTO "issue_row"
jbe@59 4464 FROM "issue" WHERE "id" = "issue_id_p"
jbe@59 4465 FOR UPDATE;
jbe@59 4466 IF "issue_row"."cleaned" ISNULL THEN
jbe@59 4467 UPDATE "issue" SET
jbe@152 4468 "state" = 'voting',
jbe@152 4469 "closed" = NULL,
jbe@59 4470 "ranks_available" = FALSE
jbe@59 4471 WHERE "id" = "issue_id_p";
jbe@59 4472 DELETE FROM "delegating_voter"
jbe@59 4473 WHERE "issue_id" = "issue_id_p";
jbe@59 4474 DELETE FROM "direct_voter"
jbe@59 4475 WHERE "issue_id" = "issue_id_p";
jbe@59 4476 DELETE FROM "delegating_interest_snapshot"
jbe@59 4477 WHERE "issue_id" = "issue_id_p";
jbe@59 4478 DELETE FROM "direct_interest_snapshot"
jbe@59 4479 WHERE "issue_id" = "issue_id_p";
jbe@59 4480 DELETE FROM "delegating_population_snapshot"
jbe@59 4481 WHERE "issue_id" = "issue_id_p";
jbe@59 4482 DELETE FROM "direct_population_snapshot"
jbe@59 4483 WHERE "issue_id" = "issue_id_p";
jbe@113 4484 DELETE FROM "non_voter"
jbe@94 4485 WHERE "issue_id" = "issue_id_p";
jbe@59 4486 DELETE FROM "delegation"
jbe@59 4487 WHERE "issue_id" = "issue_id_p";
jbe@59 4488 DELETE FROM "supporter"
jbe@325 4489 USING "initiative"
jbe@325 4490 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 4491 AND "supporter"."initiative_id" = "initiative_id";
jbe@59 4492 UPDATE "issue" SET
jbe@152 4493 "state" = "issue_row"."state",
jbe@59 4494 "closed" = "issue_row"."closed",
jbe@59 4495 "ranks_available" = "issue_row"."ranks_available",
jbe@59 4496 "cleaned" = now()
jbe@59 4497 WHERE "id" = "issue_id_p";
jbe@59 4498 END IF;
jbe@59 4499 RETURN;
jbe@59 4500 END;
jbe@59 4501 $$;
jbe@59 4502
jbe@59 4503 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 4504
jbe@8 4505
jbe@54 4506 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 4507 RETURNS VOID
jbe@8 4508 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 4509 BEGIN
jbe@9 4510 UPDATE "member" SET
jbe@57 4511 "last_login" = NULL,
jbe@45 4512 "login" = NULL,
jbe@11 4513 "password" = NULL,
jbe@101 4514 "locked" = TRUE,
jbe@54 4515 "active" = FALSE,
jbe@11 4516 "notify_email" = NULL,
jbe@11 4517 "notify_email_unconfirmed" = NULL,
jbe@11 4518 "notify_email_secret" = NULL,
jbe@11 4519 "notify_email_secret_expiry" = NULL,
jbe@57 4520 "notify_email_lock_expiry" = NULL,
jbe@11 4521 "password_reset_secret" = NULL,
jbe@11 4522 "password_reset_secret_expiry" = NULL,
jbe@11 4523 "organizational_unit" = NULL,
jbe@11 4524 "internal_posts" = NULL,
jbe@11 4525 "realname" = NULL,
jbe@11 4526 "birthday" = NULL,
jbe@11 4527 "address" = NULL,
jbe@11 4528 "email" = NULL,
jbe@11 4529 "xmpp_address" = NULL,
jbe@11 4530 "website" = NULL,
jbe@11 4531 "phone" = NULL,
jbe@11 4532 "mobile_phone" = NULL,
jbe@11 4533 "profession" = NULL,
jbe@11 4534 "external_memberships" = NULL,
jbe@11 4535 "external_posts" = NULL,
jbe@45 4536 "statement" = NULL
jbe@45 4537 WHERE "id" = "member_id_p";
jbe@11 4538 -- "text_search_data" is updated by triggers
jbe@45 4539 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@45 4540 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@45 4541 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@45 4542 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 4543 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 4544 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@235 4545 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@45 4546 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@45 4547 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@113 4548 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@45 4549 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@45 4550 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@54 4551 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
jbe@54 4552 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 4553 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 4554 DELETE FROM "direct_voter" USING "issue"
jbe@57 4555 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 4556 AND "issue"."closed" ISNULL
jbe@57 4557 AND "member_id" = "member_id_p";
jbe@45 4558 RETURN;
jbe@45 4559 END;
jbe@45 4560 $$;
jbe@45 4561
jbe@57 4562 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 4563
jbe@45 4564
jbe@45 4565 CREATE FUNCTION "delete_private_data"()
jbe@45 4566 RETURNS VOID
jbe@45 4567 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 4568 BEGIN
jbe@226 4569 DELETE FROM "member" WHERE "activated" ISNULL;
jbe@50 4570 UPDATE "member" SET
jbe@206 4571 "invite_code" = NULL,
jbe@232 4572 "invite_code_expiry" = NULL,
jbe@228 4573 "admin_comment" = NULL,
jbe@57 4574 "last_login" = NULL,
jbe@50 4575 "login" = NULL,
jbe@50 4576 "password" = NULL,
jbe@238 4577 "lang" = NULL,
jbe@50 4578 "notify_email" = NULL,
jbe@50 4579 "notify_email_unconfirmed" = NULL,
jbe@50 4580 "notify_email_secret" = NULL,
jbe@50 4581 "notify_email_secret_expiry" = NULL,
jbe@57 4582 "notify_email_lock_expiry" = NULL,
jbe@238 4583 "notify_level" = NULL,
jbe@50 4584 "password_reset_secret" = NULL,
jbe@50 4585 "password_reset_secret_expiry" = NULL,
jbe@50 4586 "organizational_unit" = NULL,
jbe@50 4587 "internal_posts" = NULL,
jbe@50 4588 "realname" = NULL,
jbe@50 4589 "birthday" = NULL,
jbe@50 4590 "address" = NULL,
jbe@50 4591 "email" = NULL,
jbe@50 4592 "xmpp_address" = NULL,
jbe@50 4593 "website" = NULL,
jbe@50 4594 "phone" = NULL,
jbe@50 4595 "mobile_phone" = NULL,
jbe@50 4596 "profession" = NULL,
jbe@50 4597 "external_memberships" = NULL,
jbe@50 4598 "external_posts" = NULL,
jbe@238 4599 "formatting_engine" = NULL,
jbe@50 4600 "statement" = NULL;
jbe@50 4601 -- "text_search_data" is updated by triggers
jbe@50 4602 DELETE FROM "setting";
jbe@50 4603 DELETE FROM "setting_map";
jbe@50 4604 DELETE FROM "member_relation_setting";
jbe@50 4605 DELETE FROM "member_image";
jbe@50 4606 DELETE FROM "contact";
jbe@113 4607 DELETE FROM "ignored_member";
jbe@235 4608 DELETE FROM "session";
jbe@50 4609 DELETE FROM "area_setting";
jbe@50 4610 DELETE FROM "issue_setting";
jbe@113 4611 DELETE FROM "ignored_initiative";
jbe@50 4612 DELETE FROM "initiative_setting";
jbe@50 4613 DELETE FROM "suggestion_setting";
jbe@113 4614 DELETE FROM "non_voter";
jbe@8 4615 DELETE FROM "direct_voter" USING "issue"
jbe@8 4616 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 4617 AND "issue"."closed" ISNULL;
jbe@8 4618 RETURN;
jbe@8 4619 END;
jbe@8 4620 $$;
jbe@8 4621
jbe@273 4622 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 4623
jbe@8 4624
jbe@8 4625
jbe@0 4626 COMMIT;

Impressum / About Us