liquid_feedback_core

annotate core.sql @ 281:2fd3ac2f8323

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

Impressum / About Us