From: Galen Charlton <gmc@equinoxinitiative.org> Date: Fri, 6 Sep 2019 21:38:02 +0000 (-0400) Subject: LP#1793802: stamp database update X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=4d3fe7d66eb2c7ab50302f6f5feb5aa6d6853938;p=contrib%2FConifer.git LP#1793802: stamp database update Signed-off-by: Galen Charlton <gmc@equinoxinitiative.org> --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 977003f998..79af8ae0ba 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 ('1180', :eg_version); -- jeffdavis/gmcharlt +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1181', :eg_version); -- berick/csharp/gmcharlt CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/1181.schema.aged-billing-payment.sql b/Open-ILS/src/sql/Pg/upgrade/1181.schema.aged-billing-payment.sql new file mode 100644 index 0000000000..5fbfd69788 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1181.schema.aged-billing-payment.sql @@ -0,0 +1,135 @@ + +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('1181', :eg_version); + +\qecho Migrating aged billing and payment data. This might take a while. + +CREATE TABLE money.aged_payment (LIKE money.payment INCLUDING INDEXES); +ALTER TABLE money.aged_payment ADD COLUMN payment_type TEXT NOT NULL; + +CREATE TABLE money.aged_billing (LIKE money.billing INCLUDING INDEXES); + +INSERT INTO money.aged_payment + SELECT mp.* FROM money.payment_view mp + JOIN action.aged_circulation circ ON (circ.id = mp.xact); + +INSERT INTO money.aged_billing + SELECT mb.* FROM money.billing mb + JOIN action.aged_circulation circ ON (circ.id = mb.xact); + +CREATE OR REPLACE VIEW money.all_payments AS + SELECT * FROM money.payment_view + UNION ALL + SELECT * FROM money.aged_payment; + +CREATE OR REPLACE VIEW money.all_billings AS + SELECT * FROM money.billing + UNION ALL + SELECT * FROM money.aged_billing; + +CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$ +DECLARE +found char := 'N'; +BEGIN + + -- If there are any renewals for this circulation, don't archive or delete + -- it yet. We'll do so later, when we archive and delete the renewals. + + SELECT 'Y' INTO found + FROM action.circulation + WHERE parent_circ = OLD.id + LIMIT 1; + + IF found = 'Y' THEN + RETURN NULL; -- don't delete + END IF; + + -- Archive a copy of the old row to action.aged_circulation + + INSERT INTO action.aged_circulation + (id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location, + copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy, + circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, grace_period, due_date, + stop_fines_time, checkin_time, create_time, duration, fine_interval, recurring_fine, + max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recurring_fine_rule, + max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ) + SELECT + id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location, + copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy, + circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, grace_period, due_date, + stop_fines_time, checkin_time, create_time, duration, fine_interval, recurring_fine, + max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recurring_fine_rule, + max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ + FROM action.all_circulation WHERE id = OLD.id; + + -- Migrate billings and payments to aged tables + + INSERT INTO money.aged_billing + SELECT * FROM money.billing WHERE xact = OLD.id; + + INSERT INTO money.aged_payment + SELECT * FROM money.payment_view WHERE xact = OLD.id; + + DELETE FROM money.payment WHERE xact = OLD.id; + DELETE FROM money.billing WHERE xact = OLD.id; + + RETURN OLD; +END; +$$ LANGUAGE 'plpgsql'; + +-- NOTE you could COMMIT here then start a new TRANSACTION if desired. + +\qecho Deleting aged payments and billings from active payment/billing +\qecho tables. This may take a while... + +ALTER TABLE money.payment DISABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.cash_payment DISABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.check_payment DISABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.credit_card_payment DISABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.forgive_payment DISABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.credit_payment DISABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.goods_payment DISABLE TRIGGER mat_summary_del_tgr; + +DELETE FROM money.payment WHERE id IN (SELECT id FROM money.aged_payment); + +ALTER TABLE money.payment ENABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.cash_payment ENABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.check_payment ENABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.credit_card_payment ENABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.forgive_payment ENABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.credit_payment ENABLE TRIGGER mat_summary_del_tgr; +ALTER TABLE money.goods_payment ENABLE TRIGGER mat_summary_del_tgr; + +-- TODO: This approach assumes most of the money.billing rows have been +-- copied to money.aged_billing. If that is not the case, which would +-- happen if circ anonymization is not enabled, it will be faster to +-- perform a simple delete instead of a truncate/rebuild. + +-- Copy all money.billing rows that are not represented in money.aged_billing +CREATE TEMPORARY TABLE tmp_money_billing ON COMMIT DROP AS + SELECT mb.* FROM money.billing mb + LEFT JOIN money.aged_billing mab USING (id) + WHERE mab.id IS NULL; + +ALTER TABLE money.billing DISABLE TRIGGER ALL; + +-- temporarily remove the foreign key constraint to money.billing on +-- account adjusment. Needed for money.billing truncate. +ALTER TABLE money.account_adjustment + DROP CONSTRAINT account_adjustment_billing_fkey; + +TRUNCATE money.billing; + +INSERT INTO money.billing SELECT * FROM tmp_money_billing; + +ALTER TABLE money.billing ENABLE TRIGGER ALL; +ALTER TABLE money.account_adjustment + ADD CONSTRAINT account_adjustment_billing_fkey + FOREIGN KEY (billing) REFERENCES money.billing (id); + +COMMIT; + +-- Good to run after truncating -- OK to run after COMMIT. +ANALYZE money.billing; + diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.aged-billing-payment.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.aged-billing-payment.sql deleted file mode 100644 index ab8128f008..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.aged-billing-payment.sql +++ /dev/null @@ -1,135 +0,0 @@ - -BEGIN; - ---SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version); - -\qecho Migrating aged billing and payment data. This might take a while. - -CREATE TABLE money.aged_payment (LIKE money.payment INCLUDING INDEXES); -ALTER TABLE money.aged_payment ADD COLUMN payment_type TEXT NOT NULL; - -CREATE TABLE money.aged_billing (LIKE money.billing INCLUDING INDEXES); - -INSERT INTO money.aged_payment - SELECT mp.* FROM money.payment_view mp - JOIN action.aged_circulation circ ON (circ.id = mp.xact); - -INSERT INTO money.aged_billing - SELECT mb.* FROM money.billing mb - JOIN action.aged_circulation circ ON (circ.id = mb.xact); - -CREATE OR REPLACE VIEW money.all_payments AS - SELECT * FROM money.payment_view - UNION ALL - SELECT * FROM money.aged_payment; - -CREATE OR REPLACE VIEW money.all_billings AS - SELECT * FROM money.billing - UNION ALL - SELECT * FROM money.aged_billing; - -CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$ -DECLARE -found char := 'N'; -BEGIN - - -- If there are any renewals for this circulation, don't archive or delete - -- it yet. We'll do so later, when we archive and delete the renewals. - - SELECT 'Y' INTO found - FROM action.circulation - WHERE parent_circ = OLD.id - LIMIT 1; - - IF found = 'Y' THEN - RETURN NULL; -- don't delete - END IF; - - -- Archive a copy of the old row to action.aged_circulation - - INSERT INTO action.aged_circulation - (id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location, - copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy, - circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, grace_period, due_date, - stop_fines_time, checkin_time, create_time, duration, fine_interval, recurring_fine, - max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recurring_fine_rule, - max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ) - SELECT - id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location, - copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy, - circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, grace_period, due_date, - stop_fines_time, checkin_time, create_time, duration, fine_interval, recurring_fine, - max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recurring_fine_rule, - max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ - FROM action.all_circulation WHERE id = OLD.id; - - -- Migrate billings and payments to aged tables - - INSERT INTO money.aged_billing - SELECT * FROM money.billing WHERE xact = OLD.id; - - INSERT INTO money.aged_payment - SELECT * FROM money.payment_view WHERE xact = OLD.id; - - DELETE FROM money.payment WHERE xact = OLD.id; - DELETE FROM money.billing WHERE xact = OLD.id; - - RETURN OLD; -END; -$$ LANGUAGE 'plpgsql'; - --- NOTE you could COMMIT here then start a new TRANSACTION if desired. - -\qecho Deleting aged payments and billings from active payment/billing -\qecho tables. This may take a while... - -ALTER TABLE money.payment DISABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.cash_payment DISABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.check_payment DISABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.credit_card_payment DISABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.forgive_payment DISABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.credit_payment DISABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.goods_payment DISABLE TRIGGER mat_summary_del_tgr; - -DELETE FROM money.payment WHERE id IN (SELECT id FROM money.aged_payment); - -ALTER TABLE money.payment ENABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.cash_payment ENABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.check_payment ENABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.credit_card_payment ENABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.forgive_payment ENABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.credit_payment ENABLE TRIGGER mat_summary_del_tgr; -ALTER TABLE money.goods_payment ENABLE TRIGGER mat_summary_del_tgr; - --- TODO: This approach assumes most of the money.billing rows have been --- copied to money.aged_billing. If that is not the case, which would --- happen if circ anonymization is not enabled, it will be faster to --- perform a simple delete instead of a truncate/rebuild. - --- Copy all money.billing rows that are not represented in money.aged_billing -CREATE TEMPORARY TABLE tmp_money_billing ON COMMIT DROP AS - SELECT mb.* FROM money.billing mb - LEFT JOIN money.aged_billing mab USING (id) - WHERE mab.id IS NULL; - -ALTER TABLE money.billing DISABLE TRIGGER ALL; - --- temporarily remove the foreign key constraint to money.billing on --- account adjusment. Needed for money.billing truncate. -ALTER TABLE money.account_adjustment - DROP CONSTRAINT account_adjustment_billing_fkey; - -TRUNCATE money.billing; - -INSERT INTO money.billing SELECT * FROM tmp_money_billing; - -ALTER TABLE money.billing ENABLE TRIGGER ALL; -ALTER TABLE money.account_adjustment - ADD CONSTRAINT account_adjustment_billing_fkey - FOREIGN KEY (billing) REFERENCES money.billing (id); - -COMMIT; - --- Good to run after truncating -- OK to run after COMMIT. -ANALYZE money.billing; -