CREATE TRIGGER z_opac_vis_mat_view_tgr AFTER INSERT OR UPDATE
ON serial.unit FOR EACH ROW EXECUTE PROCEDURE asset.cache_copy_visibility();
-SELECT CLOCK_TIMESTAMP(), 'Updating billing timestamps';
-
-ALTER TABLE money.billing
- ADD COLUMN create_date TIMESTAMP WITH TIME ZONE,
- ADD COLUMN period_start TIMESTAMP WITH TIME ZONE,
- ADD COLUMN period_end TIMESTAMP WITH TIME ZONE;
-
--- TODO: back-fill aged billing data, indexes, and null constraints
--- for consistency after deciding whether we want to delete any of them.
-ALTER TABLE money.aged_billing
- ADD COLUMN create_date TIMESTAMP WITH TIME ZONE,
- ADD COLUMN period_start TIMESTAMP WITH TIME ZONE,
- ADD COLUMN period_end TIMESTAMP WITH TIME ZONE;
-
---Disable materialized update trigger
---It takes forever, and doesn't matter yet for what we are doing, as the
---view definition is unchanged (still using billing_ts)
-ALTER TABLE money.billing DISABLE TRIGGER mat_summary_upd_tgr;
-
---Limit to btype=1 / 'Overdue Materials'
---Update day-granular fines first (i.e. 24 hour, 1 day, 2 day, etc., all of which are multiples of 86400 seconds), and simply remove the time portion of timestamp
-UPDATE money.billing mb
- SET period_start = date_trunc('day', billing_ts), period_end = date_trunc('day', billing_ts) + (ac.fine_interval - '1 second')
- FROM action.circulation ac
-WHERE mb.xact = ac.id
- AND mb.btype = 1
- AND (EXTRACT(EPOCH FROM ac.fine_interval))::integer % 86400 = 0;
-
---Update fines for non-day intervals
-UPDATE money.billing mb
- SET period_start = billing_ts - ac.fine_interval + interval '1 sec', period_end = billing_ts
- FROM action.circulation ac
-WHERE mb.xact = ac.id
- AND mb.btype = 1
- AND (EXTRACT(EPOCH FROM ac.fine_interval))::integer % 86400 > 0;
-
-SET CONSTRAINTS ALL IMMEDIATE;
-UPDATE money.billing SET create_date = COALESCE(period_start, billing_ts);
-
---Re-enable update trigger
-ALTER TABLE money.billing ENABLE TRIGGER mat_summary_upd_tgr;
-
-ALTER TABLE money.billing ALTER COLUMN create_date SET DEFAULT NOW();
-ALTER TABLE money.billing ALTER COLUMN create_date SET NOT NULL;
-
-CREATE INDEX m_b_create_date_idx ON money.billing (create_date);
-CREATE INDEX m_b_period_start_idx ON money.billing (period_start);
-CREATE INDEX m_b_period_end_idx ON money.billing (period_end);
-
-CREATE OR REPLACE FUNCTION money.maintain_billing_ts () RETURNS TRIGGER AS $$
-BEGIN
- NEW.billing_ts := COALESCE(NEW.period_end, NEW.create_date);
- RETURN NEW;
-END;
-$$ LANGUAGE PLPGSQL;
-CREATE TRIGGER maintain_billing_ts_tgr BEFORE INSERT OR UPDATE ON money.billing FOR EACH ROW EXECUTE PROCEDURE money.maintain_billing_ts();
-
SELECT CLOCK_TIMESTAMP(), 'Making copy alert types active';
UPDATE config.copy_alert_type
SET active = TRUE
WHERE id IN (4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17);
-
--- Update keyword indexes for existing patrons
-SELECT CLOCK_TIMESTAMP(), 'Updating patron name keyword vector';
-
-UPDATE actor.usr SET name_kw_tsvector =
- TO_TSVECTOR(
- COALESCE(prefix, '') || ' ' ||
- COALESCE(first_given_name, '') || ' ' ||
- COALESCE(evergreen.unaccent_and_squash(first_given_name), '') || ' ' ||
- COALESCE(second_given_name, '') || ' ' ||
- COALESCE(evergreen.unaccent_and_squash(second_given_name), '') || ' ' ||
- COALESCE(family_name, '') || ' ' ||
- COALESCE(evergreen.unaccent_and_squash(family_name), '') || ' ' ||
- COALESCE(suffix, '')
- );
-
--- Authority record re-ingest
-
SELECT CLOCK_TIMESTAMP(), 'Updating copy alert messages';
SELECT CLOCK_TIMESTAMP(), 'Copying copy alert messages to normal checkout copy alerts...';
UPDATE asset.copy SET alert_message = NULL
WHERE alert_message IS NOT NULL;
+
+/*
SELECT CLOCK_TIMESTAMP(), 'Reingesting authority records';
-- add the flag ingest.disable_authority_full_rec if it does not exist
WHERE a.name = b.name;
SELECT CLOCK_TIMESTAMP(), 'Done reingesting authority records';
+*/
--- /dev/null
+-- Deploy kcls-evergreen:3.2-data-billing-timestamps to pg
+-- requires: 2.12-3.2-db-upgrade-data
+
+BEGIN;
+
+SET STATEMENT_TIMEOUT = 0;
+
+SELECT CLOCK_TIMESTAMP(), 'Updating billing timestamps: ~5 hours';
+
+ALTER TABLE money.billing
+ ADD COLUMN create_date TIMESTAMP WITH TIME ZONE,
+ ADD COLUMN period_start TIMESTAMP WITH TIME ZONE,
+ ADD COLUMN period_end TIMESTAMP WITH TIME ZONE;
+
+-- TODO: back-fill aged billing data, indexes, and null constraints
+-- for consistency after deciding whether we want to delete any of them.
+ALTER TABLE money.aged_billing
+ ADD COLUMN create_date TIMESTAMP WITH TIME ZONE,
+ ADD COLUMN period_start TIMESTAMP WITH TIME ZONE,
+ ADD COLUMN period_end TIMESTAMP WITH TIME ZONE;
+
+--Disable materialized update trigger
+--It takes forever, and doesn't matter yet for what we are doing, as the
+--view definition is unchanged (still using billing_ts)
+ALTER TABLE money.billing DISABLE TRIGGER mat_summary_upd_tgr;
+
+SELECT CLOCK_TIMESTAMP(), 'Updating billing period start/end timestamps';
+
+--Limit to btype=1 / 'Overdue Materials'
+--Update day-granular fines first (i.e. 24 hour, 1 day, 2 day, etc., all of which are multiples of 86400 seconds), and simply remove the time portion of timestamp
+UPDATE money.billing mb
+ SET period_start = date_trunc('day', billing_ts), period_end = date_trunc('day', billing_ts) + (ac.fine_interval - '1 second')
+ FROM action.circulation ac
+WHERE mb.xact = ac.id
+ AND mb.btype = 1
+ AND (EXTRACT(EPOCH FROM ac.fine_interval))::integer % 86400 = 0;
+
+SELECT CLOCK_TIMESTAMP(), 'Updating billing period start/end timestamps (non-daily)';
+
+--Update fines for non-day intervals
+UPDATE money.billing mb
+ SET period_start = billing_ts - ac.fine_interval + interval '1 sec', period_end = billing_ts
+ FROM action.circulation ac
+WHERE mb.xact = ac.id
+ AND mb.btype = 1
+ AND (EXTRACT(EPOCH FROM ac.fine_interval))::integer % 86400 > 0;
+
+SELECT CLOCK_TIMESTAMP(), 'Updating billing create_date timestamps';
+
+SET CONSTRAINTS ALL IMMEDIATE;
+UPDATE money.billing SET create_date = COALESCE(period_start, billing_ts);
+
+--Re-enable update trigger
+ALTER TABLE money.billing ENABLE TRIGGER mat_summary_upd_tgr;
+
+ALTER TABLE money.billing ALTER COLUMN create_date SET DEFAULT NOW();
+ALTER TABLE money.billing ALTER COLUMN create_date SET NOT NULL;
+
+SELECT CLOCK_TIMESTAMP(), 'Creating billing indexes (x3)';
+
+CREATE INDEX m_b_create_date_idx ON money.billing (create_date);
+CREATE INDEX m_b_period_start_idx ON money.billing (period_start);
+CREATE INDEX m_b_period_end_idx ON money.billing (period_end);
+
+CREATE OR REPLACE FUNCTION money.maintain_billing_ts () RETURNS TRIGGER AS $$
+BEGIN
+ NEW.billing_ts := COALESCE(NEW.period_end, NEW.create_date);
+ RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+CREATE TRIGGER maintain_billing_ts_tgr BEFORE INSERT OR UPDATE ON money.billing FOR EACH ROW EXECUTE PROCEDURE money.maintain_billing_ts();
+
+COMMIT;
+
+
--- /dev/null
+-- Deploy kcls-evergreen:3.2-data-name-keywords to pg
+-- requires: 2.12-3.2-db-upgrade-data
+
+BEGIN;
+
+SET STATEMENT_TIMEOUT = 0;
+
+-- Update keyword indexes for existing patrons
+SELECT CLOCK_TIMESTAMP(), 'Updating patron name keyword vector: ~1 hour';
+
+UPDATE actor.usr SET name_kw_tsvector =
+ TO_TSVECTOR(
+ COALESCE(prefix, '') || ' ' ||
+ COALESCE(first_given_name, '') || ' ' ||
+ COALESCE(evergreen.unaccent_and_squash(first_given_name), '') || ' ' ||
+ COALESCE(second_given_name, '') || ' ' ||
+ COALESCE(evergreen.unaccent_and_squash(second_given_name), '') || ' ' ||
+ COALESCE(family_name, '') || ' ' ||
+ COALESCE(evergreen.unaccent_and_squash(family_name), '') || ' ' ||
+ COALESCE(suffix, '')
+ );
+
+COMMIT;
+
--- /dev/null
+-- Revert kcls-evergreen:3.2-data-billing-timestamps from pg
+
+BEGIN;
+
+-- XXX Add DDLs here.
+
+COMMIT;
--- /dev/null
+-- Revert kcls-evergreen:3.2-data-name-keywords from pg
+
+BEGIN;
+
+-- XXX Add DDLs here.
+
+COMMIT;
stock-browse-cleanup [stock-browse-schema] 2018-10-03T18:05:49Z Bill Erickson,,, <berick@kcls-dev> # Delete old browse data
2.12-3.2-db-upgrade-schema [ecard-notice-validator] 2018-09-12T14:46:28Z Bill Erickson,,, <berick@kcls-dev-local> # 2.12 to 3.2 DB update
2.12-3.2-db-upgrade-data [2.12-3.2-db-upgrade-schema] 2018-09-12T14:46:52Z Bill Erickson,,, <berick@kcls-dev-local> # 2.12 to 3.2 post-update data
+3.2-data-name-keywords [2.12-3.2-db-upgrade-data] 2018-09-26T20:29:00Z Bill Erickson,,, <berick@kcls-dev> # Extract name keywords
+3.2-data-billing-timestamps [2.12-3.2-db-upgrade-data] 2018-09-26T20:29:38Z Bill Erickson,,, <berick@kcls-dev> # Billing timestamp updates