liquid_feedback_core

annotate core.sql @ 450:4434b4d69def

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

Impressum / About Us