liquid_feedback_core

annotate core.sql @ 319:685d38986598

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

Impressum / About Us