liquid_feedback_core

annotate core.sql @ 484:d264e48cffbf

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

Impressum / About Us