From: Jeff Godin Date: Thu, 1 Mar 2018 19:06:06 +0000 (-0500) Subject: LP#1748924 Stamping upgrade script X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=425bc5e41e99e2eaf1c87f8fc2e94103574316e4;p=working%2FEvergreen.git LP#1748924 Stamping upgrade script Stamping upgrade script for expanding billing timestamps Signed-off-by: Jeff Godin --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index f9a44c1e18..19972c686a 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -92,7 +92,7 @@ CREATE TRIGGER no_overlapping_deps BEFORE INSERT OR UPDATE ON config.db_patch_dependencies FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates'); -INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1105', :eg_version); --cesardv/kmlussier +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1106', :eg_version); --dbwells/jeff CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/1106.data.expand_billing_timestamps.sql b/Open-ILS/src/sql/Pg/upgrade/1106.data.expand_billing_timestamps.sql new file mode 100644 index 0000000000..0e53acd5e6 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1106.data.expand_billing_timestamps.sql @@ -0,0 +1,53 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('1106', :eg_version); + +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; + +--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(); + +COMMIT; diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.data.expand_billing_timestamps.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.data.expand_billing_timestamps.sql deleted file mode 100644 index 2bb74689ff..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.data.expand_billing_timestamps.sql +++ /dev/null @@ -1,53 +0,0 @@ -BEGIN; - ---SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version); - -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; - ---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(); - -COMMIT;