liquid_feedback_core

annotate core.sql @ 280:5a32f862b2dd

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

Impressum / About Us