Wednesday, December 24, 2008

How to recreate a undo tablespace

There was an issue in the undo tablespace , where the size of one of the datafiles in the undo tablespace(ASM) did not match the size in the control file and I did the folowing to recreate the undo tablespace:

1. Make sure the database was last cleanly shut down.

sqlplus /nolog
SQL>connect sys/change@db as sysdba
SQL> shutdown immediate

2. mount database in RESTRICT mode, using pfile.

SQL> STARTUP RESTRICT MOUNT pfile=C:\Oracle\db\initdb.ora
ORACLE instance started. Total System Global Area 1620126452 bytes
Fixed Size 457460 bytes
Variable Size 545259520 bytes
Database Buffers 1073741824 bytes
Redo Buffers 667648 bytes
Database mounted.

3. Try to offline drop the bad datafile.

SQL> ALTER DATABASE DATAFILE 'C:\ORADATA\DB\UNDOTBS2_02.DBF' OFFLINE DROP;

*
ERROR at line 1:
ORA-01548: active rollback segment ‘_SYSSMU11$’ found, terminate dropping
tablespace

or this SQL:

DROP TABLESPACE undotbs2 INCLUDING CONTENTS AND DATAFILES ;
*
ERROR at line 1:
ORA-01548: active rollback segment ‘_SYSSMU11$’ found, terminate dropping
tablespace

4. Use this query to see how many rollback segments were corrupted:

SQL>select segment_name,status,tablespace_name from dba_rollback_segs where status='NEEDS RECOVERY';
SEGMENT_NAME STATUS TABLESPACE_NAME
—————————— —————- —————–
_SYSSMU11$ NEEDS RECOVERY UNDOTBS2
_SYSSMU12$ NEEDS RECOVERY UNDOTBS2
_SYSSMU13$ NEEDS RECOVERY UNDOTBS2
_SYSSMU14$ NEEDS RECOVERY UNDOTBS2
_SYSSMU15$ NEEDS RECOVERY UNDOTBS2
_SYSSMU16$ NEEDS RECOVERY UNDOTBS2
_SYSSMU17$ NEEDS RECOVERY UNDOTBS2
_SYSSMU18$ NEEDS RECOVERY UNDOTBS2
_SYSSMU19$ NEEDS RECOVERY UNDOTBS2
_SYSSMU20$ NEEDS RECOVERY UNDOTBS2

5. Add the following line to pfile:

_corrupted_rollback_segments =('_SYSSMU11$','_SYSSMU12$','_SYSSMU13$','_SYSSMU14$','_SYSSMU15$','_SYSSMU16$','_SYSSMU17$','_SYSSMU18$','_SYSSMU19$','_SYSSMU20$')

Make sure you uncomment “undo_management=AUTO”, and specify you want to use UNDOTBS1 as undo tablespace.

#undo_management=AUTO
undo_tablespace=UNDOTBS1

6. Start the database again:

SQL> STARTUP RESTRICT MOUNT pfile=C:\Oracle\db\initdb.ora


7. Drop bad rollback segments


SQL> drop rollback segment "_SYSSMU11$";
Rollback segment dropped.


SQL> drop rollback segment "_SYSSMU20$";
Rollback segment dropped.

8. Check again

SQL> select segment_name,status,tablespace_name from dba_rollback_segs;

SEGMENT_NAME STATUS TABLESPACE_NAME
—————————— —————- —————
SYSTEM ONLINE SYSTEM
_SYSSMU2$ ONLINE UNDOTBS1
_SYSSMU3$ ONLINE UNDOTBS1
_SYSSMU4$ ONLINE UNDOTBS1
_SYSSMU5$ ONLINE UNDOTBS1
_SYSSMU6$ ONLINE UNDOTBS1
_SYSSMU7$ ONLINE UNDOTBS1
_SYSSMU8$ ONLINE UNDOTBS1
_SYSSMU9$ ONLINE UNDOTBS1
_SYSSMU10$ ONLINE UNDOTBS1
_SYSSMU21$ ONLINE UNDOTBS1

9. Now drop bad undo TABLESPACE UNDOTBS2;

SQL> drop TABLESPACE UNDOTBS2;

10. Recreate the undo rollback tablespace with all its rollback segments

SQL>CREATE UNDO TABLESPACE UNDOTBS1 DATAFILE 'C:\oradata\DB\UNDOTBS01.DBF' SIZE 2000M reuse AUTOEXTEND ON ;


11. Change undo tablespace

ALTER SYSTEM SET undo_tablespace = UNDOTBS1 ;

12. Remove the following line from pfile

_corrupted_rollback_segments =('_SYSSMU11$','_SYSSMU12$','_SYSSMU13$','_SYSSMU14$','_SYSSMU15$','_SYSSMU16 $','_SYSSMU17$','_SYSSMU18$','_SYSSMU19$','_SYSSMU20$')

and uncomment “undo_management=AUTO”

undo_management=AUTO
undo_retention=10800
undo_tablespace=UNDOTBS1

13. Shutdown database

SQL>shutdown immediate;

14. Edit initCRM_18.ora, make sure you change ‘undo_tablespace=UNDOTBS2″ to “undo_tablespace=UNDOTBS1″, then start oracle database:


sqlplus /nolog
SQL>connect sys/change@db as sysdba
SQL> STARTUP RESTRICT MOUNT pfile=C:\Oracle\db\initdb.ora
ORACLE instance started.
Total System Global Area 1620126452 bytes
Fixed Size 457460 bytes
Variable Size 545259520 bytes
Database Buffers 1073741824 bytes
Redo Buffers 667648 bytes
Database mounted.
Database opened.

15. Create Undo tablespace:

SQL>CREATE UNDO TABLESPACE UNDOTBS2 DATAFILE 'C:\oradata\db\UNDOTBS02.DBF' SIZE 2000M reuse AUTOEXTEND ON ;
SQL>DROP TABLESPACE undotbs1 INCLUDING CONTENTS AND DATAFILES ;

16. Startup database with spfile

SQL> startup;
ORACLE instance started.
Total System Global Area 1620126452 bytes
Fixed Size 457460 bytes
Variable Size 545259520 bytes
Database Buffers 1073741824 bytes
Redo Buffers 667648 bytes
Database mounted.
Database opened.

Friday, December 12, 2008

Oracle 10g CLONE FROM RAC TO NON-RAC (RMAN)

Database

Target database – PRD10G => This is the source database in RACRecovery Catalog – RMCAT10G (in Machard) => This is the catalog database for RMANAuxillary database(New DB) – TST => This is the target database Non-RAC
Note: Backups are in tape , MML is Netbackup

Steps

1. The first step would be to create a auxillary instance, which will be in no-mount state.To prepare a instance, create a pfile from the spfile of PRD10G.
Eg. Create pfile=’/tmp/initprd.ora’ from spfile;

2. Then edit this pfile to remove all the parameters denoting the Cluster, in our case I commented it as below;
#tst1.__db_cache_size=260046848#tst2.__db_cache_size=260046848....#*.cluster_database=true#*.remote_listener='LISTENERS_tst'*.background_dump_dest='/rdbms/v10.1/admin/tst/bdump'*.compatible='10.1.0.4.0'*.control_files='+DG4_DEV/tst/controlfile/backup.277.629493875','+DG_DEV/tst/controlfile/backup.264.629493875'*.core_dump_dest='/rdbms/v10.1/admin/tst/cdump'*.user_dump_dest='/rdbms/v10.1/admin/tst/udump'*.db_block_size=8192*.db_create_file_dest='+DG4_DEV' ===> Modify it accoring to the file system or ASM diskgroup in the destination server....*.sessions=170*.sga_target=471859200*.undo_management='AUTO'undo_tablespace='UNDOTBS1'
3. Create a password file to login remote to the auxillay instance.

4. Add entries to the Listener.ora file and also add the prd and rmcat10g entries to the tnsnames.ora if they are not available.

5. Create any directories specified in the pfile eg.bdump,udump etc.

6. Use this pfile to startup the new instance in nomount mode
Startup new instance to check if all parameters are correct and for further RMAN operations
SQL> show parameter cluster_database
NAME TYPE VALUE------------------------------------ ----------- ------------------------------cluster_database boolean FALSEcluster_database_instances integer 1
SQL> show parameter thread
NAME TYPE VALUE------------------------------------ ----------- ------------------------------thread integer 0

7. Check the location of the target database datafiles so that we can specify the new names for them, in our case:
SQL> select name from v$datafile;
NAME--------------------------------------------------------------------------------+DG4/prd/datafile/system.260.629141721+DG4/prd/datafile/undotbs1.276.629141721...+DG4/prd/datafile/usermgr_admin.256.629142617
12 rows selected.

8. Connect to RMAN with – PRD as target, RMCAT10G as catalog and TST as Auxiliary instances.

9. From the catalog RC_% Views find the time or SCN that you want to duplicate, In our case it is up to a specific time.

10. Then run a run block similar to this:
run{allocate auxiliary channel c1 device type sbt PARMS 'SBT_LIBRARY=/usr/openv/netbackup/bin/libobk.so64';allocate auxiliary channel c2 device type sbt PARMS 'SBT_LIBRARY=/usr/openv/netbackup/bin/libobk.so64';
duplicate target database to 'tst' db_file_name_convert=('+DG4/prd/datafile/','+DG4_DEV/tst/datafile/')logfilegroup 1('+DG4_DEV/tst/onlinelog/redo01.log') size 100M,group 2 ('+DG4_DEV/tst/onlinelog/redo02.log') size 100MUNTIL TIME "to_date('2007-08-08:07:00:00','YYYY-MM-DD:HH24:MI:SS')" ;
release channel c1;release channel c2;}

This will clone a database called tst from prd as a non-rac database.

Happy cloning.