liquid_feedback_core

annotate core.sql @ 293:9ab561a91035

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

Impressum / About Us