liquid_feedback_core

annotate core.sql @ 509:3b684315c724

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

Impressum / About Us