liquid_feedback_core

annotate core.sql @ 505:be7942edfd1e

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

Impressum / About Us