liquid_feedback_core

annotate core.sql @ 278:0a42a2600a2b

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

Impressum / About Us