liquid_feedback_core

annotate core.sql @ 496:044af1eec28b

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

Impressum / About Us