liquid_feedback_core

annotate core.sql @ 457:ca21a3f49e4c

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

Impressum / About Us