From 9eff9a28b617f77b7cf488319b2f6e1399a8143e Mon Sep 17 00:00:00 2001
From: Dan Scott <dscott@laurentian.ca>
Date: Thu, 13 Oct 2011 11:49:45 -0400
Subject: [PATCH] Fix located URI merging in action.merge_record_assets()

Perhaps due to the unexpected results of the XPath expression, which
returns a count of nodes for subfields, etc, rather than just a count of
the number of 856 datafields, NULL was being concatenated onto a string
- which of course made the string NULL.

Use COALESCE() to prevent the NULLness from spreading and enable
action.merge_record_assets() to do the right thing.

Signed-off-by: Dan Scott <dscott@laurentian.ca>
Signed-off-by: Mike Rylander <mrylander@gmail.com>
---
 Open-ILS/src/sql/Pg/999.functions.global.sql       |   6 +-
 .../XXXX.schema.asset_merge_record_assets.sql      | 168 +++++++++++++++++++++
 2 files changed, 173 insertions(+), 1 deletion(-)
 create mode 100644 Open-ILS/src/sql/Pg/upgrade/XXXX.schema.asset_merge_record_assets.sql

diff --git a/Open-ILS/src/sql/Pg/999.functions.global.sql b/Open-ILS/src/sql/Pg/999.functions.global.sql
index 25dfb6aeac..ca108f1008 100644
--- a/Open-ILS/src/sql/Pg/999.functions.global.sql
+++ b/Open-ILS/src/sql/Pg/999.functions.global.sql
@@ -980,6 +980,8 @@ BEGIN
 
     IF uri_count > 0 THEN
         
+        -- This returns more nodes than you might expect:
+        -- 7 instead of 1 for an 856 with $u $y $9
         SELECT  COUNT(*) INTO counter
           FROM  oils_xpath_table(
                     'id',
@@ -1017,7 +1019,9 @@ BEGIN
                         'id=' || source_record
                     ) as t(id int,ind1 text, ind2 text,subfield text,data text);
 
-            uri_text := uri_text || uri_datafield;
+            -- As most of the results will be NULL, protect against NULLifying
+            -- the valid content that we do generate
+            uri_text := uri_text || COALESCE(uri_datafield, '');
         END LOOP;
 
         IF uri_text <> '' THEN
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.asset_merge_record_assets.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.asset_merge_record_assets.sql
new file mode 100644
index 0000000000..619adc925f
--- /dev/null
+++ b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.asset_merge_record_assets.sql
@@ -0,0 +1,168 @@
+-- Evergreen DB patch XXXX.schema.asset_merge_record_assets.sql
+--
+-- FIXME: insert description of change, if needed
+--
+BEGIN;
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+-- FIXME: add/check SQL statements to perform the upgrade
+
+CREATE OR REPLACE FUNCTION asset.merge_record_assets( target_record BIGINT, source_record BIGINT ) RETURNS INT AS $func$
+DECLARE
+    moved_objects INT := 0;
+    source_cn     asset.call_number%ROWTYPE;
+    target_cn     asset.call_number%ROWTYPE;
+    metarec       metabib.metarecord%ROWTYPE;
+    hold          action.hold_request%ROWTYPE;
+    ser_rec       serial.record_entry%ROWTYPE;
+    uri_count     INT := 0;
+    counter       INT := 0;
+    uri_datafield TEXT;
+    uri_text      TEXT := '';
+BEGIN
+
+    -- move any 856 entries on records that have at least one MARC-mapped URI entry
+    SELECT  INTO uri_count COUNT(*)
+      FROM  asset.uri_call_number_map m
+            JOIN asset.call_number cn ON (m.call_number = cn.id)
+      WHERE cn.record = source_record;
+
+    IF uri_count > 0 THEN
+        
+        -- This returns more nodes than you might expect:
+        -- 7 instead of 1 for an 856 with $u $y $9
+        SELECT  COUNT(*) INTO counter
+          FROM  oils_xpath_table(
+                    'id',
+                    'marc',
+                    'biblio.record_entry',
+                    '//*[@tag="856"]',
+                    'id=' || source_record
+                ) as t(i int,c text);
+    
+        FOR i IN 1 .. counter LOOP
+            SELECT  '<datafield xmlns="http://www.loc.gov/MARC21/slim"' || 
+			' tag="856"' ||
+			' ind1="' || FIRST(ind1) || '"'  ||
+			' ind2="' || FIRST(ind2) || '">' ||
+                        array_to_string(
+                            array_accum(
+                                '<subfield code="' || subfield || '">' ||
+                                regexp_replace(
+                                    regexp_replace(
+                                        regexp_replace(data,'&','&amp;','g'),
+                                        '>', '&gt;', 'g'
+                                    ),
+                                    '<', '&lt;', 'g'
+                                ) || '</subfield>'
+                            ), ''
+                        ) || '</datafield>' INTO uri_datafield
+              FROM  oils_xpath_table(
+                        'id',
+                        'marc',
+                        'biblio.record_entry',
+                        '//*[@tag="856"][position()=' || i || ']/@ind1|' ||
+                        '//*[@tag="856"][position()=' || i || ']/@ind2|' ||
+                        '//*[@tag="856"][position()=' || i || ']/*/@code|' ||
+                        '//*[@tag="856"][position()=' || i || ']/*[@code]',
+                        'id=' || source_record
+                    ) as t(id int,ind1 text, ind2 text,subfield text,data text);
+
+            -- As most of the results will be NULL, protect against NULLifying
+            -- the valid content that we do generate
+            uri_text := uri_text || COALESCE(uri_datafield, '');
+        END LOOP;
+
+        IF uri_text <> '' THEN
+            UPDATE  biblio.record_entry
+              SET   marc = regexp_replace(marc,'(</[^>]*record>)', uri_text || E'\\1')
+              WHERE id = target_record;
+        END IF;
+
+    END IF;
+
+	-- Find and move metarecords to the target record
+	SELECT	INTO metarec *
+	  FROM	metabib.metarecord
+	  WHERE	master_record = source_record;
+
+	IF FOUND THEN
+		UPDATE	metabib.metarecord
+		  SET	master_record = target_record,
+			mods = NULL
+		  WHERE	id = metarec.id;
+
+		moved_objects := moved_objects + 1;
+	END IF;
+
+	-- Find call numbers attached to the source ...
+	FOR source_cn IN SELECT * FROM asset.call_number WHERE record = source_record LOOP
+
+		SELECT	INTO target_cn *
+		  FROM	asset.call_number
+		  WHERE	label = source_cn.label
+			AND owning_lib = source_cn.owning_lib
+			AND record = target_record;
+
+		-- ... and if there's a conflicting one on the target ...
+		IF FOUND THEN
+
+			-- ... move the copies to that, and ...
+			UPDATE	asset.copy
+			  SET	call_number = target_cn.id
+			  WHERE	call_number = source_cn.id;
+
+			-- ... move V holds to the move-target call number
+			FOR hold IN SELECT * FROM action.hold_request WHERE target = source_cn.id AND hold_type = 'V' LOOP
+		
+				UPDATE	action.hold_request
+				  SET	target = target_cn.id
+				  WHERE	id = hold.id;
+		
+				moved_objects := moved_objects + 1;
+			END LOOP;
+
+		-- ... if not ...
+		ELSE
+			-- ... just move the call number to the target record
+			UPDATE	asset.call_number
+			  SET	record = target_record
+			  WHERE	id = source_cn.id;
+		END IF;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- Find T holds targeting the source record ...
+	FOR hold IN SELECT * FROM action.hold_request WHERE target = source_record AND hold_type = 'T' LOOP
+
+		-- ... and move them to the target record
+		UPDATE	action.hold_request
+		  SET	target = target_record
+		  WHERE	id = hold.id;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- Find serial records targeting the source record ...
+	FOR ser_rec IN SELECT * FROM serial.record_entry WHERE record = source_record LOOP
+		-- ... and move them to the target record
+		UPDATE	serial.record_entry
+		  SET	record = target_record
+		  WHERE	id = ser_rec.id;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+    -- Finally, "delete" the source record
+    DELETE FROM biblio.record_entry WHERE id = source_record;
+
+	-- That's all, folks!
+	RETURN moved_objects;
+END;
+$func$ LANGUAGE plpgsql;
+
+COMMIT;
-- 
2.11.0