liquid_feedback_core

annotate core.sql @ 276:b1360dc846be

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

Impressum / About Us