liquid_feedback_core

annotate update/core-update.v3.2.2-v4.0.0.sql @ 536:750b0be5acb6

Work on unit/area/policy events: added column "policy_id" to "event" table, added new "event_type"s
author jbe
date Mon Jun 26 15:54:26 2017 +0200 (2017-06-26)
parents 8b6433096a58
children aa261389c993
rev   line source
jbe@536 1 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'unit_created';
jbe@536 2 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'unit_updated';
jbe@536 3 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'unit_removed';
jbe@536 4 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'subject_area_created';
jbe@536 5 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'subject_area_updated';
jbe@536 6 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'subject_area_removed';
jbe@536 7 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'policy_created';
jbe@536 8 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'policy_updated';
jbe@536 9 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'policy_removed';
jbe@532 10 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'suggestion_removed';
jbe@532 11 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'member_activated';
jbe@532 12 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'member_removed';
jbe@532 13 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'member_active';
jbe@532 14 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'member_name_updated';
jbe@532 15 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'member_profile_updated';
jbe@532 16 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'member_image_updated';
jbe@532 17 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'interest';
jbe@532 18 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'initiator';
jbe@532 19 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'support';
jbe@532 20 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'support_updated';
jbe@532 21 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'suggestion_rated';
jbe@532 22 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'delegation';
jbe@532 23 ALTER TYPE "event_type" ADD VALUE IF NOT EXISTS 'contact';
jbe@532 24
jbe@532 25
jbe@532 26 BEGIN;
jbe@532 27
jbe@532 28
jbe@532 29 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
jbe@532 30 SELECT * FROM (VALUES ('4.0-dev', 4, 0, -1))
jbe@532 31 AS "subquery"("string", "major", "minor", "revision");
jbe@532 32
jbe@532 33
jbe@532 34 ALTER TABLE "system_setting" ADD COLUMN "snapshot_retention" INTERVAL;
jbe@532 35
jbe@532 36 COMMENT ON COLUMN "system_setting"."snapshot_retention" IS 'Unreferenced snapshots are retained for the given period of time after creation; set to NULL for infinite retention.';
jbe@532 37
jbe@532 38
jbe@532 39 CREATE TABLE "member_profile" (
jbe@532 40 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 41 "formatting_engine" TEXT,
jbe@532 42 "statement" TEXT,
jbe@532 43 "profile" JSONB,
jbe@532 44 "profile_text_data" TEXT,
jbe@532 45 "text_search_data" TSVECTOR );
jbe@532 46 CREATE INDEX "member_profile_text_search_data_idx" ON "member_profile" USING gin ("text_search_data");
jbe@532 47 CREATE TRIGGER "update_text_search_data"
jbe@532 48 BEFORE INSERT OR UPDATE ON "member_profile"
jbe@532 49 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 50 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@532 51 'statement', 'profile_text_data');
jbe@532 52
jbe@532 53 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
jbe@532 54 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
jbe@532 55 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
jbe@532 56 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
jbe@532 57
jbe@532 58
jbe@532 59 INSERT INTO "member_profile"
jbe@532 60 ( "member_id", "formatting_engine", "statement", "profile")
jbe@532 61 SELECT
jbe@532 62 "id" AS "member_id",
jbe@532 63 "formatting_engine",
jbe@532 64 "statement",
jbe@532 65 json_build_object(
jbe@532 66 'organizational_unit', "organizational_unit",
jbe@532 67 'internal_posts', "internal_posts",
jbe@532 68 'realname', "realname",
jbe@532 69 'birthday', to_char("birthday", 'YYYY-MM-DD'),
jbe@532 70 'address', "address",
jbe@532 71 'email', "email",
jbe@532 72 'xmpp_address', "xmpp_address",
jbe@532 73 'website', "website",
jbe@532 74 'phone', "phone",
jbe@532 75 'mobile_phone', "mobile_phone",
jbe@532 76 'profession', "profession",
jbe@532 77 'external_memberships', "external_memberships",
jbe@532 78 'external_posts', "external_posts"
jbe@532 79 ) AS "profile"
jbe@532 80 FROM "member";
jbe@532 81
jbe@532 82 UPDATE "member_profile" SET "profile_text_data" =
jbe@532 83 coalesce(("profile"->>'organizational_unit') || ' ', '') ||
jbe@532 84 coalesce(("profile"->>'internal_posts') || ' ', '') ||
jbe@532 85 coalesce(("profile"->>'realname') || ' ', '') ||
jbe@532 86 coalesce(("profile"->>'birthday') || ' ', '') ||
jbe@532 87 coalesce(("profile"->>'address') || ' ', '') ||
jbe@532 88 coalesce(("profile"->>'email') || ' ', '') ||
jbe@532 89 coalesce(("profile"->>'xmpp_address') || ' ', '') ||
jbe@532 90 coalesce(("profile"->>'website') || ' ', '') ||
jbe@532 91 coalesce(("profile"->>'phone') || ' ', '') ||
jbe@532 92 coalesce(("profile"->>'mobile_phone') || ' ', '') ||
jbe@532 93 coalesce(("profile"->>'profession') || ' ', '') ||
jbe@532 94 coalesce(("profile"->>'external_memberships') || ' ', '') ||
jbe@532 95 coalesce(("profile"->>'external_posts') || ' ', '');
jbe@532 96
jbe@532 97
jbe@532 98 DROP VIEW "newsletter_to_send";
jbe@532 99 DROP VIEW "scheduled_notification_to_send";
jbe@532 100 DROP VIEW "member_to_notify";
jbe@532 101 DROP VIEW "member_eligible_to_be_notified";
jbe@532 102
jbe@532 103
jbe@532 104 ALTER TABLE "member" DROP COLUMN "organizational_unit";
jbe@532 105 ALTER TABLE "member" DROP COLUMN "internal_posts";
jbe@532 106 ALTER TABLE "member" DROP COLUMN "realname";
jbe@532 107 ALTER TABLE "member" DROP COLUMN "birthday";
jbe@532 108 ALTER TABLE "member" DROP COLUMN "address";
jbe@532 109 ALTER TABLE "member" DROP COLUMN "email";
jbe@532 110 ALTER TABLE "member" DROP COLUMN "xmpp_address";
jbe@532 111 ALTER TABLE "member" DROP COLUMN "website";
jbe@532 112 ALTER TABLE "member" DROP COLUMN "phone";
jbe@532 113 ALTER TABLE "member" DROP COLUMN "mobile_phone";
jbe@532 114 ALTER TABLE "member" DROP COLUMN "profession";
jbe@532 115 ALTER TABLE "member" DROP COLUMN "external_memberships";
jbe@532 116 ALTER TABLE "member" DROP COLUMN "external_posts";
jbe@532 117 ALTER TABLE "member" DROP COLUMN "formatting_engine";
jbe@532 118 ALTER TABLE "member" DROP COLUMN "statement";
jbe@532 119
jbe@532 120 ALTER TABLE "member" ADD COLUMN "location" JSONB;
jbe@532 121 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
jbe@532 122 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
jbe@532 123
jbe@532 124 DROP TRIGGER "update_text_search_data" ON "member";
jbe@532 125 CREATE TRIGGER "update_text_search_data"
jbe@532 126 BEFORE INSERT OR UPDATE ON "member"
jbe@532 127 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 128 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
jbe@532 129 "name", "identification");
jbe@532 130
jbe@532 131
jbe@532 132 CREATE VIEW "member_eligible_to_be_notified" AS
jbe@532 133 SELECT * FROM "member"
jbe@532 134 WHERE "activated" NOTNULL AND "locked" = FALSE;
jbe@532 135
jbe@532 136 COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")';
jbe@532 137
jbe@532 138
jbe@532 139 CREATE VIEW "member_to_notify" AS
jbe@532 140 SELECT * FROM "member_eligible_to_be_notified"
jbe@532 141 WHERE "disable_notifications" = FALSE;
jbe@532 142
jbe@532 143 COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)';
jbe@532 144
jbe@532 145
jbe@532 146 CREATE VIEW "scheduled_notification_to_send" AS
jbe@532 147 SELECT * FROM (
jbe@532 148 SELECT
jbe@532 149 "id" AS "recipient_id",
jbe@532 150 now() - CASE WHEN "notification_dow" ISNULL THEN
jbe@532 151 ( "notification_sent"::DATE + CASE
jbe@532 152 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@532 153 THEN 0 ELSE 1 END
jbe@532 154 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@532 155 ELSE
jbe@532 156 ( "notification_sent"::DATE +
jbe@532 157 ( 7 + "notification_dow" -
jbe@532 158 EXTRACT(DOW FROM
jbe@532 159 ( "notification_sent"::DATE + CASE
jbe@532 160 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@532 161 THEN 0 ELSE 1 END
jbe@532 162 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@532 163 )::INTEGER
jbe@532 164 ) % 7 +
jbe@532 165 CASE
jbe@532 166 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
jbe@532 167 THEN 0 ELSE 1
jbe@532 168 END
jbe@532 169 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
jbe@532 170 END AS "pending"
jbe@532 171 FROM (
jbe@532 172 SELECT
jbe@532 173 "id",
jbe@532 174 COALESCE("notification_sent", "activated") AS "notification_sent",
jbe@532 175 "notification_dow",
jbe@532 176 "notification_hour"
jbe@532 177 FROM "member_to_notify"
jbe@532 178 WHERE "notification_hour" NOTNULL
jbe@532 179 ) AS "subquery1"
jbe@532 180 ) AS "subquery2"
jbe@532 181 WHERE "pending" > '0'::INTERVAL;
jbe@532 182
jbe@532 183 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
jbe@532 184
jbe@532 185 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
jbe@532 186 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
jbe@532 187
jbe@532 188
jbe@532 189 CREATE VIEW "newsletter_to_send" AS
jbe@532 190 SELECT
jbe@532 191 "member"."id" AS "recipient_id",
jbe@532 192 "newsletter"."id" AS "newsletter_id",
jbe@532 193 "newsletter"."published"
jbe@532 194 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
jbe@532 195 LEFT JOIN "privilege" ON
jbe@532 196 "privilege"."member_id" = "member"."id" AND
jbe@532 197 "privilege"."unit_id" = "newsletter"."unit_id" AND
jbe@532 198 "privilege"."voting_right" = TRUE
jbe@532 199 LEFT JOIN "subscription" ON
jbe@532 200 "subscription"."member_id" = "member"."id" AND
jbe@532 201 "subscription"."unit_id" = "newsletter"."unit_id"
jbe@532 202 WHERE "newsletter"."published" <= now()
jbe@532 203 AND "newsletter"."sent" ISNULL
jbe@532 204 AND (
jbe@532 205 "member"."disable_notifications" = FALSE OR
jbe@532 206 "newsletter"."include_all_members" = TRUE )
jbe@532 207 AND (
jbe@532 208 "newsletter"."unit_id" ISNULL OR
jbe@532 209 "privilege"."member_id" NOTNULL OR
jbe@532 210 "subscription"."member_id" NOTNULL );
jbe@532 211
jbe@532 212 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
jbe@532 213
jbe@532 214 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
jbe@532 215
jbe@532 216
jbe@532 217 DROP VIEW "expired_session";
jbe@532 218 DROP TABLE "session";
jbe@532 219
jbe@532 220
jbe@532 221 CREATE TABLE "session" (
jbe@532 222 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
jbe@532 223 "id" SERIAL8 PRIMARY KEY,
jbe@532 224 "ident" TEXT NOT NULL UNIQUE,
jbe@532 225 "additional_secret" TEXT,
jbe@532 226 "logout_token" TEXT,
jbe@532 227 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
jbe@532 228 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
jbe@532 229 "authority" TEXT,
jbe@532 230 "authority_uid" TEXT,
jbe@532 231 "authority_login" TEXT,
jbe@532 232 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@532 233 "lang" TEXT );
jbe@532 234 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
jbe@532 235
jbe@532 236 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
jbe@532 237
jbe@532 238 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
jbe@532 239 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
jbe@532 240 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
jbe@532 241 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
jbe@532 242 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
jbe@532 243 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
jbe@532 244 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
jbe@532 245 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@532 246 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
jbe@532 247
jbe@532 248
jbe@532 249 CREATE TYPE "authflow" AS ENUM ('code', 'token');
jbe@532 250
jbe@532 251 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
jbe@532 252
jbe@532 253
jbe@532 254 CREATE TABLE "system_application" (
jbe@532 255 "id" SERIAL4 PRIMARY KEY,
jbe@532 256 "name" TEXT NOT NULL,
jbe@532 257 "client_id" TEXT NOT NULL UNIQUE,
jbe@532 258 "default_redirect_uri" TEXT NOT NULL,
jbe@532 259 "cert_common_name" TEXT,
jbe@532 260 "client_cred_scope" TEXT,
jbe@532 261 "flow" "authflow",
jbe@532 262 "automatic_scope" TEXT,
jbe@532 263 "permitted_scope" TEXT,
jbe@532 264 "forbidden_scope" TEXT );
jbe@532 265
jbe@532 266 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
jbe@532 267
jbe@532 268 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
jbe@532 269 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
jbe@532 270 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
jbe@532 271 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
jbe@532 272 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
jbe@532 273 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
jbe@532 274 COMMENT ON COLUMN "system_application"."permitted_scope" IS 'Space-separated list of scopes; If set, scope that members may grant to the application is limited to the given value';
jbe@532 275 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
jbe@532 276
jbe@532 277
jbe@532 278 CREATE TABLE "system_application_redirect_uri" (
jbe@532 279 PRIMARY KEY ("system_application_id", "redirect_uri"),
jbe@532 280 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 281 "redirect_uri" TEXT );
jbe@532 282
jbe@532 283 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
jbe@532 284
jbe@532 285
jbe@532 286 CREATE TABLE "dynamic_application_scope" (
jbe@532 287 PRIMARY KEY ("redirect_uri", "flow", "scope"),
jbe@532 288 "redirect_uri" TEXT,
jbe@532 289 "flow" TEXT,
jbe@532 290 "scope" TEXT,
jbe@532 291 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
jbe@532 292 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
jbe@532 293 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
jbe@532 294
jbe@532 295 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
jbe@532 296
jbe@532 297 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
jbe@532 298 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
jbe@532 299 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
jbe@532 300 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
jbe@532 301
jbe@532 302
jbe@532 303 CREATE TABLE "member_application" (
jbe@532 304 "id" SERIAL4 PRIMARY KEY,
jbe@532 305 UNIQUE ("system_application_id", "member_id"),
jbe@532 306 UNIQUE ("domain", "member_id"),
jbe@532 307 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 308 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 309 "domain" TEXT,
jbe@532 310 "session_id" INT8,
jbe@532 311 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 312 "scope" TEXT NOT NULL,
jbe@532 313 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
jbe@532 314 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
jbe@532 315 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
jbe@532 316 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
jbe@532 317
jbe@532 318 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
jbe@532 319
jbe@532 320 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
jbe@532 321 COMMENT ON COLUMN "member_application"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
jbe@532 322 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
jbe@532 323 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
jbe@532 324
jbe@532 325
jbe@532 326 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
jbe@532 327
jbe@532 328 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
jbe@532 329
jbe@532 330
jbe@532 331 CREATE TABLE "token" (
jbe@532 332 "id" SERIAL8 PRIMARY KEY,
jbe@532 333 "token" TEXT NOT NULL UNIQUE,
jbe@532 334 "token_type" "token_type" NOT NULL,
jbe@532 335 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 336 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 337 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 338 "domain" TEXT,
jbe@532 339 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 340 "session_id" INT8,
jbe@532 341 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE, -- NOTE: deletion through "detach_token_from_session" trigger on table "session"
jbe@532 342 "redirect_uri" TEXT,
jbe@532 343 "redirect_uri_explicit" BOOLEAN,
jbe@532 344 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@532 345 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
jbe@532 346 "used" BOOLEAN NOT NULL DEFAULT FALSE,
jbe@532 347 "scope" TEXT NOT NULL,
jbe@532 348 CONSTRAINT "access_token_needs_expiry"
jbe@532 349 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
jbe@532 350 CONSTRAINT "authorization_token_needs_redirect_uri"
jbe@532 351 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
jbe@532 352 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
jbe@532 353 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
jbe@532 354 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
jbe@532 355
jbe@532 356 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
jbe@532 357
jbe@532 358 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
jbe@532 359 COMMENT ON COLUMN "token"."authorization_token_id" IS 'Reference to authorization token if tokens were originally created by Authorization Code flow (allows deletion if code is used twice)';
jbe@532 360 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
jbe@532 361 COMMENT ON COLUMN "token"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
jbe@532 362 COMMENT ON COLUMN "token"."session_id" IS 'If set, then token is tied to a session; Deletion of session sets value to NULL (via trigger) and removes all scopes without suffix ''_detached''';
jbe@532 363 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
jbe@532 364 COMMENT ON COLUMN "token"."redirect_uri_explicit" IS 'True if ''redirect_uri'' parameter was explicitly specified during authorization request of the Authorization Code flow (since RFC 6749 requires it to be included in the access token request in this case)';
jbe@532 365 COMMENT ON COLUMN "token"."expiry" IS 'Point in time when code or token expired; In case of "used" authorization codes, authorization code must not be deleted as long as tokens exist which refer to the authorization code';
jbe@532 366 COMMENT ON COLUMN "token"."used" IS 'Can be set to TRUE for authorization codes that have been used (enables deletion of authorization codes that were used twice)';
jbe@532 367 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
jbe@532 368
jbe@532 369
jbe@532 370 CREATE TABLE "token_scope" (
jbe@532 371 PRIMARY KEY ("token_id", "index"),
jbe@532 372 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 373 "index" INT4,
jbe@532 374 "scope" TEXT NOT NULL );
jbe@532 375
jbe@532 376 COMMENT ON TABLE "token_scope" IS 'Additional scopes for an authorization code if ''scope1'', ''scope2'', etc. parameters were used during Authorization Code flow to request several access and refresh tokens at once';
jbe@532 377
jbe@532 378
jbe@532 379 ALTER TABLE "policy" ADD COLUMN "issue_quorum" INT4 CHECK ("issue_quorum" >= 1);
jbe@532 380 ALTER TABLE "policy" ADD COLUMN "initiative_quorum" INT4 CHECK ("initiative_quorum" >= 1);
jbe@532 381
jbe@532 382 UPDATE "policy" SET "issue_quorum" = 1 WHERE "issue_quorum_num" NOTNULL;
jbe@532 383 UPDATE "policy" SET "initiative_quorum" = 1;
jbe@532 384
jbe@532 385 ALTER TABLE "policy" ALTER COLUMN "initiative_quorum" SET NOT NULL;
jbe@532 386
jbe@532 387 ALTER TABLE "policy" DROP CONSTRAINT "timing";
jbe@532 388 ALTER TABLE "policy" DROP CONSTRAINT "issue_quorum_if_and_only_if_not_polling";
jbe@532 389 ALTER TABLE "policy" ADD CONSTRAINT
jbe@532 390 "issue_quorum_if_and_only_if_not_polling" CHECK (
jbe@532 391 "polling" = ("issue_quorum" ISNULL) AND
jbe@532 392 "polling" = ("issue_quorum_num" ISNULL) AND
jbe@532 393 "polling" = ("issue_quorum_den" ISNULL)
jbe@532 394 );
jbe@532 395 ALTER TABLE "policy" ADD CONSTRAINT
jbe@532 396 "min_admission_time_smaller_than_max_admission_time" CHECK (
jbe@532 397 "min_admission_time" < "max_admission_time"
jbe@532 398 );
jbe@532 399 ALTER TABLE "policy" ADD CONSTRAINT
jbe@532 400 "timing_null_or_not_null_constraints" CHECK (
jbe@532 401 ( "polling" = FALSE AND
jbe@532 402 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
jbe@532 403 "discussion_time" NOTNULL AND
jbe@532 404 "verification_time" NOTNULL AND
jbe@532 405 "voting_time" NOTNULL ) OR
jbe@532 406 ( "polling" = TRUE AND
jbe@532 407 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@532 408 "discussion_time" NOTNULL AND
jbe@532 409 "verification_time" NOTNULL AND
jbe@532 410 "voting_time" NOTNULL ) OR
jbe@532 411 ( "polling" = TRUE AND
jbe@532 412 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
jbe@532 413 "discussion_time" ISNULL AND
jbe@532 414 "verification_time" ISNULL AND
jbe@532 415 "voting_time" ISNULL )
jbe@532 416 );
jbe@532 417
jbe@532 418 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open; Note: should be considerably smaller than "max_admission_time"';
jbe@532 419 COMMENT ON COLUMN "policy"."issue_quorum" IS 'Absolute number of supporters needed by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
jbe@532 420 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
jbe@532 421 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
jbe@532 422 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
jbe@532 423 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@532 424 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@532 425
jbe@532 426
jbe@532 427 ALTER TABLE "unit" ADD COLUMN "region" JSONB;
jbe@532 428
jbe@532 429 CREATE INDEX "unit_region_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("region")));
jbe@532 430
jbe@532 431 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
jbe@532 432 COMMENT ON COLUMN "unit"."region" IS 'Scattered (or hollow) polygon represented as an array of polygons indicating valid coordinates for initiatives of issues with this policy';
jbe@532 433
jbe@532 434
jbe@532 435 DROP INDEX "area_unit_id_idx";
jbe@532 436 ALTER TABLE "area" ADD UNIQUE ("unit_id", "id");
jbe@532 437
jbe@532 438 ALTER TABLE "area" ADD COLUMN "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0);
jbe@532 439 ALTER TABLE "area" ADD COLUMN "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0);
jbe@532 440 ALTER TABLE "area" ADD COLUMN "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL);
jbe@532 441 ALTER TABLE "area" ADD COLUMN "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1);
jbe@532 442 ALTER TABLE "area" ADD COLUMN "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1);
jbe@532 443 ALTER TABLE "area" ADD COLUMN "quorum_den" INT4 CHECK ("quorum_den" > 0);
jbe@532 444 ALTER TABLE "area" ADD COLUMN "issue_quorum" INT4;
jbe@532 445 ALTER TABLE "area" ADD COLUMN "region" JSONB;
jbe@532 446
jbe@532 447 ALTER TABLE "area" DROP COLUMN "direct_member_count";
jbe@532 448 ALTER TABLE "area" DROP COLUMN "member_weight";
jbe@532 449
jbe@532 450 CREATE INDEX "area_region_idx" ON "area" USING gist ((GeoJSON_to_ecluster("region")));
jbe@532 451
jbe@532 452 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
jbe@532 453 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
jbe@532 454 COMMENT ON COLUMN "area"."quorum_time" IS 'Parameter for dynamic issue quorum: discussion, verification, and voting time of open issues to result in the given default quorum (open issues with shorter time will increase quorum and open issues with longer time will reduce quorum if "quorum_exponent" is greater than zero)';
jbe@532 455 COMMENT ON COLUMN "area"."quorum_exponent" IS 'Parameter for dynamic issue quorum: set to zero to ignore duration of open issues, set to one to fully take duration of open issues into account; defaults to 0.5';
jbe@532 456 COMMENT ON COLUMN "area"."quorum_factor" IS 'Parameter for dynamic issue quorum: factor to increase dynamic quorum when a number of "quorum_issues" issues with "quorum_time" duration of discussion, verification, and voting phase are added to the number of open admitted issues';
jbe@532 457 COMMENT ON COLUMN "area"."quorum_den" IS 'Parameter for dynamic issue quorum: when set, dynamic quorum is multiplied with "issue"."population" and divided by "quorum_den" (and then rounded up)';
jbe@532 458 COMMENT ON COLUMN "area"."issue_quorum" IS 'Additional dynamic issue quorum based on the number of open accepted issues; automatically calculated by function "issue_admission"';
jbe@532 459 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
jbe@532 460 COMMENT ON COLUMN "area"."region" IS 'Scattered (or hollow) polygon represented as an array of polygons indicating valid coordinates for initiatives of issues with this policy';
jbe@532 461
jbe@532 462
jbe@532 463 CREATE TABLE "snapshot" (
jbe@532 464 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
jbe@532 465 "id" SERIAL8 PRIMARY KEY,
jbe@532 466 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
jbe@532 467 "population" INT4,
jbe@532 468 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 469 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
jbe@532 470
jbe@532 471 COMMENT ON TABLE "snapshot" IS 'Point in time when a snapshot of one or more issues (see table "snapshot_issue") and their supporter situation is taken';
jbe@532 472
jbe@532 473
jbe@532 474 CREATE TABLE "snapshot_population" (
jbe@532 475 PRIMARY KEY ("snapshot_id", "member_id"),
jbe@532 476 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 477 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
jbe@532 478
jbe@532 479 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
jbe@532 480
jbe@532 481
jbe@532 482 ALTER TABLE "issue" ADD UNIQUE ("area_id", "id");
jbe@532 483 DROP INDEX "issue_area_id_idx";
jbe@536 484 ALTER TABLE "issue" ADD UNIQUE ("policy_id", "id");
jbe@536 485 DROP INDEX "issue_policy_id_idx";
jbe@532 486
jbe@532 487 ALTER TABLE "issue" RENAME COLUMN "snapshot" TO "calculated";
jbe@532 488
jbe@532 489 ALTER TABLE "issue" ADD COLUMN "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
jbe@532 490 ALTER TABLE "issue" ADD COLUMN "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE;
jbe@532 491 ALTER TABLE "issue" ADD COLUMN "half_freeze_snapshot_id" INT8;
jbe@532 492 ALTER TABLE "issue" ADD COLUMN "full_freeze_snapshot_id" INT8;
jbe@532 493
jbe@532 494 ALTER TABLE "issue" ADD FOREIGN KEY ("id", "half_freeze_snapshot_id")
jbe@532 495 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE;
jbe@532 496 ALTER TABLE "issue" ADD FOREIGN KEY ("id", "full_freeze_snapshot_id")
jbe@532 497 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE;
jbe@532 498
jbe@532 499 ALTER TABLE "issue" DROP CONSTRAINT "last_snapshot_on_full_freeze";
jbe@532 500 ALTER TABLE "issue" DROP CONSTRAINT "freeze_requires_snapshot";
jbe@532 501 ALTER TABLE "issue" DROP CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event";
jbe@532 502
jbe@532 503 CREATE INDEX "issue_state_idx" ON "issue" ("state");
jbe@532 504 CREATE INDEX "issue_latest_snapshot_id" ON "issue" ("latest_snapshot_id");
jbe@532 505 CREATE INDEX "issue_admission_snapshot_id" ON "issue" ("admission_snapshot_id");
jbe@532 506 CREATE INDEX "issue_half_freeze_snapshot_id" ON "issue" ("half_freeze_snapshot_id");
jbe@532 507 CREATE INDEX "issue_full_freeze_snapshot_id" ON "issue" ("full_freeze_snapshot_id");
jbe@532 508
jbe@532 509 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when the issue was accepted for further discussion (see columns "issue_quorum_num" and "issue_quorum_den" of table "policy" and quorum columns of table "area")';
jbe@532 510 COMMENT ON COLUMN "issue"."calculated" IS 'Point in time, when most recent snapshot and "population" and *_count values were calculated (NOTE: value is equal to "snapshot"."calculated" of snapshot with "id"="issue"."latest_snapshot_id")';
jbe@532 511 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
jbe@532 512 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
jbe@532 513 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
jbe@532 514 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
jbe@532 515 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
jbe@532 516
jbe@532 517
jbe@532 518 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
jbe@532 519
jbe@532 520
jbe@532 521 ALTER TABLE "initiative" DROP CONSTRAINT "initiative_suggested_initiative_id_fkey";
jbe@532 522 ALTER TABLE "initiative" ADD FOREIGN KEY ("suggested_initiative_id") REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE;
jbe@532 523
jbe@532 524 ALTER TABLE "initiative" ADD COLUMN "location" JSONB;
jbe@532 525 ALTER TABLE "initiative" ADD COLUMN "draft_text_search_data" TSVECTOR;
jbe@532 526
jbe@532 527 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
jbe@532 528 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
jbe@532 529
jbe@532 530 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
jbe@532 531
jbe@532 532
jbe@532 533 ALTER TABLE "draft" ADD COLUMN "location" JSONB;
jbe@532 534
jbe@532 535 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
jbe@532 536
jbe@532 537 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
jbe@532 538
jbe@532 539
jbe@532 540 ALTER TABLE "suggestion" ADD COLUMN "location" JSONB;
jbe@532 541
jbe@532 542 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
jbe@532 543
jbe@532 544 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
jbe@532 545
jbe@532 546
jbe@532 547 CREATE TABLE "temporary_suggestion_counts" (
jbe@532 548 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 549 "minus2_unfulfilled_count" INT4 NOT NULL,
jbe@532 550 "minus2_fulfilled_count" INT4 NOT NULL,
jbe@532 551 "minus1_unfulfilled_count" INT4 NOT NULL,
jbe@532 552 "minus1_fulfilled_count" INT4 NOT NULL,
jbe@532 553 "plus1_unfulfilled_count" INT4 NOT NULL,
jbe@532 554 "plus1_fulfilled_count" INT4 NOT NULL,
jbe@532 555 "plus2_unfulfilled_count" INT4 NOT NULL,
jbe@532 556 "plus2_fulfilled_count" INT4 NOT NULL );
jbe@532 557
jbe@532 558 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
jbe@532 559
jbe@532 560 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
jbe@532 561
jbe@532 562
jbe@532 563 ALTER TABLE "interest" DROP CONSTRAINT "interest_member_id_fkey";
jbe@532 564 ALTER TABLE "interest" ADD FOREIGN KEY ("member_id") REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
jbe@532 565
jbe@532 566
jbe@532 567 ALTER TABLE "initiator" DROP CONSTRAINT "initiator_member_id_fkey";
jbe@532 568 ALTER TABLE "initiator" ADD FOREIGN KEY ("member_id") REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
jbe@532 569
jbe@532 570
jbe@532 571 ALTER TABLE "delegation" DROP CONSTRAINT "delegation_trustee_id_fkey";
jbe@532 572 ALTER TABLE "delegation" ADD FOREIGN KEY ("trustee_id") REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
jbe@532 573
jbe@532 574
jbe@532 575 CREATE TABLE "snapshot_issue" (
jbe@532 576 PRIMARY KEY ("snapshot_id", "issue_id"),
jbe@532 577 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 578 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@532 579 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
jbe@532 580
jbe@532 581 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
jbe@532 582
jbe@532 583 COMMENT ON COLUMN "snapshot_issue"."issue_id" IS 'Issue being part of the snapshot; Trigger "delete_snapshot_on_partial_delete" on "snapshot_issue" table will delete snapshot if an issue of the snapshot is deleted.';
jbe@532 584
jbe@532 585
jbe@532 586 ALTER TABLE "direct_interest_snapshot" RENAME TO "direct_interest_snapshot_old"; -- TODO!
jbe@532 587 ALTER INDEX "direct_interest_snapshot_pkey" RENAME TO "direct_interest_snapshot_old_pkey";
jbe@532 588 ALTER INDEX "direct_interest_snapshot_member_id_idx" RENAME TO "direct_interest_snapshot_old_member_id_idx";
jbe@532 589
jbe@532 590 ALTER TABLE "delegating_interest_snapshot" RENAME TO "delegating_interest_snapshot_old"; -- TODO!
jbe@532 591 ALTER INDEX "delegating_interest_snapshot_pkey" RENAME TO "delegating_interest_snapshot_old_pkey";
jbe@532 592 ALTER INDEX "delegating_interest_snapshot_member_id_idx" RENAME TO "delegating_interest_snapshot_old_member_id_idx";
jbe@532 593
jbe@532 594 ALTER TABLE "direct_supporter_snapshot" RENAME TO "direct_supporter_snapshot_old"; -- TODO!
jbe@532 595 ALTER INDEX "direct_supporter_snapshot_pkey" RENAME TO "direct_supporter_snapshot_old_pkey";
jbe@532 596 ALTER INDEX "direct_supporter_snapshot_member_id_idx" RENAME TO "direct_supporter_snapshot_old_member_id_idx";
jbe@532 597
jbe@532 598
jbe@532 599 CREATE TABLE "direct_interest_snapshot" (
jbe@532 600 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
jbe@532 601 "snapshot_id" INT8,
jbe@532 602 "issue_id" INT4,
jbe@532 603 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@532 604 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 605 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@532 606 "weight" INT4 );
jbe@532 607 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
jbe@532 608
jbe@532 609 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@532 610
jbe@532 611 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
jbe@532 612
jbe@532 613
jbe@532 614 CREATE TABLE "delegating_interest_snapshot" (
jbe@532 615 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
jbe@532 616 "snapshot_id" INT8,
jbe@532 617 "issue_id" INT4,
jbe@532 618 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@532 619 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 620 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@532 621 "weight" INT4,
jbe@532 622 "scope" "delegation_scope" NOT NULL,
jbe@532 623 "delegate_member_ids" INT4[] NOT NULL );
jbe@532 624 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
jbe@532 625
jbe@532 626 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@532 627
jbe@532 628 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
jbe@532 629 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
jbe@532 630 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@532 631
jbe@532 632
jbe@532 633 CREATE TABLE "direct_supporter_snapshot" (
jbe@532 634 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
jbe@532 635 "snapshot_id" INT8,
jbe@532 636 "issue_id" INT4 NOT NULL,
jbe@532 637 FOREIGN KEY ("snapshot_id", "issue_id")
jbe@532 638 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 639 "initiative_id" INT4,
jbe@532 640 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
jbe@532 641 "draft_id" INT8 NOT NULL,
jbe@532 642 "informed" BOOLEAN NOT NULL,
jbe@532 643 "satisfied" BOOLEAN NOT NULL,
jbe@532 644 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@532 645 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
jbe@532 646 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
jbe@532 647 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
jbe@532 648
jbe@532 649 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@532 650
jbe@532 651 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@532 652 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
jbe@532 653 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
jbe@532 654
jbe@532 655
jbe@532 656 ALTER TABLE "non_voter" DROP CONSTRAINT "non_voter_pkey";
jbe@532 657 DROP INDEX "non_voter_member_id_idx";
jbe@532 658
jbe@532 659 ALTER TABLE "non_voter" ADD PRIMARY KEY ("member_id", "issue_id");
jbe@532 660 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
jbe@532 661
jbe@532 662
jbe@532 663 ALTER TABLE "event" ADD COLUMN "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
jbe@532 664 ALTER TABLE "event" ADD COLUMN "scope" "delegation_scope";
jbe@532 665 ALTER TABLE "event" ADD COLUMN "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
jbe@532 666 ALTER TABLE "event" ADD COLUMN "area_id" INT4;
jbe@536 667 ALTER TABLE "event" ADD COLUMN "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
jbe@532 668 ALTER TABLE "event" ADD COLUMN "boolean_value" BOOLEAN;
jbe@532 669 ALTER TABLE "event" ADD COLUMN "numeric_value" INT4;
jbe@532 670 ALTER TABLE "event" ADD COLUMN "text_value" TEXT;
jbe@532 671 ALTER TABLE "event" ADD COLUMN "old_text_value" TEXT;
jbe@532 672
jbe@532 673 ALTER TABLE "event" ADD FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE;
jbe@532 674 ALTER TABLE "event" ADD FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE;
jbe@536 675 ALTER TABLE "event" ADD FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE;
jbe@532 676
jbe@532 677 ALTER TABLE "event" DROP CONSTRAINT "event_initiative_id_fkey1";
jbe@532 678 ALTER TABLE "event" DROP CONSTRAINT "null_constr_for_issue_state_changed";
jbe@532 679 ALTER TABLE "event" DROP CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft";
jbe@532 680 ALTER TABLE "event" DROP CONSTRAINT "null_constr_for_suggestion_creation";
jbe@532 681
jbe@532 682 UPDATE "event" SET "unit_id" = "area"."unit_id", "area_id" = "issue"."area_id"
jbe@532 683 FROM "issue", "area"
jbe@532 684 WHERE "issue"."id" = "event"."issue_id" AND "area"."id" = "issue"."area_id";
jbe@532 685
jbe@532 686 ALTER TABLE "event" ADD CONSTRAINT "constr_for_issue_state_changed" CHECK (
jbe@532 687 "event" != 'issue_state_changed' OR (
jbe@532 688 "member_id" ISNULL AND
jbe@532 689 "other_member_id" ISNULL AND
jbe@532 690 "scope" ISNULL AND
jbe@532 691 "unit_id" NOTNULL AND
jbe@532 692 "area_id" NOTNULL AND
jbe@536 693 "policy_id" NOTNULL AND
jbe@532 694 "issue_id" NOTNULL AND
jbe@532 695 "state" NOTNULL AND
jbe@532 696 "initiative_id" ISNULL AND
jbe@532 697 "draft_id" ISNULL AND
jbe@532 698 "suggestion_id" ISNULL AND
jbe@532 699 "boolean_value" ISNULL AND
jbe@532 700 "numeric_value" ISNULL AND
jbe@532 701 "text_value" ISNULL AND
jbe@532 702 "old_text_value" ISNULL ));
jbe@532 703 ALTER TABLE "event" ADD CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
jbe@532 704 "event" NOT IN (
jbe@532 705 'initiative_created_in_new_issue',
jbe@532 706 'initiative_created_in_existing_issue',
jbe@532 707 'initiative_revoked',
jbe@532 708 'new_draft_created'
jbe@532 709 ) OR (
jbe@532 710 "member_id" NOTNULL AND
jbe@532 711 "other_member_id" ISNULL AND
jbe@532 712 "scope" ISNULL AND
jbe@532 713 "unit_id" NOTNULL AND
jbe@532 714 "area_id" NOTNULL AND
jbe@536 715 "policy_id" NOTNULL AND
jbe@532 716 "issue_id" NOTNULL AND
jbe@532 717 "state" NOTNULL AND
jbe@532 718 "initiative_id" NOTNULL AND
jbe@532 719 "draft_id" NOTNULL AND
jbe@532 720 "suggestion_id" ISNULL AND
jbe@532 721 "boolean_value" ISNULL AND
jbe@532 722 "numeric_value" ISNULL AND
jbe@532 723 "text_value" ISNULL AND
jbe@532 724 "old_text_value" ISNULL ));
jbe@532 725 ALTER TABLE "event" ADD CONSTRAINT "constr_for_suggestion_creation" CHECK (
jbe@532 726 "event" != 'suggestion_created' OR (
jbe@532 727 "member_id" NOTNULL AND
jbe@532 728 "other_member_id" ISNULL AND
jbe@532 729 "scope" ISNULL AND
jbe@532 730 "unit_id" NOTNULL AND
jbe@532 731 "area_id" NOTNULL AND
jbe@536 732 "policy_id" NOTNULL AND
jbe@532 733 "issue_id" NOTNULL AND
jbe@532 734 "state" NOTNULL AND
jbe@532 735 "initiative_id" NOTNULL AND
jbe@532 736 "draft_id" ISNULL AND
jbe@532 737 "suggestion_id" NOTNULL AND
jbe@532 738 "boolean_value" ISNULL AND
jbe@532 739 "numeric_value" ISNULL AND
jbe@532 740 "text_value" ISNULL AND
jbe@532 741 "old_text_value" ISNULL ));
jbe@532 742 ALTER TABLE "event" ADD CONSTRAINT "constr_for_suggestion_removal" CHECK (
jbe@532 743 "event" != 'suggestion_removed' OR (
jbe@532 744 "member_id" ISNULL AND
jbe@532 745 "other_member_id" ISNULL AND
jbe@532 746 "scope" ISNULL AND
jbe@532 747 "unit_id" NOTNULL AND
jbe@532 748 "area_id" NOTNULL AND
jbe@536 749 "policy_id" NOTNULL AND
jbe@532 750 "issue_id" NOTNULL AND
jbe@532 751 "state" NOTNULL AND
jbe@532 752 "initiative_id" NOTNULL AND
jbe@532 753 "draft_id" ISNULL AND
jbe@532 754 "suggestion_id" NOTNULL AND
jbe@532 755 "boolean_value" ISNULL AND
jbe@532 756 "numeric_value" ISNULL AND
jbe@532 757 "text_value" ISNULL AND
jbe@532 758 "old_text_value" ISNULL ));
jbe@532 759 ALTER TABLE "event" ADD CONSTRAINT "constr_for_value_less_member_event" CHECK (
jbe@532 760 "event" NOT IN (
jbe@532 761 'member_activated',
jbe@532 762 'member_removed',
jbe@532 763 'member_profile_updated',
jbe@532 764 'member_image_updated'
jbe@532 765 ) OR (
jbe@532 766 "member_id" NOTNULL AND
jbe@532 767 "other_member_id" ISNULL AND
jbe@532 768 "scope" ISNULL AND
jbe@532 769 "unit_id" ISNULL AND
jbe@532 770 "area_id" ISNULL AND
jbe@536 771 "policy_id" ISNULL AND
jbe@532 772 "issue_id" ISNULL AND
jbe@532 773 "state" ISNULL AND
jbe@532 774 "initiative_id" ISNULL AND
jbe@532 775 "draft_id" ISNULL AND
jbe@532 776 "suggestion_id" ISNULL AND
jbe@532 777 "boolean_value" ISNULL AND
jbe@532 778 "numeric_value" ISNULL AND
jbe@532 779 "text_value" ISNULL AND
jbe@532 780 "old_text_value" ISNULL ));
jbe@532 781 ALTER TABLE "event" ADD CONSTRAINT "constr_for_member_active" CHECK (
jbe@532 782 "event" != 'member_active' OR (
jbe@532 783 "member_id" NOTNULL AND
jbe@532 784 "other_member_id" ISNULL AND
jbe@532 785 "scope" ISNULL AND
jbe@532 786 "unit_id" ISNULL AND
jbe@532 787 "area_id" ISNULL AND
jbe@536 788 "policy_id" ISNULL AND
jbe@532 789 "issue_id" ISNULL AND
jbe@532 790 "state" ISNULL AND
jbe@532 791 "initiative_id" ISNULL AND
jbe@532 792 "draft_id" ISNULL AND
jbe@532 793 "suggestion_id" ISNULL AND
jbe@532 794 "boolean_value" NOTNULL AND
jbe@532 795 "numeric_value" ISNULL AND
jbe@532 796 "text_value" ISNULL AND
jbe@532 797 "old_text_value" ISNULL ));
jbe@532 798 ALTER TABLE "event" ADD CONSTRAINT "constr_for_member_name_updated" CHECK (
jbe@532 799 "event" != 'member_name_updated' OR (
jbe@532 800 "member_id" NOTNULL AND
jbe@532 801 "other_member_id" ISNULL AND
jbe@532 802 "scope" ISNULL AND
jbe@532 803 "unit_id" ISNULL AND
jbe@532 804 "area_id" ISNULL AND
jbe@536 805 "policy_id" ISNULL AND
jbe@532 806 "issue_id" ISNULL AND
jbe@532 807 "state" ISNULL AND
jbe@532 808 "initiative_id" ISNULL AND
jbe@532 809 "draft_id" ISNULL AND
jbe@532 810 "suggestion_id" ISNULL AND
jbe@532 811 "boolean_value" ISNULL AND
jbe@532 812 "numeric_value" ISNULL AND
jbe@532 813 "text_value" NOTNULL AND
jbe@532 814 "old_text_value" NOTNULL ));
jbe@532 815 ALTER TABLE "event" ADD CONSTRAINT "constr_for_interest" CHECK (
jbe@532 816 "event" != 'interest' OR (
jbe@532 817 "member_id" NOTNULL AND
jbe@532 818 "other_member_id" ISNULL AND
jbe@532 819 "scope" ISNULL AND
jbe@532 820 "unit_id" NOTNULL AND
jbe@532 821 "area_id" NOTNULL AND
jbe@536 822 "policy_id" NOTNULL AND
jbe@532 823 "issue_id" NOTNULL AND
jbe@532 824 "state" NOTNULL AND
jbe@532 825 "initiative_id" ISNULL AND
jbe@532 826 "draft_id" ISNULL AND
jbe@532 827 "suggestion_id" ISNULL AND
jbe@532 828 "boolean_value" NOTNULL AND
jbe@532 829 "numeric_value" ISNULL AND
jbe@532 830 "text_value" ISNULL AND
jbe@532 831 "old_text_value" ISNULL ));
jbe@532 832 ALTER TABLE "event" ADD CONSTRAINT "constr_for_initiator" CHECK (
jbe@532 833 "event" != 'initiator' OR (
jbe@532 834 "member_id" NOTNULL AND
jbe@532 835 "other_member_id" ISNULL AND
jbe@532 836 "scope" ISNULL AND
jbe@532 837 "unit_id" NOTNULL AND
jbe@532 838 "area_id" NOTNULL AND
jbe@536 839 "policy_id" NOTNULL AND
jbe@532 840 "issue_id" NOTNULL AND
jbe@532 841 "state" NOTNULL AND
jbe@532 842 "initiative_id" NOTNULL AND
jbe@532 843 "draft_id" ISNULL AND
jbe@532 844 "suggestion_id" ISNULL AND
jbe@532 845 "boolean_value" NOTNULL AND
jbe@532 846 "numeric_value" ISNULL AND
jbe@532 847 "text_value" ISNULL AND
jbe@532 848 "old_text_value" ISNULL ));
jbe@532 849 ALTER TABLE "event" ADD CONSTRAINT "constr_for_support" CHECK (
jbe@532 850 "event" != 'support' OR (
jbe@532 851 "member_id" NOTNULL AND
jbe@532 852 "other_member_id" ISNULL AND
jbe@532 853 "scope" ISNULL AND
jbe@532 854 "unit_id" NOTNULL AND
jbe@532 855 "area_id" NOTNULL AND
jbe@536 856 "policy_id" NOTNULL AND
jbe@532 857 "issue_id" NOTNULL AND
jbe@532 858 "state" NOTNULL AND
jbe@532 859 "initiative_id" NOTNULL AND
jbe@532 860 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
jbe@532 861 "suggestion_id" ISNULL AND
jbe@532 862 "boolean_value" NOTNULL AND
jbe@532 863 "numeric_value" ISNULL AND
jbe@532 864 "text_value" ISNULL AND
jbe@532 865 "old_text_value" ISNULL ));
jbe@532 866 ALTER TABLE "event" ADD CONSTRAINT "constr_for_support_updated" CHECK (
jbe@532 867 "event" != 'support_updated' OR (
jbe@532 868 "member_id" NOTNULL AND
jbe@532 869 "other_member_id" ISNULL AND
jbe@532 870 "scope" ISNULL AND
jbe@532 871 "unit_id" NOTNULL AND
jbe@532 872 "area_id" NOTNULL AND
jbe@536 873 "policy_id" NOTNULL AND
jbe@532 874 "issue_id" NOTNULL AND
jbe@532 875 "state" NOTNULL AND
jbe@532 876 "initiative_id" NOTNULL AND
jbe@532 877 "draft_id" NOTNULL AND
jbe@532 878 "suggestion_id" ISNULL AND
jbe@532 879 "boolean_value" ISNULL AND
jbe@532 880 "numeric_value" ISNULL AND
jbe@532 881 "text_value" ISNULL AND
jbe@532 882 "old_text_value" ISNULL ));
jbe@532 883 ALTER TABLE "event" ADD CONSTRAINT "constr_for_suggestion_rated" CHECK (
jbe@532 884 "event" != 'suggestion_rated' OR (
jbe@532 885 "member_id" NOTNULL AND
jbe@532 886 "other_member_id" ISNULL AND
jbe@532 887 "scope" ISNULL AND
jbe@532 888 "unit_id" NOTNULL AND
jbe@532 889 "area_id" NOTNULL AND
jbe@536 890 "policy_id" NOTNULL AND
jbe@532 891 "issue_id" NOTNULL AND
jbe@532 892 "state" NOTNULL AND
jbe@532 893 "initiative_id" NOTNULL AND
jbe@532 894 "draft_id" ISNULL AND
jbe@532 895 "suggestion_id" NOTNULL AND
jbe@532 896 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
jbe@532 897 "numeric_value" NOTNULL AND
jbe@532 898 "numeric_value" IN (-2, -1, 0, 1, 2) AND
jbe@532 899 "text_value" ISNULL AND
jbe@532 900 "old_text_value" ISNULL ));
jbe@532 901 ALTER TABLE "event" ADD CONSTRAINT "constr_for_delegation" CHECK (
jbe@532 902 "event" != 'delegation' OR (
jbe@532 903 "member_id" NOTNULL AND
jbe@532 904 ("other_member_id" NOTNULL) OR ("boolean_value" = FALSE) AND
jbe@532 905 "scope" NOTNULL AND
jbe@532 906 "unit_id" NOTNULL AND
jbe@532 907 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
jbe@536 908 "policy_id" ISNULL AND
jbe@532 909 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
jbe@532 910 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
jbe@532 911 "initiative_id" ISNULL AND
jbe@532 912 "draft_id" ISNULL AND
jbe@532 913 "suggestion_id" ISNULL AND
jbe@532 914 "boolean_value" NOTNULL AND
jbe@532 915 "numeric_value" ISNULL AND
jbe@532 916 "text_value" ISNULL AND
jbe@532 917 "old_text_value" ISNULL ));
jbe@532 918 ALTER TABLE "event" ADD CONSTRAINT "constr_for_contact" CHECK (
jbe@532 919 "event" != 'contact' OR (
jbe@532 920 "member_id" NOTNULL AND
jbe@532 921 "other_member_id" NOTNULL AND
jbe@532 922 "scope" ISNULL AND
jbe@532 923 "unit_id" ISNULL AND
jbe@532 924 "area_id" ISNULL AND
jbe@536 925 "policy_id" ISNULL AND
jbe@532 926 "issue_id" ISNULL AND
jbe@532 927 "state" ISNULL AND
jbe@532 928 "initiative_id" ISNULL AND
jbe@532 929 "draft_id" ISNULL AND
jbe@532 930 "suggestion_id" ISNULL AND
jbe@532 931 "boolean_value" NOTNULL AND
jbe@532 932 "numeric_value" ISNULL AND
jbe@532 933 "text_value" ISNULL AND
jbe@532 934 "old_text_value" ISNULL ));
jbe@532 935
jbe@532 936
jbe@534 937 ALTER TABLE "notification_event_sent" RENAME TO "event_processed";
jbe@534 938 ALTER INDEX "notification_event_sent_singleton_idx" RENAME TO "event_processed_singleton_idx";
jbe@534 939
jbe@534 940 COMMENT ON TABLE "event_processed" IS 'This table stores one row with the last event_id, for which event handlers have been executed (e.g. notifications having been sent out)';
jbe@534 941 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
jbe@534 942
jbe@534 943
jbe@532 944 CREATE OR REPLACE FUNCTION "write_event_issue_state_changed_trigger"()
jbe@532 945 RETURNS TRIGGER
jbe@532 946 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 947 DECLARE
jbe@532 948 "area_row" "area"%ROWTYPE;
jbe@532 949 BEGIN
jbe@532 950 IF NEW."state" != OLD."state" THEN
jbe@532 951 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
jbe@532 952 FOR SHARE;
jbe@532 953 INSERT INTO "event" (
jbe@532 954 "event",
jbe@536 955 "unit_id", "area_id", "policy_id", "issue_id", "state"
jbe@532 956 ) VALUES (
jbe@532 957 'issue_state_changed',
jbe@536 958 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
jbe@536 959 NEW."id", NEW."state"
jbe@532 960 );
jbe@532 961 END IF;
jbe@532 962 RETURN NULL;
jbe@532 963 END;
jbe@532 964 $$;
jbe@532 965
jbe@532 966
jbe@532 967 CREATE OR REPLACE FUNCTION "write_event_initiative_or_draft_created_trigger"()
jbe@532 968 RETURNS TRIGGER
jbe@532 969 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 970 DECLARE
jbe@532 971 "initiative_row" "initiative"%ROWTYPE;
jbe@532 972 "issue_row" "issue"%ROWTYPE;
jbe@532 973 "area_row" "area"%ROWTYPE;
jbe@532 974 "event_v" "event_type";
jbe@532 975 BEGIN
jbe@532 976 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 977 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@532 978 SELECT * INTO "issue_row" FROM "issue"
jbe@532 979 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 980 SELECT * INTO "area_row" FROM "area"
jbe@532 981 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 982 IF EXISTS (
jbe@532 983 SELECT NULL FROM "draft"
jbe@532 984 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
jbe@532 985 FOR SHARE
jbe@532 986 ) THEN
jbe@532 987 "event_v" := 'new_draft_created';
jbe@532 988 ELSE
jbe@532 989 IF EXISTS (
jbe@532 990 SELECT NULL FROM "initiative"
jbe@532 991 WHERE "issue_id" = "initiative_row"."issue_id"
jbe@532 992 AND "id" != "initiative_row"."id"
jbe@532 993 FOR SHARE
jbe@532 994 ) THEN
jbe@532 995 "event_v" := 'initiative_created_in_existing_issue';
jbe@532 996 ELSE
jbe@532 997 "event_v" := 'initiative_created_in_new_issue';
jbe@532 998 END IF;
jbe@532 999 END IF;
jbe@532 1000 INSERT INTO "event" (
jbe@532 1001 "event", "member_id",
jbe@536 1002 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1003 "initiative_id", "draft_id"
jbe@532 1004 ) VALUES (
jbe@532 1005 "event_v", NEW."author_id",
jbe@536 1006 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
jbe@532 1007 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 1008 NEW."initiative_id", NEW."id"
jbe@532 1009 );
jbe@532 1010 RETURN NULL;
jbe@532 1011 END;
jbe@532 1012 $$;
jbe@532 1013
jbe@532 1014
jbe@532 1015 CREATE OR REPLACE FUNCTION "write_event_initiative_revoked_trigger"()
jbe@532 1016 RETURNS TRIGGER
jbe@532 1017 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1018 DECLARE
jbe@532 1019 "issue_row" "issue"%ROWTYPE;
jbe@532 1020 "area_row" "area"%ROWTYPE;
jbe@532 1021 "draft_id_v" "draft"."id"%TYPE;
jbe@532 1022 BEGIN
jbe@532 1023 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
jbe@532 1024 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1025 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 1026 SELECT * INTO "area_row" FROM "area"
jbe@532 1027 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1028 SELECT "id" INTO "draft_id_v" FROM "current_draft"
jbe@532 1029 WHERE "initiative_id" = NEW."id" FOR SHARE;
jbe@532 1030 INSERT INTO "event" (
jbe@532 1031 "event", "member_id",
jbe@536 1032 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1033 "initiative_id", "draft_id"
jbe@532 1034 ) VALUES (
jbe@532 1035 'initiative_revoked', NEW."revoked_by_member_id",
jbe@532 1036 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1037 "issue_row"."policy_id",
jbe@532 1038 NEW."issue_id", "issue_row"."state",
jbe@532 1039 NEW."id", "draft_id_v"
jbe@532 1040 );
jbe@532 1041 END IF;
jbe@532 1042 RETURN NULL;
jbe@532 1043 END;
jbe@532 1044 $$;
jbe@532 1045
jbe@532 1046
jbe@532 1047 CREATE OR REPLACE FUNCTION "write_event_suggestion_created_trigger"()
jbe@532 1048 RETURNS TRIGGER
jbe@532 1049 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1050 DECLARE
jbe@532 1051 "initiative_row" "initiative"%ROWTYPE;
jbe@532 1052 "issue_row" "issue"%ROWTYPE;
jbe@532 1053 "area_row" "area"%ROWTYPE;
jbe@532 1054 BEGIN
jbe@532 1055 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 1056 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@532 1057 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1058 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 1059 SELECT * INTO "area_row" FROM "area"
jbe@532 1060 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1061 INSERT INTO "event" (
jbe@532 1062 "event", "member_id",
jbe@536 1063 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1064 "initiative_id", "suggestion_id"
jbe@532 1065 ) VALUES (
jbe@532 1066 'suggestion_created', NEW."author_id",
jbe@536 1067 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
jbe@532 1068 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 1069 NEW."initiative_id", NEW."id"
jbe@532 1070 );
jbe@532 1071 RETURN NULL;
jbe@532 1072 END;
jbe@532 1073 $$;
jbe@532 1074
jbe@532 1075
jbe@532 1076 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
jbe@532 1077 RETURNS TRIGGER
jbe@532 1078 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1079 DECLARE
jbe@532 1080 "initiative_row" "initiative"%ROWTYPE;
jbe@532 1081 "issue_row" "issue"%ROWTYPE;
jbe@532 1082 "area_row" "area"%ROWTYPE;
jbe@532 1083 BEGIN
jbe@532 1084 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 1085 WHERE "id" = OLD."initiative_id" FOR SHARE;
jbe@532 1086 IF "initiative_row"."id" NOTNULL THEN
jbe@532 1087 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1088 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 1089 SELECT * INTO "area_row" FROM "area"
jbe@532 1090 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1091 INSERT INTO "event" (
jbe@532 1092 "event",
jbe@536 1093 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1094 "initiative_id", "suggestion_id"
jbe@532 1095 ) VALUES (
jbe@532 1096 'suggestion_removed',
jbe@532 1097 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1098 "issue_row"."policy_id",
jbe@532 1099 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 1100 OLD."initiative_id", OLD."id"
jbe@532 1101 );
jbe@532 1102 END IF;
jbe@532 1103 RETURN NULL;
jbe@532 1104 END;
jbe@532 1105 $$;
jbe@532 1106
jbe@532 1107 CREATE TRIGGER "write_event_suggestion_removed"
jbe@532 1108 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1109 "write_event_suggestion_removed_trigger"();
jbe@532 1110
jbe@532 1111 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
jbe@532 1112 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
jbe@532 1113
jbe@532 1114
jbe@532 1115 CREATE FUNCTION "write_event_member_trigger"()
jbe@532 1116 RETURNS TRIGGER
jbe@532 1117 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1118 BEGIN
jbe@532 1119 IF TG_OP = 'INSERT' THEN
jbe@532 1120 IF NEW."activated" NOTNULL THEN
jbe@532 1121 INSERT INTO "event" ("event", "member_id")
jbe@532 1122 VALUES ('member_activated', NEW."id");
jbe@532 1123 END IF;
jbe@532 1124 IF NEW."active" THEN
jbe@532 1125 INSERT INTO "event" ("event", "member_id", "boolean_value")
jbe@532 1126 VALUES ('member_active', NEW."id", TRUE);
jbe@532 1127 END IF;
jbe@532 1128 ELSIF TG_OP = 'UPDATE' THEN
jbe@532 1129 IF OLD."id" != NEW."id" THEN
jbe@532 1130 RAISE EXCEPTION 'Cannot change member ID';
jbe@532 1131 END IF;
jbe@532 1132 IF OLD."name" != NEW."name" THEN
jbe@532 1133 INSERT INTO "event" (
jbe@532 1134 "event", "member_id", "text_value", "old_text_value"
jbe@532 1135 ) VALUES (
jbe@532 1136 'member_name_updated', NEW."id", NEW."name", OLD."name"
jbe@532 1137 );
jbe@532 1138 END IF;
jbe@532 1139 IF OLD."active" != NEW."active" THEN
jbe@532 1140 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
jbe@532 1141 'member_active', NEW."id", NEW."active"
jbe@532 1142 );
jbe@532 1143 END IF;
jbe@532 1144 IF
jbe@532 1145 OLD."activated" NOTNULL AND
jbe@532 1146 NEW."last_login" ISNULL AND
jbe@532 1147 NEW."login" ISNULL AND
jbe@532 1148 NEW."authority_login" ISNULL AND
jbe@532 1149 NEW."locked" = TRUE
jbe@532 1150 THEN
jbe@532 1151 INSERT INTO "event" ("event", "member_id")
jbe@532 1152 VALUES ('member_removed', NEW."id");
jbe@532 1153 END IF;
jbe@532 1154 END IF;
jbe@532 1155 RETURN NULL;
jbe@532 1156 END;
jbe@532 1157 $$;
jbe@532 1158
jbe@532 1159 CREATE TRIGGER "write_event_member"
jbe@532 1160 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1161 "write_event_member_trigger"();
jbe@532 1162
jbe@532 1163 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
jbe@532 1164 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
jbe@532 1165
jbe@532 1166
jbe@532 1167 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
jbe@532 1168 RETURNS TRIGGER
jbe@532 1169 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1170 BEGIN
jbe@532 1171 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 1172 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
jbe@532 1173 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 1174 'member_profile_updated', OLD."member_id"
jbe@532 1175 );
jbe@532 1176 END IF;
jbe@532 1177 END IF;
jbe@532 1178 IF TG_OP = 'UPDATE' THEN
jbe@532 1179 IF OLD."member_id" = NEW."member_id" THEN
jbe@532 1180 RETURN NULL;
jbe@532 1181 END IF;
jbe@532 1182 END IF;
jbe@532 1183 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 1184 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 1185 'member_profile_updated', NEW."member_id"
jbe@532 1186 );
jbe@532 1187 END IF;
jbe@532 1188 RETURN NULL;
jbe@532 1189 END;
jbe@532 1190 $$;
jbe@532 1191
jbe@532 1192 CREATE TRIGGER "write_event_member_profile_updated"
jbe@532 1193 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
jbe@532 1194 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1195 "write_event_member_profile_updated_trigger"();
jbe@532 1196
jbe@532 1197 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
jbe@532 1198 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
jbe@532 1199
jbe@532 1200
jbe@532 1201 CREATE FUNCTION "write_event_member_image_updated_trigger"()
jbe@532 1202 RETURNS TRIGGER
jbe@532 1203 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1204 BEGIN
jbe@532 1205 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 1206 IF NOT OLD."scaled" THEN
jbe@532 1207 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
jbe@532 1208 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 1209 'member_image_updated', OLD."member_id"
jbe@532 1210 );
jbe@532 1211 END IF;
jbe@532 1212 END IF;
jbe@532 1213 END IF;
jbe@532 1214 IF TG_OP = 'UPDATE' THEN
jbe@532 1215 IF
jbe@532 1216 OLD."member_id" = NEW."member_id" AND
jbe@532 1217 OLD."scaled" = NEW."scaled"
jbe@532 1218 THEN
jbe@532 1219 RETURN NULL;
jbe@532 1220 END IF;
jbe@532 1221 END IF;
jbe@532 1222 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 1223 IF NOT NEW."scaled" THEN
jbe@532 1224 INSERT INTO "event" ("event", "member_id") VALUES (
jbe@532 1225 'member_image_updated', NEW."member_id"
jbe@532 1226 );
jbe@532 1227 END IF;
jbe@532 1228 END IF;
jbe@532 1229 RETURN NULL;
jbe@532 1230 END;
jbe@532 1231 $$;
jbe@532 1232
jbe@532 1233 CREATE TRIGGER "write_event_member_image_updated"
jbe@532 1234 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
jbe@532 1235 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1236 "write_event_member_image_updated_trigger"();
jbe@532 1237
jbe@532 1238 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
jbe@532 1239 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
jbe@532 1240
jbe@532 1241
jbe@532 1242 CREATE FUNCTION "write_event_interest_trigger"()
jbe@532 1243 RETURNS TRIGGER
jbe@532 1244 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1245 DECLARE
jbe@532 1246 "issue_row" "issue"%ROWTYPE;
jbe@532 1247 "area_row" "area"%ROWTYPE;
jbe@532 1248 BEGIN
jbe@532 1249 IF TG_OP = 'UPDATE' THEN
jbe@532 1250 IF OLD = NEW THEN
jbe@532 1251 RETURN NULL;
jbe@532 1252 END IF;
jbe@532 1253 END IF;
jbe@532 1254 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 1255 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1256 WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@532 1257 SELECT * INTO "area_row" FROM "area"
jbe@532 1258 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1259 IF "issue_row"."id" NOTNULL THEN
jbe@532 1260 INSERT INTO "event" (
jbe@532 1261 "event", "member_id",
jbe@536 1262 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1263 "boolean_value"
jbe@532 1264 ) VALUES (
jbe@532 1265 'interest', OLD."member_id",
jbe@532 1266 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1267 "issue_row"."policy_id",
jbe@532 1268 OLD."issue_id", "issue_row"."state",
jbe@532 1269 FALSE
jbe@532 1270 );
jbe@532 1271 END IF;
jbe@532 1272 END IF;
jbe@532 1273 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 1274 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1275 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 1276 SELECT * INTO "area_row" FROM "area"
jbe@532 1277 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1278 INSERT INTO "event" (
jbe@532 1279 "event", "member_id",
jbe@536 1280 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1281 "boolean_value"
jbe@532 1282 ) VALUES (
jbe@532 1283 'interest', NEW."member_id",
jbe@532 1284 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1285 "issue_row"."policy_id",
jbe@532 1286 NEW."issue_id", "issue_row"."state",
jbe@532 1287 TRUE
jbe@532 1288 );
jbe@532 1289 END IF;
jbe@532 1290 RETURN NULL;
jbe@532 1291 END;
jbe@532 1292 $$;
jbe@532 1293
jbe@532 1294 CREATE TRIGGER "write_event_interest"
jbe@532 1295 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1296 "write_event_interest_trigger"();
jbe@532 1297
jbe@532 1298 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
jbe@532 1299 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
jbe@532 1300
jbe@532 1301
jbe@532 1302 CREATE FUNCTION "write_event_initiator_trigger"()
jbe@532 1303 RETURNS TRIGGER
jbe@532 1304 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1305 DECLARE
jbe@532 1306 "initiative_row" "initiative"%ROWTYPE;
jbe@532 1307 "issue_row" "issue"%ROWTYPE;
jbe@532 1308 "area_row" "area"%ROWTYPE;
jbe@532 1309 BEGIN
jbe@532 1310 IF TG_OP = 'UPDATE' THEN
jbe@532 1311 IF
jbe@532 1312 OLD."initiative_id" = NEW."initiative_id" AND
jbe@532 1313 OLD."member_id" = NEW."member_id" AND
jbe@532 1314 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
jbe@532 1315 THEN
jbe@532 1316 RETURN NULL;
jbe@532 1317 END IF;
jbe@532 1318 END IF;
jbe@532 1319 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
jbe@532 1320 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
jbe@532 1321 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 1322 WHERE "id" = OLD."initiative_id" FOR SHARE;
jbe@532 1323 IF "initiative_row"."id" NOTNULL THEN
jbe@532 1324 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1325 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 1326 SELECT * INTO "area_row" FROM "area"
jbe@532 1327 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1328 INSERT INTO "event" (
jbe@532 1329 "event", "member_id",
jbe@536 1330 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1331 "initiative_id", "boolean_value"
jbe@532 1332 ) VALUES (
jbe@532 1333 'initiator', OLD."member_id",
jbe@532 1334 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1335 "issue_row"."policy_id",
jbe@532 1336 "issue_row"."id", "issue_row"."state",
jbe@532 1337 OLD."initiative_id", FALSE
jbe@532 1338 );
jbe@532 1339 END IF;
jbe@532 1340 END IF;
jbe@532 1341 END IF;
jbe@532 1342 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
jbe@532 1343 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
jbe@532 1344 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 1345 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@532 1346 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1347 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 1348 SELECT * INTO "area_row" FROM "area"
jbe@532 1349 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1350 INSERT INTO "event" (
jbe@532 1351 "event", "member_id",
jbe@536 1352 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1353 "initiative_id", "boolean_value"
jbe@532 1354 ) VALUES (
jbe@532 1355 'initiator', NEW."member_id",
jbe@532 1356 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1357 "issue_row"."policy_id",
jbe@532 1358 "issue_row"."id", "issue_row"."state",
jbe@532 1359 NEW."initiative_id", TRUE
jbe@532 1360 );
jbe@532 1361 END IF;
jbe@532 1362 END IF;
jbe@532 1363 RETURN NULL;
jbe@532 1364 END;
jbe@532 1365 $$;
jbe@532 1366
jbe@532 1367 CREATE TRIGGER "write_event_initiator"
jbe@532 1368 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1369 "write_event_initiator_trigger"();
jbe@532 1370
jbe@532 1371 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
jbe@532 1372 COMMENT ON TRIGGER "write_event_initiator" ON "initiator" IS 'Create entry in "event" table when accepting or removing initiatorship (NOTE: trigger does not fire on INSERT to avoid events on initiative creation)';
jbe@532 1373
jbe@532 1374
jbe@532 1375 CREATE FUNCTION "write_event_support_trigger"()
jbe@532 1376 RETURNS TRIGGER
jbe@532 1377 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1378 DECLARE
jbe@532 1379 "issue_row" "issue"%ROWTYPE;
jbe@532 1380 "area_row" "area"%ROWTYPE;
jbe@532 1381 BEGIN
jbe@532 1382 IF TG_OP = 'UPDATE' THEN
jbe@532 1383 IF
jbe@532 1384 OLD."initiative_id" = NEW."initiative_id" AND
jbe@532 1385 OLD."member_id" = NEW."member_id"
jbe@532 1386 THEN
jbe@532 1387 IF OLD."draft_id" != NEW."draft_id" THEN
jbe@532 1388 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1389 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 1390 SELECT * INTO "area_row" FROM "area"
jbe@532 1391 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1392 INSERT INTO "event" (
jbe@532 1393 "event", "member_id",
jbe@536 1394 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1395 "initiative_id", "draft_id"
jbe@532 1396 ) VALUES (
jbe@532 1397 'support_updated', NEW."member_id",
jbe@532 1398 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1399 "issue_row"."policy_id",
jbe@532 1400 "issue_row"."id", "issue_row"."state",
jbe@532 1401 NEW."initiative_id", NEW."draft_id"
jbe@532 1402 );
jbe@532 1403 END IF;
jbe@532 1404 RETURN NULL;
jbe@532 1405 END IF;
jbe@532 1406 END IF;
jbe@532 1407 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 1408 IF EXISTS (
jbe@532 1409 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
jbe@532 1410 FOR SHARE
jbe@532 1411 ) THEN
jbe@532 1412 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1413 WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@532 1414 SELECT * INTO "area_row" FROM "area"
jbe@532 1415 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1416 INSERT INTO "event" (
jbe@532 1417 "event", "member_id",
jbe@536 1418 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@535 1419 "initiative_id", "boolean_value"
jbe@532 1420 ) VALUES (
jbe@532 1421 'support', OLD."member_id",
jbe@532 1422 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1423 "issue_row"."policy_id",
jbe@532 1424 "issue_row"."id", "issue_row"."state",
jbe@535 1425 OLD."initiative_id", FALSE
jbe@532 1426 );
jbe@532 1427 END IF;
jbe@532 1428 END IF;
jbe@532 1429 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 1430 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1431 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 1432 SELECT * INTO "area_row" FROM "area"
jbe@532 1433 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1434 INSERT INTO "event" (
jbe@532 1435 "event", "member_id",
jbe@536 1436 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1437 "initiative_id", "draft_id", "boolean_value"
jbe@532 1438 ) VALUES (
jbe@532 1439 'support', NEW."member_id",
jbe@532 1440 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1441 "issue_row"."policy_id",
jbe@532 1442 "issue_row"."id", "issue_row"."state",
jbe@532 1443 NEW."initiative_id", NEW."draft_id", TRUE
jbe@532 1444 );
jbe@532 1445 END IF;
jbe@532 1446 RETURN NULL;
jbe@532 1447 END;
jbe@532 1448 $$;
jbe@532 1449
jbe@532 1450 CREATE TRIGGER "write_event_support"
jbe@532 1451 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1452 "write_event_support_trigger"();
jbe@532 1453
jbe@532 1454 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
jbe@532 1455 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
jbe@532 1456
jbe@532 1457
jbe@532 1458 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
jbe@532 1459 RETURNS TRIGGER
jbe@532 1460 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1461 DECLARE
jbe@532 1462 "same_pkey_v" BOOLEAN = FALSE;
jbe@532 1463 "initiative_row" "initiative"%ROWTYPE;
jbe@532 1464 "issue_row" "issue"%ROWTYPE;
jbe@532 1465 "area_row" "area"%ROWTYPE;
jbe@532 1466 BEGIN
jbe@532 1467 IF TG_OP = 'UPDATE' THEN
jbe@532 1468 IF
jbe@532 1469 OLD."suggestion_id" = NEW."suggestion_id" AND
jbe@532 1470 OLD."member_id" = NEW."member_id"
jbe@532 1471 THEN
jbe@532 1472 IF
jbe@532 1473 OLD."degree" = NEW."degree" AND
jbe@532 1474 OLD."fulfilled" = NEW."fulfilled"
jbe@532 1475 THEN
jbe@532 1476 RETURN NULL;
jbe@532 1477 END IF;
jbe@532 1478 "same_pkey_v" := TRUE;
jbe@532 1479 END IF;
jbe@532 1480 END IF;
jbe@532 1481 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
jbe@532 1482 IF EXISTS (
jbe@532 1483 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
jbe@532 1484 FOR SHARE
jbe@532 1485 ) THEN
jbe@532 1486 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 1487 WHERE "id" = OLD."initiative_id" FOR SHARE;
jbe@532 1488 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1489 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 1490 SELECT * INTO "area_row" FROM "area"
jbe@532 1491 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1492 INSERT INTO "event" (
jbe@532 1493 "event", "member_id",
jbe@536 1494 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1495 "initiative_id", "suggestion_id",
jbe@532 1496 "boolean_value", "numeric_value"
jbe@532 1497 ) VALUES (
jbe@532 1498 'suggestion_rated', OLD."member_id",
jbe@532 1499 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1500 "issue_row"."policy_id",
jbe@532 1501 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 1502 OLD."initiative_id", OLD."suggestion_id",
jbe@532 1503 NULL, 0
jbe@532 1504 );
jbe@532 1505 END IF;
jbe@532 1506 END IF;
jbe@532 1507 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 1508 SELECT * INTO "initiative_row" FROM "initiative"
jbe@532 1509 WHERE "id" = NEW."initiative_id" FOR SHARE;
jbe@532 1510 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1511 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
jbe@532 1512 SELECT * INTO "area_row" FROM "area"
jbe@532 1513 WHERE "id" = "issue_row"."area_id" FOR SHARE;
jbe@532 1514 INSERT INTO "event" (
jbe@532 1515 "event", "member_id",
jbe@536 1516 "unit_id", "area_id", "policy_id", "issue_id", "state",
jbe@532 1517 "initiative_id", "suggestion_id",
jbe@532 1518 "boolean_value", "numeric_value"
jbe@532 1519 ) VALUES (
jbe@532 1520 'suggestion_rated', NEW."member_id",
jbe@532 1521 "area_row"."unit_id", "issue_row"."area_id",
jbe@536 1522 "issue_row"."policy_id",
jbe@532 1523 "initiative_row"."issue_id", "issue_row"."state",
jbe@532 1524 NEW."initiative_id", NEW."suggestion_id",
jbe@532 1525 NEW."fulfilled", NEW."degree"
jbe@532 1526 );
jbe@532 1527 END IF;
jbe@532 1528 RETURN NULL;
jbe@532 1529 END;
jbe@532 1530 $$;
jbe@532 1531
jbe@532 1532 CREATE TRIGGER "write_event_suggestion_rated"
jbe@532 1533 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1534 "write_event_suggestion_rated_trigger"();
jbe@532 1535
jbe@532 1536 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
jbe@532 1537 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
jbe@532 1538
jbe@532 1539
jbe@532 1540 CREATE FUNCTION "write_event_delegation_trigger"()
jbe@532 1541 RETURNS TRIGGER
jbe@532 1542 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1543 DECLARE
jbe@532 1544 "issue_row" "issue"%ROWTYPE;
jbe@532 1545 "area_row" "area"%ROWTYPE;
jbe@532 1546 BEGIN
jbe@532 1547 IF TG_OP = 'DELETE' THEN
jbe@532 1548 IF EXISTS (
jbe@532 1549 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
jbe@532 1550 ) AND (CASE OLD."scope"
jbe@532 1551 WHEN 'unit'::"delegation_scope" THEN EXISTS (
jbe@532 1552 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
jbe@532 1553 )
jbe@532 1554 WHEN 'area'::"delegation_scope" THEN EXISTS (
jbe@532 1555 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
jbe@532 1556 )
jbe@532 1557 WHEN 'issue'::"delegation_scope" THEN EXISTS (
jbe@532 1558 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
jbe@532 1559 )
jbe@532 1560 END) THEN
jbe@532 1561 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1562 WHERE "id" = OLD."issue_id" FOR SHARE;
jbe@532 1563 SELECT * INTO "area_row" FROM "area"
jbe@532 1564 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
jbe@532 1565 FOR SHARE;
jbe@532 1566 INSERT INTO "event" (
jbe@532 1567 "event", "member_id", "scope",
jbe@532 1568 "unit_id", "area_id", "issue_id", "state",
jbe@532 1569 "boolean_value"
jbe@532 1570 ) VALUES (
jbe@532 1571 'delegation', OLD."truster_id", OLD."scope",
jbe@532 1572 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
jbe@532 1573 OLD."issue_id", "issue_row"."state",
jbe@532 1574 FALSE
jbe@532 1575 );
jbe@532 1576 END IF;
jbe@532 1577 ELSE
jbe@532 1578 SELECT * INTO "issue_row" FROM "issue"
jbe@532 1579 WHERE "id" = NEW."issue_id" FOR SHARE;
jbe@532 1580 SELECT * INTO "area_row" FROM "area"
jbe@532 1581 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
jbe@532 1582 FOR SHARE;
jbe@532 1583 INSERT INTO "event" (
jbe@532 1584 "event", "member_id", "other_member_id", "scope",
jbe@532 1585 "unit_id", "area_id", "issue_id", "state",
jbe@532 1586 "boolean_value"
jbe@532 1587 ) VALUES (
jbe@532 1588 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
jbe@532 1589 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
jbe@532 1590 NEW."issue_id", "issue_row"."state",
jbe@532 1591 TRUE
jbe@532 1592 );
jbe@532 1593 END IF;
jbe@532 1594 RETURN NULL;
jbe@532 1595 END;
jbe@532 1596 $$;
jbe@532 1597
jbe@532 1598 CREATE TRIGGER "write_event_delegation"
jbe@532 1599 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1600 "write_event_delegation_trigger"();
jbe@532 1601
jbe@532 1602 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
jbe@532 1603 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
jbe@532 1604
jbe@532 1605
jbe@532 1606 CREATE FUNCTION "write_event_contact_trigger"()
jbe@532 1607 RETURNS TRIGGER
jbe@532 1608 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1609 BEGIN
jbe@532 1610 IF TG_OP = 'UPDATE' THEN
jbe@532 1611 IF
jbe@532 1612 OLD."member_id" = NEW."member_id" AND
jbe@532 1613 OLD."other_member_id" = NEW."other_member_id" AND
jbe@532 1614 OLD."public" = NEW."public"
jbe@532 1615 THEN
jbe@532 1616 RETURN NULL;
jbe@532 1617 END IF;
jbe@532 1618 END IF;
jbe@532 1619 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
jbe@532 1620 IF OLD."public" THEN
jbe@532 1621 IF EXISTS (
jbe@532 1622 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
jbe@532 1623 FOR SHARE
jbe@532 1624 ) AND EXISTS (
jbe@532 1625 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
jbe@532 1626 FOR SHARE
jbe@532 1627 ) THEN
jbe@532 1628 INSERT INTO "event" (
jbe@532 1629 "event", "member_id", "other_member_id", "boolean_value"
jbe@532 1630 ) VALUES (
jbe@532 1631 'contact', OLD."member_id", OLD."other_member_id", FALSE
jbe@532 1632 );
jbe@532 1633 END IF;
jbe@532 1634 END IF;
jbe@532 1635 END IF;
jbe@532 1636 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
jbe@532 1637 IF NEW."public" THEN
jbe@532 1638 INSERT INTO "event" (
jbe@532 1639 "event", "member_id", "other_member_id", "boolean_value"
jbe@532 1640 ) VALUES (
jbe@532 1641 'contact', NEW."member_id", NEW."other_member_id", TRUE
jbe@532 1642 );
jbe@532 1643 END IF;
jbe@532 1644 END IF;
jbe@532 1645 RETURN NULL;
jbe@532 1646 END;
jbe@532 1647 $$;
jbe@532 1648
jbe@532 1649 CREATE TRIGGER "write_event_contact"
jbe@532 1650 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1651 "write_event_contact_trigger"();
jbe@532 1652
jbe@532 1653 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
jbe@532 1654 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
jbe@532 1655
jbe@532 1656
jbe@532 1657 CREATE FUNCTION "send_event_notify_trigger"()
jbe@532 1658 RETURNS TRIGGER
jbe@532 1659 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1660 BEGIN
jbe@532 1661 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
jbe@532 1662 RETURN NULL;
jbe@532 1663 END;
jbe@532 1664 $$;
jbe@532 1665
jbe@532 1666 CREATE TRIGGER "send_notify"
jbe@532 1667 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1668 "send_event_notify_trigger"();
jbe@532 1669
jbe@532 1670
jbe@532 1671 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
jbe@532 1672 RETURNS TRIGGER
jbe@532 1673 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1674 DECLARE
jbe@532 1675 "system_application_row" "system_application"%ROWTYPE;
jbe@532 1676 BEGIN
jbe@532 1677 IF OLD."system_application_id" NOTNULL THEN
jbe@532 1678 SELECT * FROM "system_application" INTO "system_application_row"
jbe@532 1679 WHERE "id" = OLD."system_application_id";
jbe@532 1680 DELETE FROM "token"
jbe@532 1681 WHERE "member_id" = OLD."member_id"
jbe@532 1682 AND "system_application_id" = OLD."system_application_id"
jbe@532 1683 AND NOT COALESCE(
jbe@532 1684 regexp_split_to_array("scope", E'\\s+') <@
jbe@532 1685 regexp_split_to_array(
jbe@532 1686 "system_application_row"."automatic_scope", E'\\s+'
jbe@532 1687 ),
jbe@532 1688 FALSE
jbe@532 1689 );
jbe@532 1690 END IF;
jbe@532 1691 RETURN OLD;
jbe@532 1692 END;
jbe@532 1693 $$;
jbe@532 1694
jbe@532 1695 CREATE TRIGGER "delete_extended_scope_tokens"
jbe@532 1696 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1697 "delete_extended_scope_tokens_trigger"();
jbe@532 1698
jbe@532 1699
jbe@532 1700 CREATE FUNCTION "detach_token_from_session_trigger"()
jbe@532 1701 RETURNS TRIGGER
jbe@532 1702 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1703 BEGIN
jbe@532 1704 UPDATE "token" SET "session_id" = NULL
jbe@532 1705 WHERE "session_id" = OLD."id";
jbe@532 1706 RETURN OLD;
jbe@532 1707 END;
jbe@532 1708 $$;
jbe@532 1709
jbe@532 1710 CREATE TRIGGER "detach_token_from_session"
jbe@532 1711 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1712 "detach_token_from_session_trigger"();
jbe@532 1713
jbe@532 1714
jbe@532 1715 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
jbe@532 1716 RETURNS TRIGGER
jbe@532 1717 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1718 BEGIN
jbe@532 1719 IF NEW."session_id" ISNULL THEN
jbe@532 1720 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
jbe@532 1721 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
jbe@532 1722 WHERE "element" LIKE '%_detached';
jbe@532 1723 END IF;
jbe@532 1724 RETURN NEW;
jbe@532 1725 END;
jbe@532 1726 $$;
jbe@532 1727
jbe@532 1728 CREATE TRIGGER "delete_non_detached_scope_with_session"
jbe@532 1729 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1730 "delete_non_detached_scope_with_session_trigger"();
jbe@532 1731
jbe@532 1732
jbe@532 1733 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
jbe@532 1734 RETURNS TRIGGER
jbe@532 1735 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1736 BEGIN
jbe@532 1737 IF NEW."scope" = '' THEN
jbe@532 1738 DELETE FROM "token" WHERE "id" = NEW."id";
jbe@532 1739 END IF;
jbe@532 1740 RETURN NULL;
jbe@532 1741 END;
jbe@532 1742 $$;
jbe@532 1743
jbe@532 1744 CREATE TRIGGER "delete_token_with_empty_scope"
jbe@532 1745 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1746 "delete_token_with_empty_scope_trigger"();
jbe@532 1747
jbe@532 1748
jbe@532 1749 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
jbe@532 1750 RETURNS TRIGGER
jbe@532 1751 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1752 BEGIN
jbe@532 1753 IF TG_OP = 'UPDATE' THEN
jbe@532 1754 IF
jbe@532 1755 OLD."snapshot_id" = NEW."snapshot_id" AND
jbe@532 1756 OLD."issue_id" = NEW."issue_id"
jbe@532 1757 THEN
jbe@532 1758 RETURN NULL;
jbe@532 1759 END IF;
jbe@532 1760 END IF;
jbe@532 1761 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
jbe@532 1762 RETURN NULL;
jbe@532 1763 END;
jbe@532 1764 $$;
jbe@532 1765
jbe@532 1766 CREATE TRIGGER "delete_snapshot_on_partial_delete"
jbe@532 1767 AFTER UPDATE OR DELETE ON "snapshot_issue"
jbe@532 1768 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1769 "delete_snapshot_on_partial_delete_trigger"();
jbe@532 1770
jbe@532 1771 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
jbe@532 1772 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
jbe@532 1773
jbe@532 1774
jbe@532 1775 CREATE FUNCTION "copy_current_draft_data"
jbe@532 1776 ("initiative_id_p" "initiative"."id"%TYPE )
jbe@532 1777 RETURNS VOID
jbe@532 1778 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1779 BEGIN
jbe@532 1780 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
jbe@532 1781 FOR UPDATE;
jbe@532 1782 UPDATE "initiative" SET
jbe@532 1783 "location" = "draft"."location",
jbe@532 1784 "draft_text_search_data" = "draft"."text_search_data"
jbe@532 1785 FROM "current_draft" AS "draft"
jbe@532 1786 WHERE "initiative"."id" = "initiative_id_p"
jbe@532 1787 AND "draft"."initiative_id" = "initiative_id_p";
jbe@532 1788 END;
jbe@532 1789 $$;
jbe@532 1790
jbe@532 1791 COMMENT ON FUNCTION "copy_current_draft_data"
jbe@532 1792 ( "initiative"."id"%TYPE )
jbe@532 1793 IS 'Helper function for function "copy_current_draft_data_trigger"';
jbe@532 1794
jbe@532 1795
jbe@532 1796 CREATE FUNCTION "copy_current_draft_data_trigger"()
jbe@532 1797 RETURNS TRIGGER
jbe@532 1798 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 1799 BEGIN
jbe@532 1800 IF TG_OP='DELETE' THEN
jbe@532 1801 PERFORM "copy_current_draft_data"(OLD."initiative_id");
jbe@532 1802 ELSE
jbe@532 1803 IF TG_OP='UPDATE' THEN
jbe@532 1804 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
jbe@532 1805 PERFORM "copy_current_draft_data"(OLD."initiative_id");
jbe@532 1806 END IF;
jbe@532 1807 END IF;
jbe@532 1808 PERFORM "copy_current_draft_data"(NEW."initiative_id");
jbe@532 1809 END IF;
jbe@532 1810 RETURN NULL;
jbe@532 1811 END;
jbe@532 1812 $$;
jbe@532 1813
jbe@532 1814 CREATE TRIGGER "copy_current_draft_data"
jbe@532 1815 AFTER INSERT OR UPDATE OR DELETE ON "draft"
jbe@532 1816 FOR EACH ROW EXECUTE PROCEDURE
jbe@532 1817 "copy_current_draft_data_trigger"();
jbe@532 1818
jbe@532 1819 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
jbe@532 1820 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
jbe@532 1821
jbe@532 1822
jbe@532 1823 CREATE VIEW "area_quorum" AS
jbe@532 1824 SELECT
jbe@532 1825 "area"."id" AS "area_id",
jbe@532 1826 ceil(
jbe@532 1827 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
jbe@532 1828 coalesce(
jbe@532 1829 ( SELECT sum(
jbe@532 1830 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
jbe@532 1831 extract(epoch from
jbe@532 1832 ("issue"."accepted"-"issue"."created") +
jbe@532 1833 "issue"."discussion_time" +
jbe@532 1834 "issue"."verification_time" +
jbe@532 1835 "issue"."voting_time"
jbe@532 1836 )::FLOAT8
jbe@532 1837 ) ^ "area"."quorum_exponent"::FLOAT8
jbe@532 1838 )
jbe@532 1839 FROM "issue" JOIN "policy"
jbe@532 1840 ON "issue"."policy_id" = "policy"."id"
jbe@532 1841 WHERE "issue"."area_id" = "area"."id"
jbe@532 1842 AND "issue"."accepted" NOTNULL
jbe@532 1843 AND "issue"."closed" ISNULL
jbe@532 1844 AND "policy"."polling" = FALSE
jbe@532 1845 )::FLOAT8, 0::FLOAT8
jbe@532 1846 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
jbe@532 1847 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
jbe@532 1848 SELECT "snapshot"."population"
jbe@532 1849 FROM "snapshot"
jbe@532 1850 WHERE "snapshot"."area_id" = "area"."id"
jbe@532 1851 AND "snapshot"."issue_id" ISNULL
jbe@532 1852 ORDER BY "snapshot"."id" DESC
jbe@532 1853 LIMIT 1
jbe@532 1854 ) END / coalesce("area"."quorum_den", 1)
jbe@532 1855
jbe@532 1856 )::INT4 AS "issue_quorum"
jbe@532 1857 FROM "area";
jbe@532 1858
jbe@532 1859 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
jbe@532 1860
jbe@532 1861
jbe@532 1862 CREATE VIEW "area_with_unaccepted_issues" AS
jbe@532 1863 SELECT DISTINCT ON ("area"."id") "area".*
jbe@532 1864 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
jbe@532 1865 WHERE "issue"."state" = 'admission';
jbe@532 1866
jbe@532 1867 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
jbe@532 1868
jbe@532 1869
jbe@532 1870 DROP VIEW "area_member_count";
jbe@532 1871
jbe@532 1872
jbe@532 1873 DROP TABLE "membership";
jbe@532 1874
jbe@532 1875
jbe@532 1876 DROP FUNCTION "membership_weight"
jbe@532 1877 ( "area_id_p" "area"."id"%TYPE,
jbe@532 1878 "member_id_p" "member"."id"%TYPE );
jbe@532 1879
jbe@532 1880
jbe@532 1881 DROP FUNCTION "membership_weight_with_skipping"
jbe@532 1882 ( "area_id_p" "area"."id"%TYPE,
jbe@532 1883 "member_id_p" "member"."id"%TYPE,
jbe@532 1884 "skip_member_ids_p" INT4[] ); -- TODO: ordering/cascade
jbe@532 1885
jbe@532 1886
jbe@532 1887 CREATE OR REPLACE VIEW "issue_delegation" AS
jbe@532 1888 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
jbe@532 1889 "issue"."id" AS "issue_id",
jbe@532 1890 "delegation"."id",
jbe@532 1891 "delegation"."truster_id",
jbe@532 1892 "delegation"."trustee_id",
jbe@532 1893 "delegation"."scope"
jbe@532 1894 FROM "issue"
jbe@532 1895 JOIN "area"
jbe@532 1896 ON "area"."id" = "issue"."area_id"
jbe@532 1897 JOIN "delegation"
jbe@532 1898 ON "delegation"."unit_id" = "area"."unit_id"
jbe@532 1899 OR "delegation"."area_id" = "area"."id"
jbe@532 1900 OR "delegation"."issue_id" = "issue"."id"
jbe@532 1901 JOIN "member"
jbe@532 1902 ON "delegation"."truster_id" = "member"."id"
jbe@532 1903 JOIN "privilege"
jbe@532 1904 ON "area"."unit_id" = "privilege"."unit_id"
jbe@532 1905 AND "delegation"."truster_id" = "privilege"."member_id"
jbe@532 1906 WHERE "member"."active" AND "privilege"."voting_right"
jbe@532 1907 ORDER BY
jbe@532 1908 "issue"."id",
jbe@532 1909 "delegation"."truster_id",
jbe@532 1910 "delegation"."scope" DESC;
jbe@532 1911
jbe@532 1912
jbe@532 1913 CREATE VIEW "unit_member" AS
jbe@532 1914 SELECT
jbe@532 1915 "unit"."id" AS "unit_id",
jbe@532 1916 "member"."id" AS "member_id"
jbe@532 1917 FROM "privilege"
jbe@532 1918 JOIN "unit" ON "unit_id" = "privilege"."unit_id"
jbe@532 1919 JOIN "member" ON "member"."id" = "privilege"."member_id"
jbe@532 1920 WHERE "privilege"."voting_right" AND "member"."active";
jbe@532 1921
jbe@532 1922 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
jbe@532 1923
jbe@532 1924
jbe@532 1925 CREATE OR REPLACE VIEW "unit_member_count" AS
jbe@532 1926 SELECT
jbe@532 1927 "unit"."id" AS "unit_id",
jbe@532 1928 count("unit_member"."member_id") AS "member_count"
jbe@532 1929 FROM "unit" LEFT JOIN "unit_member"
jbe@532 1930 ON "unit"."id" = "unit_member"."unit_id"
jbe@532 1931 GROUP BY "unit"."id";
jbe@532 1932
jbe@532 1933 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
jbe@532 1934
jbe@532 1935
jbe@532 1936 CREATE OR REPLACE VIEW "opening_draft" AS
jbe@532 1937 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
jbe@532 1938 ORDER BY "initiative_id", "id";
jbe@532 1939
jbe@532 1940
jbe@532 1941 CREATE OR REPLACE VIEW "current_draft" AS
jbe@532 1942 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
jbe@532 1943 ORDER BY "initiative_id", "id" DESC;
jbe@532 1944
jbe@532 1945
jbe@532 1946 CREATE OR REPLACE VIEW "issue_supporter_in_admission_state" AS
jbe@532 1947 SELECT
jbe@532 1948 "area"."unit_id",
jbe@532 1949 "issue"."area_id",
jbe@532 1950 "issue"."id" AS "issue_id",
jbe@532 1951 "supporter"."member_id",
jbe@532 1952 "direct_interest_snapshot"."weight"
jbe@532 1953 FROM "issue"
jbe@532 1954 JOIN "area" ON "area"."id" = "issue"."area_id"
jbe@532 1955 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
jbe@532 1956 JOIN "direct_interest_snapshot"
jbe@532 1957 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
jbe@532 1958 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@532 1959 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
jbe@532 1960 WHERE "issue"."state" = 'admission'::"issue_state";
jbe@532 1961
jbe@532 1962
jbe@532 1963 CREATE OR REPLACE VIEW "individual_suggestion_ranking" AS
jbe@532 1964 SELECT
jbe@532 1965 "opinion"."initiative_id",
jbe@532 1966 "opinion"."member_id",
jbe@532 1967 "direct_interest_snapshot"."weight",
jbe@532 1968 CASE WHEN
jbe@532 1969 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
jbe@532 1970 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
jbe@532 1971 THEN 1 ELSE
jbe@532 1972 CASE WHEN
jbe@532 1973 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
jbe@532 1974 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
jbe@532 1975 THEN 2 ELSE
jbe@532 1976 CASE WHEN
jbe@532 1977 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
jbe@532 1978 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
jbe@532 1979 THEN 3 ELSE 4 END
jbe@532 1980 END
jbe@532 1981 END AS "preference",
jbe@532 1982 "opinion"."suggestion_id"
jbe@532 1983 FROM "opinion"
jbe@532 1984 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
jbe@532 1985 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
jbe@532 1986 JOIN "direct_interest_snapshot"
jbe@532 1987 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
jbe@532 1988 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
jbe@532 1989 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
jbe@532 1990
jbe@532 1991
jbe@532 1992 CREATE VIEW "expired_session" AS
jbe@532 1993 SELECT * FROM "session" WHERE now() > "expiry";
jbe@532 1994
jbe@532 1995 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
jbe@532 1996 DELETE FROM "session" WHERE "id" = OLD."id";
jbe@532 1997
jbe@532 1998 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
jbe@532 1999 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
jbe@532 2000
jbe@532 2001
jbe@532 2002 CREATE VIEW "expired_token" AS
jbe@532 2003 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
jbe@532 2004 "token_type" = 'authorization' AND "used" AND EXISTS (
jbe@532 2005 SELECT NULL FROM "token" AS "other"
jbe@532 2006 WHERE "other"."authorization_token_id" = "id" ) );
jbe@532 2007
jbe@532 2008 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
jbe@532 2009 DELETE FROM "token" WHERE "id" = OLD."id";
jbe@532 2010
jbe@532 2011 COMMENT ON VIEW "expired_token" IS 'View containing all expired tokens where DELETE is possible; Note that used authorization codes must not be deleted if still referred to by other tokens';
jbe@532 2012
jbe@532 2013
jbe@532 2014 CREATE VIEW "unused_snapshot" AS
jbe@532 2015 SELECT "snapshot".* FROM "snapshot"
jbe@532 2016 LEFT JOIN "issue"
jbe@532 2017 ON "snapshot"."id" = "issue"."latest_snapshot_id"
jbe@532 2018 OR "snapshot"."id" = "issue"."admission_snapshot_id"
jbe@532 2019 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
jbe@532 2020 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
jbe@532 2021 WHERE "issue"."id" ISNULL;
jbe@532 2022
jbe@532 2023 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
jbe@532 2024 DELETE FROM "snapshot" WHERE "id" = OLD."id";
jbe@532 2025
jbe@532 2026 COMMENT ON VIEW "unused_snapshot" IS 'Snapshots that are not referenced by any issue (either as latest snapshot or as snapshot at phase/state change)';
jbe@532 2027
jbe@532 2028
jbe@532 2029 CREATE VIEW "expired_snapshot" AS
jbe@532 2030 SELECT "unused_snapshot".* FROM "unused_snapshot" CROSS JOIN "system_setting"
jbe@532 2031 WHERE "unused_snapshot"."calculated" <
jbe@532 2032 now() - "system_setting"."snapshot_retention";
jbe@532 2033
jbe@532 2034 CREATE RULE "delete" AS ON DELETE TO "expired_snapshot" DO INSTEAD
jbe@532 2035 DELETE FROM "snapshot" WHERE "id" = OLD."id";
jbe@532 2036
jbe@532 2037 COMMENT ON VIEW "expired_snapshot" IS 'Contains "unused_snapshot"s that are older than "system_setting"."snapshot_retention" (for deletion)';
jbe@532 2038
jbe@532 2039
jbe@532 2040 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
jbe@532 2041
jbe@532 2042
jbe@532 2043 CREATE OR REPLACE FUNCTION "delegation_chain"
jbe@532 2044 ( "member_id_p" "member"."id"%TYPE,
jbe@532 2045 "unit_id_p" "unit"."id"%TYPE,
jbe@532 2046 "area_id_p" "area"."id"%TYPE,
jbe@532 2047 "issue_id_p" "issue"."id"%TYPE,
jbe@532 2048 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
jbe@532 2049 "simulate_default_p" BOOLEAN DEFAULT FALSE )
jbe@532 2050 RETURNS SETOF "delegation_chain_row"
jbe@532 2051 LANGUAGE 'plpgsql' STABLE AS $$
jbe@532 2052 DECLARE
jbe@532 2053 "scope_v" "delegation_scope";
jbe@532 2054 "unit_id_v" "unit"."id"%TYPE;
jbe@532 2055 "area_id_v" "area"."id"%TYPE;
jbe@532 2056 "issue_row" "issue"%ROWTYPE;
jbe@532 2057 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
jbe@532 2058 "loop_member_id_v" "member"."id"%TYPE;
jbe@532 2059 "output_row" "delegation_chain_row";
jbe@532 2060 "output_rows" "delegation_chain_row"[];
jbe@532 2061 "simulate_v" BOOLEAN;
jbe@532 2062 "simulate_here_v" BOOLEAN;
jbe@532 2063 "delegation_row" "delegation"%ROWTYPE;
jbe@532 2064 "row_count" INT4;
jbe@532 2065 "i" INT4;
jbe@532 2066 "loop_v" BOOLEAN;
jbe@532 2067 BEGIN
jbe@532 2068 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
jbe@532 2069 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
jbe@532 2070 END IF;
jbe@532 2071 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
jbe@532 2072 "simulate_v" := TRUE;
jbe@532 2073 ELSE
jbe@532 2074 "simulate_v" := FALSE;
jbe@532 2075 END IF;
jbe@532 2076 IF
jbe@532 2077 "unit_id_p" NOTNULL AND
jbe@532 2078 "area_id_p" ISNULL AND
jbe@532 2079 "issue_id_p" ISNULL
jbe@532 2080 THEN
jbe@532 2081 "scope_v" := 'unit';
jbe@532 2082 "unit_id_v" := "unit_id_p";
jbe@532 2083 ELSIF
jbe@532 2084 "unit_id_p" ISNULL AND
jbe@532 2085 "area_id_p" NOTNULL AND
jbe@532 2086 "issue_id_p" ISNULL
jbe@532 2087 THEN
jbe@532 2088 "scope_v" := 'area';
jbe@532 2089 "area_id_v" := "area_id_p";
jbe@532 2090 SELECT "unit_id" INTO "unit_id_v"
jbe@532 2091 FROM "area" WHERE "id" = "area_id_v";
jbe@532 2092 ELSIF
jbe@532 2093 "unit_id_p" ISNULL AND
jbe@532 2094 "area_id_p" ISNULL AND
jbe@532 2095 "issue_id_p" NOTNULL
jbe@532 2096 THEN
jbe@532 2097 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
jbe@532 2098 IF "issue_row"."id" ISNULL THEN
jbe@532 2099 RETURN;
jbe@532 2100 END IF;
jbe@532 2101 IF "issue_row"."closed" NOTNULL THEN
jbe@532 2102 IF "simulate_v" THEN
jbe@532 2103 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
jbe@532 2104 END IF;
jbe@532 2105 FOR "output_row" IN
jbe@532 2106 SELECT * FROM
jbe@532 2107 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
jbe@532 2108 LOOP
jbe@532 2109 RETURN NEXT "output_row";
jbe@532 2110 END LOOP;
jbe@532 2111 RETURN;
jbe@532 2112 END IF;
jbe@532 2113 "scope_v" := 'issue';
jbe@532 2114 SELECT "area_id" INTO "area_id_v"
jbe@532 2115 FROM "issue" WHERE "id" = "issue_id_p";
jbe@532 2116 SELECT "unit_id" INTO "unit_id_v"
jbe@532 2117 FROM "area" WHERE "id" = "area_id_v";
jbe@532 2118 ELSE
jbe@532 2119 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
jbe@532 2120 END IF;
jbe@532 2121 "visited_member_ids" := '{}';
jbe@532 2122 "loop_member_id_v" := NULL;
jbe@532 2123 "output_rows" := '{}';
jbe@532 2124 "output_row"."index" := 0;
jbe@532 2125 "output_row"."member_id" := "member_id_p";
jbe@532 2126 "output_row"."member_valid" := TRUE;
jbe@532 2127 "output_row"."participation" := FALSE;
jbe@532 2128 "output_row"."overridden" := FALSE;
jbe@532 2129 "output_row"."disabled_out" := FALSE;
jbe@532 2130 "output_row"."scope_out" := NULL;
jbe@532 2131 LOOP
jbe@532 2132 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
jbe@532 2133 "loop_member_id_v" := "output_row"."member_id";
jbe@532 2134 ELSE
jbe@532 2135 "visited_member_ids" :=
jbe@532 2136 "visited_member_ids" || "output_row"."member_id";
jbe@532 2137 END IF;
jbe@532 2138 IF "output_row"."participation" ISNULL THEN
jbe@532 2139 "output_row"."overridden" := NULL;
jbe@532 2140 ELSIF "output_row"."participation" THEN
jbe@532 2141 "output_row"."overridden" := TRUE;
jbe@532 2142 END IF;
jbe@532 2143 "output_row"."scope_in" := "output_row"."scope_out";
jbe@532 2144 "output_row"."member_valid" := EXISTS (
jbe@532 2145 SELECT NULL FROM "member" JOIN "privilege"
jbe@532 2146 ON "privilege"."member_id" = "member"."id"
jbe@532 2147 AND "privilege"."unit_id" = "unit_id_v"
jbe@532 2148 WHERE "id" = "output_row"."member_id"
jbe@532 2149 AND "member"."active" AND "privilege"."voting_right"
jbe@532 2150 );
jbe@532 2151 "simulate_here_v" := (
jbe@532 2152 "simulate_v" AND
jbe@532 2153 "output_row"."member_id" = "member_id_p"
jbe@532 2154 );
jbe@532 2155 "delegation_row" := ROW(NULL);
jbe@532 2156 IF "output_row"."member_valid" OR "simulate_here_v" THEN
jbe@532 2157 IF "scope_v" = 'unit' THEN
jbe@532 2158 IF NOT "simulate_here_v" THEN
jbe@532 2159 SELECT * INTO "delegation_row" FROM "delegation"
jbe@532 2160 WHERE "truster_id" = "output_row"."member_id"
jbe@532 2161 AND "unit_id" = "unit_id_v";
jbe@532 2162 END IF;
jbe@532 2163 ELSIF "scope_v" = 'area' THEN
jbe@532 2164 IF "simulate_here_v" THEN
jbe@532 2165 IF "simulate_trustee_id_p" ISNULL THEN
jbe@532 2166 SELECT * INTO "delegation_row" FROM "delegation"
jbe@532 2167 WHERE "truster_id" = "output_row"."member_id"
jbe@532 2168 AND "unit_id" = "unit_id_v";
jbe@532 2169 END IF;
jbe@532 2170 ELSE
jbe@532 2171 SELECT * INTO "delegation_row" FROM "delegation"
jbe@532 2172 WHERE "truster_id" = "output_row"."member_id"
jbe@532 2173 AND (
jbe@532 2174 "unit_id" = "unit_id_v" OR
jbe@532 2175 "area_id" = "area_id_v"
jbe@532 2176 )
jbe@532 2177 ORDER BY "scope" DESC;
jbe@532 2178 END IF;
jbe@532 2179 ELSIF "scope_v" = 'issue' THEN
jbe@532 2180 IF "issue_row"."fully_frozen" ISNULL THEN
jbe@532 2181 "output_row"."participation" := EXISTS (
jbe@532 2182 SELECT NULL FROM "interest"
jbe@532 2183 WHERE "issue_id" = "issue_id_p"
jbe@532 2184 AND "member_id" = "output_row"."member_id"
jbe@532 2185 );
jbe@532 2186 ELSE
jbe@532 2187 IF "output_row"."member_id" = "member_id_p" THEN
jbe@532 2188 "output_row"."participation" := EXISTS (
jbe@532 2189 SELECT NULL FROM "direct_voter"
jbe@532 2190 WHERE "issue_id" = "issue_id_p"
jbe@532 2191 AND "member_id" = "output_row"."member_id"
jbe@532 2192 );
jbe@532 2193 ELSE
jbe@532 2194 "output_row"."participation" := NULL;
jbe@532 2195 END IF;
jbe@532 2196 END IF;
jbe@532 2197 IF "simulate_here_v" THEN
jbe@532 2198 IF "simulate_trustee_id_p" ISNULL THEN
jbe@532 2199 SELECT * INTO "delegation_row" FROM "delegation"
jbe@532 2200 WHERE "truster_id" = "output_row"."member_id"
jbe@532 2201 AND (
jbe@532 2202 "unit_id" = "unit_id_v" OR
jbe@532 2203 "area_id" = "area_id_v"
jbe@532 2204 )
jbe@532 2205 ORDER BY "scope" DESC;
jbe@532 2206 END IF;
jbe@532 2207 ELSE
jbe@532 2208 SELECT * INTO "delegation_row" FROM "delegation"
jbe@532 2209 WHERE "truster_id" = "output_row"."member_id"
jbe@532 2210 AND (
jbe@532 2211 "unit_id" = "unit_id_v" OR
jbe@532 2212 "area_id" = "area_id_v" OR
jbe@532 2213 "issue_id" = "issue_id_p"
jbe@532 2214 )
jbe@532 2215 ORDER BY "scope" DESC;
jbe@532 2216 END IF;
jbe@532 2217 END IF;
jbe@532 2218 ELSE
jbe@532 2219 "output_row"."participation" := FALSE;
jbe@532 2220 END IF;
jbe@532 2221 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
jbe@532 2222 "output_row"."scope_out" := "scope_v";
jbe@532 2223 "output_rows" := "output_rows" || "output_row";
jbe@532 2224 "output_row"."member_id" := "simulate_trustee_id_p";
jbe@532 2225 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
jbe@532 2226 "output_row"."scope_out" := "delegation_row"."scope";
jbe@532 2227 "output_rows" := "output_rows" || "output_row";
jbe@532 2228 "output_row"."member_id" := "delegation_row"."trustee_id";
jbe@532 2229 ELSIF "delegation_row"."scope" NOTNULL THEN
jbe@532 2230 "output_row"."scope_out" := "delegation_row"."scope";
jbe@532 2231 "output_row"."disabled_out" := TRUE;
jbe@532 2232 "output_rows" := "output_rows" || "output_row";
jbe@532 2233 EXIT;
jbe@532 2234 ELSE
jbe@532 2235 "output_row"."scope_out" := NULL;
jbe@532 2236 "output_rows" := "output_rows" || "output_row";
jbe@532 2237 EXIT;
jbe@532 2238 END IF;
jbe@532 2239 EXIT WHEN "loop_member_id_v" NOTNULL;
jbe@532 2240 "output_row"."index" := "output_row"."index" + 1;
jbe@532 2241 END LOOP;
jbe@532 2242 "row_count" := array_upper("output_rows", 1);
jbe@532 2243 "i" := 1;
jbe@532 2244 "loop_v" := FALSE;
jbe@532 2245 LOOP
jbe@532 2246 "output_row" := "output_rows"["i"];
jbe@532 2247 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
jbe@532 2248 IF "loop_v" THEN
jbe@532 2249 IF "i" + 1 = "row_count" THEN
jbe@532 2250 "output_row"."loop" := 'last';
jbe@532 2251 ELSIF "i" = "row_count" THEN
jbe@532 2252 "output_row"."loop" := 'repetition';
jbe@532 2253 ELSE
jbe@532 2254 "output_row"."loop" := 'intermediate';
jbe@532 2255 END IF;
jbe@532 2256 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
jbe@532 2257 "output_row"."loop" := 'first';
jbe@532 2258 "loop_v" := TRUE;
jbe@532 2259 END IF;
jbe@532 2260 IF "scope_v" = 'unit' THEN
jbe@532 2261 "output_row"."participation" := NULL;
jbe@532 2262 END IF;
jbe@532 2263 RETURN NEXT "output_row";
jbe@532 2264 "i" := "i" + 1;
jbe@532 2265 END LOOP;
jbe@532 2266 RETURN;
jbe@532 2267 END;
jbe@532 2268 $$;
jbe@532 2269
jbe@532 2270
jbe@532 2271 CREATE OR REPLACE FUNCTION "get_initiatives_for_notification"
jbe@532 2272 ( "recipient_id_p" "member"."id"%TYPE )
jbe@532 2273 RETURNS SETOF "initiative_for_notification"
jbe@532 2274 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2275 DECLARE
jbe@532 2276 "result_row" "initiative_for_notification"%ROWTYPE;
jbe@532 2277 "last_draft_id_v" "draft"."id"%TYPE;
jbe@532 2278 "last_suggestion_id_v" "suggestion"."id"%TYPE;
jbe@532 2279 BEGIN
jbe@532 2280 PERFORM "require_transaction_isolation"();
jbe@532 2281 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
jbe@532 2282 FOR "result_row" IN
jbe@532 2283 SELECT * FROM "initiative_for_notification"
jbe@532 2284 WHERE "recipient_id" = "recipient_id_p"
jbe@532 2285 LOOP
jbe@532 2286 SELECT "id" INTO "last_draft_id_v" FROM "draft"
jbe@532 2287 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
jbe@532 2288 ORDER BY "id" DESC LIMIT 1;
jbe@532 2289 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
jbe@532 2290 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
jbe@532 2291 ORDER BY "id" DESC LIMIT 1;
jbe@532 2292 INSERT INTO "notification_initiative_sent"
jbe@532 2293 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
jbe@532 2294 VALUES (
jbe@532 2295 "recipient_id_p",
jbe@532 2296 "result_row"."initiative_id",
jbe@532 2297 "last_draft_id_v",
jbe@532 2298 "last_suggestion_id_v" )
jbe@532 2299 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
jbe@532 2300 "last_draft_id" = "last_draft_id_v",
jbe@532 2301 "last_suggestion_id" = "last_suggestion_id_v";
jbe@532 2302 RETURN NEXT "result_row";
jbe@532 2303 END LOOP;
jbe@532 2304 DELETE FROM "notification_initiative_sent"
jbe@532 2305 USING "initiative", "issue"
jbe@532 2306 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
jbe@532 2307 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
jbe@532 2308 AND "issue"."id" = "initiative"."issue_id"
jbe@532 2309 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
jbe@532 2310 UPDATE "member" SET
jbe@532 2311 "notification_counter" = "notification_counter" + 1,
jbe@532 2312 "notification_sent" = now()
jbe@532 2313 WHERE "id" = "recipient_id_p";
jbe@532 2314 RETURN;
jbe@532 2315 END;
jbe@532 2316 $$;
jbe@532 2317
jbe@532 2318
jbe@532 2319 CREATE OR REPLACE FUNCTION "calculate_member_counts"()
jbe@532 2320 RETURNS VOID
jbe@532 2321 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2322 BEGIN
jbe@532 2323 PERFORM "require_transaction_isolation"();
jbe@532 2324 DELETE FROM "member_count";
jbe@532 2325 INSERT INTO "member_count" ("total_count")
jbe@532 2326 SELECT "total_count" FROM "member_count_view";
jbe@532 2327 UPDATE "unit" SET "member_count" = "view"."member_count"
jbe@532 2328 FROM "unit_member_count" AS "view"
jbe@532 2329 WHERE "view"."unit_id" = "unit"."id";
jbe@532 2330 RETURN;
jbe@532 2331 END;
jbe@532 2332 $$;
jbe@532 2333
jbe@532 2334 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 "unit_member_count"';
jbe@532 2335
jbe@532 2336
jbe@532 2337 CREATE FUNCTION "calculate_area_quorum"()
jbe@532 2338 RETURNS VOID
jbe@532 2339 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2340 BEGIN
jbe@532 2341 PERFORM "dont_require_transaction_isolation"();
jbe@532 2342 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
jbe@532 2343 FROM "area_quorum" AS "view"
jbe@532 2344 WHERE "view"."area_id" = "area"."id";
jbe@532 2345 RETURN;
jbe@532 2346 END;
jbe@532 2347 $$;
jbe@532 2348
jbe@532 2349 COMMENT ON FUNCTION "calculate_area_quorum"() IS 'Calculate column "issue_quorum" in table "area" from view "area_quorum"';
jbe@532 2350
jbe@532 2351
jbe@532 2352 DROP VIEW "remaining_harmonic_initiative_weight_summands";
jbe@532 2353 DROP VIEW "remaining_harmonic_supporter_weight";
jbe@532 2354
jbe@532 2355
jbe@532 2356 CREATE VIEW "remaining_harmonic_supporter_weight" AS
jbe@532 2357 SELECT
jbe@532 2358 "direct_interest_snapshot"."snapshot_id",
jbe@532 2359 "direct_interest_snapshot"."issue_id",
jbe@532 2360 "direct_interest_snapshot"."member_id",
jbe@532 2361 "direct_interest_snapshot"."weight" AS "weight_num",
jbe@532 2362 count("initiative"."id") AS "weight_den"
jbe@532 2363 FROM "issue"
jbe@532 2364 JOIN "direct_interest_snapshot"
jbe@532 2365 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
jbe@532 2366 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
jbe@532 2367 JOIN "initiative"
jbe@532 2368 ON "issue"."id" = "initiative"."issue_id"
jbe@532 2369 AND "initiative"."harmonic_weight" ISNULL
jbe@532 2370 JOIN "direct_supporter_snapshot"
jbe@532 2371 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
jbe@532 2372 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@532 2373 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@532 2374 AND (
jbe@532 2375 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@532 2376 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@532 2377 )
jbe@532 2378 GROUP BY
jbe@532 2379 "direct_interest_snapshot"."snapshot_id",
jbe@532 2380 "direct_interest_snapshot"."issue_id",
jbe@532 2381 "direct_interest_snapshot"."member_id",
jbe@532 2382 "direct_interest_snapshot"."weight";
jbe@532 2383
jbe@532 2384
jbe@532 2385 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
jbe@532 2386 SELECT
jbe@532 2387 "initiative"."issue_id",
jbe@532 2388 "initiative"."id" AS "initiative_id",
jbe@532 2389 "initiative"."admitted",
jbe@532 2390 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
jbe@532 2391 "remaining_harmonic_supporter_weight"."weight_den"
jbe@532 2392 FROM "remaining_harmonic_supporter_weight"
jbe@532 2393 JOIN "initiative"
jbe@532 2394 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
jbe@532 2395 AND "initiative"."harmonic_weight" ISNULL
jbe@532 2396 JOIN "direct_supporter_snapshot"
jbe@532 2397 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
jbe@532 2398 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
jbe@532 2399 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
jbe@532 2400 AND (
jbe@532 2401 "direct_supporter_snapshot"."satisfied" = TRUE OR
jbe@532 2402 coalesce("initiative"."admitted", FALSE) = FALSE
jbe@532 2403 )
jbe@532 2404 GROUP BY
jbe@532 2405 "initiative"."issue_id",
jbe@532 2406 "initiative"."id",
jbe@532 2407 "initiative"."admitted",
jbe@532 2408 "remaining_harmonic_supporter_weight"."weight_den";
jbe@532 2409
jbe@532 2410
jbe@532 2411 DROP FUNCTION "create_population_snapshot"
jbe@532 2412 ( "issue_id_p" "issue"."id"%TYPE );
jbe@532 2413
jbe@532 2414
jbe@532 2415 DROP FUNCTION "weight_of_added_delegations_for_population_snapshot"
jbe@532 2416 ( "issue_id_p" "issue"."id"%TYPE,
jbe@532 2417 "member_id_p" "member"."id"%TYPE,
jbe@532 2418 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE );
jbe@532 2419
jbe@532 2420
jbe@532 2421 DROP FUNCTION "weight_of_added_delegations_for_interest_snapshot"
jbe@532 2422 ( "issue_id_p" "issue"."id"%TYPE,
jbe@532 2423 "member_id_p" "member"."id"%TYPE,
jbe@532 2424 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE );
jbe@532 2425
jbe@532 2426
jbe@532 2427 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
jbe@532 2428 ( "snapshot_id_p" "snapshot"."id"%TYPE,
jbe@532 2429 "issue_id_p" "issue"."id"%TYPE,
jbe@532 2430 "member_id_p" "member"."id"%TYPE,
jbe@532 2431 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@532 2432 RETURNS "direct_interest_snapshot"."weight"%TYPE
jbe@532 2433 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2434 DECLARE
jbe@532 2435 "issue_delegation_row" "issue_delegation"%ROWTYPE;
jbe@532 2436 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
jbe@532 2437 "weight_v" INT4;
jbe@532 2438 "sub_weight_v" INT4;
jbe@532 2439 BEGIN
jbe@532 2440 PERFORM "require_transaction_isolation"();
jbe@532 2441 "weight_v" := 0;
jbe@532 2442 FOR "issue_delegation_row" IN
jbe@532 2443 SELECT * FROM "issue_delegation"
jbe@532 2444 WHERE "trustee_id" = "member_id_p"
jbe@532 2445 AND "issue_id" = "issue_id_p"
jbe@532 2446 LOOP
jbe@532 2447 IF NOT EXISTS (
jbe@532 2448 SELECT NULL FROM "direct_interest_snapshot"
jbe@532 2449 WHERE "snapshot_id" = "snapshot_id_p"
jbe@532 2450 AND "issue_id" = "issue_id_p"
jbe@532 2451 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@532 2452 ) AND NOT EXISTS (
jbe@532 2453 SELECT NULL FROM "delegating_interest_snapshot"
jbe@532 2454 WHERE "snapshot_id" = "snapshot_id_p"
jbe@532 2455 AND "issue_id" = "issue_id_p"
jbe@532 2456 AND "member_id" = "issue_delegation_row"."truster_id"
jbe@532 2457 ) THEN
jbe@532 2458 "delegate_member_ids_v" :=
jbe@532 2459 "member_id_p" || "delegate_member_ids_p";
jbe@532 2460 INSERT INTO "delegating_interest_snapshot" (
jbe@532 2461 "snapshot_id",
jbe@532 2462 "issue_id",
jbe@532 2463 "member_id",
jbe@532 2464 "scope",
jbe@532 2465 "delegate_member_ids"
jbe@532 2466 ) VALUES (
jbe@532 2467 "snapshot_id_p",
jbe@532 2468 "issue_id_p",
jbe@532 2469 "issue_delegation_row"."truster_id",
jbe@532 2470 "issue_delegation_row"."scope",
jbe@532 2471 "delegate_member_ids_v"
jbe@532 2472 );
jbe@532 2473 "sub_weight_v" := 1 +
jbe@532 2474 "weight_of_added_delegations_for_snapshot"(
jbe@532 2475 "snapshot_id_p",
jbe@532 2476 "issue_id_p",
jbe@532 2477 "issue_delegation_row"."truster_id",
jbe@532 2478 "delegate_member_ids_v"
jbe@532 2479 );
jbe@532 2480 UPDATE "delegating_interest_snapshot"
jbe@532 2481 SET "weight" = "sub_weight_v"
jbe@532 2482 WHERE "snapshot_id" = "snapshot_id_p"
jbe@532 2483 AND "issue_id" = "issue_id_p"
jbe@532 2484 AND "member_id" = "issue_delegation_row"."truster_id";
jbe@532 2485 "weight_v" := "weight_v" + "sub_weight_v";
jbe@532 2486 END IF;
jbe@532 2487 END LOOP;
jbe@532 2488 RETURN "weight_v";
jbe@532 2489 END;
jbe@532 2490 $$;
jbe@532 2491
jbe@532 2492 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
jbe@532 2493 ( "snapshot"."id"%TYPE,
jbe@532 2494 "issue"."id"%TYPE,
jbe@532 2495 "member"."id"%TYPE,
jbe@532 2496 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
jbe@532 2497 IS 'Helper function for "fill_snapshot" function';
jbe@532 2498
jbe@532 2499
jbe@532 2500 DROP FUNCTION "create_interest_snapshot"
jbe@532 2501 ( "issue_id_p" "issue"."id"%TYPE );
jbe@532 2502
jbe@532 2503
jbe@532 2504 DROP FUNCTION "create_snapshot"
jbe@532 2505 ( "issue_id_p" "issue"."id"%TYPE );
jbe@532 2506
jbe@532 2507
jbe@532 2508 CREATE FUNCTION "take_snapshot"
jbe@532 2509 ( "issue_id_p" "issue"."id"%TYPE,
jbe@532 2510 "area_id_p" "area"."id"%TYPE = NULL )
jbe@532 2511 RETURNS "snapshot"."id"%TYPE
jbe@532 2512 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2513 DECLARE
jbe@532 2514 "area_id_v" "area"."id"%TYPE;
jbe@532 2515 "unit_id_v" "unit"."id"%TYPE;
jbe@532 2516 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@532 2517 "issue_id_v" "issue"."id"%TYPE;
jbe@532 2518 "member_id_v" "member"."id"%TYPE;
jbe@532 2519 BEGIN
jbe@532 2520 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
jbe@532 2521 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
jbe@532 2522 END IF;
jbe@532 2523 PERFORM "require_transaction_isolation"();
jbe@532 2524 IF "issue_id_p" ISNULL THEN
jbe@532 2525 "area_id_v" := "area_id_p";
jbe@532 2526 ELSE
jbe@532 2527 SELECT "area_id" INTO "area_id_v"
jbe@532 2528 FROM "issue" WHERE "id" = "issue_id_p";
jbe@532 2529 END IF;
jbe@532 2530 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_p";
jbe@532 2531 INSERT INTO "snapshot" ("area_id", "issue_id")
jbe@532 2532 VALUES ("area_id_v", "issue_id_p")
jbe@532 2533 RETURNING "id" INTO "snapshot_id_v";
jbe@532 2534 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
jbe@532 2535 SELECT "snapshot_id_v", "member_id"
jbe@532 2536 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
jbe@532 2537 UPDATE "snapshot" SET
jbe@532 2538 "population" = (
jbe@532 2539 SELECT count(1) FROM "snapshot_population"
jbe@532 2540 WHERE "snapshot_id" = "snapshot_id_v"
jbe@532 2541 ) WHERE "id" = "snapshot_id_v";
jbe@532 2542 FOR "issue_id_v" IN
jbe@532 2543 SELECT "id" FROM "issue"
jbe@532 2544 WHERE CASE WHEN "issue_id_p" ISNULL THEN
jbe@532 2545 "area_id" = "area_id_p" AND
jbe@532 2546 "state" = 'admission'
jbe@532 2547 ELSE
jbe@532 2548 "id" = "issue_id_p"
jbe@532 2549 END
jbe@532 2550 LOOP
jbe@532 2551 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
jbe@532 2552 VALUES ("snapshot_id_v", "issue_id_v");
jbe@532 2553 INSERT INTO "direct_interest_snapshot"
jbe@532 2554 ("snapshot_id", "issue_id", "member_id")
jbe@532 2555 SELECT
jbe@532 2556 "snapshot_id_v" AS "snapshot_id",
jbe@532 2557 "issue_id_v" AS "issue_id",
jbe@532 2558 "member"."id" AS "member_id"
jbe@532 2559 FROM "issue"
jbe@532 2560 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@532 2561 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@532 2562 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@532 2563 JOIN "privilege"
jbe@532 2564 ON "privilege"."unit_id" = "area"."unit_id"
jbe@532 2565 AND "privilege"."member_id" = "member"."id"
jbe@532 2566 WHERE "issue"."id" = "issue_id_v"
jbe@532 2567 AND "member"."active" AND "privilege"."voting_right";
jbe@532 2568 FOR "member_id_v" IN
jbe@532 2569 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@532 2570 WHERE "snapshot_id" = "snapshot_id_v"
jbe@532 2571 AND "issue_id" = "issue_id_v"
jbe@532 2572 LOOP
jbe@532 2573 UPDATE "direct_interest_snapshot" SET
jbe@532 2574 "weight" = 1 +
jbe@532 2575 "weight_of_added_delegations_for_snapshot"(
jbe@532 2576 "snapshot_id_v",
jbe@532 2577 "issue_id_v",
jbe@532 2578 "member_id_v",
jbe@532 2579 '{}'
jbe@532 2580 )
jbe@532 2581 WHERE "snapshot_id" = "snapshot_id_v"
jbe@532 2582 AND "issue_id" = "issue_id_v"
jbe@532 2583 AND "member_id" = "member_id_v";
jbe@532 2584 END LOOP;
jbe@532 2585 INSERT INTO "direct_supporter_snapshot"
jbe@532 2586 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
jbe@532 2587 "draft_id", "informed", "satisfied" )
jbe@532 2588 SELECT
jbe@532 2589 "snapshot_id_v" AS "snapshot_id",
jbe@532 2590 "issue_id_v" AS "issue_id",
jbe@532 2591 "initiative"."id" AS "initiative_id",
jbe@532 2592 "supporter"."member_id" AS "member_id",
jbe@532 2593 "supporter"."draft_id" AS "draft_id",
jbe@532 2594 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@532 2595 NOT EXISTS (
jbe@532 2596 SELECT NULL FROM "critical_opinion"
jbe@532 2597 WHERE "initiative_id" = "initiative"."id"
jbe@532 2598 AND "member_id" = "supporter"."member_id"
jbe@532 2599 ) AS "satisfied"
jbe@532 2600 FROM "initiative"
jbe@532 2601 JOIN "supporter"
jbe@532 2602 ON "supporter"."initiative_id" = "initiative"."id"
jbe@532 2603 JOIN "current_draft"
jbe@532 2604 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@532 2605 JOIN "direct_interest_snapshot"
jbe@532 2606 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
jbe@532 2607 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@532 2608 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@532 2609 WHERE "initiative"."issue_id" = "issue_id_v";
jbe@532 2610 DELETE FROM "temporary_suggestion_counts";
jbe@532 2611 INSERT INTO "temporary_suggestion_counts"
jbe@532 2612 ( "id",
jbe@532 2613 "minus2_unfulfilled_count", "minus2_fulfilled_count",
jbe@532 2614 "minus1_unfulfilled_count", "minus1_fulfilled_count",
jbe@532 2615 "plus1_unfulfilled_count", "plus1_fulfilled_count",
jbe@532 2616 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
jbe@532 2617 SELECT
jbe@532 2618 "suggestion"."id",
jbe@532 2619 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2620 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2621 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2622 AND "di"."issue_id" = "issue_id_v"
jbe@532 2623 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2624 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2625 AND "opinion"."degree" = -2
jbe@532 2626 AND "opinion"."fulfilled" = FALSE
jbe@532 2627 ) AS "minus2_unfulfilled_count",
jbe@532 2628 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2629 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2630 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2631 AND "di"."issue_id" = "issue_id_v"
jbe@532 2632 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2633 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2634 AND "opinion"."degree" = -2
jbe@532 2635 AND "opinion"."fulfilled" = TRUE
jbe@532 2636 ) AS "minus2_fulfilled_count",
jbe@532 2637 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2638 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2639 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2640 AND "di"."issue_id" = "issue_id_v"
jbe@532 2641 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2642 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2643 AND "opinion"."degree" = -1
jbe@532 2644 AND "opinion"."fulfilled" = FALSE
jbe@532 2645 ) AS "minus1_unfulfilled_count",
jbe@532 2646 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2647 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2648 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2649 AND "di"."issue_id" = "issue_id_v"
jbe@532 2650 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2651 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2652 AND "opinion"."degree" = -1
jbe@532 2653 AND "opinion"."fulfilled" = TRUE
jbe@532 2654 ) AS "minus1_fulfilled_count",
jbe@532 2655 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2656 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2657 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2658 AND "di"."issue_id" = "issue_id_v"
jbe@532 2659 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2660 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2661 AND "opinion"."degree" = 1
jbe@532 2662 AND "opinion"."fulfilled" = FALSE
jbe@532 2663 ) AS "plus1_unfulfilled_count",
jbe@532 2664 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2665 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2666 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2667 AND "di"."issue_id" = "issue_id_v"
jbe@532 2668 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2669 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2670 AND "opinion"."degree" = 1
jbe@532 2671 AND "opinion"."fulfilled" = TRUE
jbe@532 2672 ) AS "plus1_fulfilled_count",
jbe@532 2673 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2674 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2675 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2676 AND "di"."issue_id" = "issue_id_v"
jbe@532 2677 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2678 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2679 AND "opinion"."degree" = 2
jbe@532 2680 AND "opinion"."fulfilled" = FALSE
jbe@532 2681 ) AS "plus2_unfulfilled_count",
jbe@532 2682 ( SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2683 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
jbe@532 2684 ON "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2685 AND "di"."issue_id" = "issue_id_v"
jbe@532 2686 AND "di"."member_id" = "opinion"."member_id"
jbe@532 2687 WHERE "opinion"."suggestion_id" = "suggestion"."id"
jbe@532 2688 AND "opinion"."degree" = 2
jbe@532 2689 AND "opinion"."fulfilled" = TRUE
jbe@532 2690 ) AS "plus2_fulfilled_count"
jbe@532 2691 FROM "suggestion" JOIN "initiative"
jbe@532 2692 ON "suggestion"."initiative_id" = "initiative"."id"
jbe@532 2693 WHERE "initiative"."issue_id" = "issue_id_v";
jbe@532 2694 END LOOP;
jbe@532 2695 RETURN "snapshot_id_v";
jbe@532 2696 END;
jbe@532 2697 $$;
jbe@532 2698
jbe@532 2699 COMMENT ON FUNCTION "take_snapshot"
jbe@532 2700 ( "issue"."id"%TYPE,
jbe@532 2701 "area"."id"%TYPE )
jbe@532 2702 IS 'This function creates a new interest/supporter snapshot of a particular issue, or, if the first argument is NULL, for all issues in ''admission'' phase of the area given as second argument. It must be executed with TRANSACTION ISOLATION LEVEL REPEATABLE READ. The snapshot must later be finished by calling "finish_snapshot" for every issue.';
jbe@532 2703
jbe@532 2704
jbe@532 2705 DROP FUNCTION "set_snapshot_event"
jbe@532 2706 ( "issue_id_p" "issue"."id"%TYPE,
jbe@532 2707 "event_p" "snapshot_event" );
jbe@532 2708
jbe@532 2709
jbe@532 2710 CREATE FUNCTION "finish_snapshot"
jbe@532 2711 ( "issue_id_p" "issue"."id"%TYPE )
jbe@532 2712 RETURNS VOID
jbe@532 2713 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2714 DECLARE
jbe@532 2715 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@532 2716 BEGIN
jbe@532 2717 -- NOTE: function does not require snapshot isolation but we don't call
jbe@532 2718 -- "dont_require_snapshot_isolation" here because this function is
jbe@532 2719 -- also invoked by "check_issue"
jbe@532 2720 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
jbe@532 2721 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
jbe@532 2722 ORDER BY "id" DESC LIMIT 1;
jbe@532 2723 UPDATE "issue" SET
jbe@532 2724 "calculated" = "snapshot"."calculated",
jbe@532 2725 "latest_snapshot_id" = "snapshot_id_v",
jbe@532 2726 "population" = "snapshot"."population"
jbe@532 2727 FROM "snapshot"
jbe@532 2728 WHERE "issue"."id" = "issue_id_p"
jbe@532 2729 AND "snapshot"."id" = "snapshot_id_v";
jbe@532 2730 UPDATE "initiative" SET
jbe@532 2731 "supporter_count" = (
jbe@532 2732 SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2733 FROM "direct_interest_snapshot" AS "di"
jbe@532 2734 JOIN "direct_supporter_snapshot" AS "ds"
jbe@532 2735 ON "di"."member_id" = "ds"."member_id"
jbe@532 2736 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2737 AND "di"."issue_id" = "issue_id_p"
jbe@532 2738 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@532 2739 AND "ds"."initiative_id" = "initiative"."id"
jbe@532 2740 ),
jbe@532 2741 "informed_supporter_count" = (
jbe@532 2742 SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2743 FROM "direct_interest_snapshot" AS "di"
jbe@532 2744 JOIN "direct_supporter_snapshot" AS "ds"
jbe@532 2745 ON "di"."member_id" = "ds"."member_id"
jbe@532 2746 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2747 AND "di"."issue_id" = "issue_id_p"
jbe@532 2748 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@532 2749 AND "ds"."initiative_id" = "initiative"."id"
jbe@532 2750 AND "ds"."informed"
jbe@532 2751 ),
jbe@532 2752 "satisfied_supporter_count" = (
jbe@532 2753 SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2754 FROM "direct_interest_snapshot" AS "di"
jbe@532 2755 JOIN "direct_supporter_snapshot" AS "ds"
jbe@532 2756 ON "di"."member_id" = "ds"."member_id"
jbe@532 2757 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2758 AND "di"."issue_id" = "issue_id_p"
jbe@532 2759 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@532 2760 AND "ds"."initiative_id" = "initiative"."id"
jbe@532 2761 AND "ds"."satisfied"
jbe@532 2762 ),
jbe@532 2763 "satisfied_informed_supporter_count" = (
jbe@532 2764 SELECT coalesce(sum("di"."weight"), 0)
jbe@532 2765 FROM "direct_interest_snapshot" AS "di"
jbe@532 2766 JOIN "direct_supporter_snapshot" AS "ds"
jbe@532 2767 ON "di"."member_id" = "ds"."member_id"
jbe@532 2768 WHERE "di"."snapshot_id" = "snapshot_id_v"
jbe@532 2769 AND "di"."issue_id" = "issue_id_p"
jbe@532 2770 AND "ds"."snapshot_id" = "snapshot_id_v"
jbe@532 2771 AND "ds"."initiative_id" = "initiative"."id"
jbe@532 2772 AND "ds"."informed"
jbe@532 2773 AND "ds"."satisfied"
jbe@532 2774 )
jbe@532 2775 WHERE "issue_id" = "issue_id_p";
jbe@532 2776 UPDATE "suggestion" SET
jbe@532 2777 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
jbe@532 2778 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
jbe@532 2779 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
jbe@532 2780 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
jbe@532 2781 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
jbe@532 2782 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
jbe@532 2783 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
jbe@532 2784 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
jbe@532 2785 FROM "temporary_suggestion_counts" AS "temp", "initiative"
jbe@532 2786 WHERE "temp"."id" = "suggestion"."id"
jbe@532 2787 AND "initiative"."issue_id" = "issue_id_p"
jbe@532 2788 AND "suggestion"."initiative_id" = "initiative"."id";
jbe@532 2789 DELETE FROM "temporary_suggestion_counts";
jbe@532 2790 RETURN;
jbe@532 2791 END;
jbe@532 2792 $$;
jbe@532 2793
jbe@532 2794 COMMENT ON FUNCTION "finish_snapshot"
jbe@532 2795 ( "issue"."id"%TYPE )
jbe@532 2796 IS 'After calling "take_snapshot", this function "finish_snapshot" needs to be called for every issue in the snapshot (separate function calls keep locking time minimal)';
jbe@532 2797
jbe@532 2798
jbe@532 2799 CREATE FUNCTION "issue_admission"
jbe@532 2800 ( "area_id_p" "area"."id"%TYPE )
jbe@532 2801 RETURNS BOOLEAN
jbe@532 2802 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2803 DECLARE
jbe@532 2804 "issue_id_v" "issue"."id"%TYPE;
jbe@532 2805 BEGIN
jbe@532 2806 PERFORM "dont_require_transaction_isolation"();
jbe@532 2807 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
jbe@532 2808 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
jbe@532 2809 FROM "area_quorum" AS "view"
jbe@532 2810 WHERE "area"."id" = "view"."area_id"
jbe@532 2811 AND "area"."id" = "area_id_p";
jbe@532 2812 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
jbe@532 2813 WHERE "area_id" = "area_id_p";
jbe@532 2814 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
jbe@532 2815 UPDATE "issue" SET
jbe@532 2816 "admission_snapshot_id" = "latest_snapshot_id",
jbe@532 2817 "state" = 'discussion',
jbe@532 2818 "accepted" = now(),
jbe@532 2819 "phase_finished" = NULL
jbe@532 2820 WHERE "id" = "issue_id_v";
jbe@532 2821 RETURN TRUE;
jbe@532 2822 END;
jbe@532 2823 $$;
jbe@532 2824
jbe@532 2825 COMMENT ON FUNCTION "issue_admission"
jbe@532 2826 ( "area"."id"%TYPE )
jbe@532 2827 IS 'Checks if an issue in the area can be admitted for further discussion; returns TRUE on success in which case the function must be called again until it returns FALSE';
jbe@532 2828
jbe@532 2829
jbe@532 2830 CREATE OR REPLACE FUNCTION "check_issue"
jbe@532 2831 ( "issue_id_p" "issue"."id"%TYPE,
jbe@532 2832 "persist" "check_issue_persistence" )
jbe@532 2833 RETURNS "check_issue_persistence"
jbe@532 2834 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 2835 DECLARE
jbe@532 2836 "issue_row" "issue"%ROWTYPE;
jbe@532 2837 "last_calculated_v" "snapshot"."calculated"%TYPE;
jbe@532 2838 "policy_row" "policy"%ROWTYPE;
jbe@532 2839 "initiative_row" "initiative"%ROWTYPE;
jbe@532 2840 "state_v" "issue_state";
jbe@532 2841 BEGIN
jbe@532 2842 PERFORM "require_transaction_isolation"();
jbe@532 2843 IF "persist" ISNULL THEN
jbe@532 2844 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@532 2845 FOR UPDATE;
jbe@532 2846 SELECT "calculated" INTO "last_calculated_v"
jbe@532 2847 FROM "snapshot" JOIN "snapshot_issue"
jbe@532 2848 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
jbe@532 2849 WHERE "snapshot_issue"."issue_id" = "issue_id_p";
jbe@532 2850 IF "issue_row"."closed" NOTNULL THEN
jbe@532 2851 RETURN NULL;
jbe@532 2852 END IF;
jbe@532 2853 "persist"."state" := "issue_row"."state";
jbe@532 2854 IF
jbe@532 2855 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
jbe@532 2856 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
jbe@532 2857 ( "issue_row"."state" = 'discussion' AND now() >=
jbe@532 2858 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
jbe@532 2859 ( "issue_row"."state" = 'verification' AND now() >=
jbe@532 2860 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
jbe@532 2861 ( "issue_row"."state" = 'voting' AND now() >=
jbe@532 2862 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
jbe@532 2863 THEN
jbe@532 2864 "persist"."phase_finished" := TRUE;
jbe@532 2865 ELSE
jbe@532 2866 "persist"."phase_finished" := FALSE;
jbe@532 2867 END IF;
jbe@532 2868 IF
jbe@532 2869 NOT EXISTS (
jbe@532 2870 -- all initiatives are revoked
jbe@532 2871 SELECT NULL FROM "initiative"
jbe@532 2872 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@532 2873 ) AND (
jbe@532 2874 -- and issue has not been accepted yet
jbe@532 2875 "persist"."state" = 'admission' OR
jbe@532 2876 -- or verification time has elapsed
jbe@532 2877 ( "persist"."state" = 'verification' AND
jbe@532 2878 "persist"."phase_finished" ) OR
jbe@532 2879 -- or no initiatives have been revoked lately
jbe@532 2880 NOT EXISTS (
jbe@532 2881 SELECT NULL FROM "initiative"
jbe@532 2882 WHERE "issue_id" = "issue_id_p"
jbe@532 2883 AND now() < "revoked" + "issue_row"."verification_time"
jbe@532 2884 )
jbe@532 2885 )
jbe@532 2886 THEN
jbe@532 2887 "persist"."issue_revoked" := TRUE;
jbe@532 2888 ELSE
jbe@532 2889 "persist"."issue_revoked" := FALSE;
jbe@532 2890 END IF;
jbe@532 2891 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
jbe@532 2892 UPDATE "issue" SET "phase_finished" = now()
jbe@532 2893 WHERE "id" = "issue_row"."id";
jbe@532 2894 RETURN "persist";
jbe@532 2895 ELSIF
jbe@532 2896 "persist"."state" IN ('admission', 'discussion', 'verification')
jbe@532 2897 THEN
jbe@532 2898 RETURN "persist";
jbe@532 2899 ELSE
jbe@532 2900 RETURN NULL;
jbe@532 2901 END IF;
jbe@532 2902 END IF;
jbe@532 2903 IF
jbe@532 2904 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@532 2905 coalesce("persist"."snapshot_created", FALSE) = FALSE
jbe@532 2906 THEN
jbe@532 2907 IF "persist"."state" != 'admission' THEN
jbe@532 2908 PERFORM "take_snapshot"("issue_id_p");
jbe@532 2909 PERFORM "finish_snapshot"("issue_id_p");
jbe@532 2910 END IF;
jbe@532 2911 "persist"."snapshot_created" = TRUE;
jbe@532 2912 IF "persist"."phase_finished" THEN
jbe@532 2913 IF "persist"."state" = 'admission' THEN
jbe@532 2914 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id";
jbe@532 2915 ELSIF "persist"."state" = 'discussion' THEN
jbe@532 2916 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id";
jbe@532 2917 ELSIF "persist"."state" = 'verification' THEN
jbe@532 2918 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id";
jbe@532 2919 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
jbe@532 2920 SELECT * INTO "policy_row" FROM "policy"
jbe@532 2921 WHERE "id" = "issue_row"."policy_id";
jbe@532 2922 FOR "initiative_row" IN
jbe@532 2923 SELECT * FROM "initiative"
jbe@532 2924 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
jbe@532 2925 FOR UPDATE
jbe@532 2926 LOOP
jbe@532 2927 IF
jbe@532 2928 "initiative_row"."polling" OR (
jbe@532 2929 "initiative_row"."satisfied_supporter_count" >
jbe@532 2930 "policy_row"."initiative_quorum" AND
jbe@532 2931 "initiative_row"."satisfied_supporter_count" *
jbe@532 2932 "policy_row"."initiative_quorum_den" >=
jbe@532 2933 "issue_row"."population" * "policy_row"."initiative_quorum_num"
jbe@532 2934 )
jbe@532 2935 THEN
jbe@532 2936 UPDATE "initiative" SET "admitted" = TRUE
jbe@532 2937 WHERE "id" = "initiative_row"."id";
jbe@532 2938 ELSE
jbe@532 2939 UPDATE "initiative" SET "admitted" = FALSE
jbe@532 2940 WHERE "id" = "initiative_row"."id";
jbe@532 2941 END IF;
jbe@532 2942 END LOOP;
jbe@532 2943 END IF;
jbe@532 2944 END IF;
jbe@532 2945 RETURN "persist";
jbe@532 2946 END IF;
jbe@532 2947 IF
jbe@532 2948 "persist"."state" IN ('admission', 'discussion', 'verification') AND
jbe@532 2949 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
jbe@532 2950 THEN
jbe@532 2951 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
jbe@532 2952 "persist"."harmonic_weights_set" = TRUE;
jbe@532 2953 IF
jbe@532 2954 "persist"."phase_finished" OR
jbe@532 2955 "persist"."issue_revoked" OR
jbe@532 2956 "persist"."state" = 'admission'
jbe@532 2957 THEN
jbe@532 2958 RETURN "persist";
jbe@532 2959 ELSE
jbe@532 2960 RETURN NULL;
jbe@532 2961 END IF;
jbe@532 2962 END IF;
jbe@532 2963 IF "persist"."issue_revoked" THEN
jbe@532 2964 IF "persist"."state" = 'admission' THEN
jbe@532 2965 "state_v" := 'canceled_revoked_before_accepted';
jbe@532 2966 ELSIF "persist"."state" = 'discussion' THEN
jbe@532 2967 "state_v" := 'canceled_after_revocation_during_discussion';
jbe@532 2968 ELSIF "persist"."state" = 'verification' THEN
jbe@532 2969 "state_v" := 'canceled_after_revocation_during_verification';
jbe@532 2970 END IF;
jbe@532 2971 UPDATE "issue" SET
jbe@532 2972 "state" = "state_v",
jbe@532 2973 "closed" = "phase_finished",
jbe@532 2974 "phase_finished" = NULL
jbe@532 2975 WHERE "id" = "issue_id_p";
jbe@532 2976 RETURN NULL;
jbe@532 2977 END IF;
jbe@532 2978 IF "persist"."state" = 'admission' THEN
jbe@532 2979 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@532 2980 FOR UPDATE;
jbe@532 2981 IF "issue_row"."phase_finished" NOTNULL THEN
jbe@532 2982 UPDATE "issue" SET
jbe@532 2983 "state" = 'canceled_issue_not_accepted',
jbe@532 2984 "closed" = "phase_finished",
jbe@532 2985 "phase_finished" = NULL
jbe@532 2986 WHERE "id" = "issue_id_p";
jbe@532 2987 END IF;
jbe@532 2988 RETURN NULL;
jbe@532 2989 END IF;
jbe@532 2990 IF "persist"."phase_finished" THEN
jbe@532 2991 IF "persist"."state" = 'discussion' THEN
jbe@532 2992 UPDATE "issue" SET
jbe@532 2993 "state" = 'verification',
jbe@532 2994 "half_frozen" = "phase_finished",
jbe@532 2995 "phase_finished" = NULL
jbe@532 2996 WHERE "id" = "issue_id_p";
jbe@532 2997 RETURN NULL;
jbe@532 2998 END IF;
jbe@532 2999 IF "persist"."state" = 'verification' THEN
jbe@532 3000 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
jbe@532 3001 FOR UPDATE;
jbe@532 3002 SELECT * INTO "policy_row" FROM "policy"
jbe@532 3003 WHERE "id" = "issue_row"."policy_id";
jbe@532 3004 IF EXISTS (
jbe@532 3005 SELECT NULL FROM "initiative"
jbe@532 3006 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
jbe@532 3007 ) THEN
jbe@532 3008 UPDATE "issue" SET
jbe@532 3009 "state" = 'voting',
jbe@532 3010 "fully_frozen" = "phase_finished",
jbe@532 3011 "phase_finished" = NULL
jbe@532 3012 WHERE "id" = "issue_id_p";
jbe@532 3013 ELSE
jbe@532 3014 UPDATE "issue" SET
jbe@532 3015 "state" = 'canceled_no_initiative_admitted',
jbe@532 3016 "fully_frozen" = "phase_finished",
jbe@532 3017 "closed" = "phase_finished",
jbe@532 3018 "phase_finished" = NULL
jbe@532 3019 WHERE "id" = "issue_id_p";
jbe@532 3020 -- NOTE: The following DELETE statements have effect only when
jbe@532 3021 -- issue state has been manipulated
jbe@532 3022 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
jbe@532 3023 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
jbe@532 3024 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
jbe@532 3025 END IF;
jbe@532 3026 RETURN NULL;
jbe@532 3027 END IF;
jbe@532 3028 IF "persist"."state" = 'voting' THEN
jbe@532 3029 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
jbe@532 3030 PERFORM "close_voting"("issue_id_p");
jbe@532 3031 "persist"."closed_voting" = TRUE;
jbe@532 3032 RETURN "persist";
jbe@532 3033 END IF;
jbe@532 3034 PERFORM "calculate_ranks"("issue_id_p");
jbe@532 3035 RETURN NULL;
jbe@532 3036 END IF;
jbe@532 3037 END IF;
jbe@532 3038 RAISE WARNING 'should not happen';
jbe@532 3039 RETURN NULL;
jbe@532 3040 END;
jbe@532 3041 $$;
jbe@532 3042
jbe@532 3043
jbe@532 3044 CREATE OR REPLACE FUNCTION "check_everything"()
jbe@532 3045 RETURNS VOID
jbe@532 3046 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 3047 DECLARE
jbe@532 3048 "area_id_v" "area"."id"%TYPE;
jbe@532 3049 "snapshot_id_v" "snapshot"."id"%TYPE;
jbe@532 3050 "issue_id_v" "issue"."id"%TYPE;
jbe@532 3051 "persist_v" "check_issue_persistence";
jbe@532 3052 BEGIN
jbe@532 3053 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
jbe@532 3054 DELETE FROM "expired_session";
jbe@532 3055 DELETE FROM "expired_token";
jbe@532 3056 DELETE FROM "expired_snapshot";
jbe@532 3057 PERFORM "check_activity"();
jbe@532 3058 PERFORM "calculate_member_counts"();
jbe@532 3059 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
jbe@532 3060 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
jbe@532 3061 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
jbe@532 3062 WHERE "snapshot_id" = "snapshot_id_v";
jbe@532 3063 LOOP
jbe@532 3064 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
jbe@532 3065 END LOOP;
jbe@532 3066 END LOOP;
jbe@532 3067 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
jbe@532 3068 "persist_v" := NULL;
jbe@532 3069 LOOP
jbe@532 3070 "persist_v" := "check_issue"("issue_id_v", "persist_v");
jbe@532 3071 EXIT WHEN "persist_v" ISNULL;
jbe@532 3072 END LOOP;
jbe@532 3073 END LOOP;
jbe@532 3074 RETURN;
jbe@532 3075 END;
jbe@532 3076 $$;
jbe@532 3077
jbe@532 3078 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. For production, use lf_update binary instead';
jbe@532 3079
jbe@532 3080
jbe@532 3081 CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
jbe@532 3082 RETURNS VOID
jbe@532 3083 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 3084 BEGIN
jbe@532 3085 IF EXISTS (
jbe@532 3086 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
jbe@532 3087 ) THEN
jbe@532 3088 -- override protection triggers:
jbe@532 3089 INSERT INTO "temporary_transaction_data" ("key", "value")
jbe@532 3090 VALUES ('override_protection_triggers', TRUE::TEXT);
jbe@532 3091 -- clean data:
jbe@532 3092 DELETE FROM "delegating_voter"
jbe@532 3093 WHERE "issue_id" = "issue_id_p";
jbe@532 3094 DELETE FROM "direct_voter"
jbe@532 3095 WHERE "issue_id" = "issue_id_p";
jbe@532 3096 DELETE FROM "delegating_interest_snapshot"
jbe@532 3097 WHERE "issue_id" = "issue_id_p";
jbe@532 3098 DELETE FROM "direct_interest_snapshot"
jbe@532 3099 WHERE "issue_id" = "issue_id_p";
jbe@532 3100 DELETE FROM "non_voter"
jbe@532 3101 WHERE "issue_id" = "issue_id_p";
jbe@532 3102 DELETE FROM "delegation"
jbe@532 3103 WHERE "issue_id" = "issue_id_p";
jbe@532 3104 DELETE FROM "supporter"
jbe@532 3105 USING "initiative" -- NOTE: due to missing index on issue_id
jbe@532 3106 WHERE "initiative"."issue_id" = "issue_id_p"
jbe@532 3107 AND "supporter"."initiative_id" = "initiative_id";
jbe@532 3108 -- mark issue as cleaned:
jbe@532 3109 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
jbe@532 3110 -- finish overriding protection triggers (avoids garbage):
jbe@532 3111 DELETE FROM "temporary_transaction_data"
jbe@532 3112 WHERE "key" = 'override_protection_triggers';
jbe@532 3113 END IF;
jbe@532 3114 RETURN;
jbe@532 3115 END;
jbe@532 3116 $$;
jbe@532 3117
jbe@532 3118
jbe@532 3119 CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
jbe@532 3120 RETURNS VOID
jbe@532 3121 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 3122 BEGIN
jbe@532 3123 UPDATE "member" SET
jbe@532 3124 "last_login" = NULL,
jbe@532 3125 "last_delegation_check" = NULL,
jbe@532 3126 "login" = NULL,
jbe@532 3127 "password" = NULL,
jbe@532 3128 "authority" = NULL,
jbe@532 3129 "authority_uid" = NULL,
jbe@532 3130 "authority_login" = NULL,
jbe@532 3131 "locked" = TRUE,
jbe@532 3132 "active" = FALSE,
jbe@532 3133 "notify_email" = NULL,
jbe@532 3134 "notify_email_unconfirmed" = NULL,
jbe@532 3135 "notify_email_secret" = NULL,
jbe@532 3136 "notify_email_secret_expiry" = NULL,
jbe@532 3137 "notify_email_lock_expiry" = NULL,
jbe@532 3138 "disable_notifications" = TRUE,
jbe@532 3139 "notification_counter" = DEFAULT,
jbe@532 3140 "notification_sample_size" = 0,
jbe@532 3141 "notification_dow" = NULL,
jbe@532 3142 "notification_hour" = NULL,
jbe@532 3143 "login_recovery_expiry" = NULL,
jbe@532 3144 "password_reset_secret" = NULL,
jbe@532 3145 "password_reset_secret_expiry" = NULL,
jbe@532 3146 "location" = NULL
jbe@532 3147 WHERE "id" = "member_id_p";
jbe@532 3148 -- "text_search_data" is updated by triggers
jbe@532 3149 DELETE FROM "setting" WHERE "member_id" = "member_id_p";
jbe@532 3150 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p";
jbe@532 3151 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
jbe@532 3152 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
jbe@532 3153 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
jbe@532 3154 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
jbe@532 3155 DELETE FROM "session" WHERE "member_id" = "member_id_p";
jbe@532 3156 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p";
jbe@532 3157 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p";
jbe@532 3158 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
jbe@532 3159 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
jbe@532 3160 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
jbe@532 3161 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
jbe@532 3162 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
jbe@532 3163 DELETE FROM "direct_voter" USING "issue"
jbe@532 3164 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@532 3165 AND "issue"."closed" ISNULL
jbe@532 3166 AND "member_id" = "member_id_p";
jbe@532 3167 RETURN;
jbe@532 3168 END;
jbe@532 3169 $$;
jbe@532 3170
jbe@532 3171
jbe@532 3172 CREATE OR REPLACE FUNCTION "delete_private_data"()
jbe@532 3173 RETURNS VOID
jbe@532 3174 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@532 3175 BEGIN
jbe@532 3176 DELETE FROM "temporary_transaction_data";
jbe@532 3177 DELETE FROM "member" WHERE "activated" ISNULL;
jbe@532 3178 UPDATE "member" SET
jbe@532 3179 "invite_code" = NULL,
jbe@532 3180 "invite_code_expiry" = NULL,
jbe@532 3181 "admin_comment" = NULL,
jbe@532 3182 "last_login" = NULL,
jbe@532 3183 "last_delegation_check" = NULL,
jbe@532 3184 "login" = NULL,
jbe@532 3185 "password" = NULL,
jbe@532 3186 "authority" = NULL,
jbe@532 3187 "authority_uid" = NULL,
jbe@532 3188 "authority_login" = NULL,
jbe@532 3189 "lang" = NULL,
jbe@532 3190 "notify_email" = NULL,
jbe@532 3191 "notify_email_unconfirmed" = NULL,
jbe@532 3192 "notify_email_secret" = NULL,
jbe@532 3193 "notify_email_secret_expiry" = NULL,
jbe@532 3194 "notify_email_lock_expiry" = NULL,
jbe@532 3195 "disable_notifications" = TRUE,
jbe@532 3196 "notification_counter" = DEFAULT,
jbe@532 3197 "notification_sample_size" = 0,
jbe@532 3198 "notification_dow" = NULL,
jbe@532 3199 "notification_hour" = NULL,
jbe@532 3200 "login_recovery_expiry" = NULL,
jbe@532 3201 "password_reset_secret" = NULL,
jbe@532 3202 "password_reset_secret_expiry" = NULL,
jbe@532 3203 "location" = NULL;
jbe@532 3204 -- "text_search_data" is updated by triggers
jbe@532 3205 DELETE FROM "setting";
jbe@532 3206 DELETE FROM "setting_map";
jbe@532 3207 DELETE FROM "member_relation_setting";
jbe@532 3208 DELETE FROM "member_image";
jbe@532 3209 DELETE FROM "contact";
jbe@532 3210 DELETE FROM "ignored_member";
jbe@532 3211 DELETE FROM "session";
jbe@532 3212 DELETE FROM "area_setting";
jbe@532 3213 DELETE FROM "issue_setting";
jbe@532 3214 DELETE FROM "ignored_initiative";
jbe@532 3215 DELETE FROM "initiative_setting";
jbe@532 3216 DELETE FROM "suggestion_setting";
jbe@532 3217 DELETE FROM "non_voter";
jbe@532 3218 DELETE FROM "direct_voter" USING "issue"
jbe@532 3219 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@532 3220 AND "issue"."closed" ISNULL;
jbe@532 3221 RETURN;
jbe@532 3222 END;
jbe@532 3223 $$;
jbe@532 3224
jbe@532 3225
jbe@532 3226 CREATE TEMPORARY TABLE "old_snapshot" AS
jbe@532 3227 SELECT "ordered".*, row_number() OVER () AS "snapshot_id"
jbe@532 3228 FROM (
jbe@532 3229 SELECT * FROM (
jbe@532 3230 SELECT
jbe@532 3231 "id" AS "issue_id",
jbe@532 3232 'end_of_admission'::"snapshot_event" AS "event",
jbe@532 3233 "accepted" AS "calculated"
jbe@532 3234 FROM "issue" WHERE "accepted" NOTNULL
jbe@532 3235 UNION ALL
jbe@532 3236 SELECT
jbe@532 3237 "id" AS "issue_id",
jbe@532 3238 'half_freeze'::"snapshot_event" AS "event",
jbe@532 3239 "half_frozen" AS "calculated"
jbe@532 3240 FROM "issue" WHERE "half_frozen" NOTNULL
jbe@532 3241 UNION ALL
jbe@532 3242 SELECT
jbe@532 3243 "id" AS "issue_id",
jbe@532 3244 'full_freeze'::"snapshot_event" AS "event",
jbe@532 3245 "fully_frozen" AS "calculated"
jbe@532 3246 FROM "issue" WHERE "fully_frozen" NOTNULL
jbe@532 3247 ) AS "unordered"
jbe@532 3248 ORDER BY "calculated", "issue_id", "event"
jbe@532 3249 ) AS "ordered";
jbe@532 3250
jbe@532 3251
jbe@532 3252 INSERT INTO "snapshot" ("id", "calculated", "population", "area_id", "issue_id")
jbe@532 3253 SELECT
jbe@532 3254 "old_snapshot"."snapshot_id" AS "id",
jbe@532 3255 "old_snapshot"."calculated",
jbe@532 3256 ( SELECT COALESCE(sum("weight"), 0)
jbe@532 3257 FROM "direct_population_snapshot" "dps"
jbe@532 3258 WHERE "dps"."issue_id" = "old_snapshot"."issue_id"
jbe@532 3259 AND "dps"."event" = "old_snapshot"."event"
jbe@532 3260 ) AS "population",
jbe@532 3261 "issue"."area_id" AS "area_id",
jbe@532 3262 "issue"."id" AS "issue_id"
jbe@532 3263 FROM "old_snapshot" JOIN "issue"
jbe@532 3264 ON "old_snapshot"."issue_id" = "issue"."id";
jbe@532 3265
jbe@532 3266
jbe@532 3267 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
jbe@532 3268 SELECT "id" AS "snapshot_id", "issue_id" FROM "snapshot";
jbe@532 3269
jbe@532 3270
jbe@532 3271 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
jbe@532 3272 SELECT
jbe@532 3273 "old_snapshot"."snapshot_id",
jbe@532 3274 "direct_population_snapshot"."member_id"
jbe@532 3275 FROM "old_snapshot" JOIN "direct_population_snapshot"
jbe@532 3276 ON "old_snapshot"."issue_id" = "direct_population_snapshot"."issue_id"
jbe@532 3277 AND "old_snapshot"."event" = "direct_population_snapshot"."event";
jbe@532 3278
jbe@532 3279 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
jbe@532 3280 SELECT
jbe@532 3281 "old_snapshot"."snapshot_id",
jbe@532 3282 "delegating_population_snapshot"."member_id"
jbe@532 3283 FROM "old_snapshot" JOIN "delegating_population_snapshot"
jbe@532 3284 ON "old_snapshot"."issue_id" = "delegating_population_snapshot"."issue_id"
jbe@532 3285 AND "old_snapshot"."event" = "delegating_population_snapshot"."event";
jbe@532 3286
jbe@532 3287
jbe@532 3288 INSERT INTO "direct_interest_snapshot"
jbe@532 3289 ("snapshot_id", "issue_id", "member_id", "weight")
jbe@532 3290 SELECT
jbe@532 3291 "old_snapshot"."snapshot_id",
jbe@532 3292 "old_snapshot"."issue_id",
jbe@532 3293 "direct_interest_snapshot_old"."member_id",
jbe@532 3294 "direct_interest_snapshot_old"."weight"
jbe@532 3295 FROM "old_snapshot" JOIN "direct_interest_snapshot_old"
jbe@532 3296 ON "old_snapshot"."issue_id" = "direct_interest_snapshot_old"."issue_id"
jbe@532 3297 AND "old_snapshot"."event" = "direct_interest_snapshot_old"."event";
jbe@532 3298
jbe@532 3299 INSERT INTO "delegating_interest_snapshot"
jbe@532 3300 ( "snapshot_id", "issue_id",
jbe@532 3301 "member_id", "weight", "scope", "delegate_member_ids" )
jbe@532 3302 SELECT
jbe@532 3303 "old_snapshot"."snapshot_id",
jbe@532 3304 "old_snapshot"."issue_id",
jbe@532 3305 "delegating_interest_snapshot_old"."member_id",
jbe@532 3306 "delegating_interest_snapshot_old"."weight",
jbe@532 3307 "delegating_interest_snapshot_old"."scope",
jbe@532 3308 "delegating_interest_snapshot_old"."delegate_member_ids"
jbe@532 3309 FROM "old_snapshot" JOIN "delegating_interest_snapshot_old"
jbe@532 3310 ON "old_snapshot"."issue_id" = "delegating_interest_snapshot_old"."issue_id"
jbe@532 3311 AND "old_snapshot"."event" = "delegating_interest_snapshot_old"."event";
jbe@532 3312
jbe@532 3313 INSERT INTO "direct_supporter_snapshot"
jbe@532 3314 ( "snapshot_id", "issue_id",
jbe@532 3315 "initiative_id", "member_id", "draft_id", "informed", "satisfied" )
jbe@532 3316 SELECT
jbe@532 3317 "old_snapshot"."snapshot_id",
jbe@532 3318 "old_snapshot"."issue_id",
jbe@532 3319 "direct_supporter_snapshot_old"."initiative_id",
jbe@532 3320 "direct_supporter_snapshot_old"."member_id",
jbe@532 3321 "direct_supporter_snapshot_old"."draft_id",
jbe@532 3322 "direct_supporter_snapshot_old"."informed",
jbe@532 3323 "direct_supporter_snapshot_old"."satisfied"
jbe@532 3324 FROM "old_snapshot" JOIN "direct_supporter_snapshot_old"
jbe@532 3325 ON "old_snapshot"."issue_id" = "direct_supporter_snapshot_old"."issue_id"
jbe@532 3326 AND "old_snapshot"."event" = "direct_supporter_snapshot_old"."event";
jbe@532 3327
jbe@532 3328
jbe@532 3329 ALTER TABLE "issue" DISABLE TRIGGER USER; -- NOTE: required to modify table later
jbe@532 3330
jbe@532 3331 UPDATE "issue" SET "latest_snapshot_id" = "snapshot"."id"
jbe@532 3332 FROM (
jbe@532 3333 SELECT DISTINCT ON ("issue_id") "issue_id", "id"
jbe@532 3334 FROM "snapshot" ORDER BY "issue_id", "id" DESC
jbe@532 3335 ) AS "snapshot"
jbe@532 3336 WHERE "snapshot"."issue_id" = "issue"."id";
jbe@532 3337
jbe@532 3338 UPDATE "issue" SET "admission_snapshot_id" = "old_snapshot"."snapshot_id"
jbe@532 3339 FROM "old_snapshot"
jbe@532 3340 WHERE "old_snapshot"."issue_id" = "issue"."id"
jbe@532 3341 AND "old_snapshot"."event" = 'end_of_admission';
jbe@532 3342
jbe@532 3343 UPDATE "issue" SET "half_freeze_snapshot_id" = "old_snapshot"."snapshot_id"
jbe@532 3344 FROM "old_snapshot"
jbe@532 3345 WHERE "old_snapshot"."issue_id" = "issue"."id"
jbe@532 3346 AND "old_snapshot"."event" = 'half_freeze';
jbe@532 3347
jbe@532 3348 UPDATE "issue" SET "full_freeze_snapshot_id" = "old_snapshot"."snapshot_id"
jbe@532 3349 FROM "old_snapshot"
jbe@532 3350 WHERE "old_snapshot"."issue_id" = "issue"."id"
jbe@532 3351 AND "old_snapshot"."event" = 'full_freeze';
jbe@532 3352
jbe@532 3353 ALTER TABLE "issue" ENABLE TRIGGER USER;
jbe@532 3354
jbe@532 3355
jbe@532 3356 DROP TABLE "old_snapshot";
jbe@532 3357
jbe@532 3358 DROP TABLE "direct_supporter_snapshot_old";
jbe@532 3359 DROP TABLE "delegating_interest_snapshot_old";
jbe@532 3360 DROP TABLE "direct_interest_snapshot_old";
jbe@532 3361 DROP TABLE "delegating_population_snapshot";
jbe@532 3362 DROP TABLE "direct_population_snapshot";
jbe@532 3363
jbe@532 3364
jbe@532 3365 DROP VIEW "open_issue";
jbe@532 3366
jbe@532 3367
jbe@532 3368 ALTER TABLE "issue" DROP COLUMN "latest_snapshot_event";
jbe@532 3369
jbe@532 3370
jbe@532 3371 CREATE VIEW "open_issue" AS
jbe@532 3372 SELECT * FROM "issue" WHERE "closed" ISNULL;
jbe@532 3373
jbe@532 3374 COMMENT ON VIEW "open_issue" IS 'All open issues';
jbe@532 3375
jbe@532 3376
jbe@532 3377 -- NOTE: create "issue_for_admission" view after altering table "issue"
jbe@532 3378 CREATE VIEW "issue_for_admission" AS
jbe@532 3379 SELECT DISTINCT ON ("issue"."area_id")
jbe@532 3380 "issue".*,
jbe@532 3381 max("initiative"."supporter_count") AS "max_supporter_count"
jbe@532 3382 FROM "issue"
jbe@532 3383 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
jbe@532 3384 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
jbe@532 3385 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@532 3386 WHERE "issue"."state" = 'admission'::"issue_state"
jbe@532 3387 AND now() >= "issue"."created" + "issue"."min_admission_time"
jbe@532 3388 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
jbe@532 3389 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
jbe@532 3390 "issue"."population" * "policy"."issue_quorum_num"
jbe@532 3391 AND "initiative"."supporter_count" >= "area"."issue_quorum"
jbe@532 3392 AND "initiative"."revoked" ISNULL
jbe@532 3393 GROUP BY "issue"."id"
jbe@532 3394 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
jbe@532 3395
jbe@532 3396 COMMENT ON VIEW "issue_for_admission" IS 'Contains up to 1 issue per area eligible to pass from ''admission'' to ''discussion'' state; needs to be recalculated after admitting the issue in this view';
jbe@532 3397
jbe@532 3398
jbe@532 3399 DROP TYPE "snapshot_event";
jbe@532 3400
jbe@532 3401
jbe@532 3402 ALTER TABLE "issue" ADD CONSTRAINT "snapshot_required" CHECK (
jbe@532 3403 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
jbe@532 3404 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) );
jbe@532 3405
jbe@532 3406
jbe@532 3407 COMMIT;

Impressum / About Us