liquid_feedback_core

annotate core.sql @ 270:b555a544c724

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

Impressum / About Us