liquid_feedback_core

annotate core.sql @ 473:234c9760589d

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

Impressum / About Us