liquid_feedback_core

annotate core.sql @ 469:c1e283fd6483

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

Impressum / About Us