We usually need to duplicate our databases to test servers which have different disk layouts than production server. So we need to distribute the datafiles according to the disk space and directory structure of the new server. It becomes a time-consuming task if you’re dealing with hundreds of datafiles. Today I saw a PL/SQL script written by Bobby Durrett for renaming datafiles for RMAN restore. It produces required “set newname” commands which can be used by RMAN. That was a great idea and I decided to write my own version to satisfy my needs:
DECLARE
CURSOR DF_CURSOR IS
SELECT 'data' ft, FILE_ID, FILE_NAME,
BYTES / (1024 * 1024 * 1024) fsize
FROM dba_data_files
union all
SELECT 'temp' ft, FILE_ID, FILE_NAME,
BYTES / (1024 * 1024 * 1024) fsize
FROM dba_temp_files
ORDER BY ft, file_id;
TYPE array_number IS TABLE OF NUMBER;
TYPE array_varchar2 IS TABLE OF VARCHAR2 (200);
diskno NUMBER;
diskspace array_number := array_number (
1000,
500,
500,
2500); -- Sizes in GB
diskpath array_varchar2 := array_varchar2 (
'/u02/orauat1',
'/u02/orauat2',
'/u02/orauat3',
'/u02/orauat4');
prefix VARCHAR2 (200) := '/ouinvrep/data'; -- will be added to diskpaths
BEGIN
FOR df IN DF_CURSOR
LOOP
FOR diskno IN 1 .. diskspace.COUNT
LOOP
IF (diskspace (diskno) > df.fsize)
THEN
DBMS_OUTPUT.put_line ( 'set newname for ' || df.ft || 'file '
|| df.FILE_ID || ' to ''' || diskpath (diskno) || prefix
|| SUBSTR (df.FILE_NAME, INSTR (df.FILE_NAME, '/', -1))
|| ''';');
diskspace (diskno) := diskspace (diskno) - df.fsize;
EXIT;
END IF;
END LOOP;
END LOOP;
END;
/
set newname for datafile 1 to '/u02/orauat1/ouinvrep/data/system.1109.765271585';
set newname for datafile 2 to '/u02/orauat1/ouinvrep/data/af_bu_data.339.765264843';
Note: Don't use this script directly on production environment without testing.
No comments:
Post a Comment