From: Lebbeous Fogle-Weekley Date: Tue, 23 Oct 2012 16:25:18 +0000 (-0400) Subject: Fix divergence of stock serials schema and upgraded schema X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=0e1335cab7cf7328d107c86b0cd237146bda38e2;p=contrib%2FConifer.git Fix divergence of stock serials schema and upgraded schema And additionally make a function used in a constraint on serial.issuance.holding_code a little bit smarter. These issues were reported to me by Galen Charlton. The upgrade script included here will set serial.issuance.holding_code to NULL in cases where the value doesn't validate, but in those cases there is no part of Evergreen that could have made use of the data anyway, and the data is just plain bad. Signed-off-by: Lebbeous Fogle-Weekley Signed-off-by: Mike Rylander --- diff --git a/Open-ILS/src/sql/Pg/000.functions.general.sql b/Open-ILS/src/sql/Pg/000.functions.general.sql index ffbc6299d0..51ce2b7764 100644 --- a/Open-ILS/src/sql/Pg/000.functions.general.sql +++ b/Open-ILS/src/sql/Pg/000.functions.general.sql @@ -57,4 +57,23 @@ $func$; COMMENT ON FUNCTION evergreen.xml_pretty_print(input XML) IS 'Simple pretty printer for XML, as written by Andrew Dunstan at http://goo.gl/zBHIk'; +CREATE OR REPLACE FUNCTION evergreen.could_be_serial_holding_code(TEXT) RETURNS BOOL AS $$ + use JSON::XS; + use MARC::Field; + + eval { + my $holding_code = (new JSON::XS)->decode(shift); + new MARC::Field('999', @$holding_code); + }; + return 0 if $@; + # verify that subfield labels are exactly one character long + foreach (keys %{ { @$holding_code } }) { + return 0 if length($_) != 1; + } + return 1; +$$ LANGUAGE PLPERLU; + +COMMENT ON FUNCTION evergreen.could_be_serial_holding_code(TEXT) IS + 'Return true if parameter is valid JSON representing an array that at minimum doesn''t make MARC::Field balk and only has subfield labels exactly one character long. Otherwise false.'; + COMMIT; diff --git a/Open-ILS/src/sql/Pg/210.schema.serials.sql b/Open-ILS/src/sql/Pg/210.schema.serials.sql index 39fb75e057..d025d5e6a6 100644 --- a/Open-ILS/src/sql/Pg/210.schema.serials.sql +++ b/Open-ILS/src/sql/Pg/210.schema.serials.sql @@ -193,7 +193,9 @@ CREATE TABLE serial.issuance ( date_published TIMESTAMP WITH TIME ZONE, caption_and_pattern INT REFERENCES serial.caption_and_pattern (id) DEFERRABLE INITIALLY DEFERRED, - holding_code TEXT, + holding_code TEXT CONSTRAINT issuance_holding_code_check CHECK ( + holding_code IS NULL OR could_be_serial_holding_code(holding_code) + ), holding_type TEXT CONSTRAINT valid_holding_type CHECK ( holding_type IS NULL diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.serials-holding-code-test-improved.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.serials-holding-code-test-improved.sql new file mode 100644 index 0000000000..d1c3c38d98 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.serials-holding-code-test-improved.sql @@ -0,0 +1,38 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version); + +CREATE OR REPLACE FUNCTION evergreen.could_be_serial_holding_code(TEXT) RETURNS BOOL AS $$ + use JSON::XS; + use MARC::Field; + + eval { + my $holding_code = (new JSON::XS)->decode(shift); + new MARC::Field('999', @$holding_code); + }; + return 0 if $@; + # verify that subfield labels are exactly one character long + foreach (keys %{ { @$holding_code } }) { + return 0 if length($_) != 1; + } + return 1; +$$ LANGUAGE PLPERLU; + +COMMENT ON FUNCTION evergreen.could_be_serial_holding_code(TEXT) IS + 'Return true if parameter is valid JSON representing an array that at minimu +m doesn''t make MARC::Field balk and only has subfield labels exactly one character long. Otherwise false.'; + + +-- This UPDATE throws away data, but only bad data that makes things break +-- anyway. +UPDATE serial.issuance + SET holding_code = NULL + WHERE NOT could_be_serial_holding_code(holding_code); + +ALTER TABLE serial.issuance + DROP CONSTRAINT IF EXISTS issuance_holding_code_check; + +ALTER TABLE serial.issuance + ADD CHECK (holding_code IS NULL OR could_be_serial_holding_code(holding_code)); + +COMMIT;