liquid_feedback_core

annotate core.sql @ 279:03897de17853

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

Impressum / About Us