From: Kathy Lussier Date: Tue, 18 Sep 2018 18:53:47 +0000 (-0400) Subject: LP#1787274: Stamping upgrade script for no dupe transits X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=cbe09037cf0829ca2516b8c1730df6099fbeb138;p=Evergreen.git LP#1787274: Stamping upgrade script for no dupe transits Signed-off-by: Kathy Lussier Conflicts: Open-ILS/src/sql/Pg/002.schema.config.sql --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 3b0a67232d..581d8732b0 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 ('1130', :eg_version); -- Dyrcona/mmorgan/gmcharlt +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1133', :eg_version); -- berick/kmlussier CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/1133.schema.no-dupe-transits.sql b/Open-ILS/src/sql/Pg/upgrade/1133.schema.no-dupe-transits.sql new file mode 100644 index 0000000000..7faa26acec --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1133.schema.no-dupe-transits.sql @@ -0,0 +1,73 @@ + +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('1133', :eg_version); + +\qecho Applying a unique constraint to action.transit_copy. This will +\qecho only effect newly created transits. Admins are encouraged to manually +\qecho remove any existing duplicate transits by applying values for cancel_time +\qecho or dest_recv_time, or by deleting the offending transits. Below is a +\qecho query to locate duplicate transits. Note dupes may exist accross +\qecho parent (action.transit_copy) and child tables (action.hold_transit_copy, +\qecho action.reservation_transit_copy) +\qecho +\qecho WITH dupe_transits AS ( +\qecho SELECT COUNT(*), target_copy FROM action.transit_copy +\qecho WHERE dest_recv_time IS NULL AND cancel_time IS NULL +\qecho GROUP BY 2 HAVING COUNT(*) > 1 +\qecho ) SELECT atc.* +\qecho FROM dupe_transits +\qecho JOIN action.transit_copy atc USING (target_copy) +\qecho WHERE dest_recv_time IS NULL AND cancel_time IS NULL; +\qecho + +/* +Unique indexes are not inherited by child tables, so they will not prevent +duplicate inserts on action.transit_copy and action.hold_transit_copy, +for example. Use check constraints instead to enforce unique-per-copy +transits accross all transit types. +*/ + +-- Create an index for speedy check constraint lookups. +CREATE INDEX active_transit_for_copy + ON action.transit_copy (target_copy) + WHERE dest_recv_time IS NULL AND cancel_time IS NULL; + +-- Check for duplicate transits across all transit types +CREATE OR REPLACE FUNCTION action.copy_transit_is_unique() + RETURNS TRIGGER AS $func$ +BEGIN + PERFORM * FROM action.transit_copy + WHERE target_copy = NEW.target_copy + AND dest_recv_time IS NULL + AND cancel_time IS NULL; + IF FOUND THEN + RAISE EXCEPTION 'Copy id=% is already in transit', NEW.target_copy; + END IF; + RETURN NULL; +END; +$func$ LANGUAGE PLPGSQL STABLE; + +-- Apply constraint to all transit tables +CREATE CONSTRAINT TRIGGER transit_copy_is_unique_check + AFTER INSERT ON action.transit_copy + FOR EACH ROW EXECUTE PROCEDURE action.copy_transit_is_unique(); + +CREATE CONSTRAINT TRIGGER hold_transit_copy_is_unique_check + AFTER INSERT ON action.hold_transit_copy + FOR EACH ROW EXECUTE PROCEDURE action.copy_transit_is_unique(); + +CREATE CONSTRAINT TRIGGER reservation_transit_copy_is_unique_check + AFTER INSERT ON action.reservation_transit_copy + FOR EACH ROW EXECUTE PROCEDURE action.copy_transit_is_unique(); + +/* +-- UNDO +DROP TRIGGER transit_copy_is_unique_check ON action.transit_copy; +DROP TRIGGER hold_transit_copy_is_unique_check ON action.hold_transit_copy; +DROP TRIGGER reservation_transit_copy_is_unique_check ON action.reservation_transit_copy; +DROP INDEX action.active_transit_for_copy; +*/ + +COMMIT; + diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.no-dupe-transits.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.no-dupe-transits.sql deleted file mode 100644 index 0016a42f0f..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.no-dupe-transits.sql +++ /dev/null @@ -1,73 +0,0 @@ - -BEGIN; - ---SELECT evergreen.upgrade_deps_block_check('XXX', :eg_version); - -\qecho Applying a unique constraint to action.transit_copy. This will -\qecho only effect newly created transits. Admins are encouraged to manually -\qecho remove any existing duplicate transits by applying values for cancel_time -\qecho or dest_recv_time, or by deleting the offending transits. Below is a -\qecho query to locate duplicate transits. Note dupes may exist accross -\qecho parent (action.transit_copy) and child tables (action.hold_transit_copy, -\qecho action.reservation_transit_copy) -\qecho -\qecho WITH dupe_transits AS ( -\qecho SELECT COUNT(*), target_copy FROM action.transit_copy -\qecho WHERE dest_recv_time IS NULL AND cancel_time IS NULL -\qecho GROUP BY 2 HAVING COUNT(*) > 1 -\qecho ) SELECT atc.* -\qecho FROM dupe_transits -\qecho JOIN action.transit_copy atc USING (target_copy) -\qecho WHERE dest_recv_time IS NULL AND cancel_time IS NULL; -\qecho - -/* -Unique indexes are not inherited by child tables, so they will not prevent -duplicate inserts on action.transit_copy and action.hold_transit_copy, -for example. Use check constraints instead to enforce unique-per-copy -transits accross all transit types. -*/ - --- Create an index for speedy check constraint lookups. -CREATE INDEX active_transit_for_copy - ON action.transit_copy (target_copy) - WHERE dest_recv_time IS NULL AND cancel_time IS NULL; - --- Check for duplicate transits across all transit types -CREATE OR REPLACE FUNCTION action.copy_transit_is_unique() - RETURNS TRIGGER AS $func$ -BEGIN - PERFORM * FROM action.transit_copy - WHERE target_copy = NEW.target_copy - AND dest_recv_time IS NULL - AND cancel_time IS NULL; - IF FOUND THEN - RAISE EXCEPTION 'Copy id=% is already in transit', NEW.target_copy; - END IF; - RETURN NULL; -END; -$func$ LANGUAGE PLPGSQL STABLE; - --- Apply constraint to all transit tables -CREATE CONSTRAINT TRIGGER transit_copy_is_unique_check - AFTER INSERT ON action.transit_copy - FOR EACH ROW EXECUTE PROCEDURE action.copy_transit_is_unique(); - -CREATE CONSTRAINT TRIGGER hold_transit_copy_is_unique_check - AFTER INSERT ON action.hold_transit_copy - FOR EACH ROW EXECUTE PROCEDURE action.copy_transit_is_unique(); - -CREATE CONSTRAINT TRIGGER reservation_transit_copy_is_unique_check - AFTER INSERT ON action.reservation_transit_copy - FOR EACH ROW EXECUTE PROCEDURE action.copy_transit_is_unique(); - -/* --- UNDO -DROP TRIGGER transit_copy_is_unique_check ON action.transit_copy; -DROP TRIGGER hold_transit_copy_is_unique_check ON action.hold_transit_copy; -DROP TRIGGER reservation_transit_copy_is_unique_check ON action.reservation_transit_copy; -DROP INDEX action.active_transit_for_copy; -*/ - -COMMIT; -