liquid_feedback_core

annotate core.sql @ 265:e3c9f737a096

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

Impressum / About Us