liquid_feedback_core

annotate core.sql @ 337:c8289a674ef2

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

Impressum / About Us