[open-ils-commits] r20433 - branches/rel_2_0/Open-ILS/src/sql/Pg (miker)
svn at svn.open-ils.org
svn at svn.open-ils.org
Thu May 5 14:07:31 EDT 2011
Author: miker
Date: 2011-05-05 14:07:27 -0400 (Thu, 05 May 2011)
New Revision: 20433
Added:
branches/rel_2_0/Open-ILS/src/sql/Pg/2.0.5-2.0.6-upgrade-db.sql
Log:
adding upgrade script
Added: branches/rel_2_0/Open-ILS/src/sql/Pg/2.0.5-2.0.6-upgrade-db.sql
===================================================================
--- branches/rel_2_0/Open-ILS/src/sql/Pg/2.0.5-2.0.6-upgrade-db.sql (rev 0)
+++ branches/rel_2_0/Open-ILS/src/sql/Pg/2.0.5-2.0.6-upgrade-db.sql 2011-05-05 18:07:27 UTC (rev 20433)
@@ -0,0 +1,972 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('2.0.6');
+INSERT INTO config.upgrade_log (version) VALUES ('0508'); -- gmc
+
+CREATE OR REPLACE FUNCTION maintain_901 () RETURNS TRIGGER AS $func$
+DECLARE
+ use_id_for_tcn BOOLEAN;
+ norm_tcn_value TEXT;
+ norm_tcn_source TEXT;
+BEGIN
+ -- Remove any existing 901 fields before we insert the authoritative one
+ NEW.marc := REGEXP_REPLACE(NEW.marc, E'<datafield[^>]*?tag="901".+?</datafield>', '', 'g');
+
+ IF TG_TABLE_SCHEMA = 'biblio' THEN
+ -- Set TCN value to record ID?
+ SELECT enabled FROM config.global_flag INTO use_id_for_tcn
+ WHERE name = 'cat.bib.use_id_for_tcn';
+
+ IF use_id_for_tcn = 't' THEN
+ NEW.tcn_value := NEW.id;
+ norm_tcn_value := NEW.tcn_value;
+ ELSE
+ -- yes, ampersands can show up in tcn_values ...
+ norm_tcn_value := REGEXP_REPLACE(NEW.tcn_value, E'&(?!\\S+;)', '&', 'g');
+ END IF;
+ -- ... and TCN sources
+ -- FIXME we have here yet another (stub) version of entityize
+ norm_tcn_source := REGEXP_REPLACE(NEW.tcn_source, E'&(?!\\S+;)', '&', 'g');
+
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="a">' || norm_tcn_value || E'</subfield>' ||
+ '<subfield code="b">' || norm_tcn_source || E'</subfield>' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ CASE WHEN NEW.owner IS NOT NULL THEN '<subfield code="o">' || NEW.owner || E'</subfield>' ELSE '' END ||
+ CASE WHEN NEW.share_depth IS NOT NULL THEN '<subfield code="d">' || NEW.share_depth || E'</subfield>' ELSE '' END ||
+ E'</datafield>\\1'
+ );
+ ELSIF TG_TABLE_SCHEMA = 'authority' THEN
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ E'</datafield>\\1'
+ );
+ ELSIF TG_TABLE_SCHEMA = 'serial' THEN
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ '<subfield code="o">' || NEW.owning_lib || E'</subfield>' ||
+ CASE WHEN NEW.record IS NOT NULL THEN '<subfield code="r">' || NEW.record || E'</subfield>' ELSE '' END ||
+ E'</datafield>\\1'
+ );
+ ELSE
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ E'</datafield>\\1'
+ );
+ END IF;
+
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0509'); -- gmc
+
+CREATE OR REPLACE FUNCTION evergreen.xml_escape(str TEXT) RETURNS text AS $$
+ SELECT REPLACE(REPLACE(REPLACE($1,
+ '&', '&'),
+ '<', '<'),
+ '>', '>');
+$$ LANGUAGE SQL IMMUTABLE;
+
+CREATE OR REPLACE FUNCTION maintain_901 () RETURNS TRIGGER AS $func$
+DECLARE
+ use_id_for_tcn BOOLEAN;
+BEGIN
+ -- Remove any existing 901 fields before we insert the authoritative one
+ NEW.marc := REGEXP_REPLACE(NEW.marc, E'<datafield[^>]*?tag="901".+?</datafield>', '', 'g');
+
+ IF TG_TABLE_SCHEMA = 'biblio' THEN
+ -- Set TCN value to record ID?
+ SELECT enabled FROM config.global_flag INTO use_id_for_tcn
+ WHERE name = 'cat.bib.use_id_for_tcn';
+
+ IF use_id_for_tcn = 't' THEN
+ NEW.tcn_value := NEW.id;
+ END IF;
+
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="a">' || evergreen.xml_escape(NEW.tcn_value) || E'</subfield>' ||
+ '<subfield code="b">' || evergreen.xml_escape(NEW.tcn_source) || E'</subfield>' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ CASE WHEN NEW.owner IS NOT NULL THEN '<subfield code="o">' || NEW.owner || E'</subfield>' ELSE '' END ||
+ CASE WHEN NEW.share_depth IS NOT NULL THEN '<subfield code="d">' || NEW.share_depth || E'</subfield>' ELSE '' END ||
+ E'</datafield>\\1'
+ );
+ ELSIF TG_TABLE_SCHEMA = 'authority' THEN
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ E'</datafield>\\1'
+ );
+ ELSIF TG_TABLE_SCHEMA = 'serial' THEN
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ '<subfield code="o">' || NEW.owning_lib || E'</subfield>' ||
+ CASE WHEN NEW.record IS NOT NULL THEN '<subfield code="r">' || NEW.record || E'</subfield>' ELSE '' END ||
+ E'</datafield>\\1'
+ );
+ ELSE
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ E'</datafield>\\1'
+ );
+ END IF;
+
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0510'); -- miker
+
+SELECT evergreen.change_db_setting('search_path', ARRAY['evergreen','public','pg_catalog']);
+
+-- Fix function breakage due to short search path
+CREATE OR REPLACE FUNCTION evergreen.force_unicode_normal_form(string TEXT, form TEXT) RETURNS TEXT AS $func$
+use Unicode::Normalize 'normalize';
+return normalize($_[1],$_[0]); # reverse the params
+$func$ LANGUAGE PLPERLU;
+
+CREATE OR REPLACE FUNCTION evergreen.facet_force_nfc() RETURNS TRIGGER AS $$
+BEGIN
+ NEW.value := force_unicode_normal_form(NEW.value,'NFC');
+ RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER facet_force_nfc_tgr ON metabib.facet_entry;
+
+CREATE TRIGGER facet_force_nfc_tgr
+ BEFORE UPDATE OR INSERT ON metabib.facet_entry
+ FOR EACH ROW EXECUTE PROCEDURE evergreen.facet_force_nfc();
+
+DROP FUNCTION IF EXISTS public.force_unicode_normal_form (TEXT,TEXT);
+DROP FUNCTION IF EXISTS public.facet_force_nfc ();
+
+CREATE OR REPLACE FUNCTION evergreen.xml_escape(str TEXT) RETURNS text AS $$
+ SELECT REPLACE(REPLACE(REPLACE($1,
+ '&', '&'),
+ '<', '<'),
+ '>', '>');
+$$ LANGUAGE SQL IMMUTABLE;
+
+CREATE OR REPLACE FUNCTION evergreen.maintain_901 () RETURNS TRIGGER AS $func$
+DECLARE
+ use_id_for_tcn BOOLEAN;
+BEGIN
+ -- Remove any existing 901 fields before we insert the authoritative one
+ NEW.marc := REGEXP_REPLACE(NEW.marc, E'<datafield[^>]*?tag="901".+?</datafield>', '', 'g');
+
+ IF TG_TABLE_SCHEMA = 'biblio' THEN
+ -- Set TCN value to record ID?
+ SELECT enabled FROM config.global_flag INTO use_id_for_tcn
+ WHERE name = 'cat.bib.use_id_for_tcn';
+
+ IF use_id_for_tcn = 't' THEN
+ NEW.tcn_value := NEW.id;
+ END IF;
+
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="a">' || evergreen.xml_escape(NEW.tcn_value) || E'</subfield>' ||
+ '<subfield code="b">' || evergreen.xml_escape(NEW.tcn_source) || E'</subfield>' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ CASE WHEN NEW.owner IS NOT NULL THEN '<subfield code="o">' || NEW.owner || E'</subfield>' ELSE '' END ||
+ CASE WHEN NEW.share_depth IS NOT NULL THEN '<subfield code="d">' || NEW.share_depth || E'</subfield>' ELSE '' END ||
+ E'</datafield>\\1'
+ );
+ ELSIF TG_TABLE_SCHEMA = 'authority' THEN
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ E'</datafield>\\1'
+ );
+ ELSIF TG_TABLE_SCHEMA = 'serial' THEN
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ '<subfield code="o">' || NEW.owning_lib || E'</subfield>' ||
+ CASE WHEN NEW.record IS NOT NULL THEN '<subfield code="r">' || NEW.record || E'</subfield>' ELSE '' END ||
+ E'</datafield>\\1'
+ );
+ ELSE
+ NEW.marc := REGEXP_REPLACE(
+ NEW.marc,
+ E'(</(?:[^:]*?:)?record>)',
+ E'<datafield tag="901" ind1=" " ind2=" ">' ||
+ '<subfield code="c">' || NEW.id || E'</subfield>' ||
+ '<subfield code="t">' || TG_TABLE_SCHEMA || E'</subfield>' ||
+ E'</datafield>\\1'
+ );
+ END IF;
+
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER b_maintain_901 ON biblio.record_entry;
+DROP TRIGGER b_maintain_901 ON authority.record_entry;
+DROP TRIGGER b_maintain_901 ON serial.record_entry;
+
+CREATE TRIGGER b_maintain_901 BEFORE INSERT OR UPDATE ON biblio.record_entry FOR EACH ROW EXECUTE PROCEDURE evergreen.maintain_901();
+CREATE TRIGGER b_maintain_901 BEFORE INSERT OR UPDATE ON authority.record_entry FOR EACH ROW EXECUTE PROCEDURE evergreen.maintain_901();
+CREATE TRIGGER b_maintain_901 BEFORE INSERT OR UPDATE ON serial.record_entry FOR EACH ROW EXECUTE PROCEDURE evergreen.maintain_901();
+
+DROP FUNCTION IF EXISTS public.maintain_901 ();
+
+INSERT INTO config.upgrade_log (version) VALUES ('0511'); -- miker
+
+CREATE OR REPLACE FUNCTION evergreen.fake_fkey_tgr () RETURNS TRIGGER AS $F$
+DECLARE
+ copy_id BIGINT;
+BEGIN
+ EXECUTE 'SELECT ($1).' || quote_ident(TG_ARGV[0]) INTO copy_id USING NEW;
+ PERFORM * FROM asset.copy WHERE id = copy_id;
+ IF NOT FOUND THEN
+ RAISE EXCEPTION 'Key (%.%=%) does not exist in asset.copy', TG_TABLE_SCHEMA, TG_TABLE_NAME, copy_id;
+ END IF;
+ RETURN NULL;
+END;
+$F$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER action_circulation_target_copy_trig AFTER INSERT OR UPDATE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE evergreen.fake_fkey_tgr('target_copy');
+
+INSERT INTO config.upgrade_log (version) VALUES ('0516');
+
+CREATE OR REPLACE FUNCTION public.extract_acq_marc_field ( BIGINT, TEXT, TEXT) RETURNS TEXT AS $$
+ SELECT extract_marc_field('acq.lineitem', $1, $2, $3);
+$$ LANGUAGE SQL;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0517'); --miker
+
+CREATE OR REPLACE FUNCTION biblio.extract_located_uris( bib_id BIGINT, marcxml TEXT, editor_id INT ) RETURNS VOID AS $func$
+DECLARE
+ uris TEXT[];
+ uri_xml TEXT;
+ uri_label TEXT;
+ uri_href TEXT;
+ uri_use TEXT;
+ uri_owner_list TEXT[];
+ uri_owner TEXT;
+ uri_owner_id INT;
+ uri_id INT;
+ uri_cn_id INT;
+ uri_map_id INT;
+BEGIN
+
+ uris := oils_xpath('//*[@tag="856" and (@ind1="4" or @ind1="1") and (@ind2="0" or @ind2="1")]',marcxml);
+ IF ARRAY_UPPER(uris,1) > 0 THEN
+ FOR i IN 1 .. ARRAY_UPPER(uris, 1) LOOP
+ -- First we pull info out of the 856
+ uri_xml := uris[i];
+
+ uri_href := (oils_xpath('//*[@code="u"]/text()',uri_xml))[1];
+ uri_label := (oils_xpath('//*[@code="y"]/text()|//*[@code="3"]/text()|//*[@code="u"]/text()',uri_xml))[1];
+ uri_use := (oils_xpath('//*[@code="z"]/text()|//*[@code="2"]/text()|//*[@code="n"]/text()|//*[@code="u"]/text()',uri_xml))[1];
+ CONTINUE WHEN uri_href IS NULL OR uri_label IS NULL;
+
+ -- Get the distinct list of libraries wanting to use
+ SELECT ARRAY_ACCUM(
+ DISTINCT REGEXP_REPLACE(
+ x,
+ $re$^.*?\((\w+)\).*$$re$,
+ E'\\1'
+ )
+ ) INTO uri_owner_list
+ FROM UNNEST(
+ oils_xpath(
+ '//*[@code="9"]/text()|//*[@code="w"]/text()|//*[@code="n"]/text()',
+ uri_xml
+ )
+ )x;
+
+ IF ARRAY_UPPER(uri_owner_list,1) > 0 THEN
+
+ -- look for a matching uri
+ SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active;
+ IF NOT FOUND THEN -- create one
+ INSERT INTO asset.uri (label, href, use_restriction) VALUES (uri_label, uri_href, uri_use);
+ SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active;
+ END IF;
+
+ FOR j IN 1 .. ARRAY_UPPER(uri_owner_list, 1) LOOP
+ uri_owner := uri_owner_list[j];
+
+ SELECT id INTO uri_owner_id FROM actor.org_unit WHERE shortname = uri_owner;
+ CONTINUE WHEN NOT FOUND;
+
+ -- we need a call number to link through
+ SELECT id INTO uri_cn_id FROM asset.call_number WHERE owning_lib = uri_owner_id AND record = bib_id AND label = '##URI##' AND NOT deleted;
+ IF NOT FOUND THEN
+ INSERT INTO asset.call_number (owning_lib, record, create_date, edit_date, creator, editor, label)
+ VALUES (uri_owner_id, bib_id, 'now', 'now', editor_id, editor_id, '##URI##');
+ SELECT id INTO uri_cn_id FROM asset.call_number WHERE owning_lib = uri_owner_id AND record = bib_id AND label = '##URI##' AND NOT deleted;
+ END IF;
+
+ -- now, link them if they're not already
+ SELECT id INTO uri_map_id FROM asset.uri_call_number_map WHERE call_number = uri_cn_id AND uri = uri_id;
+ IF NOT FOUND THEN
+ INSERT INTO asset.uri_call_number_map (call_number, uri) VALUES (uri_cn_id, uri_id);
+ END IF;
+
+ END LOOP;
+
+ END IF;
+
+ END LOOP;
+ END IF;
+
+ RETURN;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0520'); --dbs
+INSERT INTO config.upgrade_log (version) VALUES ('0521'); --dbs
+
+CREATE OR REPLACE FUNCTION biblio.extract_located_uris( bib_id BIGINT, marcxml TEXT, editor_id INT ) RETURNS VOID AS $func$
+DECLARE
+ uris TEXT[];
+ uri_xml TEXT;
+ uri_label TEXT;
+ uri_href TEXT;
+ uri_use TEXT;
+ uri_owner_list TEXT[];
+ uri_owner TEXT;
+ uri_owner_id INT;
+ uri_id INT;
+ uri_cn_id INT;
+ uri_map_id INT;
+BEGIN
+
+ -- Clear any URI mappings and call numbers for this bib.
+ -- This leads to acn / auricnm inflation, but also enables
+ -- old acn/auricnm's to go away and for bibs to be deleted.
+ FOR uri_cn_id IN SELECT id FROM asset.call_number WHERE record = bib_id AND label = '##URI##' AND NOT deleted LOOP
+ DELETE FROM asset.uri_call_number_map WHERE call_number = uri_cn_id;
+ DELETE FROM asset.call_number WHERE id = uri_cn_id;
+ END LOOP;
+
+ uris := oils_xpath('//*[@tag="856" and (@ind1="4" or @ind1="1") and (@ind2="0" or @ind2="1")]',marcxml);
+ IF ARRAY_UPPER(uris,1) > 0 THEN
+ FOR i IN 1 .. ARRAY_UPPER(uris, 1) LOOP
+ -- First we pull info out of the 856
+ uri_xml := uris[i];
+
+ uri_href := (oils_xpath('//*[@code="u"]/text()',uri_xml))[1];
+ uri_label := (oils_xpath('//*[@code="y"]/text()|//*[@code="3"]/text()|//*[@code="u"]/text()',uri_xml))[1];
+ uri_use := (oils_xpath('//*[@code="z"]/text()|//*[@code="2"]/text()|//*[@code="n"]/text()',uri_xml))[1];
+ CONTINUE WHEN uri_href IS NULL OR uri_label IS NULL;
+
+ -- Get the distinct list of libraries wanting to use
+ SELECT ARRAY_ACCUM(
+ DISTINCT REGEXP_REPLACE(
+ x,
+ $re$^.*?\((\w+)\).*$$re$,
+ E'\\1'
+ )
+ ) INTO uri_owner_list
+ FROM UNNEST(
+ oils_xpath(
+ '//*[@code="9"]/text()|//*[@code="w"]/text()|//*[@code="n"]/text()',
+ uri_xml
+ )
+ )x;
+
+ IF ARRAY_UPPER(uri_owner_list,1) > 0 THEN
+
+ -- look for a matching uri
+ SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active;
+ IF NOT FOUND THEN -- create one
+ INSERT INTO asset.uri (label, href, use_restriction) VALUES (uri_label, uri_href, uri_use);
+ IF uri_use IS NULL THEN
+ SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction IS NULL AND active;
+ ELSE
+ SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active;
+ END IF;
+ END IF;
+
+ FOR j IN 1 .. ARRAY_UPPER(uri_owner_list, 1) LOOP
+ uri_owner := uri_owner_list[j];
+
+ SELECT id INTO uri_owner_id FROM actor.org_unit WHERE shortname = uri_owner;
+ CONTINUE WHEN NOT FOUND;
+
+ -- we need a call number to link through
+ SELECT id INTO uri_cn_id FROM asset.call_number WHERE owning_lib = uri_owner_id AND record = bib_id AND label = '##URI##' AND NOT deleted;
+ IF NOT FOUND THEN
+ INSERT INTO asset.call_number (owning_lib, record, create_date, edit_date, creator, editor, label)
+ VALUES (uri_owner_id, bib_id, 'now', 'now', editor_id, editor_id, '##URI##');
+ SELECT id INTO uri_cn_id FROM asset.call_number WHERE owning_lib = uri_owner_id AND record = bib_id AND label = '##URI##' AND NOT deleted;
+ END IF;
+
+ -- now, link them if they're not already
+ SELECT id INTO uri_map_id FROM asset.uri_call_number_map WHERE call_number = uri_cn_id AND uri = uri_id;
+ IF NOT FOUND THEN
+ INSERT INTO asset.uri_call_number_map (call_number, uri) VALUES (uri_cn_id, uri_id);
+ END IF;
+
+ END LOOP;
+
+ END IF;
+
+ END LOOP;
+ END IF;
+
+ RETURN;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0528'); -- dbs
+
+CREATE OR REPLACE FUNCTION maintain_control_numbers() RETURNS TRIGGER AS $func$
+use strict;
+use MARC::Record;
+use MARC::File::XML (BinaryEncoding => 'UTF-8');
+use MARC::Charset;
+use Encode;
+use Unicode::Normalize;
+
+MARC::Charset->assume_unicode(1);
+
+my $record = MARC::Record->new_from_xml($_TD->{new}{marc});
+my $schema = $_TD->{table_schema};
+my $rec_id = $_TD->{new}{id};
+
+# Short-circuit if maintaining control numbers per MARC21 spec is not enabled
+my $enable = spi_exec_query("SELECT enabled FROM config.global_flag WHERE name = 'cat.maintain_control_numbers'");
+if (!($enable->{processed}) or $enable->{rows}[0]->{enabled} eq 'f') {
+ return;
+}
+
+# Get the control number identifier from an OU setting based on $_TD->{new}{owner}
+my $ou_cni = 'EVRGRN';
+
+my $owner;
+if ($schema eq 'serial') {
+ $owner = $_TD->{new}{owning_lib};
+} else {
+ # are.owner and bre.owner can be null, so fall back to the consortial setting
+ $owner = $_TD->{new}{owner} || 1;
+}
+
+my $ous_rv = spi_exec_query("SELECT value FROM actor.org_unit_ancestor_setting('cat.marc_control_number_identifier', $owner)");
+if ($ous_rv->{processed}) {
+ $ou_cni = $ous_rv->{rows}[0]->{value};
+ $ou_cni =~ s/"//g; # Stupid VIM syntax highlighting"
+} else {
+ # Fall back to the shortname of the OU if there was no OU setting
+ $ous_rv = spi_exec_query("SELECT shortname FROM actor.org_unit WHERE id = $owner");
+ if ($ous_rv->{processed}) {
+ $ou_cni = $ous_rv->{rows}[0]->{shortname};
+ }
+}
+
+my ($create, $munge) = (0, 0);
+
+my @scns = $record->field('035');
+
+foreach my $id_field ('001', '003') {
+ my $spec_value;
+ my @controls = $record->field($id_field);
+
+ if ($id_field eq '001') {
+ $spec_value = $rec_id;
+ } else {
+ $spec_value = $ou_cni;
+ }
+
+ # Create the 001/003 if none exist
+ if (scalar(@controls) == 1) {
+ # Only one field; check to see if we need to munge it
+ unless (grep $_->data() eq $spec_value, @controls) {
+ $munge = 1;
+ }
+ } else {
+ # Delete the other fields, as with more than 1 001/003 we do not know which 003/001 to match
+ foreach my $control (@controls) {
+ unless ($control->data() eq $spec_value) {
+ $record->delete_field($control);
+ }
+ }
+ $record->insert_fields_ordered(MARC::Field->new($id_field, $spec_value));
+ $create = 1;
+ }
+}
+
+# Now, if we need to munge the 001, we will first push the existing 001/003
+# into the 035; but if the record did not have one (and one only) 001 and 003
+# to begin with, skip this process
+if ($munge and not $create) {
+ my $scn = "(" . $record->field('003')->data() . ")" . $record->field('001')->data();
+
+ # Do not create duplicate 035 fields
+ unless (grep $_->subfield('a') eq $scn, @scns) {
+ $record->insert_fields_ordered(MARC::Field->new('035', '', '', 'a' => $scn));
+ }
+}
+
+# Set the 001/003 and update the MARC
+if ($create or $munge) {
+ $record->field('001')->data($rec_id);
+ $record->field('003')->data($ou_cni);
+
+ my $xml = $record->as_xml_record();
+ $xml =~ s/\n//sgo;
+ $xml =~ s/^<\?xml.+\?\s*>//go;
+ $xml =~ s/>\s+</></go;
+ $xml =~ s/\p{Cc}//go;
+
+ # Embed a version of OpenILS::Application::AppUtils->entityize()
+ # to avoid having to set PERL5LIB for PostgreSQL as well
+
+ # If we are going to convert non-ASCII characters to XML entities,
+ # we had better be dealing with a UTF8 string to begin with
+ $xml = decode_utf8($xml);
+
+ $xml = NFC($xml);
+
+ # Convert raw ampersands to entities
+ $xml =~ s/&(?!\S+;)/&/gso;
+
+ # Convert Unicode characters to entities
+ $xml =~ s/([\x{0080}-\x{fffd}])/sprintf('&#x%X;',ord($1))/sgoe;
+
+ $xml =~ s/[\x00-\x1f]//go;
+ $_TD->{new}{marc} = $xml;
+
+ return "MODIFY";
+}
+
+return;
+$func$ LANGUAGE PLPERLU;
+
+CREATE OR REPLACE FUNCTION authority.generate_overlay_template ( TEXT, BIGINT ) RETURNS TEXT AS $func$
+
+ use MARC::Record;
+ use MARC::File::XML (BinaryEncoding => 'UTF-8');
+ use MARC::Charset;
+
+ MARC::Charset->assume_unicode(1);
+
+ my $xml = shift;
+ my $r = MARC::Record->new_from_xml( $xml );
+
+ return undef unless ($r);
+
+ my $id = shift() || $r->subfield( '901' => 'c' );
+ $id =~ s/^\s*(?:\([^)]+\))?\s*(.+)\s*?$/$1/;
+ return undef unless ($id); # We need an ID!
+
+ my $tmpl = MARC::Record->new();
+ $tmpl->encoding( 'UTF-8' );
+
+ my @rule_fields;
+ for my $field ( $r->field( '1..' ) ) { # Get main entry fields from the authority record
+
+ my $tag = $field->tag;
+ my $i1 = $field->indicator(1);
+ my $i2 = $field->indicator(2);
+ my $sf = join '', map { $_->[0] } $field->subfields;
+ my @data = map { @$_ } $field->subfields;
+
+ my @replace_them;
+
+ # Map the authority field to bib fields it can control.
+ if ($tag >= 100 and $tag <= 111) { # names
+ @replace_them = map { $tag + $_ } (0, 300, 500, 600, 700);
+ } elsif ($tag eq '130') { # uniform title
+ @replace_them = qw/130 240 440 730 830/;
+ } elsif ($tag >= 150 and $tag <= 155) { # subjects
+ @replace_them = ($tag + 500);
+ } elsif ($tag >= 180 and $tag <= 185) { # floating subdivisions
+ @replace_them = qw/100 400 600 700 800 110 410 610 710 810 111 411 611 711 811 130 240 440 730 830 650 651 655/;
+ } else {
+ next;
+ }
+
+ # Dummy up the bib-side data
+ $tmpl->append_fields(
+ map {
+ MARC::Field->new( $_, $i1, $i2, @data )
+ } @replace_them
+ );
+
+ # Construct some 'replace' rules
+ push @rule_fields, map { $_ . $sf . '[0~\)' .$id . '$]' } @replace_them;
+ }
+
+ # Insert the replace rules into the template
+ $tmpl->append_fields(
+ MARC::Field->new( '905' => ' ' => ' ' => 'r' => join(',', @rule_fields ) )
+ );
+
+ $xml = $tmpl->as_xml_record;
+ $xml =~ s/^<\?.+?\?>$//mo;
+ $xml =~ s/\n//sgo;
+ $xml =~ s/>\s+</></sgo;
+
+ return $xml;
+
+$func$ LANGUAGE PLPERLU;
+
+CREATE OR REPLACE FUNCTION vandelay.add_field ( target_xml TEXT, source_xml TEXT, field TEXT, force_add INT ) RETURNS TEXT AS $_$
+
+ use MARC::Record;
+ use MARC::File::XML (BinaryEncoding => 'UTF-8');
+ use MARC::Charset;
+ use strict;
+
+ MARC::Charset->assume_unicode(1);
+
+ my $target_xml = shift;
+ my $source_xml = shift;
+ my $field_spec = shift;
+ my $force_add = shift || 0;
+
+ my $target_r = MARC::Record->new_from_xml( $target_xml );
+ my $source_r = MARC::Record->new_from_xml( $source_xml );
+
+ return $target_xml unless ($target_r && $source_r);
+
+ my @field_list = split(',', $field_spec);
+
+ my %fields;
+ for my $f (@field_list) {
+ $f =~ s/^\s*//; $f =~ s/\s*$//;
+ if ($f =~ /^(.{3})(\w*)(?:\[([^]]*)\])?$/) {
+ my $field = $1;
+ $field =~ s/\s+//;
+ my $sf = $2;
+ $sf =~ s/\s+//;
+ my $match = $3;
+ $match =~ s/^\s*//; $match =~ s/\s*$//;
+ $fields{$field} = { sf => [ split('', $sf) ] };
+ if ($match) {
+ my ($msf,$mre) = split('~', $match);
+ if (length($msf) > 0 and length($mre) > 0) {
+ $msf =~ s/^\s*//; $msf =~ s/\s*$//;
+ $mre =~ s/^\s*//; $mre =~ s/\s*$//;
+ $fields{$field}{match} = { sf => $msf, re => qr/$mre/ };
+ }
+ }
+ }
+ }
+
+ for my $f ( keys %fields) {
+ if ( @{$fields{$f}{sf}} ) {
+ for my $from_field ($source_r->field( $f )) {
+ my @tos = $target_r->field( $f );
+ if (!@tos) {
+ next if (exists($fields{$f}{match}) and !$force_add);
+ my @new_fields = map { $_->clone } $source_r->field( $f );
+ $target_r->insert_fields_ordered( @new_fields );
+ } else {
+ for my $to_field (@tos) {
+ if (exists($fields{$f}{match})) {
+ next unless (grep { $_ =~ $fields{$f}{match}{re} } $to_field->subfield($fields{$f}{match}{sf}));
+ }
+ my @new_sf = map { ($_ => $from_field->subfield($_)) } @{$fields{$f}{sf}};
+ $to_field->add_subfields( @new_sf );
+ }
+ }
+ }
+ } else {
+ my @new_fields = map { $_->clone } $source_r->field( $f );
+ $target_r->insert_fields_ordered( @new_fields );
+ }
+ }
+
+ $target_xml = $target_r->as_xml_record;
+ $target_xml =~ s/^<\?.+?\?>$//mo;
+ $target_xml =~ s/\n//sgo;
+ $target_xml =~ s/>\s+</></sgo;
+
+ return $target_xml;
+
+$_$ LANGUAGE PLPERLU;
+
+CREATE OR REPLACE FUNCTION authority.normalize_heading( TEXT ) RETURNS TEXT AS $func$
+ use strict;
+ use warnings;
+
+ use utf8;
+ use MARC::Record;
+ use MARC::File::XML (BinaryEncoding => 'UTF8');
+ use MARC::Charset;
+ use UUID::Tiny ':std';
+
+ MARC::Charset->assume_unicode(1);
+
+ my $xml = shift() or return undef;
+
+ my $r;
+
+ # Prevent errors in XML parsing from blowing out ungracefully
+ eval {
+ $r = MARC::Record->new_from_xml( $xml );
+ 1;
+ } or do {
+ return 'BAD_MARCXML_' . create_uuid_as_string(UUID_MD5, $xml);
+ };
+
+ if (!$r) {
+ return 'BAD_MARCXML_' . create_uuid_as_string(UUID_MD5, $xml);
+ }
+
+ # From http://www.loc.gov/standards/sourcelist/subject.html
+ my $thes_code_map = {
+ a => 'lcsh',
+ b => 'lcshac',
+ c => 'mesh',
+ d => 'nal',
+ k => 'cash',
+ n => 'notapplicable',
+ r => 'aat',
+ s => 'sears',
+ v => 'rvm',
+ };
+
+ # Default to "No attempt to code" if the leader is horribly broken
+ my $fixed_field = $r->field('008');
+ my $thes_char = '|';
+ if ($fixed_field) {
+ $thes_char = substr($fixed_field->data(), 11, 1) || '|';
+ }
+
+ my $thes_code = 'UNDEFINED';
+
+ if ($thes_char eq 'z') {
+ # Grab the 040 $f per http://www.loc.gov/marc/authority/ad040.html
+ $thes_code = $r->subfield('040', 'f') || 'UNDEFINED';
+ } elsif ($thes_code_map->{$thes_char}) {
+ $thes_code = $thes_code_map->{$thes_char};
+ }
+
+ my $auth_txt = '';
+ my $head = $r->field('1..');
+ if ($head) {
+ # Concatenate all of these subfields together, prefixed by their code
+ # to prevent collisions along the lines of "Fiction, North Carolina"
+ foreach my $sf ($head->subfields()) {
+ $auth_txt .= '‡' . $sf->[0] . ' ' . $sf->[1];
+ }
+ }
+
+ if ($auth_txt) {
+ my $stmt = spi_prepare('SELECT public.naco_normalize($1) AS norm_text', 'TEXT');
+ my $result = spi_exec_prepared($stmt, $auth_txt);
+ my $norm_txt = $result->{rows}[0]->{norm_text};
+ spi_freeplan($stmt);
+ undef($stmt);
+ return $head->tag() . "_" . $thes_code . " " . $norm_txt;
+ }
+
+ return 'NOHEADING_' . $thes_code . ' ' . create_uuid_as_string(UUID_MD5, $xml);
+$func$ LANGUAGE 'plperlu' IMMUTABLE;
+
+CREATE OR REPLACE FUNCTION vandelay.strip_field ( xml TEXT, field TEXT ) RETURNS TEXT AS $_$
+
+ use MARC::Record;
+ use MARC::File::XML (BinaryEncoding => 'UTF-8');
+ use MARC::Charset;
+ use strict;
+
+ MARC::Charset->assume_unicode(1);
+
+ my $xml = shift;
+ my $r = MARC::Record->new_from_xml( $xml );
+
+ return $xml unless ($r);
+
+ my $field_spec = shift;
+ my @field_list = split(',', $field_spec);
+
+ my %fields;
+ for my $f (@field_list) {
+ $f =~ s/^\s*//; $f =~ s/\s*$//;
+ if ($f =~ /^(.{3})(\w*)(?:\[([^]]*)\])?$/) {
+ my $field = $1;
+ $field =~ s/\s+//;
+ my $sf = $2;
+ $sf =~ s/\s+//;
+ my $match = $3;
+ $match =~ s/^\s*//; $match =~ s/\s*$//;
+ $fields{$field} = { sf => [ split('', $sf) ] };
+ if ($match) {
+ my ($msf,$mre) = split('~', $match);
+ if (length($msf) > 0 and length($mre) > 0) {
+ $msf =~ s/^\s*//; $msf =~ s/\s*$//;
+ $mre =~ s/^\s*//; $mre =~ s/\s*$//;
+ $fields{$field}{match} = { sf => $msf, re => qr/$mre/ };
+ }
+ }
+ }
+ }
+
+ for my $f ( keys %fields) {
+ for my $to_field ($r->field( $f )) {
+ if (exists($fields{$f}{match})) {
+ next unless (grep { $_ =~ $fields{$f}{match}{re} } $to_field->subfield($fields{$f}{match}{sf}));
+ }
+
+ if ( @{$fields{$f}{sf}} ) {
+ $to_field->delete_subfield(code => $fields{$f}{sf});
+ } else {
+ $r->delete_field( $to_field );
+ }
+ }
+ }
+
+ $xml = $r->as_xml_record;
+ $xml =~ s/^<\?.+?\?>$//mo;
+ $xml =~ s/\n//sgo;
+ $xml =~ s/>\s+</></sgo;
+
+ return $xml;
+
+$_$ LANGUAGE PLPERLU;
+
+CREATE OR REPLACE FUNCTION biblio.flatten_marc ( TEXT ) RETURNS SETOF metabib.full_rec AS $func$
+
+use MARC::Record;
+use MARC::File::XML (BinaryEncoding => 'UTF-8');
+use MARC::Charset;
+
+MARC::Charset->assume_unicode(1);
+
+my $xml = shift;
+my $r = MARC::Record->new_from_xml( $xml );
+
+return_next( { tag => 'LDR', value => $r->leader } );
+
+for my $f ( $r->fields ) {
+ if ($f->is_control_field) {
+ return_next({ tag => $f->tag, value => $f->data });
+ } else {
+ for my $s ($f->subfields) {
+ return_next({
+ tag => $f->tag,
+ ind1 => $f->indicator(1),
+ ind2 => $f->indicator(2),
+ subfield => $s->[0],
+ value => $s->[1]
+ });
+
+ if ( $f->tag eq '245' and $s->[0] eq 'a' ) {
+ my $trim = $f->indicator(2) || 0;
+ return_next({
+ tag => 'tnf',
+ ind1 => $f->indicator(1),
+ ind2 => $f->indicator(2),
+ subfield => 'a',
+ value => substr( $s->[1], $trim )
+ });
+ }
+ }
+ }
+}
+
+return undef;
+
+$func$ LANGUAGE PLPERLU;
+
+CREATE OR REPLACE FUNCTION authority.flatten_marc ( TEXT ) RETURNS SETOF authority.full_rec AS $func$
+
+use MARC::Record;
+use MARC::File::XML (BinaryEncoding => 'UTF-8');
+use MARC::Charset;
+
+MARC::Charset->assume_unicode(1);
+
+my $xml = shift;
+my $r = MARC::Record->new_from_xml( $xml );
+
+return_next( { tag => 'LDR', value => $r->leader } );
+
+for my $f ( $r->fields ) {
+ if ($f->is_control_field) {
+ return_next({ tag => $f->tag, value => $f->data });
+ } else {
+ for my $s ($f->subfields) {
+ return_next({
+ tag => $f->tag,
+ ind1 => $f->indicator(1),
+ ind2 => $f->indicator(2),
+ subfield => $s->[0],
+ value => $s->[1]
+ });
+
+ }
+ }
+}
+
+return undef;
+
+$func$ LANGUAGE PLPERLU;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0529');
+
+INSERT INTO config.org_unit_setting_type
+( name, label, description, datatype ) VALUES
+( 'circ.user_merge.delete_addresses',
+ 'Circ: Patron Merge Address Delete',
+ 'Delete address(es) of subordinate user(s) in a patron merge',
+ 'bool'
+);
+
+INSERT INTO config.org_unit_setting_type
+( name, label, description, datatype ) VALUES
+( 'circ.user_merge.delete_cards',
+ 'Circ: Patron Merge Barcode Delete',
+ 'Delete barcode(s) of subordinate user(s) in a patron merge',
+ 'bool'
+);
+
+INSERT INTO config.org_unit_setting_type
+( name, label, description, datatype ) VALUES
+( 'circ.user_merge.deactivate_cards',
+ 'Circ: Patron Merge Deactivate Card',
+ 'Mark barcode(s) of subordinate user(s) in a patron merge as inactive',
+ 'bool'
+);
+
+COMMIT;
More information about the open-ils-commits
mailing list