liquid_feedback_core

annotate core.sql @ 269:cbe1d7bb1d40

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

Impressum / About Us