liquid_feedback_core

annotate core.sql @ 458:fae00a5c1c71

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