liquid_feedback_core

annotate core.sql @ 504:d07e6a046d41

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

Impressum / About Us