liquid_feedback_core

annotate core.sql @ 529:96ee2db56bec

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

Impressum / About Us