--- /dev/null
+-- credit to Thomas Berezansky for this function
+
+DO $FUNC$
+ DECLARE
+ asset_copy asset.copy%ROWTYPE;
+ copy_owning_lib INT;
+ new_copy_location INT;
+ BEGIN
+ FOR asset_copy IN SELECT acp.*
+ FROM asset.copy acp
+ JOIN asset.call_number acn ON acp.call_number = acn.id
+ JOIN asset.copy_location acpl ON acp.location = acpl.id
+ WHERE acn.owning_lib != acpl.owning_lib AND acp.circ_lib != acpl.owning_lib AND acp.circ_lib IN (SELECT id FROM actor.org_unit WHERE parent_ou IN (SELECT id FROM actor.org_unit WHERE shortname = 'HOU')) LOOP
+ SELECT INTO copy_owning_lib owning_lib FROM asset.call_number WHERE id = asset_copy.call_number;
+ SELECT INTO new_copy_location acpl.id FROM asset.copy_location acpl JOIN (SELECT * FROM actor.org_unit_ancestors_distance(copy_owning_lib) UNION SELECT * FROM actor.org_unit_ancestors_distance(asset_copy.circ_lib)) aouad ON acpl.owning_lib = aouad.id WHERE name = (SELECT name FROM asset.copy_location WHERE id = asset_copy.location) ORDER BY distance LIMIT 1;
+ IF NOT FOUND OR new_copy_location = asset_copy.location THEN
+ CONTINUE;
+ END IF;
+ RAISE NOTICE 'OLD % NEW % COPY %', asset_copy.location, new_copy_location, asset_copy.id;
+ UPDATE asset.copy SET location = new_copy_location WHERE id = asset_copy.id;
+ END LOOP;
+ END;
+$FUNC$;
+