liquid_feedback_core

annotate core.sql @ 463:88b47f0dacde

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

Impressum / About Us