[open-ils-commits] [GIT] Evergreen ILS branch rel_2_0 updated. 6572b5fd2d58bdb3ae86667ab6d138a7e7a3ea17

Evergreen Git git at git.evergreen-ils.org
Thu Jun 16 10:25:29 EDT 2011


This is an automated email from the git hooks/post-receive script. It was
generated because a ref change was pushed to the repository containing
the project "Evergreen ILS".

The branch, rel_2_0 has been updated
       via  6572b5fd2d58bdb3ae86667ab6d138a7e7a3ea17 (commit)
       via  f157c6f75baecc42aa8a46c2fc8af8a3903b73a1 (commit)
      from  4e448e9d8680121a413e21b3c54893c410be6d98 (commit)

Those revisions listed above that are new to this repository have
not appeared on any other notification email; so we list those
revisions in full, below.

- Log -----------------------------------------------------------------
commit 6572b5fd2d58bdb3ae86667ab6d138a7e7a3ea17
Author: Mike Rylander <mrylander at gmail.com>
Date:   Thu Jun 16 10:16:39 2011 -0400

    Move the user/dbs/lp797304_lp797307 upgrade script into place with a number
    
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql
index 4d6eb99..12ba802 100644
--- a/Open-ILS/src/sql/Pg/002.schema.config.sql
+++ b/Open-ILS/src/sql/Pg/002.schema.config.sql
@@ -57,7 +57,7 @@ CREATE TABLE config.upgrade_log (
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0556'); -- dbs
+INSERT INTO config.upgrade_log (version) VALUES ('0559'); -- dbs via miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.biblio.extract_located_uris.sql b/Open-ILS/src/sql/Pg/upgrade/0559.schema.biblio.extract_located_uris.sql
similarity index 93%
rename from Open-ILS/src/sql/Pg/upgrade/XXXX.biblio.extract_located_uris.sql
rename to Open-ILS/src/sql/Pg/upgrade/0559.schema.biblio.extract_located_uris.sql
index 434443d..9287e99 100644
--- a/Open-ILS/src/sql/Pg/upgrade/XXXX.biblio.extract_located_uris.sql
+++ b/Open-ILS/src/sql/Pg/upgrade/0559.schema.biblio.extract_located_uris.sql
@@ -1,3 +1,16 @@
+-- Evergreen DB patch 0559.schema.biblio.extract_located_uris.sql
+--
+-- * Add a stored procedure to reingest problematic URIs
+-- * Avoid duplicate row issues in biblio.extract_located_uris
+-- * Fix LP 797304 and 797307 - asset.uri parsing bugs
+--
+BEGIN;
+
+
+-- check whether patch can be applied
+INSERT INTO config.upgrade_log (version) VALUES ('0559'); -- dbs
+
+-- FIXME: add/check SQL statements to perform the upgrade
 CREATE OR REPLACE FUNCTION biblio.extract_located_uris( bib_id BIGINT, marcxml TEXT, editor_id INT ) RETURNS VOID AS $func$
 DECLARE
     uris            TEXT[];
@@ -135,3 +148,6 @@ $func$ LANGUAGE PLPGSQL;
 
 -- Kick off the reingest; this may take a while
 SELECT biblio.reingest_uris();
+
+
+COMMIT;

commit f157c6f75baecc42aa8a46c2fc8af8a3903b73a1
Author: Mike Rylander <mrylander at gmail.com>
Date:   Thu Jun 16 09:50:25 2011 -0400

    Merging branch user/dbs/lp797304_lp797307
    
    Signed-off-by: Mike Rylander <mrylander at gmail.com>
    
    Cherry picking the following:
    
    commit 7be2a32620587af27de4316e42a308e913e9314c
    Author: Dan Scott <dan at coffeecode.net>
    Date:   Tue Jun 14 22:35:26 2011 -0400
    
        Add a stored procedure to reingest problematic URIs
    
        Assuming that href = label in asset.uri is a red enough flag for the
        problem in LP 797307 where the perfectly good label was being thrown
        away, reingest the unique set of records connected with such asset.uri
        rows.
    
        Signed-off-by: Dan Scott <dscott at laurentian.ca>
    
    commit 39fe0c4a8a3074ff4c1e427ad9f00a0760bac260
    Author: Dan Scott <dan at coffeecode.net>
    Date:   Tue Jun 14 21:54:51 2011 -0400
    
        Add unwrapped upgrade script for biblio.extract_located_uris
    
        See XXXX.biblio.extract_located_uris.sql for the upgrade script, waiting
        to be signed off and committed.
    
        Signed-off-by: Dan Scott <dscott at laurentian.ca>
    
     create mode 100644 Open-ILS/src/sql/Pg/upgrade/XXXX.biblio.extract_located_uris.sql
    
    commit 7e6d2bfd7e9a5cbe57e4aacdf0b4b015a566883d
    Author: Dan Scott <dan at coffeecode.net>
    Date:   Tue Jun 14 21:34:15 2011 -0400
    
        Avoid duplicate row issues in biblio.extract_located_uris
    
        As there is currently no unique constraint on the non-ID columns of
        asset.uri, ensure that we only select a single ID from the tables until
        we dedupe the tables. Use an ORDER BY to grab the matching row with the
        lowest ID so we can clear out the rows with higher IDs.
    
        Signed-off-by: Dan Scott <dscott at laurentian.ca>
    
    commit e79a805299ec734a29ee5bfa77dc74bc1fd208cd
    Author: Dan Scott <dan at coffeecode.net>
    Date:   Tue Jun 14 14:02:49 2011 -0400
    
        Fix LP 797304 and 797307 - asset.uri parsing bugs
    
        Per 797304: one would expect asset.uri.label to be populated with the
        value of 856 $y, however, it was getting populated with 856 $u - perhaps
        as a result of the ordering of array entries in XPATH() not matching the
        XPath expression. Instead of including 856 $u in the XPath expression
        for uri_label, just assign its value to uri_label if uri_label is
        otherwise NULL.
    
        Per 797307: biblio.extract_located_uris() tries to reuse an existing
        active asset.uri entry rather than create a new row; however, it does
        not handle the case where there is no public note aka "use restriction"
        and will end up creating a duplicate row every time the record is
        reingested. Teach it to handle NULL values properly.
    
        Signed-off-by: Dan Scott <dscott at laurentian.ca>
    (cherry picked from commit da70b778268afff19c3dd4f2e9e4c9e85cfeb7e3)
    
    Signed-off-by: Mike Rylander <mrylander at gmail.com>
    (cherry picked from commit 6019d97c2a0604675cd0c00ec747f248f3f79849)
    
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/Open-ILS/src/sql/Pg/030.schema.metabib.sql b/Open-ILS/src/sql/Pg/030.schema.metabib.sql
index f96ffe8..e978b36 100644
--- a/Open-ILS/src/sql/Pg/030.schema.metabib.sql
+++ b/Open-ILS/src/sql/Pg/030.schema.metabib.sql
@@ -827,9 +827,13 @@ BEGIN
             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_label   := (oils_xpath('//*[@code="y"]/text()|//*[@code="3"]/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;
+
+            IF uri_label IS NULL THEN
+                uri_label := uri_href;
+            END IF;
+            CONTINUE WHEN uri_href IS NULL;
 
             -- Get the distinct list of libraries wanting to use 
             SELECT  ARRAY_ACCUM(
@@ -849,13 +853,27 @@ BEGIN
             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;
+                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
+                        ORDER BY id LIMIT 1;
+                    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 IS NULL AND active;
+                    END IF;
+                ELSE
+                    SELECT id INTO uri_id
+                        FROM asset.uri
+                        WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active
+                        ORDER BY id LIMIT 1;
+                    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;
                 END IF;
 
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.biblio.extract_located_uris.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.biblio.extract_located_uris.sql
new file mode 100644
index 0000000..434443d
--- /dev/null
+++ b/Open-ILS/src/sql/Pg/upgrade/XXXX.biblio.extract_located_uris.sql
@@ -0,0 +1,137 @@
+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()',uri_xml))[1];
+            uri_use     := (oils_xpath('//*[@code="z"]/text()|//*[@code="2"]/text()|//*[@code="n"]/text()',uri_xml))[1];
+
+            IF uri_label IS NULL THEN
+                uri_label := uri_href;
+            END IF;
+            CONTINUE WHEN uri_href 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
+                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
+                        ORDER BY id LIMIT 1;
+                    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 IS NULL AND active;
+                    END IF;
+                ELSE
+                    SELECT id INTO uri_id
+                        FROM asset.uri
+                        WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active
+                        ORDER BY id LIMIT 1;
+                    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;
+                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;
+
+CREATE OR REPLACE FUNCTION biblio.reingest_uris() RETURNS VOID AS $func$
+DECLARE
+    rec_id BIGINT;
+BEGIN
+    -- Get the distinct set of record IDs that need to be reingested
+    -- (assuming that href = label is a reasonable red flag)
+    FOR rec_id IN SELECT rec_uris.id FROM (
+        SELECT acn.record AS id
+            FROM asset.call_number acn
+                INNER JOIN asset.uri_call_number_map auricnm ON auricnm.call_number = acn.id
+                INNER JOIN asset.uri auri ON auri.id = auricnm.uri
+            WHERE auri.href = auri.label
+            GROUP BY acn.record
+            ORDER BY acn.record
+        ) AS rec_uris
+    LOOP
+        -- Reingest the offending records
+        PERFORM biblio.extract_located_uris(rec_id, bre.marc, 1)
+            FROM biblio.record_entry bre
+            WHERE bre.id = rec_id;
+    END LOOP;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+-- Kick off the reingest; this may take a while
+SELECT biblio.reingest_uris();

-----------------------------------------------------------------------

Summary of changes:
 Open-ILS/src/sql/Pg/002.schema.config.sql          |    2 +-
 Open-ILS/src/sql/Pg/030.schema.metabib.sql         |   36 +++++++---
 ...=> 0559.schema.biblio.extract_located_uris.sql} |   76 +++++++++++++++++---
 3 files changed, 93 insertions(+), 21 deletions(-)
 copy Open-ILS/src/sql/Pg/upgrade/{0521.schema.u-no-uri-use.sql => 0559.schema.biblio.extract_located_uris.sql} (55%)


hooks/post-receive
-- 
Evergreen ILS


More information about the open-ils-commits mailing list