liquid_feedback_core

annotate core.sql @ 449:6cef981cdcdf

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

Impressum / About Us