liquid_feedback_core

annotate core.sql @ 350:49c25dbc27bc

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

Impressum / About Us