liquid_feedback_core

annotate core.sql @ 266:d1d5dca15491

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

Impressum / About Us