liquid_feedback_core

annotate core.sql @ 471:124b9e7c3c23

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

Impressum / About Us