From: Mike Rylander <mrylander@gmail.com>
Date: Tue, 15 Nov 2011 20:45:02 +0000 (-0500)
Subject: Stamped upgrade for asset.merge_record_assets fix
X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=50600776185d1e083d80eaa93a924a96ee9ae8d2;p=evergreen%2Fmasslnc.git

Stamped upgrade for asset.merge_record_assets fix

Signed-off-by: Mike Rylander <mrylander@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 2a45321d3b..db5e247f06 100644
--- a/Open-ILS/src/sql/Pg/002.schema.config.sql
+++ b/Open-ILS/src/sql/Pg/002.schema.config.sql
@@ -86,7 +86,7 @@ CREATE TRIGGER no_overlapping_deps
     BEFORE INSERT OR UPDATE ON config.db_patch_dependencies
     FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates');
 
-INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0647', :eg_version); -- berick/miker
+INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0648', :eg_version); -- phasefx/miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,
diff --git a/Open-ILS/src/sql/Pg/upgrade/0648.function.merge_record_assets_meets_acq.sql b/Open-ILS/src/sql/Pg/upgrade/0648.function.merge_record_assets_meets_acq.sql
new file mode 100644
index 0000000000..8f7b8e2e2d
--- /dev/null
+++ b/Open-ILS/src/sql/Pg/upgrade/0648.function.merge_record_assets_meets_acq.sql
@@ -0,0 +1,263 @@
+-- Evergreen DB patch 0648.function.merge_record_assets_meets_acq.sql
+--
+BEGIN;
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0648', :eg_version);
+
+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;
+    ser_sub       serial.subscription%ROWTYPE;
+    acq_lineitem  acq.lineitem%ROWTYPE;
+    acq_request   acq.user_request%ROWTYPE;
+    booking       booking.resource_type%ROWTYPE;
+    source_part   biblio.monograph_part%ROWTYPE;
+    target_part   biblio.monograph_part%ROWTYPE;
+    multi_home    biblio.peer_bib_copy_map%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
+        
+        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);
+
+            uri_text := uri_text || 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;
+
+	-- Find serial subscriptions targeting the source record ...
+	FOR ser_sub IN SELECT * FROM serial.subscription WHERE record_entry = source_record LOOP
+		-- ... and move them to the target record
+		UPDATE	serial.subscription
+		  SET	record_entry = target_record
+		  WHERE	id = ser_sub.id;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- Find booking resource types targeting the source record ...
+	FOR booking IN SELECT * FROM booking.resource_type WHERE record = source_record LOOP
+		-- ... and move them to the target record
+		UPDATE	booking.resource_type
+		  SET	record = target_record
+		  WHERE	id = booking.id;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- Find acq lineitems targeting the source record ...
+	FOR acq_lineitem IN SELECT * FROM acq.lineitem WHERE eg_bib_id = source_record LOOP
+		-- ... and move them to the target record
+		UPDATE	acq.lineitem
+		  SET	eg_bib_id = target_record
+		  WHERE	id = acq_lineitem.id;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- Find acq user purchase requests targeting the source record ...
+	FOR acq_request IN SELECT * FROM acq.user_request WHERE eg_bib = source_record LOOP
+		-- ... and move them to the target record
+		UPDATE	acq.user_request
+		  SET	eg_bib = target_record
+		  WHERE	id = acq_request.id;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- Find parts attached to the source ...
+	FOR source_part IN SELECT * FROM biblio.monograph_part WHERE record = source_record LOOP
+
+		SELECT	INTO target_part *
+		  FROM	biblio.monograph_part
+		  WHERE	label = source_part.label
+			AND record = target_record;
+
+		-- ... and if there's a conflicting one on the target ...
+		IF FOUND THEN
+
+			-- ... move the copy-part maps to that, and ...
+			UPDATE	asset.copy_part_map
+			  SET	part = target_part.id
+			  WHERE	part = source_part.id;
+
+			-- ... move P holds to the move-target part
+			FOR hold IN SELECT * FROM action.hold_request WHERE target = source_part.id AND hold_type = 'P' LOOP
+		
+				UPDATE	action.hold_request
+				  SET	target = target_part.id
+				  WHERE	id = hold.id;
+		
+				moved_objects := moved_objects + 1;
+			END LOOP;
+
+		-- ... if not ...
+		ELSE
+			-- ... just move the part to the target record
+			UPDATE	biblio.monograph_part
+			  SET	record = target_record
+			  WHERE	id = source_part.id;
+		END IF;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- Find multi_home items attached to the source ...
+	FOR multi_home IN SELECT * FROM biblio.peer_bib_copy_map WHERE peer_record = source_record LOOP
+		-- ... and move them to the target record
+		UPDATE	biblio.peer_bib_copy_map
+		  SET	peer_record = target_record
+		  WHERE	id = multi_home.id;
+
+		moved_objects := moved_objects + 1;
+	END LOOP;
+
+	-- And delete mappings where the item's home bib was merged with the peer bib
+	DELETE FROM biblio.peer_bib_copy_map WHERE peer_record = (
+		SELECT (SELECT record FROM asset.call_number WHERE id = call_number)
+		FROM asset.copy WHERE id = target_copy
+	);
+
+    -- 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;
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.merge_record_assets_meets_acq.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.function.merge_record_assets_meets_acq.sql
deleted file mode 100644
index b2992d9d6d..0000000000
--- a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.merge_record_assets_meets_acq.sql
+++ /dev/null
@@ -1,252 +0,0 @@
-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;
-    ser_sub       serial.subscription%ROWTYPE;
-    acq_lineitem  acq.lineitem%ROWTYPE;
-    acq_request   acq.user_request%ROWTYPE;
-    booking       booking.resource_type%ROWTYPE;
-    source_part   biblio.monograph_part%ROWTYPE;
-    target_part   biblio.monograph_part%ROWTYPE;
-    multi_home    biblio.peer_bib_copy_map%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
-        
-        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);
-
-            uri_text := uri_text || 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;
-
-	-- Find serial subscriptions targeting the source record ...
-	FOR ser_sub IN SELECT * FROM serial.subscription WHERE record_entry = source_record LOOP
-		-- ... and move them to the target record
-		UPDATE	serial.subscription
-		  SET	record_entry = target_record
-		  WHERE	id = ser_sub.id;
-
-		moved_objects := moved_objects + 1;
-	END LOOP;
-
-	-- Find booking resource types targeting the source record ...
-	FOR booking IN SELECT * FROM booking.resource_type WHERE record = source_record LOOP
-		-- ... and move them to the target record
-		UPDATE	booking.resource_type
-		  SET	record = target_record
-		  WHERE	id = booking.id;
-
-		moved_objects := moved_objects + 1;
-	END LOOP;
-
-	-- Find acq lineitems targeting the source record ...
-	FOR acq_lineitem IN SELECT * FROM acq.lineitem WHERE eg_bib_id = source_record LOOP
-		-- ... and move them to the target record
-		UPDATE	acq.lineitem
-		  SET	eg_bib_id = target_record
-		  WHERE	id = acq_lineitem.id;
-
-		moved_objects := moved_objects + 1;
-	END LOOP;
-
-	-- Find acq user purchase requests targeting the source record ...
-	FOR acq_request IN SELECT * FROM acq.user_request WHERE eg_bib = source_record LOOP
-		-- ... and move them to the target record
-		UPDATE	acq.user_request
-		  SET	eg_bib = target_record
-		  WHERE	id = acq_request.id;
-
-		moved_objects := moved_objects + 1;
-	END LOOP;
-
-	-- Find parts attached to the source ...
-	FOR source_part IN SELECT * FROM biblio.monograph_part WHERE record = source_record LOOP
-
-		SELECT	INTO target_part *
-		  FROM	biblio.monograph_part
-		  WHERE	label = source_part.label
-			AND record = target_record;
-
-		-- ... and if there's a conflicting one on the target ...
-		IF FOUND THEN
-
-			-- ... move the copy-part maps to that, and ...
-			UPDATE	asset.copy_part_map
-			  SET	part = target_part.id
-			  WHERE	part = source_part.id;
-
-			-- ... move P holds to the move-target part
-			FOR hold IN SELECT * FROM action.hold_request WHERE target = source_part.id AND hold_type = 'P' LOOP
-		
-				UPDATE	action.hold_request
-				  SET	target = target_part.id
-				  WHERE	id = hold.id;
-		
-				moved_objects := moved_objects + 1;
-			END LOOP;
-
-		-- ... if not ...
-		ELSE
-			-- ... just move the part to the target record
-			UPDATE	biblio.monograph_part
-			  SET	record = target_record
-			  WHERE	id = source_part.id;
-		END IF;
-
-		moved_objects := moved_objects + 1;
-	END LOOP;
-
-	-- Find multi_home items attached to the source ...
-	FOR multi_home IN SELECT * FROM biblio.peer_bib_copy_map WHERE peer_record = source_record LOOP
-		-- ... and move them to the target record
-		UPDATE	biblio.peer_bib_copy_map
-		  SET	peer_record = target_record
-		  WHERE	id = multi_home.id;
-
-		moved_objects := moved_objects + 1;
-	END LOOP;
-
-	-- And delete mappings where the item's home bib was merged with the peer bib
-	DELETE FROM biblio.peer_bib_copy_map WHERE peer_record = (
-		SELECT (SELECT record FROM asset.call_number WHERE id = call_number)
-		FROM asset.copy WHERE id = target_copy
-	);
-
-    -- 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;
-
-