liquid_feedback_core

annotate core.sql @ 474:5cafa61745bd

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

Impressum / About Us