[open-ils-commits] r20119 - in branches/rel_2_0/Open-ILS/src/sql/Pg: . upgrade (dbs)
svn at svn.open-ils.org
svn at svn.open-ils.org
Fri Apr 15 22:20:08 EDT 2011
Author: dbs
Date: 2011-04-15 22:20:06 -0400 (Fri, 15 Apr 2011)
New Revision: 20119
Added:
branches/rel_2_0/Open-ILS/src/sql/Pg/upgrade/0520.schema.clear-old-asset-uris.sql
Modified:
branches/rel_2_0/Open-ILS/src/sql/Pg/002.schema.config.sql
branches/rel_2_0/Open-ILS/src/sql/Pg/030.schema.metabib.sql
Log:
Delete ##URI## call numbers and uri_call_number_map entries on bib reingest
This approach will lead to some acn/auricnm ID inflation, but it works.
Addresses LP# 761130 (immortal ##URI## entries in asset.call_number) reported
by Ben Shum and LP# 761085 (cannot delete bib with ##URI## volumes) reported
by Jason Etheridge.
Modified: branches/rel_2_0/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- branches/rel_2_0/Open-ILS/src/sql/Pg/002.schema.config.sql 2011-04-16 02:17:53 UTC (rev 20118)
+++ branches/rel_2_0/Open-ILS/src/sql/Pg/002.schema.config.sql 2011-04-16 02:20:06 UTC (rev 20119)
@@ -70,7 +70,7 @@
install_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-INSERT INTO config.upgrade_log (version) VALUES ('0517'); -- miker
+INSERT INTO config.upgrade_log (version) VALUES ('0519'); -- dbs
CREATE TABLE config.bib_source (
id SERIAL PRIMARY KEY,
Modified: branches/rel_2_0/Open-ILS/src/sql/Pg/030.schema.metabib.sql
===================================================================
--- branches/rel_2_0/Open-ILS/src/sql/Pg/030.schema.metabib.sql 2011-04-16 02:17:53 UTC (rev 20118)
+++ branches/rel_2_0/Open-ILS/src/sql/Pg/030.schema.metabib.sql 2011-04-16 02:20:06 UTC (rev 20119)
@@ -809,6 +809,14 @@
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
@@ -849,7 +857,7 @@
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
@@ -857,13 +865,13 @@
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;
Copied: branches/rel_2_0/Open-ILS/src/sql/Pg/upgrade/0520.schema.clear-old-asset-uris.sql (from rev 20117, trunk/Open-ILS/src/sql/Pg/upgrade/0520.schema.clear-old-asset-uris.sql)
===================================================================
--- branches/rel_2_0/Open-ILS/src/sql/Pg/upgrade/0520.schema.clear-old-asset-uris.sql (rev 0)
+++ branches/rel_2_0/Open-ILS/src/sql/Pg/upgrade/0520.schema.clear-old-asset-uris.sql 2011-04-16 02:20:06 UTC (rev 20119)
@@ -0,0 +1,95 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0520'); --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()|//*[@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;
+
+COMMIT;
+
More information about the open-ils-commits
mailing list