liquid_feedback_core

annotate core.sql @ 468:c39ff9540f4d

Work on "issue_for_notification" table
author jbe
date Sat Mar 26 22:24:23 2016 +0100 (2016-03-26)
parents 1e7e8b025346
children c1e283fd6483
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@467 1279 CREATE TABLE "advertisement" ( -- 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@462 1284 CREATE INDEX "advertisement_initiative_id_idx" ON "advertisement" ("initiative_id");
jbe@462 1285 CREATE INDEX "advertisement_member_id_idx" ON "advertisement" ("member_id");
jbe@462 1286
jbe@462 1287 COMMENT ON TABLE "advertisement" IS 'Stores which initiatives have been advertised to a member in a mail digest';
jbe@462 1288
jbe@462 1289 COMMENT ON COLUMN "advertisement"."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@468 2396 CREATE VIEW "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@468 2420 "ignored_area"."member_id" ISNULL ) ); -- TODO: add certain issues in admission phase
jbe@468 2421
jbe@468 2422 COMMENT ON VIEW "issue_for_notification" IS 'Issues that are considered in notifications sent to the member';
jbe@467 2423
jbe@467 2424
jbe@0 2425
jbe@242 2426 ------------------------------------------------------
jbe@242 2427 -- Row set returning function for delegation chains --
jbe@242 2428 ------------------------------------------------------
jbe@5 2429
jbe@5 2430
jbe@5 2431 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
jbe@5 2432 ('first', 'intermediate', 'last', 'repetition');
jbe@5 2433
jbe@5 2434 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
jbe@5 2435
jbe@5 2436
jbe@5 2437 CREATE TYPE "delegation_chain_row" AS (
jbe@5 2438 "index" INT4,
jbe@5 2439 "member_id" INT4,
jbe@97 2440 "member_valid" BOOLEAN,
jbe@5 2441 "participation" BOOLEAN,
jbe@5 2442 "overridden" BOOLEAN,
jbe@5 2443 "scope_in" "delegation_scope",
jbe@5 2444 "scope_out" "delegation_scope",
jbe@86 2445 "disabled_out" BOOLEAN,
jbe@5 2446 "loop" "delegation_chain_loop_tag" );
jbe@5 2447
jbe@243 2448 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
jbe@5 2449
jbe@5 2450 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
jbe@5 2451 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 2452 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
jbe@5 2453 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
jbe@5 2454 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
jbe@86 2455 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 2456 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 2457
jbe@5 2458
jbe@242 2459 CREATE FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2460 ( "member_id_p" "member"."id"%TYPE,
jbe@242 2461 "issue_id_p" "issue"."id"%TYPE )
jbe@242 2462 RETURNS SETOF "delegation_chain_row"
jbe@242 2463 LANGUAGE 'plpgsql' STABLE AS $$
jbe@242 2464 DECLARE
jbe@242 2465 "output_row" "delegation_chain_row";
jbe@242 2466 "direct_voter_row" "direct_voter"%ROWTYPE;
jbe@242 2467 "delegating_voter_row" "delegating_voter"%ROWTYPE;
jbe@242 2468 BEGIN
jbe@242 2469 "output_row"."index" := 0;
jbe@242 2470 "output_row"."member_id" := "member_id_p";
jbe@242 2471 "output_row"."member_valid" := TRUE;
jbe@242 2472 "output_row"."participation" := FALSE;
jbe@242 2473 "output_row"."overridden" := FALSE;
jbe@242 2474 "output_row"."disabled_out" := FALSE;
jbe@242 2475 LOOP
jbe@242 2476 SELECT INTO "direct_voter_row" * FROM "direct_voter"
jbe@242 2477 WHERE "issue_id" = "issue_id_p"
jbe@242 2478 AND "member_id" = "output_row"."member_id";
jbe@242 2479 IF "direct_voter_row"."member_id" NOTNULL THEN
jbe@242 2480 "output_row"."participation" := TRUE;
jbe@242 2481 "output_row"."scope_out" := NULL;
jbe@242 2482 "output_row"."disabled_out" := NULL;
jbe@242 2483 RETURN NEXT "output_row";
jbe@242 2484 RETURN;
jbe@242 2485 END IF;
jbe@242 2486 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
jbe@242 2487 WHERE "issue_id" = "issue_id_p"
jbe@242 2488 AND "member_id" = "output_row"."member_id";
jbe@242 2489 IF "delegating_voter_row"."member_id" ISNULL THEN
jbe@242 2490 RETURN;
jbe@242 2491 END IF;
jbe@242 2492 "output_row"."scope_out" := "delegating_voter_row"."scope";
jbe@242 2493 RETURN NEXT "output_row";
jbe@242 2494 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
jbe@242 2495 "output_row"."scope_in" := "output_row"."scope_out";
jbe@242 2496 END LOOP;
jbe@242 2497 END;
jbe@242 2498 $$;
jbe@242 2499
jbe@242 2500 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
jbe@242 2501 ( "member"."id"%TYPE,
jbe@242 2502 "member"."id"%TYPE )
jbe@242 2503 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
jbe@242 2504
jbe@242 2505
jbe@5 2506 CREATE FUNCTION "delegation_chain"
jbe@5 2507 ( "member_id_p" "member"."id"%TYPE,
jbe@97 2508 "unit_id_p" "unit"."id"%TYPE,
jbe@5 2509 "area_id_p" "area"."id"%TYPE,
jbe@5 2510 "issue_id_p" "issue"."id"%TYPE,
jbe@255 2511 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 2512 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@5 2513 RETURNS SETOF "delegation_chain_row"
jbe@5 2514 LANGUAGE 'plpgsql' STABLE AS $$
jbe@5 2515 DECLARE
jbe@97 2516 "scope_v" "delegation_scope";
jbe@97 2517 "unit_id_v" "unit"."id"%TYPE;
jbe@97 2518 "area_id_v" "area"."id"%TYPE;
jbe@241 2519 "issue_row" "issue"%ROWTYPE;
jbe@5 2520 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@5 2521 "loop_member_id_v" "member"."id"%TYPE;
jbe@5 2522 "output_row" "delegation_chain_row";
jbe@5 2523 "output_rows" "delegation_chain_row"[];
jbe@255 2524 "simulate_v" BOOLEAN;
jbe@255 2525 "simulate_here_v" BOOLEAN;
jbe@5 2526 "delegation_row" "delegation"%ROWTYPE;
jbe@5 2527 "row_count" INT4;
jbe@5 2528 "i" INT4;
jbe@5 2529 "loop_v" BOOLEAN;
jbe@5 2530 BEGIN
jbe@255 2531 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
jbe@255 2532 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
jbe@255 2533 END IF;
jbe@255 2534 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
jbe@255 2535 "simulate_v" := TRUE;
jbe@255 2536 ELSE
jbe@255 2537 "simulate_v" := FALSE;
jbe@255 2538 END IF;
jbe@97 2539 IF
jbe@97 2540 "unit_id_p" NOTNULL AND
jbe@97 2541 "area_id_p" ISNULL AND
jbe@97 2542 "issue_id_p" ISNULL
jbe@97 2543 THEN
jbe@97 2544 "scope_v" := 'unit';
jbe@97 2545 "unit_id_v" := "unit_id_p";
jbe@97 2546 ELSIF
jbe@97 2547 "unit_id_p" ISNULL AND
jbe@97 2548 "area_id_p" NOTNULL AND
jbe@97 2549 "issue_id_p" ISNULL
jbe@97 2550 THEN
jbe@97 2551 "scope_v" := 'area';
jbe@97 2552 "area_id_v" := "area_id_p";
jbe@97 2553 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2554 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2555 ELSIF
jbe@97 2556 "unit_id_p" ISNULL AND
jbe@97 2557 "area_id_p" ISNULL AND
jbe@97 2558 "issue_id_p" NOTNULL
jbe@97 2559 THEN
jbe@242 2560 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@242 2561 IF "issue_row"."id" ISNULL THEN
jbe@242 2562 RETURN;
jbe@242 2563 END IF;
jbe@242 2564 IF "issue_row"."closed" NOTNULL THEN
jbe@255 2565 IF "simulate_v" THEN
jbe@242 2566 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@242 2567 END IF;
jbe@242 2568 FOR "output_row" IN
jbe@242 2569 SELECT * FROM
jbe@242 2570 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@242 2571 LOOP
jbe@242 2572 RETURN NEXT "output_row";
jbe@242 2573 END LOOP;
jbe@242 2574 RETURN;
jbe@242 2575 END IF;
jbe@97 2576 "scope_v" := 'issue';
jbe@97 2577 SELECT "area_id" INTO "area_id_v"
jbe@97 2578 FROM "issue" WHERE "id" = "issue_id_p";
jbe@97 2579 SELECT "unit_id" INTO "unit_id_v"
jbe@97 2580 FROM "area" WHERE "id" = "area_id_v";
jbe@97 2581 ELSE
jbe@97 2582 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@97 2583 END IF;
jbe@5 2584 "visited_member_ids" := '{}';
jbe@5 2585 "loop_member_id_v" := NULL;
jbe@5 2586 "output_rows" := '{}';
jbe@5 2587 "output_row"."index" := 0;
jbe@5 2588 "output_row"."member_id" := "member_id_p";
jbe@97 2589 "output_row"."member_valid" := TRUE;
jbe@5 2590 "output_row"."participation" := FALSE;
jbe@5 2591 "output_row"."overridden" := FALSE;
jbe@86 2592 "output_row"."disabled_out" := FALSE;
jbe@5 2593 "output_row"."scope_out" := NULL;
jbe@5 2594 LOOP
jbe@5 2595 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@5 2596 "loop_member_id_v" := "output_row"."member_id";
jbe@5 2597 ELSE
jbe@5 2598 "visited_member_ids" :=
jbe@5 2599 "visited_member_ids" || "output_row"."member_id";
jbe@5 2600 END IF;
jbe@241 2601 IF "output_row"."participation" ISNULL THEN
jbe@241 2602 "output_row"."overridden" := NULL;
jbe@241 2603 ELSIF "output_row"."participation" THEN
jbe@5 2604 "output_row"."overridden" := TRUE;
jbe@5 2605 END IF;
jbe@5 2606 "output_row"."scope_in" := "output_row"."scope_out";
jbe@255 2607 "output_row"."member_valid" := EXISTS (
jbe@97 2608 SELECT NULL FROM "member" JOIN "privilege"
jbe@97 2609 ON "privilege"."member_id" = "member"."id"
jbe@97 2610 AND "privilege"."unit_id" = "unit_id_v"
jbe@97 2611 WHERE "id" = "output_row"."member_id"
jbe@97 2612 AND "member"."active" AND "privilege"."voting_right"
jbe@255 2613 );
jbe@255 2614 "simulate_here_v" := (
jbe@255 2615 "simulate_v" AND
jbe@255 2616 "output_row"."member_id" = "member_id_p"
jbe@255 2617 );
jbe@255 2618 "delegation_row" := ROW(NULL);
jbe@255 2619 IF "output_row"."member_valid" OR "simulate_here_v" THEN
jbe@97 2620 IF "scope_v" = 'unit' THEN
jbe@255 2621 IF NOT "simulate_here_v" THEN
jbe@255 2622 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2623 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2624 AND "unit_id" = "unit_id_v";
jbe@255 2625 END IF;
jbe@97 2626 ELSIF "scope_v" = 'area' THEN
jbe@5 2627 "output_row"."participation" := EXISTS (
jbe@5 2628 SELECT NULL FROM "membership"
jbe@5 2629 WHERE "area_id" = "area_id_p"
jbe@5 2630 AND "member_id" = "output_row"."member_id"
jbe@5 2631 );
jbe@255 2632 IF "simulate_here_v" THEN
jbe@255 2633 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 2634 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2635 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2636 AND "unit_id" = "unit_id_v";
jbe@255 2637 END IF;
jbe@255 2638 ELSE
jbe@255 2639 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2640 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2641 AND (
jbe@255 2642 "unit_id" = "unit_id_v" OR
jbe@255 2643 "area_id" = "area_id_v"
jbe@255 2644 )
jbe@255 2645 ORDER BY "scope" DESC;
jbe@255 2646 END IF;
jbe@97 2647 ELSIF "scope_v" = 'issue' THEN
jbe@241 2648 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@241 2649 "output_row"."participation" := EXISTS (
jbe@241 2650 SELECT NULL FROM "interest"
jbe@241 2651 WHERE "issue_id" = "issue_id_p"
jbe@241 2652 AND "member_id" = "output_row"."member_id"
jbe@241 2653 );
jbe@241 2654 ELSE
jbe@241 2655 IF "output_row"."member_id" = "member_id_p" THEN
jbe@241 2656 "output_row"."participation" := EXISTS (
jbe@241 2657 SELECT NULL FROM "direct_voter"
jbe@241 2658 WHERE "issue_id" = "issue_id_p"
jbe@241 2659 AND "member_id" = "output_row"."member_id"
jbe@241 2660 );
jbe@241 2661 ELSE
jbe@241 2662 "output_row"."participation" := NULL;
jbe@241 2663 END IF;
jbe@241 2664 END IF;
jbe@255 2665 IF "simulate_here_v" THEN
jbe@255 2666 IF "simulate_trustee_id_p" ISNULL THEN
jbe@255 2667 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2668 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2669 AND (
jbe@255 2670 "unit_id" = "unit_id_v" OR
jbe@255 2671 "area_id" = "area_id_v"
jbe@255 2672 )
jbe@255 2673 ORDER BY "scope" DESC;
jbe@255 2674 END IF;
jbe@255 2675 ELSE
jbe@255 2676 SELECT * INTO "delegation_row" FROM "delegation"
jbe@255 2677 WHERE "truster_id" = "output_row"."member_id"
jbe@255 2678 AND (
jbe@255 2679 "unit_id" = "unit_id_v" OR
jbe@255 2680 "area_id" = "area_id_v" OR
jbe@255 2681 "issue_id" = "issue_id_p"
jbe@255 2682 )
jbe@255 2683 ORDER BY "scope" DESC;
jbe@255 2684 END IF;
jbe@5 2685 END IF;
jbe@5 2686 ELSE
jbe@5 2687 "output_row"."participation" := FALSE;
jbe@5 2688 END IF;
jbe@255 2689 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
jbe@97 2690 "output_row"."scope_out" := "scope_v";
jbe@5 2691 "output_rows" := "output_rows" || "output_row";
jbe@5 2692 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@5 2693 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@10 2694 "output_row"."scope_out" := "delegation_row"."scope";
jbe@5 2695 "output_rows" := "output_rows" || "output_row";
jbe@5 2696 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@86 2697 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@86 2698 "output_row"."scope_out" := "delegation_row"."scope";
jbe@86 2699 "output_row"."disabled_out" := TRUE;
jbe@86 2700 "output_rows" := "output_rows" || "output_row";
jbe@86 2701 EXIT;
jbe@5 2702 ELSE
jbe@5 2703 "output_row"."scope_out" := NULL;
jbe@5 2704 "output_rows" := "output_rows" || "output_row";
jbe@5 2705 EXIT;
jbe@5 2706 END IF;
jbe@5 2707 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@5 2708 "output_row"."index" := "output_row"."index" + 1;
jbe@5 2709 END LOOP;
jbe@5 2710 "row_count" := array_upper("output_rows", 1);
jbe@5 2711 "i" := 1;
jbe@5 2712 "loop_v" := FALSE;
jbe@5 2713 LOOP
jbe@5 2714 "output_row" := "output_rows"["i"];
jbe@98 2715 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@5 2716 IF "loop_v" THEN
jbe@5 2717 IF "i" + 1 = "row_count" THEN
jbe@5 2718 "output_row"."loop" := 'last';
jbe@5 2719 ELSIF "i" = "row_count" THEN
jbe@5 2720 "output_row"."loop" := 'repetition';
jbe@5 2721 ELSE
jbe@5 2722 "output_row"."loop" := 'intermediate';
jbe@5 2723 END IF;
jbe@5 2724 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@5 2725 "output_row"."loop" := 'first';
jbe@5 2726 "loop_v" := TRUE;
jbe@5 2727 END IF;
jbe@97 2728 IF "scope_v" = 'unit' THEN
jbe@5 2729 "output_row"."participation" := NULL;
jbe@5 2730 END IF;
jbe@5 2731 RETURN NEXT "output_row";
jbe@5 2732 "i" := "i" + 1;
jbe@5 2733 END LOOP;
jbe@5 2734 RETURN;
jbe@5 2735 END;
jbe@5 2736 $$;
jbe@5 2737
jbe@5 2738 COMMENT ON FUNCTION "delegation_chain"
jbe@5 2739 ( "member"."id"%TYPE,
jbe@97 2740 "unit"."id"%TYPE,
jbe@5 2741 "area"."id"%TYPE,
jbe@5 2742 "issue"."id"%TYPE,
jbe@255 2743 "member"."id"%TYPE,
jbe@255 2744 BOOLEAN )
jbe@242 2745 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
jbe@242 2746
jbe@242 2747
jbe@242 2748
jbe@242 2749 ---------------------------------------------------------
jbe@242 2750 -- Single row returning function for delegation chains --
jbe@242 2751 ---------------------------------------------------------
jbe@242 2752
jbe@242 2753
jbe@242 2754 CREATE TYPE "delegation_info_loop_type" AS ENUM
jbe@242 2755 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
jbe@240 2756
jbe@243 2757 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 2758
jbe@243 2759
jbe@240 2760 CREATE TYPE "delegation_info_type" AS (
jbe@242 2761 "own_participation" BOOLEAN,
jbe@242 2762 "own_delegation_scope" "delegation_scope",
jbe@242 2763 "first_trustee_id" INT4,
jbe@240 2764 "first_trustee_participation" BOOLEAN,
jbe@242 2765 "first_trustee_ellipsis" BOOLEAN,
jbe@242 2766 "other_trustee_id" INT4,
jbe@240 2767 "other_trustee_participation" BOOLEAN,
jbe@242 2768 "other_trustee_ellipsis" BOOLEAN,
jbe@253 2769 "delegation_loop" "delegation_info_loop_type",
jbe@253 2770 "participating_member_id" INT4 );
jbe@240 2771
jbe@243 2772 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 2773
jbe@243 2774 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
jbe@243 2775 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
jbe@243 2776 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
jbe@243 2777 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
jbe@243 2778 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
jbe@243 2779 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
jbe@243 2780 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 2781 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
jbe@243 2782 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 2783 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
jbe@243 2784
jbe@243 2785
jbe@240 2786 CREATE FUNCTION "delegation_info"
jbe@242 2787 ( "member_id_p" "member"."id"%TYPE,
jbe@242 2788 "unit_id_p" "unit"."id"%TYPE,
jbe@242 2789 "area_id_p" "area"."id"%TYPE,
jbe@242 2790 "issue_id_p" "issue"."id"%TYPE,
jbe@255 2791 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@255 2792 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@240 2793 RETURNS "delegation_info_type"
jbe@240 2794 LANGUAGE 'plpgsql' STABLE AS $$
jbe@240 2795 DECLARE
jbe@242 2796 "current_row" "delegation_chain_row";
jbe@242 2797 "result" "delegation_info_type";
jbe@240 2798 BEGIN
jbe@242 2799 "result"."own_participation" := FALSE;
jbe@242 2800 FOR "current_row" IN
jbe@242 2801 SELECT * FROM "delegation_chain"(
jbe@242 2802 "member_id_p",
jbe@242 2803 "unit_id_p", "area_id_p", "issue_id_p",
jbe@255 2804 "simulate_trustee_id_p", "simulate_default_p")
jbe@242 2805 LOOP
jbe@253 2806 IF
jbe@253 2807 "result"."participating_member_id" ISNULL AND
jbe@253 2808 "current_row"."participation"
jbe@253 2809 THEN
jbe@253 2810 "result"."participating_member_id" := "current_row"."member_id";
jbe@253 2811 END IF;
jbe@242 2812 IF "current_row"."member_id" = "member_id_p" THEN
jbe@242 2813 "result"."own_participation" := "current_row"."participation";
jbe@242 2814 "result"."own_delegation_scope" := "current_row"."scope_out";
jbe@242 2815 IF "current_row"."loop" = 'first' THEN
jbe@242 2816 "result"."delegation_loop" := 'own';
jbe@242 2817 END IF;
jbe@242 2818 ELSIF
jbe@242 2819 "current_row"."member_valid" AND
jbe@242 2820 ( "current_row"."loop" ISNULL OR
jbe@242 2821 "current_row"."loop" != 'repetition' )
jbe@242 2822 THEN
jbe@242 2823 IF "result"."first_trustee_id" ISNULL THEN
jbe@242 2824 "result"."first_trustee_id" := "current_row"."member_id";
jbe@242 2825 "result"."first_trustee_participation" := "current_row"."participation";
jbe@242 2826 "result"."first_trustee_ellipsis" := FALSE;
jbe@242 2827 IF "current_row"."loop" = 'first' THEN
jbe@242 2828 "result"."delegation_loop" := 'first';
jbe@242 2829 END IF;
jbe@242 2830 ELSIF "result"."other_trustee_id" ISNULL THEN
jbe@247 2831 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
jbe@242 2832 "result"."other_trustee_id" := "current_row"."member_id";
jbe@242 2833 "result"."other_trustee_participation" := TRUE;
jbe@242 2834 "result"."other_trustee_ellipsis" := FALSE;
jbe@242 2835 IF "current_row"."loop" = 'first' THEN
jbe@242 2836 "result"."delegation_loop" := 'other';
jbe@240 2837 END IF;
jbe@240 2838 ELSE
jbe@242 2839 "result"."first_trustee_ellipsis" := TRUE;
jbe@242 2840 IF "current_row"."loop" = 'first' THEN
jbe@242 2841 "result"."delegation_loop" := 'first_ellipsis';
jbe@242 2842 END IF;
jbe@242 2843 END IF;
jbe@242 2844 ELSE
jbe@242 2845 "result"."other_trustee_ellipsis" := TRUE;
jbe@242 2846 IF "current_row"."loop" = 'first' THEN
jbe@242 2847 "result"."delegation_loop" := 'other_ellipsis';
jbe@240 2848 END IF;
jbe@240 2849 END IF;
jbe@240 2850 END IF;
jbe@242 2851 END LOOP;
jbe@240 2852 RETURN "result";
jbe@240 2853 END;
jbe@240 2854 $$;
jbe@240 2855
jbe@243 2856 COMMENT ON FUNCTION "delegation_info"
jbe@243 2857 ( "member"."id"%TYPE,
jbe@243 2858 "unit"."id"%TYPE,
jbe@243 2859 "area"."id"%TYPE,
jbe@243 2860 "issue"."id"%TYPE,
jbe@255 2861 "member"."id"%TYPE,
jbe@255 2862 BOOLEAN )
jbe@243 2863 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
jbe@243 2864
jbe@240 2865
jbe@240 2866
jbe@333 2867 ---------------------------
jbe@333 2868 -- Transaction isolation --
jbe@333 2869 ---------------------------
jbe@333 2870
jbe@344 2871
jbe@333 2872 CREATE FUNCTION "require_transaction_isolation"()
jbe@333 2873 RETURNS VOID
jbe@333 2874 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 2875 BEGIN
jbe@333 2876 IF
jbe@333 2877 current_setting('transaction_isolation') NOT IN
jbe@333 2878 ('repeatable read', 'serializable')
jbe@333 2879 THEN
jbe@463 2880 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
jbe@463 2881 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
jbe@333 2882 END IF;
jbe@333 2883 RETURN;
jbe@333 2884 END;
jbe@333 2885 $$;
jbe@333 2886
jbe@344 2887 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
jbe@344 2888
jbe@333 2889
jbe@333 2890 CREATE FUNCTION "dont_require_transaction_isolation"()
jbe@333 2891 RETURNS VOID
jbe@333 2892 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@333 2893 BEGIN
jbe@333 2894 IF
jbe@333 2895 current_setting('transaction_isolation') IN
jbe@333 2896 ('repeatable read', 'serializable')
jbe@333 2897 THEN
jbe@333 2898 RAISE WARNING 'Unneccessary transaction isolation level: %',
jbe@333 2899 current_setting('transaction_isolation');
jbe@333 2900 END IF;
jbe@333 2901 RETURN;
jbe@333 2902 END;
jbe@333 2903 $$;
jbe@333 2904
jbe@344 2905 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
jbe@344 2906
jbe@333 2907
jbe@333 2908
jbe@103 2909 ------------------------------------------------------------------------
jbe@103 2910 -- Regular tasks, except calculcation of snapshots and voting results --
jbe@103 2911 ------------------------------------------------------------------------
jbe@103 2912
jbe@333 2913
jbe@184 2914 CREATE FUNCTION "check_activity"()
jbe@103 2915 RETURNS VOID
jbe@103 2916 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@104 2917 DECLARE
jbe@104 2918 "system_setting_row" "system_setting"%ROWTYPE;
jbe@103 2919 BEGIN
jbe@333 2920 PERFORM "dont_require_transaction_isolation"();
jbe@104 2921 SELECT * INTO "system_setting_row" FROM "system_setting";
jbe@104 2922 IF "system_setting_row"."member_ttl" NOTNULL THEN
jbe@104 2923 UPDATE "member" SET "active" = FALSE
jbe@104 2924 WHERE "active" = TRUE
jbe@184 2925 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
jbe@104 2926 END IF;
jbe@103 2927 RETURN;
jbe@103 2928 END;
jbe@103 2929 $$;
jbe@103 2930
jbe@184 2931 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
jbe@103 2932
jbe@4 2933
jbe@4 2934 CREATE FUNCTION "calculate_member_counts"()
jbe@4 2935 RETURNS VOID
jbe@4 2936 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@4 2937 BEGIN
jbe@333 2938 PERFORM "require_transaction_isolation"();
jbe@4 2939 DELETE FROM "member_count";
jbe@5 2940 INSERT INTO "member_count" ("total_count")
jbe@5 2941 SELECT "total_count" FROM "member_count_view";
jbe@97 2942 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@97 2943 FROM "unit_member_count" AS "view"
jbe@97 2944 WHERE "view"."unit_id" = "unit"."id";
jbe@5 2945 UPDATE "area" SET
jbe@5 2946 "direct_member_count" = "view"."direct_member_count",
jbe@169 2947 "member_weight" = "view"."member_weight"
jbe@5 2948 FROM "area_member_count" AS "view"
jbe@5 2949 WHERE "view"."area_id" = "area"."id";
jbe@4 2950 RETURN;
jbe@4 2951 END;
jbe@4 2952 $$;
jbe@4 2953
jbe@4 2954 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 2955
jbe@4 2956
jbe@4 2957
jbe@327 2958 ------------------------------------
jbe@327 2959 -- Calculation of harmonic weight --
jbe@327 2960 ------------------------------------
jbe@310 2961
jbe@312 2962
jbe@310 2963 CREATE VIEW "remaining_harmonic_supporter_weight" AS
jbe@310 2964 SELECT
jbe@310 2965 "direct_interest_snapshot"."issue_id",
jbe@310 2966 "direct_interest_snapshot"."event",
jbe@310 2967 "direct_interest_snapshot"."member_id",
jbe@310 2968 "direct_interest_snapshot"."weight" AS "weight_num",
jbe@310 2969 count("initiative"."id") AS "weight_den"
jbe@312 2970 FROM "issue"
jbe@312 2971 JOIN "direct_interest_snapshot"
jbe@312 2972 ON "issue"."id" = "direct_interest_snapshot"."issue_id"
jbe@312 2973 AND "issue"."latest_snapshot_event" = "direct_interest_snapshot"."event"
jbe@327 2974 JOIN "initiative"
jbe@327 2975 ON "issue"."id" = "initiative"."issue_id"
jbe@327 2976 AND "initiative"."harmonic_weight" ISNULL
jbe@310 2977 JOIN "direct_supporter_snapshot"
jbe@327 2978 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 2979 AND "direct_interest_snapshot"."event" = "direct_supporter_snapshot"."event"
jbe@310 2980 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 2981 AND (
jbe@321 2982 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 2983 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 2984 )
jbe@310 2985 GROUP BY
jbe@310 2986 "direct_interest_snapshot"."issue_id",
jbe@310 2987 "direct_interest_snapshot"."event",
jbe@310 2988 "direct_interest_snapshot"."member_id",
jbe@310 2989 "direct_interest_snapshot"."weight";
jbe@310 2990
jbe@310 2991 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 2992
jbe@310 2993
jbe@310 2994 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
jbe@310 2995 SELECT
jbe@310 2996 "initiative"."issue_id",
jbe@310 2997 "initiative"."id" AS "initiative_id",
jbe@320 2998 "initiative"."admitted",
jbe@310 2999 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
jbe@310 3000 "remaining_harmonic_supporter_weight"."weight_den"
jbe@310 3001 FROM "remaining_harmonic_supporter_weight"
jbe@327 3002 JOIN "initiative"
jbe@327 3003 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
jbe@327 3004 AND "initiative"."harmonic_weight" ISNULL
jbe@310 3005 JOIN "direct_supporter_snapshot"
jbe@327 3006 ON "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@310 3007 AND "remaining_harmonic_supporter_weight"."event" = "direct_supporter_snapshot"."event"
jbe@310 3008 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@321 3009 AND (
jbe@321 3010 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@321 3011 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@321 3012 )
jbe@310 3013 GROUP BY
jbe@310 3014 "initiative"."issue_id",
jbe@310 3015 "initiative"."id",
jbe@320 3016 "initiative"."admitted",
jbe@310 3017 "remaining_harmonic_supporter_weight"."weight_den";
jbe@310 3018
jbe@310 3019 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
jbe@310 3020
jbe@310 3021
jbe@349 3022 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
jbe@349 3023 SELECT
jbe@349 3024 "issue_id",
jbe@349 3025 "id" AS "initiative_id",
jbe@349 3026 "admitted",
jbe@349 3027 0 AS "weight_num",
jbe@349 3028 1 AS "weight_den"
jbe@349 3029 FROM "initiative"
jbe@349 3030 WHERE "harmonic_weight" ISNULL;
jbe@349 3031
jbe@349 3032 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 3033
jbe@349 3034
jbe@310 3035 CREATE FUNCTION "set_harmonic_initiative_weights"
jbe@310 3036 ( "issue_id_p" "issue"."id"%TYPE )
jbe@310 3037 RETURNS VOID
jbe@310 3038 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@310 3039 DECLARE
jbe@310 3040 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
jbe@310 3041 "i" INT4;
jbe@310 3042 "count_v" INT4;
jbe@310 3043 "summand_v" FLOAT;
jbe@310 3044 "id_ary" INT4[];
jbe@310 3045 "weight_ary" FLOAT[];
jbe@310 3046 "min_weight_v" FLOAT;
jbe@310 3047 BEGIN
jbe@333 3048 PERFORM "require_transaction_isolation"();
jbe@312 3049 UPDATE "initiative" SET "harmonic_weight" = NULL
jbe@312 3050 WHERE "issue_id" = "issue_id_p";
jbe@310 3051 LOOP
jbe@310 3052 "min_weight_v" := NULL;
jbe@310 3053 "i" := 0;
jbe@310 3054 "count_v" := 0;
jbe@310 3055 FOR "weight_row" IN
jbe@310 3056 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
jbe@310 3057 WHERE "issue_id" = "issue_id_p"
jbe@320 3058 AND (
jbe@320 3059 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@320 3060 SELECT NULL FROM "initiative"
jbe@320 3061 WHERE "issue_id" = "issue_id_p"
jbe@320 3062 AND "harmonic_weight" ISNULL
jbe@320 3063 AND coalesce("admitted", FALSE) = FALSE
jbe@320 3064 )
jbe@320 3065 )
jbe@349 3066 UNION ALL -- needed for corner cases
jbe@349 3067 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
jbe@349 3068 WHERE "issue_id" = "issue_id_p"
jbe@349 3069 AND (
jbe@349 3070 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
jbe@349 3071 SELECT NULL FROM "initiative"
jbe@349 3072 WHERE "issue_id" = "issue_id_p"
jbe@349 3073 AND "harmonic_weight" ISNULL
jbe@349 3074 AND coalesce("admitted", FALSE) = FALSE
jbe@349 3075 )
jbe@349 3076 )
jbe@310 3077 ORDER BY "initiative_id" DESC, "weight_den" DESC
jbe@320 3078 -- NOTE: non-admitted initiatives placed first (at last positions),
jbe@320 3079 -- latest initiatives treated worse in case of tie
jbe@310 3080 LOOP
jbe@310 3081 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
jbe@310 3082 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
jbe@310 3083 "i" := "i" + 1;
jbe@310 3084 "count_v" := "i";
jbe@310 3085 "id_ary"["i"] := "weight_row"."initiative_id";
jbe@310 3086 "weight_ary"["i"] := "summand_v";
jbe@310 3087 ELSE
jbe@310 3088 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
jbe@310 3089 END IF;
jbe@310 3090 END LOOP;
jbe@310 3091 EXIT WHEN "count_v" = 0;
jbe@310 3092 "i" := 1;
jbe@310 3093 LOOP
jbe@313 3094 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
jbe@310 3095 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
jbe@310 3096 "min_weight_v" := "weight_ary"["i"];
jbe@310 3097 END IF;
jbe@310 3098 "i" := "i" + 1;
jbe@310 3099 EXIT WHEN "i" > "count_v";
jbe@310 3100 END LOOP;
jbe@310 3101 "i" := 1;
jbe@310 3102 LOOP
jbe@310 3103 IF "weight_ary"["i"] = "min_weight_v" THEN
jbe@310 3104 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
jbe@310 3105 WHERE "id" = "id_ary"["i"];
jbe@310 3106 EXIT;
jbe@310 3107 END IF;
jbe@310 3108 "i" := "i" + 1;
jbe@310 3109 END LOOP;
jbe@310 3110 END LOOP;
jbe@316 3111 UPDATE "initiative" SET "harmonic_weight" = 0
jbe@316 3112 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
jbe@310 3113 END;
jbe@310 3114 $$;
jbe@310 3115
jbe@310 3116 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
jbe@310 3117 ( "issue"."id"%TYPE )
jbe@310 3118 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
jbe@310 3119
jbe@310 3120
jbe@312 3121
jbe@0 3122 ------------------------------
jbe@0 3123 -- Calculation of snapshots --
jbe@0 3124 ------------------------------
jbe@0 3125
jbe@312 3126
jbe@0 3127 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3128 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3129 "member_id_p" "member"."id"%TYPE,
jbe@0 3130 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3131 RETURNS "direct_population_snapshot"."weight"%TYPE
jbe@0 3132 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3133 DECLARE
jbe@0 3134 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3135 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3136 "weight_v" INT4;
jbe@8 3137 "sub_weight_v" INT4;
jbe@0 3138 BEGIN
jbe@336 3139 PERFORM "require_transaction_isolation"();
jbe@0 3140 "weight_v" := 0;
jbe@0 3141 FOR "issue_delegation_row" IN
jbe@0 3142 SELECT * FROM "issue_delegation"
jbe@0 3143 WHERE "trustee_id" = "member_id_p"
jbe@0 3144 AND "issue_id" = "issue_id_p"
jbe@0 3145 LOOP
jbe@0 3146 IF NOT EXISTS (
jbe@0 3147 SELECT NULL FROM "direct_population_snapshot"
jbe@0 3148 WHERE "issue_id" = "issue_id_p"
jbe@0 3149 AND "event" = 'periodic'
jbe@0 3150 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3151 ) AND NOT EXISTS (
jbe@0 3152 SELECT NULL FROM "delegating_population_snapshot"
jbe@0 3153 WHERE "issue_id" = "issue_id_p"
jbe@0 3154 AND "event" = 'periodic'
jbe@0 3155 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3156 ) THEN
jbe@0 3157 "delegate_member_ids_v" :=
jbe@0 3158 "member_id_p" || "delegate_member_ids_p";
jbe@10 3159 INSERT INTO "delegating_population_snapshot" (
jbe@10 3160 "issue_id",
jbe@10 3161 "event",
jbe@10 3162 "member_id",
jbe@10 3163 "scope",
jbe@10 3164 "delegate_member_ids"
jbe@10 3165 ) VALUES (
jbe@0 3166 "issue_id_p",
jbe@0 3167 'periodic',
jbe@0 3168 "issue_delegation_row"."truster_id",
jbe@10 3169 "issue_delegation_row"."scope",
jbe@0 3170 "delegate_member_ids_v"
jbe@0 3171 );
jbe@8 3172 "sub_weight_v" := 1 +
jbe@0 3173 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3174 "issue_id_p",
jbe@0 3175 "issue_delegation_row"."truster_id",
jbe@0 3176 "delegate_member_ids_v"
jbe@0 3177 );
jbe@8 3178 UPDATE "delegating_population_snapshot"
jbe@8 3179 SET "weight" = "sub_weight_v"
jbe@8 3180 WHERE "issue_id" = "issue_id_p"
jbe@8 3181 AND "event" = 'periodic'
jbe@8 3182 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3183 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3184 END IF;
jbe@0 3185 END LOOP;
jbe@0 3186 RETURN "weight_v";
jbe@0 3187 END;
jbe@0 3188 $$;
jbe@0 3189
jbe@0 3190 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@0 3191 ( "issue"."id"%TYPE,
jbe@0 3192 "member"."id"%TYPE,
jbe@0 3193 "delegating_population_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3194 IS 'Helper function for "create_population_snapshot" function';
jbe@0 3195
jbe@0 3196
jbe@0 3197 CREATE FUNCTION "create_population_snapshot"
jbe@0 3198 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3199 RETURNS VOID
jbe@0 3200 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3201 DECLARE
jbe@0 3202 "member_id_v" "member"."id"%TYPE;
jbe@0 3203 BEGIN
jbe@336 3204 PERFORM "require_transaction_isolation"();
jbe@0 3205 DELETE FROM "direct_population_snapshot"
jbe@0 3206 WHERE "issue_id" = "issue_id_p"
jbe@0 3207 AND "event" = 'periodic';
jbe@0 3208 DELETE FROM "delegating_population_snapshot"
jbe@0 3209 WHERE "issue_id" = "issue_id_p"
jbe@0 3210 AND "event" = 'periodic';
jbe@0 3211 INSERT INTO "direct_population_snapshot"
jbe@54 3212 ("issue_id", "event", "member_id")
jbe@54 3213 SELECT
jbe@54 3214 "issue_id_p" AS "issue_id",
jbe@54 3215 'periodic'::"snapshot_event" AS "event",
jbe@54 3216 "member"."id" AS "member_id"
jbe@54 3217 FROM "issue"
jbe@54 3218 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@54 3219 JOIN "membership" ON "area"."id" = "membership"."area_id"
jbe@54 3220 JOIN "member" ON "membership"."member_id" = "member"."id"
jbe@97 3221 JOIN "privilege"
jbe@97 3222 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3223 AND "privilege"."member_id" = "member"."id"
jbe@54 3224 WHERE "issue"."id" = "issue_id_p"
jbe@97 3225 AND "member"."active" AND "privilege"."voting_right"
jbe@54 3226 UNION
jbe@54 3227 SELECT
jbe@54 3228 "issue_id_p" AS "issue_id",
jbe@54 3229 'periodic'::"snapshot_event" AS "event",
jbe@54 3230 "member"."id" AS "member_id"
jbe@97 3231 FROM "issue"
jbe@97 3232 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3233 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3234 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3235 JOIN "privilege"
jbe@97 3236 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3237 AND "privilege"."member_id" = "member"."id"
jbe@97 3238 WHERE "issue"."id" = "issue_id_p"
jbe@97 3239 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3240 FOR "member_id_v" IN
jbe@0 3241 SELECT "member_id" FROM "direct_population_snapshot"
jbe@0 3242 WHERE "issue_id" = "issue_id_p"
jbe@0 3243 AND "event" = 'periodic'
jbe@0 3244 LOOP
jbe@0 3245 UPDATE "direct_population_snapshot" SET
jbe@0 3246 "weight" = 1 +
jbe@0 3247 "weight_of_added_delegations_for_population_snapshot"(
jbe@0 3248 "issue_id_p",
jbe@0 3249 "member_id_v",
jbe@0 3250 '{}'
jbe@0 3251 )
jbe@0 3252 WHERE "issue_id" = "issue_id_p"
jbe@0 3253 AND "event" = 'periodic'
jbe@0 3254 AND "member_id" = "member_id_v";
jbe@0 3255 END LOOP;
jbe@0 3256 RETURN;
jbe@0 3257 END;
jbe@0 3258 $$;
jbe@0 3259
jbe@0 3260 COMMENT ON FUNCTION "create_population_snapshot"
jbe@67 3261 ( "issue"."id"%TYPE )
jbe@0 3262 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 3263
jbe@0 3264
jbe@0 3265 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3266 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3267 "member_id_p" "member"."id"%TYPE,
jbe@0 3268 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3269 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@0 3270 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3271 DECLARE
jbe@0 3272 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3273 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@0 3274 "weight_v" INT4;
jbe@8 3275 "sub_weight_v" INT4;
jbe@0 3276 BEGIN
jbe@336 3277 PERFORM "require_transaction_isolation"();
jbe@0 3278 "weight_v" := 0;
jbe@0 3279 FOR "issue_delegation_row" IN
jbe@0 3280 SELECT * FROM "issue_delegation"
jbe@0 3281 WHERE "trustee_id" = "member_id_p"
jbe@0 3282 AND "issue_id" = "issue_id_p"
jbe@0 3283 LOOP
jbe@0 3284 IF NOT EXISTS (
jbe@0 3285 SELECT NULL FROM "direct_interest_snapshot"
jbe@0 3286 WHERE "issue_id" = "issue_id_p"
jbe@0 3287 AND "event" = 'periodic'
jbe@0 3288 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3289 ) AND NOT EXISTS (
jbe@0 3290 SELECT NULL FROM "delegating_interest_snapshot"
jbe@0 3291 WHERE "issue_id" = "issue_id_p"
jbe@0 3292 AND "event" = 'periodic'
jbe@0 3293 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3294 ) THEN
jbe@0 3295 "delegate_member_ids_v" :=
jbe@0 3296 "member_id_p" || "delegate_member_ids_p";
jbe@10 3297 INSERT INTO "delegating_interest_snapshot" (
jbe@10 3298 "issue_id",
jbe@10 3299 "event",
jbe@10 3300 "member_id",
jbe@10 3301 "scope",
jbe@10 3302 "delegate_member_ids"
jbe@10 3303 ) VALUES (
jbe@0 3304 "issue_id_p",
jbe@0 3305 'periodic',
jbe@0 3306 "issue_delegation_row"."truster_id",
jbe@10 3307 "issue_delegation_row"."scope",
jbe@0 3308 "delegate_member_ids_v"
jbe@0 3309 );
jbe@8 3310 "sub_weight_v" := 1 +
jbe@0 3311 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3312 "issue_id_p",
jbe@0 3313 "issue_delegation_row"."truster_id",
jbe@0 3314 "delegate_member_ids_v"
jbe@0 3315 );
jbe@8 3316 UPDATE "delegating_interest_snapshot"
jbe@8 3317 SET "weight" = "sub_weight_v"
jbe@8 3318 WHERE "issue_id" = "issue_id_p"
jbe@8 3319 AND "event" = 'periodic'
jbe@8 3320 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3321 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3322 END IF;
jbe@0 3323 END LOOP;
jbe@0 3324 RETURN "weight_v";
jbe@0 3325 END;
jbe@0 3326 $$;
jbe@0 3327
jbe@0 3328 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@0 3329 ( "issue"."id"%TYPE,
jbe@0 3330 "member"."id"%TYPE,
jbe@0 3331 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@0 3332 IS 'Helper function for "create_interest_snapshot" function';
jbe@0 3333
jbe@0 3334
jbe@0 3335 CREATE FUNCTION "create_interest_snapshot"
jbe@0 3336 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3337 RETURNS VOID
jbe@0 3338 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3339 DECLARE
jbe@0 3340 "member_id_v" "member"."id"%TYPE;
jbe@0 3341 BEGIN
jbe@336 3342 PERFORM "require_transaction_isolation"();
jbe@0 3343 DELETE FROM "direct_interest_snapshot"
jbe@0 3344 WHERE "issue_id" = "issue_id_p"
jbe@0 3345 AND "event" = 'periodic';
jbe@0 3346 DELETE FROM "delegating_interest_snapshot"
jbe@0 3347 WHERE "issue_id" = "issue_id_p"
jbe@0 3348 AND "event" = 'periodic';
jbe@0 3349 DELETE FROM "direct_supporter_snapshot"
jbe@325 3350 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 3351 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 3352 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 3353 AND "direct_supporter_snapshot"."event" = 'periodic';
jbe@0 3354 INSERT INTO "direct_interest_snapshot"
jbe@144 3355 ("issue_id", "event", "member_id")
jbe@0 3356 SELECT
jbe@0 3357 "issue_id_p" AS "issue_id",
jbe@0 3358 'periodic' AS "event",
jbe@144 3359 "member"."id" AS "member_id"
jbe@97 3360 FROM "issue"
jbe@97 3361 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@97 3362 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@97 3363 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@97 3364 JOIN "privilege"
jbe@97 3365 ON "privilege"."unit_id" = "area"."unit_id"
jbe@97 3366 AND "privilege"."member_id" = "member"."id"
jbe@97 3367 WHERE "issue"."id" = "issue_id_p"
jbe@97 3368 AND "member"."active" AND "privilege"."voting_right";
jbe@0 3369 FOR "member_id_v" IN
jbe@0 3370 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@0 3371 WHERE "issue_id" = "issue_id_p"
jbe@0 3372 AND "event" = 'periodic'
jbe@0 3373 LOOP
jbe@0 3374 UPDATE "direct_interest_snapshot" SET
jbe@0 3375 "weight" = 1 +
jbe@0 3376 "weight_of_added_delegations_for_interest_snapshot"(
jbe@0 3377 "issue_id_p",
jbe@0 3378 "member_id_v",
jbe@0 3379 '{}'
jbe@0 3380 )
jbe@0 3381 WHERE "issue_id" = "issue_id_p"
jbe@0 3382 AND "event" = 'periodic'
jbe@0 3383 AND "member_id" = "member_id_v";
jbe@0 3384 END LOOP;
jbe@0 3385 INSERT INTO "direct_supporter_snapshot"
jbe@0 3386 ( "issue_id", "initiative_id", "event", "member_id",
jbe@204 3387 "draft_id", "informed", "satisfied" )
jbe@0 3388 SELECT
jbe@96 3389 "issue_id_p" AS "issue_id",
jbe@96 3390 "initiative"."id" AS "initiative_id",
jbe@96 3391 'periodic' AS "event",
jbe@96 3392 "supporter"."member_id" AS "member_id",
jbe@204 3393 "supporter"."draft_id" AS "draft_id",
jbe@0 3394 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@0 3395 NOT EXISTS (
jbe@0 3396 SELECT NULL FROM "critical_opinion"
jbe@0 3397 WHERE "initiative_id" = "initiative"."id"
jbe@96 3398 AND "member_id" = "supporter"."member_id"
jbe@0 3399 ) AS "satisfied"
jbe@96 3400 FROM "initiative"
jbe@96 3401 JOIN "supporter"
jbe@0 3402 ON "supporter"."initiative_id" = "initiative"."id"
jbe@0 3403 JOIN "current_draft"
jbe@0 3404 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@0 3405 JOIN "direct_interest_snapshot"
jbe@96 3406 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@0 3407 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@3 3408 AND "event" = 'periodic'
jbe@96 3409 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@0 3410 RETURN;
jbe@0 3411 END;
jbe@0 3412 $$;
jbe@0 3413
jbe@0 3414 COMMENT ON FUNCTION "create_interest_snapshot"
jbe@0 3415 ( "issue"."id"%TYPE )
jbe@0 3416 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 3417
jbe@0 3418
jbe@0 3419 CREATE FUNCTION "create_snapshot"
jbe@0 3420 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3421 RETURNS VOID
jbe@0 3422 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3423 DECLARE
jbe@0 3424 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3425 "suggestion_id_v" "suggestion"."id"%TYPE;
jbe@0 3426 BEGIN
jbe@333 3427 PERFORM "require_transaction_isolation"();
jbe@0 3428 PERFORM "create_population_snapshot"("issue_id_p");
jbe@0 3429 PERFORM "create_interest_snapshot"("issue_id_p");
jbe@0 3430 UPDATE "issue" SET
jbe@331 3431 "snapshot" = coalesce("phase_finished", now()),
jbe@8 3432 "latest_snapshot_event" = 'periodic',
jbe@0 3433 "population" = (
jbe@0 3434 SELECT coalesce(sum("weight"), 0)
jbe@0 3435 FROM "direct_population_snapshot"
jbe@0 3436 WHERE "issue_id" = "issue_id_p"
jbe@0 3437 AND "event" = 'periodic'
jbe@0 3438 )
jbe@0 3439 WHERE "id" = "issue_id_p";
jbe@0 3440 FOR "initiative_id_v" IN
jbe@0 3441 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
jbe@0 3442 LOOP
jbe@0 3443 UPDATE "initiative" SET
jbe@0 3444 "supporter_count" = (
jbe@0 3445 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3446 FROM "direct_interest_snapshot" AS "di"
jbe@0 3447 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3448 ON "di"."member_id" = "ds"."member_id"
jbe@0 3449 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3450 AND "di"."event" = 'periodic'
jbe@0 3451 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3452 AND "ds"."event" = 'periodic'
jbe@0 3453 ),
jbe@0 3454 "informed_supporter_count" = (
jbe@0 3455 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3456 FROM "direct_interest_snapshot" AS "di"
jbe@0 3457 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3458 ON "di"."member_id" = "ds"."member_id"
jbe@0 3459 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3460 AND "di"."event" = 'periodic'
jbe@0 3461 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3462 AND "ds"."event" = 'periodic'
jbe@0 3463 AND "ds"."informed"
jbe@0 3464 ),
jbe@0 3465 "satisfied_supporter_count" = (
jbe@0 3466 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3467 FROM "direct_interest_snapshot" AS "di"
jbe@0 3468 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3469 ON "di"."member_id" = "ds"."member_id"
jbe@0 3470 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3471 AND "di"."event" = 'periodic'
jbe@0 3472 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3473 AND "ds"."event" = 'periodic'
jbe@0 3474 AND "ds"."satisfied"
jbe@0 3475 ),
jbe@0 3476 "satisfied_informed_supporter_count" = (
jbe@0 3477 SELECT coalesce(sum("di"."weight"), 0)
jbe@0 3478 FROM "direct_interest_snapshot" AS "di"
jbe@0 3479 JOIN "direct_supporter_snapshot" AS "ds"
jbe@0 3480 ON "di"."member_id" = "ds"."member_id"
jbe@0 3481 WHERE "di"."issue_id" = "issue_id_p"
jbe@0 3482 AND "di"."event" = 'periodic'
jbe@0 3483 AND "ds"."initiative_id" = "initiative_id_v"
jbe@0 3484 AND "ds"."event" = 'periodic'
jbe@0 3485 AND "ds"."informed"
jbe@0 3486 AND "ds"."satisfied"
jbe@0 3487 )
jbe@0 3488 WHERE "id" = "initiative_id_v";
jbe@0 3489 FOR "suggestion_id_v" IN
jbe@0 3490 SELECT "id" FROM "suggestion"
jbe@0 3491 WHERE "initiative_id" = "initiative_id_v"
jbe@0 3492 LOOP
jbe@0 3493 UPDATE "suggestion" SET
jbe@0 3494 "minus2_unfulfilled_count" = (
jbe@0 3495 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3496 FROM "issue" CROSS JOIN "opinion"
jbe@36 3497 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3498 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3499 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3500 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3501 WHERE "issue"."id" = "issue_id_p"
jbe@36 3502 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3503 AND "opinion"."degree" = -2
jbe@0 3504 AND "opinion"."fulfilled" = FALSE
jbe@0 3505 ),
jbe@0 3506 "minus2_fulfilled_count" = (
jbe@0 3507 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3508 FROM "issue" CROSS JOIN "opinion"
jbe@36 3509 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3510 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3511 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3512 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3513 WHERE "issue"."id" = "issue_id_p"
jbe@36 3514 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3515 AND "opinion"."degree" = -2
jbe@0 3516 AND "opinion"."fulfilled" = TRUE
jbe@0 3517 ),
jbe@0 3518 "minus1_unfulfilled_count" = (
jbe@0 3519 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3520 FROM "issue" CROSS JOIN "opinion"
jbe@36 3521 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3522 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3523 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3524 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3525 WHERE "issue"."id" = "issue_id_p"
jbe@36 3526 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3527 AND "opinion"."degree" = -1
jbe@0 3528 AND "opinion"."fulfilled" = FALSE
jbe@0 3529 ),
jbe@0 3530 "minus1_fulfilled_count" = (
jbe@0 3531 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3532 FROM "issue" CROSS JOIN "opinion"
jbe@36 3533 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3534 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3535 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3536 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3537 WHERE "issue"."id" = "issue_id_p"
jbe@36 3538 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3539 AND "opinion"."degree" = -1
jbe@0 3540 AND "opinion"."fulfilled" = TRUE
jbe@0 3541 ),
jbe@0 3542 "plus1_unfulfilled_count" = (
jbe@0 3543 SELECT coalesce(sum("snapshot"."weight"), 0)
jbe@36 3544 FROM "issue" CROSS JOIN "opinion"
jbe@36 3545 JOIN "direct_interest_snapshot" AS "snapshot"
jbe@36 3546 ON "snapshot"."issue_id" = "issue"."id"
jbe@36 3547 AND "snapshot"."event" = "issue"."latest_snapshot_event"
jbe@36 3548 AND "snapshot"."member_id" = "opinion"."member_id"
jbe@36 3549 WHERE "issue"."id" = "issue_id_p"
jbe@36 3550 AND "opinion"."suggestion_id" = "suggestion_id_v"
jbe@0 3551 AND "opinion"."degree" = 1
jbe@0 3552 AND "opinion"."fulfilled" = FALSE
jbe@0 3553 ),
jbe@0 3554 "plus1_fulfilled_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" = 1
jbe@0 3564 AND "opinion"."fulfilled" = TRUE
jbe@0 3565 ),
jbe@0 3566 "plus2_unfulfilled_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" = FALSE
jbe@0 3577 ),
jbe@0 3578 "plus2_fulfilled_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" = 2
jbe@0 3588 AND "opinion"."fulfilled" = TRUE
jbe@0 3589 )
jbe@0 3590 WHERE "suggestion"."id" = "suggestion_id_v";
jbe@0 3591 END LOOP;
jbe@0 3592 END LOOP;
jbe@0 3593 RETURN;
jbe@0 3594 END;
jbe@0 3595 $$;
jbe@0 3596
jbe@0 3597 COMMENT ON FUNCTION "create_snapshot"
jbe@0 3598 ( "issue"."id"%TYPE )
jbe@0 3599 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 3600
jbe@0 3601
jbe@0 3602 CREATE FUNCTION "set_snapshot_event"
jbe@0 3603 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3604 "event_p" "snapshot_event" )
jbe@0 3605 RETURNS VOID
jbe@0 3606 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@21 3607 DECLARE
jbe@21 3608 "event_v" "issue"."latest_snapshot_event"%TYPE;
jbe@0 3609 BEGIN
jbe@333 3610 PERFORM "require_transaction_isolation"();
jbe@21 3611 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue"
jbe@21 3612 WHERE "id" = "issue_id_p" FOR UPDATE;
jbe@8 3613 UPDATE "issue" SET "latest_snapshot_event" = "event_p"
jbe@8 3614 WHERE "id" = "issue_id_p";
jbe@3 3615 UPDATE "direct_population_snapshot" SET "event" = "event_p"
jbe@21 3616 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3617 UPDATE "delegating_population_snapshot" SET "event" = "event_p"
jbe@21 3618 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3619 UPDATE "direct_interest_snapshot" SET "event" = "event_p"
jbe@21 3620 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3621 UPDATE "delegating_interest_snapshot" SET "event" = "event_p"
jbe@21 3622 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v";
jbe@3 3623 UPDATE "direct_supporter_snapshot" SET "event" = "event_p"
jbe@325 3624 FROM "initiative" -- NOTE: due to missing index on issue_id
jbe@325 3625 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 3626 AND "direct_supporter_snapshot"."initiative_id" = "initiative"."id"
jbe@325 3627 AND "direct_supporter_snapshot"."event" = "event_v";
jbe@0 3628 RETURN;
jbe@0 3629 END;
jbe@0 3630 $$;
jbe@0 3631
jbe@0 3632 COMMENT ON FUNCTION "set_snapshot_event"
jbe@0 3633 ( "issue"."id"%TYPE,
jbe@0 3634 "snapshot_event" )
jbe@0 3635 IS 'Change "event" attribute of the previous ''periodic'' snapshot';
jbe@0 3636
jbe@0 3637
jbe@0 3638
jbe@0 3639 -----------------------
jbe@0 3640 -- Counting of votes --
jbe@0 3641 -----------------------
jbe@0 3642
jbe@0 3643
jbe@5 3644 CREATE FUNCTION "weight_of_added_vote_delegations"
jbe@0 3645 ( "issue_id_p" "issue"."id"%TYPE,
jbe@0 3646 "member_id_p" "member"."id"%TYPE,
jbe@0 3647 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3648 RETURNS "direct_voter"."weight"%TYPE
jbe@0 3649 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3650 DECLARE
jbe@0 3651 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@0 3652 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
jbe@0 3653 "weight_v" INT4;
jbe@8 3654 "sub_weight_v" INT4;
jbe@0 3655 BEGIN
jbe@336 3656 PERFORM "require_transaction_isolation"();
jbe@0 3657 "weight_v" := 0;
jbe@0 3658 FOR "issue_delegation_row" IN
jbe@0 3659 SELECT * FROM "issue_delegation"
jbe@0 3660 WHERE "trustee_id" = "member_id_p"
jbe@0 3661 AND "issue_id" = "issue_id_p"
jbe@0 3662 LOOP
jbe@0 3663 IF NOT EXISTS (
jbe@0 3664 SELECT NULL FROM "direct_voter"
jbe@0 3665 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3666 AND "issue_id" = "issue_id_p"
jbe@0 3667 ) AND NOT EXISTS (
jbe@0 3668 SELECT NULL FROM "delegating_voter"
jbe@0 3669 WHERE "member_id" = "issue_delegation_row"."truster_id"
jbe@0 3670 AND "issue_id" = "issue_id_p"
jbe@0 3671 ) THEN
jbe@0 3672 "delegate_member_ids_v" :=
jbe@0 3673 "member_id_p" || "delegate_member_ids_p";
jbe@10 3674 INSERT INTO "delegating_voter" (
jbe@10 3675 "issue_id",
jbe@10 3676 "member_id",
jbe@10 3677 "scope",
jbe@10 3678 "delegate_member_ids"
jbe@10 3679 ) VALUES (
jbe@5 3680 "issue_id_p",
jbe@5 3681 "issue_delegation_row"."truster_id",
jbe@10 3682 "issue_delegation_row"."scope",
jbe@5 3683 "delegate_member_ids_v"
jbe@5 3684 );
jbe@8 3685 "sub_weight_v" := 1 +
jbe@8 3686 "weight_of_added_vote_delegations"(
jbe@8 3687 "issue_id_p",
jbe@8 3688 "issue_delegation_row"."truster_id",
jbe@8 3689 "delegate_member_ids_v"
jbe@8 3690 );
jbe@8 3691 UPDATE "delegating_voter"
jbe@8 3692 SET "weight" = "sub_weight_v"
jbe@8 3693 WHERE "issue_id" = "issue_id_p"
jbe@8 3694 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@8 3695 "weight_v" := "weight_v" + "sub_weight_v";
jbe@0 3696 END IF;
jbe@0 3697 END LOOP;
jbe@0 3698 RETURN "weight_v";
jbe@0 3699 END;
jbe@0 3700 $$;
jbe@0 3701
jbe@5 3702 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
jbe@0 3703 ( "issue"."id"%TYPE,
jbe@0 3704 "member"."id"%TYPE,
jbe@0 3705 "delegating_voter"."delegate_member_ids"%TYPE )
jbe@0 3706 IS 'Helper function for "add_vote_delegations" function';
jbe@0 3707
jbe@0 3708
jbe@0 3709 CREATE FUNCTION "add_vote_delegations"
jbe@0 3710 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3711 RETURNS VOID
jbe@0 3712 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3713 DECLARE
jbe@0 3714 "member_id_v" "member"."id"%TYPE;
jbe@0 3715 BEGIN
jbe@336 3716 PERFORM "require_transaction_isolation"();
jbe@0 3717 FOR "member_id_v" IN
jbe@0 3718 SELECT "member_id" FROM "direct_voter"
jbe@0 3719 WHERE "issue_id" = "issue_id_p"
jbe@0 3720 LOOP
jbe@0 3721 UPDATE "direct_voter" SET
jbe@5 3722 "weight" = "weight" + "weight_of_added_vote_delegations"(
jbe@0 3723 "issue_id_p",
jbe@0 3724 "member_id_v",
jbe@0 3725 '{}'
jbe@0 3726 )
jbe@0 3727 WHERE "member_id" = "member_id_v"
jbe@0 3728 AND "issue_id" = "issue_id_p";
jbe@0 3729 END LOOP;
jbe@0 3730 RETURN;
jbe@0 3731 END;
jbe@0 3732 $$;
jbe@0 3733
jbe@0 3734 COMMENT ON FUNCTION "add_vote_delegations"
jbe@0 3735 ( "issue_id_p" "issue"."id"%TYPE )
jbe@0 3736 IS 'Helper function for "close_voting" function';
jbe@0 3737
jbe@0 3738
jbe@0 3739 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3740 RETURNS VOID
jbe@0 3741 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3742 DECLARE
jbe@97 3743 "area_id_v" "area"."id"%TYPE;
jbe@97 3744 "unit_id_v" "unit"."id"%TYPE;
jbe@0 3745 "member_id_v" "member"."id"%TYPE;
jbe@0 3746 BEGIN
jbe@333 3747 PERFORM "require_transaction_isolation"();
jbe@129 3748 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
jbe@129 3749 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
jbe@383 3750 -- override protection triggers:
jbe@385 3751 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 3752 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@285 3753 -- delete timestamp of voting comment:
jbe@285 3754 UPDATE "direct_voter" SET "comment_changed" = NULL
jbe@285 3755 WHERE "issue_id" = "issue_id_p";
jbe@169 3756 -- delete delegating votes (in cases of manual reset of issue state):
jbe@0 3757 DELETE FROM "delegating_voter"
jbe@0 3758 WHERE "issue_id" = "issue_id_p";
jbe@169 3759 -- delete votes from non-privileged voters:
jbe@97 3760 DELETE FROM "direct_voter"
jbe@97 3761 USING (
jbe@97 3762 SELECT
jbe@97 3763 "direct_voter"."member_id"
jbe@97 3764 FROM "direct_voter"
jbe@97 3765 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
jbe@97 3766 LEFT JOIN "privilege"
jbe@97 3767 ON "privilege"."unit_id" = "unit_id_v"
jbe@97 3768 AND "privilege"."member_id" = "direct_voter"."member_id"
jbe@97 3769 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
jbe@97 3770 "member"."active" = FALSE OR
jbe@97 3771 "privilege"."voting_right" ISNULL OR
jbe@97 3772 "privilege"."voting_right" = FALSE
jbe@97 3773 )
jbe@97 3774 ) AS "subquery"
jbe@97 3775 WHERE "direct_voter"."issue_id" = "issue_id_p"
jbe@97 3776 AND "direct_voter"."member_id" = "subquery"."member_id";
jbe@169 3777 -- consider delegations:
jbe@0 3778 UPDATE "direct_voter" SET "weight" = 1
jbe@0 3779 WHERE "issue_id" = "issue_id_p";
jbe@0 3780 PERFORM "add_vote_delegations"("issue_id_p");
jbe@414 3781 -- mark first preferences:
jbe@414 3782 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
jbe@414 3783 FROM (
jbe@414 3784 SELECT
jbe@414 3785 "vote"."initiative_id",
jbe@414 3786 "vote"."member_id",
jbe@414 3787 CASE WHEN "vote"."grade" > 0 THEN
jbe@414 3788 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
jbe@414 3789 ELSE NULL
jbe@414 3790 END AS "first_preference"
jbe@415 3791 FROM "vote"
jbe@415 3792 JOIN "initiative" -- NOTE: due to missing index on issue_id
jbe@415 3793 ON "vote"."issue_id" = "initiative"."issue_id"
jbe@415 3794 JOIN "vote" AS "agg"
jbe@415 3795 ON "initiative"."id" = "agg"."initiative_id"
jbe@415 3796 AND "vote"."member_id" = "agg"."member_id"
jbe@433 3797 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
jbe@414 3798 ) AS "subquery"
jbe@414 3799 WHERE "vote"."issue_id" = "issue_id_p"
jbe@414 3800 AND "vote"."initiative_id" = "subquery"."initiative_id"
jbe@414 3801 AND "vote"."member_id" = "subquery"."member_id";
jbe@385 3802 -- finish overriding protection triggers (avoids garbage):
jbe@385 3803 DELETE FROM "temporary_transaction_data"
jbe@385 3804 WHERE "key" = 'override_protection_triggers';
jbe@137 3805 -- materialize battle_view:
jbe@61 3806 -- NOTE: "closed" column of issue must be set at this point
jbe@61 3807 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@61 3808 INSERT INTO "battle" (
jbe@61 3809 "issue_id",
jbe@61 3810 "winning_initiative_id", "losing_initiative_id",
jbe@61 3811 "count"
jbe@61 3812 ) SELECT
jbe@61 3813 "issue_id",
jbe@61 3814 "winning_initiative_id", "losing_initiative_id",
jbe@61 3815 "count"
jbe@61 3816 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
jbe@331 3817 -- set voter count:
jbe@331 3818 UPDATE "issue" SET
jbe@331 3819 "voter_count" = (
jbe@331 3820 SELECT coalesce(sum("weight"), 0)
jbe@331 3821 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
jbe@331 3822 )
jbe@331 3823 WHERE "id" = "issue_id_p";
jbe@437 3824 -- copy "positive_votes" and "negative_votes" from "battle" table:
jbe@437 3825 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
jbe@437 3826 UPDATE "initiative" SET
jbe@437 3827 "first_preference_votes" = 0,
jbe@437 3828 "positive_votes" = "battle_win"."count",
jbe@437 3829 "negative_votes" = "battle_lose"."count"
jbe@437 3830 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
jbe@437 3831 WHERE
jbe@437 3832 "battle_win"."issue_id" = "issue_id_p" AND
jbe@437 3833 "battle_win"."winning_initiative_id" = "initiative"."id" AND
jbe@437 3834 "battle_win"."losing_initiative_id" ISNULL AND
jbe@437 3835 "battle_lose"."issue_id" = "issue_id_p" AND
jbe@437 3836 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
jbe@437 3837 "battle_lose"."winning_initiative_id" ISNULL;
jbe@414 3838 -- calculate "first_preference_votes":
jbe@437 3839 -- NOTE: will only set values not equal to zero
jbe@437 3840 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
jbe@414 3841 FROM (
jbe@414 3842 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
jbe@414 3843 FROM "vote" JOIN "direct_voter"
jbe@414 3844 ON "vote"."issue_id" = "direct_voter"."issue_id"
jbe@414 3845 AND "vote"."member_id" = "direct_voter"."member_id"
jbe@414 3846 WHERE "vote"."first_preference"
jbe@414 3847 GROUP BY "vote"."initiative_id"
jbe@414 3848 ) AS "subquery"
jbe@414 3849 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@414 3850 AND "initiative"."admitted"
jbe@414 3851 AND "initiative"."id" = "subquery"."initiative_id";
jbe@0 3852 END;
jbe@0 3853 $$;
jbe@0 3854
jbe@0 3855 COMMENT ON FUNCTION "close_voting"
jbe@0 3856 ( "issue"."id"%TYPE )
jbe@0 3857 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 3858
jbe@0 3859
jbe@30 3860 CREATE FUNCTION "defeat_strength"
jbe@424 3861 ( "positive_votes_p" INT4,
jbe@424 3862 "negative_votes_p" INT4,
jbe@424 3863 "defeat_strength_p" "defeat_strength" )
jbe@30 3864 RETURNS INT8
jbe@30 3865 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@30 3866 BEGIN
jbe@424 3867 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
jbe@424 3868 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 3869 RETURN "positive_votes_p";
jbe@424 3870 ELSE
jbe@424 3871 RETURN 0;
jbe@424 3872 END IF;
jbe@30 3873 ELSE
jbe@424 3874 IF "positive_votes_p" > "negative_votes_p" THEN
jbe@424 3875 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
jbe@424 3876 ELSIF "positive_votes_p" = "negative_votes_p" THEN
jbe@424 3877 RETURN 0;
jbe@424 3878 ELSE
jbe@424 3879 RETURN -1;
jbe@424 3880 END IF;
jbe@30 3881 END IF;
jbe@30 3882 END;
jbe@30 3883 $$;
jbe@30 3884
jbe@425 3885 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 3886
jbe@30 3887
jbe@423 3888 CREATE FUNCTION "secondary_link_strength"
jbe@426 3889 ( "initiative1_ord_p" INT4,
jbe@426 3890 "initiative2_ord_p" INT4,
jbe@424 3891 "tie_breaking_p" "tie_breaking" )
jbe@423 3892 RETURNS INT8
jbe@423 3893 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@423 3894 BEGIN
jbe@426 3895 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
jbe@423 3896 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
jbe@423 3897 END IF;
jbe@423 3898 RETURN (
jbe@426 3899 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
jbe@426 3900 0
jbe@424 3901 ELSE
jbe@426 3902 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
jbe@426 3903 1::INT8 << 62
jbe@426 3904 ELSE 0 END
jbe@426 3905 +
jbe@426 3906 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
jbe@426 3907 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
jbe@426 3908 ELSE
jbe@426 3909 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
jbe@426 3910 END
jbe@424 3911 END
jbe@423 3912 );
jbe@423 3913 END;
jbe@423 3914 $$;
jbe@423 3915
jbe@424 3916 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 3917
jbe@423 3918
jbe@426 3919 CREATE TYPE "link_strength" AS (
jbe@426 3920 "primary" INT8,
jbe@426 3921 "secondary" INT8 );
jbe@426 3922
jbe@428 3923 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 3924
jbe@427 3925
jbe@427 3926 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
jbe@427 3927 RETURNS "link_strength"[][]
jbe@427 3928 LANGUAGE 'plpgsql' IMMUTABLE AS $$
jbe@427 3929 DECLARE
jbe@427 3930 "dimension_v" INT4;
jbe@427 3931 "matrix_p" "link_strength"[][];
jbe@427 3932 "i" INT4;
jbe@427 3933 "j" INT4;
jbe@427 3934 "k" INT4;
jbe@427 3935 BEGIN
jbe@427 3936 "dimension_v" := array_upper("matrix_d", 1);
jbe@427 3937 "matrix_p" := "matrix_d";
jbe@427 3938 "i" := 1;
jbe@427 3939 LOOP
jbe@427 3940 "j" := 1;
jbe@427 3941 LOOP
jbe@427 3942 IF "i" != "j" THEN
jbe@427 3943 "k" := 1;
jbe@427 3944 LOOP
jbe@427 3945 IF "i" != "k" AND "j" != "k" THEN
jbe@427 3946 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
jbe@427 3947 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
jbe@427 3948 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
jbe@427 3949 END IF;
jbe@427 3950 ELSE
jbe@427 3951 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
jbe@427 3952 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
jbe@427 3953 END IF;
jbe@427 3954 END IF;
jbe@427 3955 END IF;
jbe@427 3956 EXIT WHEN "k" = "dimension_v";
jbe@427 3957 "k" := "k" + 1;
jbe@427 3958 END LOOP;
jbe@427 3959 END IF;
jbe@427 3960 EXIT WHEN "j" = "dimension_v";
jbe@427 3961 "j" := "j" + 1;
jbe@427 3962 END LOOP;
jbe@427 3963 EXIT WHEN "i" = "dimension_v";
jbe@427 3964 "i" := "i" + 1;
jbe@427 3965 END LOOP;
jbe@427 3966 RETURN "matrix_p";
jbe@427 3967 END;
jbe@427 3968 $$;
jbe@427 3969
jbe@428 3970 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
jbe@426 3971
jbe@426 3972
jbe@0 3973 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
jbe@0 3974 RETURNS VOID
jbe@0 3975 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 3976 DECLARE
jbe@427 3977 "issue_row" "issue"%ROWTYPE;
jbe@427 3978 "policy_row" "policy"%ROWTYPE;
jbe@427 3979 "dimension_v" INT4;
jbe@427 3980 "matrix_a" INT4[][]; -- absolute votes
jbe@427 3981 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
jbe@427 3982 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
jbe@427 3983 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
jbe@427 3984 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
jbe@427 3985 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
jbe@427 3986 "i" INT4;
jbe@427 3987 "j" INT4;
jbe@427 3988 "m" INT4;
jbe@427 3989 "n" INT4;
jbe@427 3990 "battle_row" "battle"%ROWTYPE;
jbe@427 3991 "rank_ary" INT4[];
jbe@427 3992 "rank_v" INT4;
jbe@427 3993 "initiative_id_v" "initiative"."id"%TYPE;
jbe@0 3994 BEGIN
jbe@333 3995 PERFORM "require_transaction_isolation"();
jbe@155 3996 SELECT * INTO "issue_row"
jbe@331 3997 FROM "issue" WHERE "id" = "issue_id_p";
jbe@155 3998 SELECT * INTO "policy_row"
jbe@155 3999 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@126 4000 SELECT count(1) INTO "dimension_v"
jbe@126 4001 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
jbe@428 4002 -- create "matrix_a" with absolute number of votes in pairwise
jbe@170 4003 -- comparison:
jbe@427 4004 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4005 "i" := 1;
jbe@170 4006 "j" := 2;
jbe@170 4007 FOR "battle_row" IN
jbe@170 4008 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
jbe@170 4009 ORDER BY
jbe@411 4010 "winning_initiative_id" NULLS FIRST,
jbe@411 4011 "losing_initiative_id" NULLS FIRST
jbe@170 4012 LOOP
jbe@427 4013 "matrix_a"["i"]["j"] := "battle_row"."count";
jbe@170 4014 IF "j" = "dimension_v" THEN
jbe@170 4015 "i" := "i" + 1;
jbe@170 4016 "j" := 1;
jbe@170 4017 ELSE
jbe@170 4018 "j" := "j" + 1;
jbe@170 4019 IF "j" = "i" THEN
jbe@170 4020 "j" := "j" + 1;
jbe@170 4021 END IF;
jbe@170 4022 END IF;
jbe@170 4023 END LOOP;
jbe@170 4024 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
jbe@170 4025 RAISE EXCEPTION 'Wrong battle count (should not happen)';
jbe@170 4026 END IF;
jbe@428 4027 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
jbe@427 4028 -- and "secondary_link_strength" functions:
jbe@427 4029 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4030 "i" := 1;
jbe@170 4031 LOOP
jbe@170 4032 "j" := 1;
jbe@0 4033 LOOP
jbe@170 4034 IF "i" != "j" THEN
jbe@427 4035 "matrix_d"["i"]["j"] := (
jbe@426 4036 "defeat_strength"(
jbe@427 4037 "matrix_a"["i"]["j"],
jbe@427 4038 "matrix_a"["j"]["i"],
jbe@426 4039 "policy_row"."defeat_strength"
jbe@426 4040 ),
jbe@426 4041 "secondary_link_strength"(
jbe@426 4042 "i",
jbe@426 4043 "j",
jbe@426 4044 "policy_row"."tie_breaking"
jbe@426 4045 )
jbe@426 4046 )::"link_strength";
jbe@0 4047 END IF;
jbe@170 4048 EXIT WHEN "j" = "dimension_v";
jbe@170 4049 "j" := "j" + 1;
jbe@0 4050 END LOOP;
jbe@170 4051 EXIT WHEN "i" = "dimension_v";
jbe@170 4052 "i" := "i" + 1;
jbe@170 4053 END LOOP;
jbe@428 4054 -- find best paths:
jbe@427 4055 "matrix_p" := "find_best_paths"("matrix_d");
jbe@428 4056 -- create partial order:
jbe@427 4057 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
jbe@170 4058 "i" := 1;
jbe@170 4059 LOOP
jbe@427 4060 "j" := "i" + 1;
jbe@170 4061 LOOP
jbe@170 4062 IF "i" != "j" THEN
jbe@427 4063 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
jbe@427 4064 "matrix_b"["i"]["j"] := TRUE;
jbe@427 4065 "matrix_b"["j"]["i"] := FALSE;
jbe@427 4066 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
jbe@427 4067 "matrix_b"["i"]["j"] := FALSE;
jbe@427 4068 "matrix_b"["j"]["i"] := TRUE;
jbe@427 4069 END IF;
jbe@170 4070 END IF;
jbe@170 4071 EXIT WHEN "j" = "dimension_v";
jbe@170 4072 "j" := "j" + 1;
jbe@170 4073 END LOOP;
jbe@427 4074 EXIT WHEN "i" = "dimension_v" - 1;
jbe@170 4075 "i" := "i" + 1;
jbe@170 4076 END LOOP;
jbe@428 4077 -- tie-breaking by forbidding shared weakest links in beat-paths
jbe@428 4078 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
jbe@428 4079 -- is performed later by initiative id):
jbe@427 4080 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
jbe@427 4081 "m" := 1;
jbe@427 4082 LOOP
jbe@427 4083 "n" := "m" + 1;
jbe@427 4084 LOOP
jbe@428 4085 -- only process those candidates m and n, which are tied:
jbe@427 4086 IF "matrix_b"["m"]["n"] ISNULL THEN
jbe@428 4087 -- start with beat-paths prior tie-breaking:
jbe@427 4088 "matrix_t" := "matrix_p";
jbe@428 4089 -- start with all links allowed:
jbe@427 4090 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
jbe@427 4091 LOOP
jbe@428 4092 -- determine (and forbid) that link that is the weakest link
jbe@428 4093 -- in both the best path from candidate m to candidate n and
jbe@428 4094 -- from candidate n to candidate m:
jbe@427 4095 "i" := 1;
jbe@427 4096 <<forbid_one_link>>
jbe@427 4097 LOOP
jbe@427 4098 "j" := 1;
jbe@427 4099 LOOP
jbe@427 4100 IF "i" != "j" THEN
jbe@427 4101 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
jbe@427 4102 "matrix_f"["i"]["j"] := TRUE;
jbe@427 4103 -- exit for performance reasons,
jbe@428 4104 -- as exactly one link will be found:
jbe@427 4105 EXIT forbid_one_link;
jbe@427 4106 END IF;
jbe@427 4107 END IF;
jbe@427 4108 EXIT WHEN "j" = "dimension_v";
jbe@427 4109 "j" := "j" + 1;
jbe@427 4110 END LOOP;
jbe@427 4111 IF "i" = "dimension_v" THEN
jbe@428 4112 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
jbe@427 4113 END IF;
jbe@427 4114 "i" := "i" + 1;
jbe@427 4115 END LOOP;
jbe@428 4116 -- calculate best beat-paths while ignoring forbidden links:
jbe@427 4117 "i" := 1;
jbe@427 4118 LOOP
jbe@427 4119 "j" := 1;
jbe@427 4120 LOOP
jbe@427 4121 IF "i" != "j" THEN
jbe@427 4122 "matrix_t"["i"]["j"] := CASE
jbe@427 4123 WHEN "matrix_f"["i"]["j"]
jbe@431 4124 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
jbe@427 4125 ELSE "matrix_d"["i"]["j"] END;
jbe@427 4126 END IF;
jbe@427 4127 EXIT WHEN "j" = "dimension_v";
jbe@427 4128 "j" := "j" + 1;
jbe@427 4129 END LOOP;
jbe@427 4130 EXIT WHEN "i" = "dimension_v";
jbe@427 4131 "i" := "i" + 1;
jbe@427 4132 END LOOP;
jbe@427 4133 "matrix_t" := "find_best_paths"("matrix_t");
jbe@428 4134 -- extend partial order, if tie-breaking was successful:
jbe@427 4135 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
jbe@427 4136 "matrix_b"["m"]["n"] := TRUE;
jbe@427 4137 "matrix_b"["n"]["m"] := FALSE;
jbe@427 4138 EXIT;
jbe@427 4139 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
jbe@427 4140 "matrix_b"["m"]["n"] := FALSE;
jbe@427 4141 "matrix_b"["n"]["m"] := TRUE;
jbe@427 4142 EXIT;
jbe@427 4143 END IF;
jbe@427 4144 END LOOP;
jbe@427 4145 END IF;
jbe@427 4146 EXIT WHEN "n" = "dimension_v";
jbe@427 4147 "n" := "n" + 1;
jbe@427 4148 END LOOP;
jbe@427 4149 EXIT WHEN "m" = "dimension_v" - 1;
jbe@427 4150 "m" := "m" + 1;
jbe@427 4151 END LOOP;
jbe@427 4152 END IF;
jbe@428 4153 -- store a unique ranking in "rank_ary":
jbe@170 4154 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
jbe@170 4155 "rank_v" := 1;
jbe@170 4156 LOOP
jbe@0 4157 "i" := 1;
jbe@428 4158 <<assign_next_rank>>
jbe@0 4159 LOOP
jbe@170 4160 IF "rank_ary"["i"] ISNULL THEN
jbe@170 4161 "j" := 1;
jbe@170 4162 LOOP
jbe@170 4163 IF
jbe@170 4164 "i" != "j" AND
jbe@170 4165 "rank_ary"["j"] ISNULL AND
jbe@427 4166 ( "matrix_b"["j"]["i"] OR
jbe@411 4167 -- tie-breaking by "id"
jbe@427 4168 ( "matrix_b"["j"]["i"] ISNULL AND
jbe@411 4169 "j" < "i" ) )
jbe@170 4170 THEN
jbe@170 4171 -- someone else is better
jbe@170 4172 EXIT;
jbe@170 4173 END IF;
jbe@428 4174 IF "j" = "dimension_v" THEN
jbe@170 4175 -- noone is better
jbe@411 4176 "rank_ary"["i"] := "rank_v";
jbe@428 4177 EXIT assign_next_rank;
jbe@170 4178 END IF;
jbe@428 4179 "j" := "j" + 1;
jbe@170 4180 END LOOP;
jbe@170 4181 END IF;
jbe@0 4182 "i" := "i" + 1;
jbe@411 4183 IF "i" > "dimension_v" THEN
jbe@411 4184 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
jbe@411 4185 END IF;
jbe@0 4186 END LOOP;
jbe@411 4187 EXIT WHEN "rank_v" = "dimension_v";
jbe@170 4188 "rank_v" := "rank_v" + 1;
jbe@170 4189 END LOOP;
jbe@170 4190 -- write preliminary results:
jbe@411 4191 "i" := 2; -- omit status quo with "i" = 1
jbe@170 4192 FOR "initiative_id_v" IN
jbe@170 4193 SELECT "id" FROM "initiative"
jbe@170 4194 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@170 4195 ORDER BY "id"
jbe@170 4196 LOOP
jbe@170 4197 UPDATE "initiative" SET
jbe@170 4198 "direct_majority" =
jbe@170 4199 CASE WHEN "policy_row"."direct_majority_strict" THEN
jbe@170 4200 "positive_votes" * "policy_row"."direct_majority_den" >
jbe@170 4201 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4202 ELSE
jbe@170 4203 "positive_votes" * "policy_row"."direct_majority_den" >=
jbe@170 4204 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4205 END
jbe@170 4206 AND "positive_votes" >= "policy_row"."direct_majority_positive"
jbe@170 4207 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4208 "policy_row"."direct_majority_non_negative",
jbe@170 4209 "indirect_majority" =
jbe@170 4210 CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4211 "positive_votes" * "policy_row"."indirect_majority_den" >
jbe@170 4212 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4213 ELSE
jbe@170 4214 "positive_votes" * "policy_row"."indirect_majority_den" >=
jbe@170 4215 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
jbe@170 4216 END
jbe@170 4217 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
jbe@170 4218 AND "issue_row"."voter_count"-"negative_votes" >=
jbe@170 4219 "policy_row"."indirect_majority_non_negative",
jbe@171 4220 "schulze_rank" = "rank_ary"["i"],
jbe@411 4221 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
jbe@411 4222 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
jbe@411 4223 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
jbe@429 4224 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
jbe@429 4225 THEN NULL
jbe@429 4226 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
jbe@216 4227 "eligible" = FALSE,
jbe@250 4228 "winner" = FALSE,
jbe@250 4229 "rank" = NULL -- NOTE: in cases of manual reset of issue state
jbe@170 4230 WHERE "id" = "initiative_id_v";
jbe@170 4231 "i" := "i" + 1;
jbe@170 4232 END LOOP;
jbe@411 4233 IF "i" != "dimension_v" + 1 THEN
jbe@170 4234 RAISE EXCEPTION 'Wrong winner count (should not happen)';
jbe@0 4235 END IF;
jbe@170 4236 -- take indirect majorities into account:
jbe@170 4237 LOOP
jbe@170 4238 UPDATE "initiative" SET "indirect_majority" = TRUE
jbe@139 4239 FROM (
jbe@170 4240 SELECT "new_initiative"."id" AS "initiative_id"
jbe@170 4241 FROM "initiative" "old_initiative"
jbe@170 4242 JOIN "initiative" "new_initiative"
jbe@170 4243 ON "new_initiative"."issue_id" = "issue_id_p"
jbe@170 4244 AND "new_initiative"."indirect_majority" = FALSE
jbe@139 4245 JOIN "battle" "battle_win"
jbe@139 4246 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4247 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
jbe@170 4248 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
jbe@139 4249 JOIN "battle" "battle_lose"
jbe@139 4250 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4251 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
jbe@170 4252 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
jbe@170 4253 WHERE "old_initiative"."issue_id" = "issue_id_p"
jbe@170 4254 AND "old_initiative"."indirect_majority" = TRUE
jbe@170 4255 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
jbe@170 4256 "battle_win"."count" * "policy_row"."indirect_majority_den" >
jbe@170 4257 "policy_row"."indirect_majority_num" *
jbe@170 4258 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4259 ELSE
jbe@170 4260 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
jbe@170 4261 "policy_row"."indirect_majority_num" *
jbe@170 4262 ("battle_win"."count"+"battle_lose"."count")
jbe@170 4263 END
jbe@170 4264 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
jbe@170 4265 AND "issue_row"."voter_count"-"battle_lose"."count" >=
jbe@170 4266 "policy_row"."indirect_majority_non_negative"
jbe@139 4267 ) AS "subquery"
jbe@139 4268 WHERE "id" = "subquery"."initiative_id";
jbe@170 4269 EXIT WHEN NOT FOUND;
jbe@170 4270 END LOOP;
jbe@170 4271 -- set "multistage_majority" for remaining matching initiatives:
jbe@216 4272 UPDATE "initiative" SET "multistage_majority" = TRUE
jbe@170 4273 FROM (
jbe@170 4274 SELECT "losing_initiative"."id" AS "initiative_id"
jbe@170 4275 FROM "initiative" "losing_initiative"
jbe@170 4276 JOIN "initiative" "winning_initiative"
jbe@170 4277 ON "winning_initiative"."issue_id" = "issue_id_p"
jbe@170 4278 AND "winning_initiative"."admitted"
jbe@170 4279 JOIN "battle" "battle_win"
jbe@170 4280 ON "battle_win"."issue_id" = "issue_id_p"
jbe@170 4281 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
jbe@170 4282 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
jbe@170 4283 JOIN "battle" "battle_lose"
jbe@170 4284 ON "battle_lose"."issue_id" = "issue_id_p"
jbe@170 4285 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
jbe@170 4286 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
jbe@170 4287 WHERE "losing_initiative"."issue_id" = "issue_id_p"
jbe@170 4288 AND "losing_initiative"."admitted"
jbe@170 4289 AND "winning_initiative"."schulze_rank" <
jbe@170 4290 "losing_initiative"."schulze_rank"
jbe@170 4291 AND "battle_win"."count" > "battle_lose"."count"
jbe@170 4292 AND (
jbe@170 4293 "battle_win"."count" > "winning_initiative"."positive_votes" OR
jbe@170 4294 "battle_lose"."count" < "losing_initiative"."negative_votes" )
jbe@170 4295 ) AS "subquery"
jbe@170 4296 WHERE "id" = "subquery"."initiative_id";
jbe@170 4297 -- mark eligible initiatives:
jbe@170 4298 UPDATE "initiative" SET "eligible" = TRUE
jbe@171 4299 WHERE "issue_id" = "issue_id_p"
jbe@171 4300 AND "initiative"."direct_majority"
jbe@171 4301 AND "initiative"."indirect_majority"
jbe@171 4302 AND "initiative"."better_than_status_quo"
jbe@171 4303 AND (
jbe@171 4304 "policy_row"."no_multistage_majority" = FALSE OR
jbe@429 4305 "initiative"."multistage_majority" = FALSE )
jbe@429 4306 AND (
jbe@429 4307 "policy_row"."no_reverse_beat_path" = FALSE OR
jbe@429 4308 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
jbe@170 4309 -- mark final winner:
jbe@170 4310 UPDATE "initiative" SET "winner" = TRUE
jbe@170 4311 FROM (
jbe@170 4312 SELECT "id" AS "initiative_id"
jbe@170 4313 FROM "initiative"
jbe@170 4314 WHERE "issue_id" = "issue_id_p" AND "eligible"
jbe@217 4315 ORDER BY
jbe@217 4316 "schulze_rank",
jbe@217 4317 "id"
jbe@170 4318 LIMIT 1
jbe@170 4319 ) AS "subquery"
jbe@170 4320 WHERE "id" = "subquery"."initiative_id";
jbe@173 4321 -- write (final) ranks:
jbe@173 4322 "rank_v" := 1;
jbe@173 4323 FOR "initiative_id_v" IN
jbe@173 4324 SELECT "id"
jbe@173 4325 FROM "initiative"
jbe@173 4326 WHERE "issue_id" = "issue_id_p" AND "admitted"
jbe@174 4327 ORDER BY
jbe@174 4328 "winner" DESC,
jbe@217 4329 "eligible" DESC,
jbe@174 4330 "schulze_rank",
jbe@174 4331 "id"
jbe@173 4332 LOOP
jbe@173 4333 UPDATE "initiative" SET "rank" = "rank_v"
jbe@173 4334 WHERE "id" = "initiative_id_v";
jbe@173 4335 "rank_v" := "rank_v" + 1;
jbe@173 4336 END LOOP;
jbe@170 4337 -- set schulze rank of status quo and mark issue as finished:
jbe@111 4338 UPDATE "issue" SET
jbe@411 4339 "status_quo_schulze_rank" = "rank_ary"[1],
jbe@111 4340 "state" =
jbe@139 4341 CASE WHEN EXISTS (
jbe@139 4342 SELECT NULL FROM "initiative"
jbe@139 4343 WHERE "issue_id" = "issue_id_p" AND "winner"
jbe@139 4344 ) THEN
jbe@139 4345 'finished_with_winner'::"issue_state"
jbe@139 4346 ELSE
jbe@121 4347 'finished_without_winner'::"issue_state"
jbe@111 4348 END,
jbe@331 4349 "closed" = "phase_finished",
jbe@331 4350 "phase_finished" = NULL
jbe@0 4351 WHERE "id" = "issue_id_p";
jbe@0 4352 RETURN;
jbe@0 4353 END;
jbe@0 4354 $$;
jbe@0 4355
jbe@0 4356 COMMENT ON FUNCTION "calculate_ranks"
jbe@0 4357 ( "issue"."id"%TYPE )
jbe@0 4358 IS 'Determine ranking (Votes have to be counted first)';
jbe@0 4359
jbe@0 4360
jbe@0 4361
jbe@0 4362 -----------------------------
jbe@0 4363 -- Automatic state changes --
jbe@0 4364 -----------------------------
jbe@0 4365
jbe@0 4366
jbe@331 4367 CREATE TYPE "check_issue_persistence" AS (
jbe@331 4368 "state" "issue_state",
jbe@331 4369 "phase_finished" BOOLEAN,
jbe@331 4370 "issue_revoked" BOOLEAN,
jbe@331 4371 "snapshot_created" BOOLEAN,
jbe@331 4372 "harmonic_weights_set" BOOLEAN,
jbe@331 4373 "closed_voting" BOOLEAN );
jbe@331 4374
jbe@336 4375 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 4376
jbe@336 4377
jbe@0 4378 CREATE FUNCTION "check_issue"
jbe@331 4379 ( "issue_id_p" "issue"."id"%TYPE,
jbe@331 4380 "persist" "check_issue_persistence" )
jbe@331 4381 RETURNS "check_issue_persistence"
jbe@0 4382 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4383 DECLARE
jbe@336 4384 "issue_row" "issue"%ROWTYPE;
jbe@336 4385 "policy_row" "policy"%ROWTYPE;
jbe@336 4386 "initiative_row" "initiative"%ROWTYPE;
jbe@336 4387 "state_v" "issue_state";
jbe@0 4388 BEGIN
jbe@333 4389 PERFORM "require_transaction_isolation"();
jbe@331 4390 IF "persist" ISNULL THEN
jbe@331 4391 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@331 4392 FOR UPDATE;
jbe@331 4393 IF "issue_row"."closed" NOTNULL THEN
jbe@331 4394 RETURN NULL;
jbe@0 4395 END IF;
jbe@331 4396 "persist"."state" := "issue_row"."state";
jbe@331 4397 IF
jbe@331 4398 ( "issue_row"."state" = 'admission' AND now() >=
jbe@447 4399 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
jbe@331 4400 ( "issue_row"."state" = 'discussion' AND now() >=
jbe@331 4401 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
jbe@331 4402 ( "issue_row"."state" = 'verification' AND now() >=
jbe@331 4403 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
jbe@331 4404 ( "issue_row"."state" = 'voting' AND now() >=
jbe@331 4405 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
jbe@331 4406 THEN
jbe@331 4407 "persist"."phase_finished" := TRUE;
jbe@331 4408 ELSE
jbe@331 4409 "persist"."phase_finished" := FALSE;
jbe@0 4410 END IF;
jbe@0 4411 IF
jbe@24 4412 NOT EXISTS (
jbe@24 4413 -- all initiatives are revoked
jbe@24 4414 SELECT NULL FROM "initiative"
jbe@24 4415 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@24 4416 ) AND (
jbe@111 4417 -- and issue has not been accepted yet
jbe@331 4418 "persist"."state" = 'admission' OR
jbe@331 4419 -- or verification time has elapsed
jbe@331 4420 ( "persist"."state" = 'verification' AND
jbe@331 4421 "persist"."phase_finished" ) OR
jbe@331 4422 -- or no initiatives have been revoked lately
jbe@24 4423 NOT EXISTS (
jbe@24 4424 SELECT NULL FROM "initiative"
jbe@24 4425 WHERE "issue_id" = "issue_id_p"
jbe@24 4426 AND now() < "revoked" + "issue_row"."verification_time"
jbe@24 4427 )
jbe@24 4428 )
jbe@24 4429 THEN
jbe@331 4430 "persist"."issue_revoked" := TRUE;
jbe@331 4431 ELSE
jbe@331 4432 "persist"."issue_revoked" := FALSE;
jbe@24 4433 END IF;
jbe@331 4434 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
jbe@331 4435 UPDATE "issue" SET "phase_finished" = now()
jbe@331 4436 WHERE "id" = "issue_row"."id";
jbe@331 4437 RETURN "persist";
jbe@331 4438 ELSIF
jbe@331 4439 "persist"."state" IN ('admission', 'discussion', 'verification')
jbe@3 4440 THEN
jbe@331 4441 RETURN "persist";
jbe@331 4442 ELSE
jbe@331 4443 RETURN NULL;
jbe@322 4444 END IF;
jbe@0 4445 END IF;
jbe@331 4446 IF
jbe@331 4447 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 4448 coalesce("persist"."snapshot_created", FALSE) = FALSE
jbe@331 4449 THEN
jbe@331 4450 PERFORM "create_snapshot"("issue_id_p");
jbe@331 4451 "persist"."snapshot_created" = TRUE;
jbe@331 4452 IF "persist"."phase_finished" THEN
jbe@331 4453 IF "persist"."state" = 'admission' THEN
jbe@331 4454 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
jbe@331 4455 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 4456 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
jbe@331 4457 ELSIF "persist"."state" = 'verification' THEN
jbe@331 4458 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
jbe@336 4459 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@336 4460 SELECT * INTO "policy_row" FROM "policy"
jbe@336 4461 WHERE "id" = "issue_row"."policy_id";
jbe@336 4462 FOR "initiative_row" IN
jbe@336 4463 SELECT * FROM "initiative"
jbe@336 4464 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@336 4465 FOR UPDATE
jbe@336 4466 LOOP
jbe@336 4467 IF
jbe@336 4468 "initiative_row"."polling" OR (
jbe@336 4469 "initiative_row"."satisfied_supporter_count" > 0 AND
jbe@336 4470 "initiative_row"."satisfied_supporter_count" *
jbe@336 4471 "policy_row"."initiative_quorum_den" >=
jbe@336 4472 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@336 4473 )
jbe@336 4474 THEN
jbe@336 4475 UPDATE "initiative" SET "admitted" = TRUE
jbe@336 4476 WHERE "id" = "initiative_row"."id";
jbe@336 4477 ELSE
jbe@336 4478 UPDATE "initiative" SET "admitted" = FALSE
jbe@336 4479 WHERE "id" = "initiative_row"."id";
jbe@336 4480 END IF;
jbe@336 4481 END LOOP;
jbe@331 4482 END IF;
jbe@331 4483 END IF;
jbe@331 4484 RETURN "persist";
jbe@331 4485 END IF;
jbe@331 4486 IF
jbe@331 4487 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@331 4488 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
jbe@331 4489 THEN
jbe@331 4490 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@331 4491 "persist"."harmonic_weights_set" = TRUE;
jbe@332 4492 IF
jbe@332 4493 "persist"."phase_finished" OR
jbe@332 4494 "persist"."issue_revoked" OR
jbe@332 4495 "persist"."state" = 'admission'
jbe@332 4496 THEN
jbe@331 4497 RETURN "persist";
jbe@331 4498 ELSE
jbe@331 4499 RETURN NULL;
jbe@331 4500 END IF;
jbe@331 4501 END IF;
jbe@331 4502 IF "persist"."issue_revoked" THEN
jbe@331 4503 IF "persist"."state" = 'admission' THEN
jbe@331 4504 "state_v" := 'canceled_revoked_before_accepted';
jbe@331 4505 ELSIF "persist"."state" = 'discussion' THEN
jbe@331 4506 "state_v" := 'canceled_after_revocation_during_discussion';
jbe@331 4507 ELSIF "persist"."state" = 'verification' THEN
jbe@331 4508 "state_v" := 'canceled_after_revocation_during_verification';
jbe@331 4509 END IF;
jbe@331 4510 UPDATE "issue" SET
jbe@331 4511 "state" = "state_v",
jbe@331 4512 "closed" = "phase_finished",
jbe@331 4513 "phase_finished" = NULL
jbe@332 4514 WHERE "id" = "issue_id_p";
jbe@331 4515 RETURN NULL;
jbe@331 4516 END IF;
jbe@331 4517 IF "persist"."state" = 'admission' THEN
jbe@336 4518 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 4519 FOR UPDATE;
jbe@336 4520 SELECT * INTO "policy_row"
jbe@336 4521 FROM "policy" WHERE "id" = "issue_row"."policy_id";
jbe@447 4522 IF
jbe@447 4523 ( now() >=
jbe@447 4524 "issue_row"."created" + "issue_row"."min_admission_time" ) AND
jbe@447 4525 EXISTS (
jbe@447 4526 SELECT NULL FROM "initiative"
jbe@447 4527 WHERE "issue_id" = "issue_id_p"
jbe@447 4528 AND "supporter_count" > 0
jbe@447 4529 AND "supporter_count" * "policy_row"."issue_quorum_den"
jbe@447 4530 >= "issue_row"."population" * "policy_row"."issue_quorum_num"
jbe@447 4531 )
jbe@447 4532 THEN
jbe@336 4533 UPDATE "issue" SET
jbe@336 4534 "state" = 'discussion',
jbe@336 4535 "accepted" = coalesce("phase_finished", now()),
jbe@336 4536 "phase_finished" = NULL
jbe@336 4537 WHERE "id" = "issue_id_p";
jbe@336 4538 ELSIF "issue_row"."phase_finished" NOTNULL THEN
jbe@336 4539 UPDATE "issue" SET
jbe@336 4540 "state" = 'canceled_issue_not_accepted',
jbe@336 4541 "closed" = "phase_finished",
jbe@336 4542 "phase_finished" = NULL
jbe@336 4543 WHERE "id" = "issue_id_p";
jbe@336 4544 END IF;
jbe@331 4545 RETURN NULL;
jbe@331 4546 END IF;
jbe@332 4547 IF "persist"."phase_finished" THEN
jbe@443 4548 IF "persist"."state" = 'discussion' THEN
jbe@332 4549 UPDATE "issue" SET
jbe@332 4550 "state" = 'verification',
jbe@332 4551 "half_frozen" = "phase_finished",
jbe@332 4552 "phase_finished" = NULL
jbe@332 4553 WHERE "id" = "issue_id_p";
jbe@332 4554 RETURN NULL;
jbe@332 4555 END IF;
jbe@332 4556 IF "persist"."state" = 'verification' THEN
jbe@336 4557 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@336 4558 FOR UPDATE;
jbe@336 4559 SELECT * INTO "policy_row" FROM "policy"
jbe@336 4560 WHERE "id" = "issue_row"."policy_id";
jbe@336 4561 IF EXISTS (
jbe@336 4562 SELECT NULL FROM "initiative"
jbe@336 4563 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@336 4564 ) THEN
jbe@336 4565 UPDATE "issue" SET
jbe@343 4566 "state" = 'voting',
jbe@343 4567 "fully_frozen" = "phase_finished",
jbe@336 4568 "phase_finished" = NULL
jbe@336 4569 WHERE "id" = "issue_id_p";
jbe@336 4570 ELSE
jbe@336 4571 UPDATE "issue" SET
jbe@343 4572 "state" = 'canceled_no_initiative_admitted',
jbe@343 4573 "fully_frozen" = "phase_finished",
jbe@343 4574 "closed" = "phase_finished",
jbe@343 4575 "phase_finished" = NULL
jbe@336 4576 WHERE "id" = "issue_id_p";
jbe@336 4577 -- NOTE: The following DELETE statements have effect only when
jbe@336 4578 -- issue state has been manipulated
jbe@336 4579 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 4580 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@336 4581 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@336 4582 END IF;
jbe@332 4583 RETURN NULL;
jbe@332 4584 END IF;
jbe@332 4585 IF "persist"."state" = 'voting' THEN
jbe@332 4586 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
jbe@332 4587 PERFORM "close_voting"("issue_id_p");
jbe@332 4588 "persist"."closed_voting" = TRUE;
jbe@332 4589 RETURN "persist";
jbe@332 4590 END IF;
jbe@332 4591 PERFORM "calculate_ranks"("issue_id_p");
jbe@332 4592 RETURN NULL;
jbe@332 4593 END IF;
jbe@331 4594 END IF;
jbe@331 4595 RAISE WARNING 'should not happen';
jbe@331 4596 RETURN NULL;
jbe@0 4597 END;
jbe@0 4598 $$;
jbe@0 4599
jbe@0 4600 COMMENT ON FUNCTION "check_issue"
jbe@331 4601 ( "issue"."id"%TYPE,
jbe@331 4602 "check_issue_persistence" )
jbe@336 4603 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 4604
jbe@0 4605
jbe@0 4606 CREATE FUNCTION "check_everything"()
jbe@0 4607 RETURNS VOID
jbe@0 4608 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@0 4609 DECLARE
jbe@0 4610 "issue_id_v" "issue"."id"%TYPE;
jbe@331 4611 "persist_v" "check_issue_persistence";
jbe@0 4612 BEGIN
jbe@333 4613 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
jbe@235 4614 DELETE FROM "expired_session";
jbe@184 4615 PERFORM "check_activity"();
jbe@4 4616 PERFORM "calculate_member_counts"();
jbe@4 4617 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@331 4618 "persist_v" := NULL;
jbe@331 4619 LOOP
jbe@331 4620 "persist_v" := "check_issue"("issue_id_v", "persist_v");
jbe@331 4621 EXIT WHEN "persist_v" ISNULL;
jbe@331 4622 END LOOP;
jbe@0 4623 END LOOP;
jbe@0 4624 RETURN;
jbe@0 4625 END;
jbe@0 4626 $$;
jbe@0 4627
jbe@336 4628 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 4629
jbe@0 4630
jbe@0 4631
jbe@59 4632 ----------------------
jbe@59 4633 -- Deletion of data --
jbe@59 4634 ----------------------
jbe@59 4635
jbe@59 4636
jbe@59 4637 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@59 4638 RETURNS VOID
jbe@59 4639 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@59 4640 BEGIN
jbe@385 4641 IF EXISTS (
jbe@385 4642 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
jbe@385 4643 ) THEN
jbe@385 4644 -- override protection triggers:
jbe@385 4645 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@385 4646 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@385 4647 -- clean data:
jbe@59 4648 DELETE FROM "delegating_voter"
jbe@59 4649 WHERE "issue_id" = "issue_id_p";
jbe@59 4650 DELETE FROM "direct_voter"
jbe@59 4651 WHERE "issue_id" = "issue_id_p";
jbe@59 4652 DELETE FROM "delegating_interest_snapshot"
jbe@59 4653 WHERE "issue_id" = "issue_id_p";
jbe@59 4654 DELETE FROM "direct_interest_snapshot"
jbe@59 4655 WHERE "issue_id" = "issue_id_p";
jbe@59 4656 DELETE FROM "delegating_population_snapshot"
jbe@59 4657 WHERE "issue_id" = "issue_id_p";
jbe@59 4658 DELETE FROM "direct_population_snapshot"
jbe@59 4659 WHERE "issue_id" = "issue_id_p";
jbe@113 4660 DELETE FROM "non_voter"
jbe@94 4661 WHERE "issue_id" = "issue_id_p";
jbe@59 4662 DELETE FROM "delegation"
jbe@59 4663 WHERE "issue_id" = "issue_id_p";
jbe@59 4664 DELETE FROM "supporter"
jbe@329 4665 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@325 4666 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@325 4667 AND "supporter"."initiative_id" = "initiative_id";
jbe@385 4668 -- mark issue as cleaned:
jbe@385 4669 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
jbe@385 4670 -- finish overriding protection triggers (avoids garbage):
jbe@385 4671 DELETE FROM "temporary_transaction_data"
jbe@385 4672 WHERE "key" = 'override_protection_triggers';
jbe@59 4673 END IF;
jbe@59 4674 RETURN;
jbe@59 4675 END;
jbe@59 4676 $$;
jbe@59 4677
jbe@59 4678 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
jbe@8 4679
jbe@8 4680
jbe@54 4681 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@8 4682 RETURNS VOID
jbe@8 4683 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@8 4684 BEGIN
jbe@9 4685 UPDATE "member" SET
jbe@57 4686 "last_login" = NULL,
jbe@387 4687 "last_delegation_check" = NULL,
jbe@45 4688 "login" = NULL,
jbe@11 4689 "password" = NULL,
jbe@441 4690 "authority" = NULL,
jbe@441 4691 "authority_uid" = NULL,
jbe@441 4692 "authority_login" = NULL,
jbe@101 4693 "locked" = TRUE,
jbe@54 4694 "active" = FALSE,
jbe@11 4695 "notify_email" = NULL,
jbe@11 4696 "notify_email_unconfirmed" = NULL,
jbe@11 4697 "notify_email_secret" = NULL,
jbe@11 4698 "notify_email_secret_expiry" = NULL,
jbe@57 4699 "notify_email_lock_expiry" = NULL,
jbe@387 4700 "login_recovery_expiry" = NULL,
jbe@11 4701 "password_reset_secret" = NULL,
jbe@11 4702 "password_reset_secret_expiry" = NULL,
jbe@11 4703 "organizational_unit" = NULL,
jbe@11 4704 "internal_posts" = NULL,
jbe@11 4705 "realname" = NULL,
jbe@11 4706 "birthday" = NULL,
jbe@11 4707 "address" = NULL,
jbe@11 4708 "email" = NULL,
jbe@11 4709 "xmpp_address" = NULL,
jbe@11 4710 "website" = NULL,
jbe@11 4711 "phone" = NULL,
jbe@11 4712 "mobile_phone" = NULL,
jbe@11 4713 "profession" = NULL,
jbe@11 4714 "external_memberships" = NULL,
jbe@11 4715 "external_posts" = NULL,
jbe@45 4716 "statement" = NULL
jbe@45 4717 WHERE "id" = "member_id_p";
jbe@11 4718 -- "text_search_data" is updated by triggers
jbe@45 4719 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@45 4720 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@45 4721 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@45 4722 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@45 4723 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@113 4724 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@235 4725 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@45 4726 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@45 4727 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@113 4728 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@45 4729 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@45 4730 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@54 4731 DELETE FROM "membership" WHERE "member_id" = "member_id_p";
jbe@54 4732 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@113 4733 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@57 4734 DELETE FROM "direct_voter" USING "issue"
jbe@57 4735 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@57 4736 AND "issue"."closed" ISNULL
jbe@57 4737 AND "member_id" = "member_id_p";
jbe@45 4738 RETURN;
jbe@45 4739 END;
jbe@45 4740 $$;
jbe@45 4741
jbe@57 4742 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 4743
jbe@45 4744
jbe@45 4745 CREATE FUNCTION "delete_private_data"()
jbe@45 4746 RETURNS VOID
jbe@45 4747 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@45 4748 BEGIN
jbe@385 4749 DELETE FROM "temporary_transaction_data";
jbe@226 4750 DELETE FROM "member" WHERE "activated" ISNULL;
jbe@50 4751 UPDATE "member" SET
jbe@206 4752 "invite_code" = NULL,
jbe@232 4753 "invite_code_expiry" = NULL,
jbe@228 4754 "admin_comment" = NULL,
jbe@57 4755 "last_login" = NULL,
jbe@387 4756 "last_delegation_check" = NULL,
jbe@50 4757 "login" = NULL,
jbe@50 4758 "password" = NULL,
jbe@441 4759 "authority" = NULL,
jbe@441 4760 "authority_uid" = NULL,
jbe@441 4761 "authority_login" = NULL,
jbe@238 4762 "lang" = NULL,
jbe@50 4763 "notify_email" = NULL,
jbe@50 4764 "notify_email_unconfirmed" = NULL,
jbe@50 4765 "notify_email_secret" = NULL,
jbe@50 4766 "notify_email_secret_expiry" = NULL,
jbe@57 4767 "notify_email_lock_expiry" = NULL,
jbe@238 4768 "notify_level" = NULL,
jbe@387 4769 "login_recovery_expiry" = NULL,
jbe@50 4770 "password_reset_secret" = NULL,
jbe@50 4771 "password_reset_secret_expiry" = NULL,
jbe@50 4772 "organizational_unit" = NULL,
jbe@50 4773 "internal_posts" = NULL,
jbe@50 4774 "realname" = NULL,
jbe@50 4775 "birthday" = NULL,
jbe@50 4776 "address" = NULL,
jbe@50 4777 "email" = NULL,
jbe@50 4778 "xmpp_address" = NULL,
jbe@50 4779 "website" = NULL,
jbe@50 4780 "phone" = NULL,
jbe@50 4781 "mobile_phone" = NULL,
jbe@50 4782 "profession" = NULL,
jbe@50 4783 "external_memberships" = NULL,
jbe@50 4784 "external_posts" = NULL,
jbe@238 4785 "formatting_engine" = NULL,
jbe@50 4786 "statement" = NULL;
jbe@50 4787 -- "text_search_data" is updated by triggers
jbe@50 4788 DELETE FROM "setting";
jbe@50 4789 DELETE FROM "setting_map";
jbe@50 4790 DELETE FROM "member_relation_setting";
jbe@50 4791 DELETE FROM "member_image";
jbe@50 4792 DELETE FROM "contact";
jbe@113 4793 DELETE FROM "ignored_member";
jbe@235 4794 DELETE FROM "session";
jbe@50 4795 DELETE FROM "area_setting";
jbe@50 4796 DELETE FROM "issue_setting";
jbe@113 4797 DELETE FROM "ignored_initiative";
jbe@50 4798 DELETE FROM "initiative_setting";
jbe@50 4799 DELETE FROM "suggestion_setting";
jbe@113 4800 DELETE FROM "non_voter";
jbe@8 4801 DELETE FROM "direct_voter" USING "issue"
jbe@8 4802 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@8 4803 AND "issue"."closed" ISNULL;
jbe@8 4804 RETURN;
jbe@8 4805 END;
jbe@8 4806 $$;
jbe@8 4807
jbe@273 4808 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 4809
jbe@8 4810
jbe@8 4811
jbe@0 4812 COMMIT;

Impressum / About Us