liquid_feedback_core

annotate core.sql @ 277:028a52d23e56

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

Impressum / About Us