Friday, 25 May 2012


DBA Tips Archive for Oracle
   

Migrating Databases from non-ASM to ASM and Vice-Versa



by Jeff Hunter, Sr. Database Administrator
Contents
Overview
Current Configuration
Migrating Oracle Database from Local File System to ASM
Migrating Oracle Database from ASM to Local File System

Overview
Automatic Storage Management (ASM) was introduced in Oracle10g Release 1 and is used to alleviate the DBA from having to manage individual files and drives. ASM is built into the Oracle kernel and provides the DBA with a way to manage thousands of disk drives 24x7 for both single and clustered instances of Oracle. Essentially, ASM is a file system / volume manager for all Oracle physical database files (datafiles, online redo logs, controlfiles, archived redo logs, RMAN backupsets, and SPFILEs). All of the database files (and directories) to be used for Oracle will be contained in a disk group. ASM automatically performs load balancing in parallel across all available disk drives to prevent hot spots and maximize performance, even with rapidly changing data usage patterns.
Configuring an ASM environment (an ASM instance) is a straightforward process and can be done through the Database Configuration Assistant (DBCA) or manually (see Manually Creating an ASM Instance). Once the ASM instance is configured on a node and an ASM Disk Group is created, any database that resides on that node can start taking advantage of it. For example, consider an ASM instance named +ASM with an ASM disk group named TESTDB_DATA1. Creating a tablespace where the datafile will reside in ASM is as easy as:
SQL> CREATE TABLESPACE users2 DATAFILE '+TESTDB_DATA1' SIZE 100M;

Tablespace created.

SQL> SELECT tablespace_name, file_name FROM dba_data_files WHERE tablespace_name = 'USERS2';

TABLESPACE_NAME FILE_NAME
--------------- --------------------------------------------------
USERS2          +TESTDB_DATA1/testdb/datafile/users2.268.598475429
Given the SQL statement above, a new datafile will be created using Oracle Managed Files (OMF) in an ASM disk group named TESTDB_DATA1.
But, what if you already have an existing Oracle database which stores its database files using the local file system on the node you just configured ASM on and now want to relocate the entire database to be stored in ASM? Well, as with most file management tasks that involve ASM, it's RMAN to the rescue!
In this article, I will explain the steps necessary to migrate an existing Oracle database stored on the local file system to ASM. This will include all datafiles, tempfiles, online redo logfiles, controlfiles, and all flash recovery area files. I will then, within a follow-up section, explain how the process works in reverse - migrating a database stored in ASM to a local file system.

Current Configuration
The testing environment that I will be using for this article is best described in the following illustration and table of values:

Oracle ASM Configuration
Machine Name: linux3.idevelopment.info
Oracle SID: TESTDB
Database Name: TESTDB
Available
ASM Disk Groups: +TESTDB_DATA1
+TESTDB_DATA2
+FLASH_RECOVERY_AREA
Available File System for DB Files: /u02/oradata
Available File System for Flash Recovery Area: /u02/flash_recovery_area
Operating System: Red Hat Linux 3 - (CentOS 3.4)
Oracle Release: Oracle10g Release 2 - (10.2.0.2.0)
  Please note that although I have two Oracle ASM disk groups defined for database files (+TESTDB_DATA1 and +TESTDB_DATA2), I will only be using+TESTDB_DATA1.
  This article assumes the database is open and in ARCHIVELOG mode:
SQL> archive log list
Database log mode              Archive Mode
Automatic archival             Enabled
Archive destination            USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence     34
Next log sequence to archive   36
Current log sequence           36

Migrating Oracle Database from Local File System to ASM
The following query lists database files as they exist on the local file system for the TESTDB database. All of the files listed in this query will be relocated from the local file system to ASM:
$ ORACLE_SID=TESTDB; export ORACLE_SID
$ sqlplus "/ as sysdba"

SQL> @dba_files_all

Tablespace Name /
File Class            Filename                                                              File Size Auto        Next            Max
--------------------- --------------------------------------------------------------- --------------- ---- ----------- --------------
APEX22                /u02/oradata/TESTDB/datafile/o1_mf_apex22_2ft4eswu_.dbf             104,857,600 NO             0              0
EXAMPLE               /u02/oradata/TESTDB/datafile/o1_mf_example_2fb4ccw2_.dbf            157,286,400 YES      655,360 34,359,721,984
FLOW_1                /u02/oradata/TESTDB/datafile/o1_mf_flow_1_2fb4cegw_.dbf              52,494,336 NO             0              0
SYSAUX                /u02/oradata/TESTDB/datafile/o1_mf_sysaux_2fb4cb7z_.dbf             419,430,400 YES   10,485,760 34,359,721,984
SYSTEM                /u02/oradata/TESTDB/datafile/o1_mf_system_2fb4b8s2_.dbf             608,174,080 YES   10,485,760 34,359,721,984
TEMP                  /u02/oradata/TESTDB/datafile/o1_mf_temp_2g17lvcq_.tmp               536,870,912 YES  262,144,000 34,359,721,984
UNDOTBS1              /u02/oradata/TESTDB/datafile/o1_mf_undotbs1_2fb4c2wf_.dbf           209,715,200 YES    5,242,880 34,359,721,984
USERS                 /u02/oradata/TESTDB/datafile/o1_mf_users_2fb4cqf4_.dbf            2,382,888,960 YES    1,310,720 34,359,721,984
[ CONTROL FILE    ]   /u02/oradata/TESTDB/controlfile/o1_mf_8du3s3er_.ctl
[ CONTROL FILE    ]   /u02/oradata/TESTDB/controlfile/o1_mf_y2is93je_.ctl
[ ONLINE REDO LOG ]   /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_1_2g1g6bq0_.log     262,144,000
[ ONLINE REDO LOG ]   /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_2_2g1gdgn1_.log     262,144,000
[ ONLINE REDO LOG ]   /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_3_2g1ghz8z_.log     262,144,000
[ ONLINE REDO LOG ]   /u02/oradata/TESTDB/onlinelog/o1_mf_1_2g1g61bm_.log                 262,144,000
[ ONLINE REDO LOG ]   /u02/oradata/TESTDB/onlinelog/o1_mf_2_2g1gd4pr_.log                 262,144,000
[ ONLINE REDO LOG ]   /u02/oradata/TESTDB/onlinelog/o1_mf_3_2g1ghs0t_.log                 262,144,000
                                                                                      ---------------
sum                                                                                     6,044,581,888

16 rows selected.
Also note that the target database uses an SPFILE on the local file system:
    $ORACLE_HOME/dbs/spfileTESTDB.ora
Use the following steps to fully migrate an existing Oracle database from a local file system to ASM:
With the target database open, edit the initialization parameter control_files and db_create_file_dest to point to the ASM disk group+TESTDB_DATA1. Also configure db_recovery_file_dest to point to the ASM disk group +FLASH_RECOVERY_AREA:
SQL> ALTER SYSTEM SET control_files='+TESTDB_DATA1' SCOPE=spfile;

System altered.

SQL> ALTER SYSTEM SET db_create_file_dest='+TESTDB_DATA1' SCOPE=spfile;

System altered.

SQL> ALTER SYSTEM SET db_recovery_file_dest='+FLASH_RECOVERY_AREA' SCOPE=spfile;

System altered.
Startup the target database in NOMOUNT mode:
SQL> SHUTDOWN IMMEDIATE
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> STARTUP NOMOUNT
ORACLE instance started.

Total System Global Area  285212672 bytes
Fixed Size                  1260420 bytes
Variable Size             171967612 bytes
Database Buffers          109051904 bytes
Redo Buffers                2932736 bytes
From an RMAN session, copy one of your controlfiles from the local file system to its new location in ASM. The new controlfile will be copied to the value specified in the initialization parameter control_files:
RMAN> RESTORE CONTROLFILE FROM '/u02/oradata/TESTDB/controlfile/o1_mf_8du3s3er_.ctl';

Starting restore at 14-AUG-06
using channel ORA_DISK_1

channel ORA_DISK_1: copied control file copy
output filename=+TESTDB_DATA1/testdb/controlfile/backup.268.598481391
Finished restore at 14-AUG-06
From an RMAN or SQL*Plus session, mount the database. This will mount the database using the controlfile stored in ASM:
RMAN> ALTER DATABASE MOUNT;

database mounted
released channel: ORA_DISK_1
From an RMAN session, copy the database files from the local file system to ASM:
RMAN> BACKUP AS COPY DATABASE FORMAT '+TESTDB_DATA1';

Starting backup at 14-AUG-06
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=158 devtype=DISK
channel ORA_DISK_1: starting datafile copy
input datafile fno=00005 name=/u02/oradata/TESTDB/datafile/o1_mf_users_2fb4cqf4_.dbf
output filename=+TESTDB_DATA1/testdb/datafile/users.270.598481673 tag=TAG20060814T205432 recid=36 stamp=598482095
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:07:06
channel ORA_DISK_1: starting datafile copy
input datafile fno=00001 name=/u02/oradata/TESTDB/datafile/o1_mf_system_2fb4b8s2_.dbf
output filename=+TESTDB_DATA1/testdb/datafile/system.269.598482099 tag=TAG20060814T205432 recid=37 stamp=598482206
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:55
channel ORA_DISK_1: starting datafile copy
input datafile fno=00003 name=/u02/oradata/TESTDB/datafile/o1_mf_sysaux_2fb4cb7z_.dbf
output filename=+TESTDB_DATA1/testdb/datafile/sysaux.267.598482213 tag=TAG20060814T205432 recid=38 stamp=598482292
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:01:25
channel ORA_DISK_1: starting datafile copy
input datafile fno=00002 name=/u02/oradata/TESTDB/datafile/o1_mf_undotbs1_2fb4c2wf_.dbf
output filename=+TESTDB_DATA1/testdb/datafile/undotbs1.256.598482299 tag=TAG20060814T205432 recid=39 stamp=598482340
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:45
channel ORA_DISK_1: starting datafile copy
input datafile fno=00004 name=/u02/oradata/TESTDB/datafile/o1_mf_example_2fb4ccw2_.dbf
output filename=+TESTDB_DATA1/testdb/datafile/example.264.598482345 tag=TAG20060814T205432 recid=40 stamp=598482374
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:35
channel ORA_DISK_1: starting datafile copy
input datafile fno=00006 name=/u02/oradata/TESTDB/datafile/o1_mf_apex22_2ft4eswu_.dbf
output filename=+TESTDB_DATA1/testdb/datafile/apex22.263.598482381 tag=TAG20060814T205432 recid=41 stamp=598482399
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile fno=00007 name=/u02/oradata/TESTDB/datafile/o1_mf_flow_1_2fb4cegw_.dbf
output filename=+TESTDB_DATA1/testdb/datafile/flow_1.262.598482405 tag=TAG20060814T205432 recid=42 stamp=598482415
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting datafile copy
copying current control file
output filename=+TESTDB_DATA1/testdb/controlfile/backup.261.598482421 tag=TAG20060814T205432 recid=43 stamp=598482423
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:03
channel ORA_DISK_1: starting full datafile backupset
channel ORA_DISK_1: specifying datafile(s) in backupset
including current SPFILE in backupset
channel ORA_DISK_1: starting piece 1 at 14-AUG-06
channel ORA_DISK_1: finished piece 1 at 14-AUG-06
piece handle=+TESTDB_DATA1/testdb/backupset/2006_08_14/nnsnf0_tag20060814t205432_0.260.598482425 tag=TAG20060814T205432 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:02
Finished backup at 14-AUG-06
From an RMAN session, update the control file / data dictionary so that all database files point to the RMAN copy made in ASM:
RMAN> SWITCH DATABASE TO COPY;

datafile 1 switched to datafile copy "+TESTDB_DATA1/testdb/datafile/system.269.598482099"
datafile 2 switched to datafile copy "+TESTDB_DATA1/testdb/datafile/undotbs1.256.598482299"
datafile 3 switched to datafile copy "+TESTDB_DATA1/testdb/datafile/sysaux.267.598482213"
datafile 4 switched to datafile copy "+TESTDB_DATA1/testdb/datafile/example.264.598482345"
datafile 5 switched to datafile copy "+TESTDB_DATA1/testdb/datafile/users.270.598481673"
datafile 6 switched to datafile copy "+TESTDB_DATA1/testdb/datafile/apex22.263.598482381"
datafile 7 switched to datafile copy "+TESTDB_DATA1/testdb/datafile/flow_1.262.598482405"
From a SQL*Plus session, perform incomplete recovery and open the database using the RESETLOGS option:
SQL> RECOVER DATABASE USING BACKUP CONTROLFILE UNTIL CANCEL;

ORA-00279: change 7937583 generated at 08/14/2006 20:33:55 needed for thread 1
ORA-00289: suggestion : +FLASH_RECOVERY_AREA
ORA-00280: change 7937583 for thread 1 is in sequence #36


Specify log: {<RET>=suggested | filename | AUTO | CANCEL}
CANCEL
Media recovery cancelled.

SQL> ALTER DATABASE OPEN RESETLOGS;

Database altered.
From a SQL*Plus session, re-create any tempfiles that are still currently on the local file system to ASM. This is done by simply dropping the tempfiles from the local file system and re-creating them in ASM. This example relies on the initialization parameter db_create_file_dest=+TESTDB_DATA1:
SQL> select tablespace_name, file_name, bytes from dba_temp_files;

TABLESPACE_NAME FILE_NAME                                                 BYTES
--------------- ----------------------------------------------------- ---------
TEMP            /u02/oradata/TESTDB/datafile/o1_mf_temp_2g17lvcq_.tmp 536870912

SQL> alter database tempfile
  2  '/u02/oradata/TESTDB/datafile/o1_mf_temp_2g17lvcq_.tmp'
  3  drop including datafiles;

Database altered.

SQL> alter tablespace temp add tempfile size 512m
  2  autoextend on next 250m maxsize unlimited;

Tablespace altered.

SQL> select tablespace_name, file_name, bytes from dba_temp_files;

TABLESPACE_NAME FILE_NAME                                            BYTES
--------------- ------------------------------------------------ ---------
TEMP            +TESTDB_DATA1/testdb/tempfile/temp.261.598485663 536870912
  If users are currently accessing the tempfile(s) you are attempting to drop, you may receive the following error:
SQL> alter database tempfile
  2  '/u02/oradata/TESTDB/datafile/o1_mf_temp_2g17lvcq_.tmp'
  3  drop including datafiles;

ERROR at line 1:
ORA-25152: TEMPFILE cannot be dropped at this time
As for the poor users who were using the tempfile, their transaction will end and will be greeted with the following error message:
SQL> @testTemp.sql
       join dba_extents  c on (b.segment_name = c.segment_name)
            *
ERROR at line 4:
ORA-00372: file 601 cannot be modified at this time
ORA-01110: data file 601: '/u02/oradata/TESTDB/datafile/o1_mf_temp_2g17lvcq_.tmp'
ORA-00372: file 601 cannot be modified at this time
ORA-01110: data file 601: '/u02/oradata/TESTDB/datafile/o1_mf_temp_2g17lvcq_.tmp'
If this happens, you should attempt to drop the tempfile again so the operation is successful:
SQL> alter database tempfile
  2  '/u02/oradata/TESTDB/datafile/o1_mf_temp_2g17lvcq_.tmp'
  3  drop including datafiles;

Database altered.
From a SQL*Plus session, re-create any online redo logfiles that are still currently on the local file system to ASM. This is done by simply dropping the logfiles from the local file system and re-creating them in ASM. This example relies on the initialization parametersdb_create_file_dest=+TESTDB_DATA1 and db_recovery_file_dest=+FLASH_RECOVERY_AREA:
Determine the current online redo logfiles to move to ASM by examining the file names (and sizes) from V$LOGFILE:
SQL> select a.group#, a.member, b.bytes
  2  from v$logfile a, v$log b where a.group# = b.group#;

GROUP# MEMBER                                                              BYTES
------ --------------------------------------------------------------- ---------
     1 /u02/oradata/TESTDB/onlinelog/o1_mf_1_2g1g61bm_.log             262144000
     2 /u02/oradata/TESTDB/onlinelog/o1_mf_2_2g1gd4pr_.log             262144000
     3 /u02/oradata/TESTDB/onlinelog/o1_mf_3_2g1ghs0t_.log             262144000
     1 /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_1_2g1g6bq0_.log 262144000
     2 /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_2_2g1gdgn1_.log 262144000
     3 /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_3_2g1ghz8z_.log 262144000

6 rows selected.
Force a log switch until the last redo log is marked "CURRENT" by issuing the following command:
SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 CURRENT
         2 INACTIVE
         3 INACTIVE

SQL> alter system switch logfile;

SQL> alter system switch logfile;

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 INACTIVE
         2 INACTIVE
         3 CURRENT
After making the last online redo log file the CURRENT one, drop the first online redo log:
SQL> alter database drop logfile group 1;

Database altered.
  As a DBA, you should already be aware that if you are going to drop a logfile group, it cannot be the current logfile group. I have run into instances; however, where attempting to drop the logfile group resulted in the following error as a result of the logfile group having an activestatus:
SQL> ALTER DATABASE DROP LOGFILE GROUP 1;
ALTER DATABASE DROP LOGFILE GROUP 1
*
ERROR at line 1:
ORA-01624: log 1 needed for crash recovery of instance TESTDB (thread 1)
ORA-00312: online log 1 thread 1: '<file_name>'
Easy problem to resolve. Simply perform a checkpoint on the database:
SQL> ALTER SYSTEM CHECKPOINT GLOBAL;

System altered.

SQL> ALTER DATABASE DROP LOGFILE GROUP 1;

Database altered.
Re-create the dropped redo log group in ASM (and a different size if desired):
SQL> alter database add logfile group 1 size 250m;

Database altered.
After re-creating the online redo log group, force a log switch. The online redo log group just created should become the CURRENT one:
SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 UNUSED
         2 INACTIVE
         3 CURRENT

SQL> alter system switch logfile;

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 CURRENT
         2 INACTIVE
         3 ACTIVE
After re-creating the first online redo log group, loop back to drop / re-create the next online redo logfile until all logs are rebuilt in ASM.
Verify all online redo logfiles have been created in ASM:
SQL> select a.group#, a.member, b.bytes
  2  from v$logfile a, v$log b where a.group# = b.group#;

GROUP# MEMBER                                                          BYTES
------ ----------------------------------------------------------- ---------
     1 +TESTDB_DATA1/testdb/onlinelog/group_1.259.598486831        262144000
     2 +TESTDB_DATA1/testdb/onlinelog/group_2.260.598487179        262144000
     3 +TESTDB_DATA1/testdb/onlinelog/group_3.258.598487365        262144000
     1 +FLASH_RECOVERY_AREA/testdb/onlinelog/group_1.259.598486879 262144000
     2 +FLASH_RECOVERY_AREA/testdb/onlinelog/group_2.257.598487225 262144000
     3 +FLASH_RECOVERY_AREA/testdb/onlinelog/group_3.260.598487411 262144000

6 rows selected.
Perform the following steps to relocate the SPFILE from the local file system to an ASM disk group.
Create a text-based initialization parameter file from the current binary SPFILE located on the local file system:
SQL> CREATE PFILE='$ORACLE_HOME/dbs/initTESTDB.ora'
  2  FROM SPFILE='$ORACLE_HOME/dbs/spfileTESTDB.ora';

File created.
Create new SPFILE in an ASM disk group:
SQL> CREATE SPFILE='+TESTDB_DATA1/TESTDB/spfileTESTDB.ora'
  2  FROM PFILE='$ORACLE_HOME/dbs/initTESTDB.ora';

File created.
Shutdown the Oracle database:
SQL> SHUTDOWN IMMEDIATE
Database closed.
Database dismounted.
ORACLE instance shut down.
Update the text-based init<SID>.ora file with the new location of the SPFILE in ASM:
$ echo "SPFILE='+TESTDB_DATA1/TESTDB/spfileTESTDB.ora'" > $ORACLE_HOME/dbs/initTESTDB.ora
Remove (actually rename) the old SPFILE on the local file system so that the new text-based init<SID>.ora will be used:
$ mv $ORACLE_HOME/dbs/spfileTESTDB.ora $ORACLE_HOME/dbs/BACKUP_ASM.spfileTESTDB.ora
Open the Oracle database using the new SPFILE:
SQL> STARTUP
Verify that all database files have been created in ASM:
$ sqlplus "/ as sysdba"

SQL> @dba_files_all

Tablespace Name /
File Class            Filename                                                          File Size Auto        Next             Max
--------------------- ----------------------------------------------------------- --------------- ---- ----------- ---------------
APEX22                +TESTDB_DATA1/testdb/datafile/apex22.263.598482381              104,857,600 NO             0               0
EXAMPLE               +TESTDB_DATA1/testdb/datafile/example.264.598482345             157,286,400 YES      655,360  34,359,721,984
FLOW_1                +TESTDB_DATA1/testdb/datafile/flow_1.262.598482405               52,494,336 NO             0               0
SYSAUX                +TESTDB_DATA1/testdb/datafile/sysaux.267.598482213              419,430,400 YES   10,485,760  34,359,721,984
SYSTEM                +TESTDB_DATA1/testdb/datafile/system.269.598482099              608,174,080 YES   10,485,760  34,359,721,984
TEMP                  +TESTDB_DATA1/testdb/tempfile/temp.261.598485663                536,870,912 YES  262,144,000  34,359,721,984
UNDOTBS1              +TESTDB_DATA1/testdb/datafile/undotbs1.256.598482299            209,715,200 YES    5,242,880  34,359,721,984
USERS                 +TESTDB_DATA1/testdb/datafile/users.270.598481673             2,382,888,960 YES    1,310,720  34,359,721,984
[ CONTROL FILE    ]   +TESTDB_DATA1/testdb/controlfile/backup.268.598481391
[ ONLINE REDO LOG ]   +FLASH_RECOVERY_AREA/testdb/onlinelog/group_1.259.598486879     262,144,000
[ ONLINE REDO LOG ]   +FLASH_RECOVERY_AREA/testdb/onlinelog/group_2.257.598487225     262,144,000
[ ONLINE REDO LOG ]   +FLASH_RECOVERY_AREA/testdb/onlinelog/group_3.260.598487411     262,144,000
[ ONLINE REDO LOG ]   +TESTDB_DATA1/testdb/onlinelog/group_1.259.598486831            262,144,000
[ ONLINE REDO LOG ]   +TESTDB_DATA1/testdb/onlinelog/group_2.260.598487179            262,144,000
[ ONLINE REDO LOG ]   +TESTDB_DATA1/testdb/onlinelog/group_3.258.598487365            262,144,000
                                                                                  ---------------
sum                                                                                 6,044,581,888

15 rows selected.
At this point, the target database is open with all of its datafiles, controlfiles, online redo logfiles, tempfiles, and SPFILE stored in ASM. If we wanted to remove the database files that were stored on the local file system (which are actually now RMAN copies), this could be done from an RMAN session. You could also then remove the old version of the controfile(s) that were stored on the local file system:
  If this is a production database, it would be best practice to first backup the database files on the local disk before removing them!
RMAN> DELETE NOPROMPT FORCE COPY;

allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=139 devtype=DISK

List of Datafile Copies
Key     File S Completion Time Ckp SCN    Ckp Time        Name
------- ---- - --------------- ---------- --------------- ----
44      1    A 14-AUG-06       7937583    14-AUG-06       /u02/oradata/TESTDB/datafile/o1_mf_system_2fb4b8s2_.dbf
45      2    A 14-AUG-06       7937583    14-AUG-06       /u02/oradata/TESTDB/datafile/o1_mf_undotbs1_2fb4c2wf_.dbf
46      3    A 14-AUG-06       7937583    14-AUG-06       /u02/oradata/TESTDB/datafile/o1_mf_sysaux_2fb4cb7z_.dbf
47      4    A 14-AUG-06       7937583    14-AUG-06       /u02/oradata/TESTDB/datafile/o1_mf_example_2fb4ccw2_.dbf
48      5    A 14-AUG-06       7937583    14-AUG-06       /u02/oradata/TESTDB/datafile/o1_mf_users_2fb4cqf4_.dbf
49      6    A 14-AUG-06       7937583    14-AUG-06       /u02/oradata/TESTDB/datafile/o1_mf_apex22_2ft4eswu_.dbf
50      7    A 14-AUG-06       7937583    14-AUG-06       /u02/oradata/TESTDB/datafile/o1_mf_flow_1_2fb4cegw_.dbf

List of Control File Copies
Key     S Completion Time Ckp SCN    Ckp Time        Name
------- - --------------- ---------- --------------- ----
43      A 14-AUG-06       7937583    14-AUG-06       +TESTDB_DATA1/testdb/controlfile/backup.261.598482421

List of Archived Log Copies
Key     Thrd Seq     S Low Time  Name
------- ---- ------- - --------- ----
48      1    34      A 14-AUG-06 +FLASH_RECOVERY_AREA/testdb/archivelog/2006_08_14/thread_1_seq_34.259.598482825
49      1    35      A 14-AUG-06 +FLASH_RECOVERY_AREA/testdb/archivelog/2006_08_14/thread_1_seq_35.258.598482825
47      1    36      A 14-AUG-06 +FLASH_RECOVERY_AREA/testdb/archivelog/2006_08_14/thread_1_seq_36.260.598482821
deleted datafile copy
datafile copy filename=/u02/oradata/TESTDB/datafile/o1_mf_system_2fb4b8s2_.dbf recid=44 stamp=598482495
deleted datafile copy
datafile copy filename=/u02/oradata/TESTDB/datafile/o1_mf_undotbs1_2fb4c2wf_.dbf recid=45 stamp=598482495
deleted datafile copy
datafile copy filename=/u02/oradata/TESTDB/datafile/o1_mf_sysaux_2fb4cb7z_.dbf recid=46 stamp=598482496
deleted datafile copy
datafile copy filename=/u02/oradata/TESTDB/datafile/o1_mf_example_2fb4ccw2_.dbf recid=47 stamp=598482496
deleted datafile copy
datafile copy filename=/u02/oradata/TESTDB/datafile/o1_mf_users_2fb4cqf4_.dbf recid=48 stamp=598482496
deleted datafile copy
datafile copy filename=/u02/oradata/TESTDB/datafile/o1_mf_apex22_2ft4eswu_.dbf recid=49 stamp=598482496
deleted datafile copy
datafile copy filename=/u02/oradata/TESTDB/datafile/o1_mf_flow_1_2fb4cegw_.dbf recid=50 stamp=598482496
deleted control file copy
control file copy filename=+TESTDB_DATA1/testdb/controlfile/backup.261.598482421 recid=43 stamp=598482423
deleted archive log
archive log filename=+FLASH_RECOVERY_AREA/testdb/archivelog/2006_08_14/thread_1_seq_34.259.598482825 recid=48 stamp=598482824
deleted archive log
archive log filename=+FLASH_RECOVERY_AREA/testdb/archivelog/2006_08_14/thread_1_seq_35.258.598482825 recid=49 stamp=598482824
deleted archive log
archive log filename=+FLASH_RECOVERY_AREA/testdb/archivelog/2006_08_14/thread_1_seq_36.260.598482821 recid=47 stamp=598482824
Deleted 11 objects

RMAN> exit

$ rm /u02/oradata/TESTDB/controlfile/o1_mf_8du3s3er_.ctl
$ rm /u02/oradata/TESTDB/controlfile/o1_mf_y2is93je_.ctl

Migrating Oracle Database from ASM to Local File System
The following query lists database files as they exist in ASM for the TESTDB database. All of the files listed in this query will be relocated from ASM to the local file system:
$ ORACLE_SID=TESTDB; export ORACLE_SID
$ sqlplus "/ as sysdba"

SQL> @dba_files_all

Tablespace Name /
File Class            Filename                                                          File Size Auto        Next             Max
--------------------- ----------------------------------------------------------- --------------- ---- ----------- ---------------
APEX22                +TESTDB_DATA1/testdb/datafile/apex22.263.598482381              104,857,600 NO             0               0
EXAMPLE               +TESTDB_DATA1/testdb/datafile/example.264.598482345             157,286,400 YES      655,360  34,359,721,984
FLOW_1                +TESTDB_DATA1/testdb/datafile/flow_1.262.598482405               52,494,336 NO             0               0
SYSAUX                +TESTDB_DATA1/testdb/datafile/sysaux.267.598482213              419,430,400 YES   10,485,760  34,359,721,984
SYSTEM                +TESTDB_DATA1/testdb/datafile/system.269.598482099              608,174,080 YES   10,485,760  34,359,721,984
TEMP                  +TESTDB_DATA1/testdb/tempfile/temp.261.598485663                536,870,912 YES  262,144,000  34,359,721,984
UNDOTBS1              +TESTDB_DATA1/testdb/datafile/undotbs1.256.598482299            209,715,200 YES    5,242,880  34,359,721,984
USERS                 +TESTDB_DATA1/testdb/datafile/users.270.598481673             2,382,888,960 YES    1,310,720  34,359,721,984
[ CONTROL FILE    ]   +TESTDB_DATA1/testdb/controlfile/backup.268.598481391
[ ONLINE REDO LOG ]   +FLASH_RECOVERY_AREA/testdb/onlinelog/group_1.259.598486879     262,144,000
[ ONLINE REDO LOG ]   +FLASH_RECOVERY_AREA/testdb/onlinelog/group_2.257.598487225     262,144,000
[ ONLINE REDO LOG ]   +FLASH_RECOVERY_AREA/testdb/onlinelog/group_3.260.598487411     262,144,000
[ ONLINE REDO LOG ]   +TESTDB_DATA1/testdb/onlinelog/group_1.259.598486831            262,144,000
[ ONLINE REDO LOG ]   +TESTDB_DATA1/testdb/onlinelog/group_2.260.598487179            262,144,000
[ ONLINE REDO LOG ]   +TESTDB_DATA1/testdb/onlinelog/group_3.258.598487365            262,144,000
                                                                                  ---------------
sum                                                                                 6,044,581,888

15 rows selected.
Also note that the target database uses an SPFILE which is stored in ASM. The target database starts using a text-based init<SID>.ora($ORACLE_HOME/dbs/initTESTDB.ora) which defines the location of the SPFILE in ASM:
    SPFILE='+TESTDB_DATA1/TESTDB/spfileTESTDB.ora'
Use the following steps to fully migrate an existing Oracle database from ASM to a local file system:
With the target database open, edit the initialization parameter control_files and db_create_file_dest to point to locations on the local file system (/u02/oradata). Also configure db_recovery_file_dest to point to the Flash Recovery Area on the local file system (/u02/flash_recovery_area):
SQL> ALTER SYSTEM SET control_files='/u02/oradata/TESTDB/control01.ctl' SCOPE=spfile;

System altered.

SQL> ALTER SYSTEM SET db_create_file_dest='/u02/oradata' SCOPE=spfile;

System altered.

SQL> ALTER SYSTEM SET db_recovery_file_dest='/u02/flash_recovery_area' SCOPE=spfile;

System altered.
Backup the current SPFILE (in ASM) to a text-based init<SID>.ora file on the local file system. Then convert the text-based init<SID>.ora file to a binary SPFILE on the local file system:
SQL> HOST mv $ORACLE_HOME/dbs/initTESTDB.ora $ORACLE_HOME/dbs/BACKUP_ASM.initTESTDB.ora

SQL> CREATE PFILE='$ORACLE_HOME/dbs/initTESTDB.ora' FROM SPFILE='+TESTDB_DATA1/TESTDB/spfileTESTDB.ora';

File created.

SQL> CREATE SPFILE='$ORACLE_HOME/dbs/spfileTESTDB.ora' FROM PFILE='$ORACLE_HOME/dbs/initTESTDB.ora';

File created.
Startup the target database in NOMOUNT mode:
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> startup nomount
ORACLE instance started.

Total System Global Area  285212672 bytes
Fixed Size                  1260420 bytes
Variable Size             150996092 bytes
Database Buffers          130023424 bytes
Redo Buffers                2932736 bytes
From an RMAN session, copy one of your controlfiles from ASM to its new location on the local file system. The new controlfile will be copied to the value specified in the initialization parameter control_files:
RMAN> RESTORE CONTROLFILE FROM '+TESTDB_DATA1/TESTDB/CONTROLFILE/backup.268.598481391';

Starting restore at 15-AUG-06
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=156 devtype=DISK

channel ORA_DISK_1: copied control file copy
output filename=/u02/oradata/TESTDB/control01.ctl
Finished restore at 15-AUG-06
From an RMAN or SQL*Plus session, mount the database. This will mount the database using the controlfile stored on the local file system:
RMAN> ALTER DATABASE MOUNT;

using target database control file instead of recovery catalog
database mounted
From an RMAN session, copy the database files from ASM to the local file system:
RMAN> BACKUP AS COPY DATABASE FORMAT '/u02/oradata/TESTDB/%U';

Starting backup at 15-AUG-06
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=156 devtype=DISK
channel ORA_DISK_1: starting datafile copy
input datafile fno=00005 name=+TESTDB_DATA1/testdb/datafile/users.270.598481673
output filename=/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-USERS_FNO-5_0vhqpltd tag=TAG20060815T101925 recid=51 stamp=598530181
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:03:36
channel ORA_DISK_1: starting datafile copy
input datafile fno=00001 name=+TESTDB_DATA1/testdb/datafile/system.269.598482099
output filename=/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSTEM_FNO-1_10hqpm45 tag=TAG20060815T101925 recid=52 stamp=598530235
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:55
channel ORA_DISK_1: starting datafile copy
input datafile fno=00003 name=+TESTDB_DATA1/testdb/datafile/sysaux.267.598482213
output filename=/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSAUX_FNO-3_11hqpm5s tag=TAG20060815T101925 recid=53 stamp=598530274
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:46
channel ORA_DISK_1: starting datafile copy
input datafile fno=00002 name=+TESTDB_DATA1/testdb/datafile/undotbs1.256.598482299
output filename=/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-UNDOTBS1_FNO-2_12hqpm7a tag=TAG20060815T101925 recid=54 stamp=598530304
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile fno=00004 name=+TESTDB_DATA1/testdb/datafile/example.264.598482345
output filename=/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-EXAMPLE_FNO-4_13hqpm83 tag=TAG20060815T101925 recid=55 stamp=598530323
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile fno=00006 name=+TESTDB_DATA1/testdb/datafile/apex22.263.598482381
output filename=/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-APEX22_FNO-6_14hqpm8s tag=TAG20060815T101925 recid=56 stamp=598530343
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:16
channel ORA_DISK_1: starting datafile copy
input datafile fno=00007 name=+TESTDB_DATA1/testdb/datafile/flow_1.262.598482405
output filename=/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-FLOW_1_FNO-7_15hqpm9c tag=TAG20060815T101925 recid=57 stamp=598530353
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07
channel ORA_DISK_1: starting datafile copy
copying current control file
output filename=/u02/oradata/TESTDB/cf_D-TESTDB_id-2370649665_16hqpm9j tag=TAG20060815T101925 recid=58 stamp=598530356
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
channel ORA_DISK_1: starting full datafile backupset
channel ORA_DISK_1: specifying datafile(s) in backupset
including current SPFILE in backupset
channel ORA_DISK_1: starting piece 1 at 15-AUG-06
channel ORA_DISK_1: finished piece 1 at 15-AUG-06
piece handle=/u02/oradata/TESTDB/17hqpm9k_1_1 tag=TAG20060815T101925 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:02
Finished backup at 15-AUG-06
From an RMAN session, update the control file / data dictionary so that all database files point to the RMAN copy made on the local file system:
RMAN> SWITCH DATABASE TO COPY;

datafile 1 switched to datafile copy "/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSTEM_FNO-1_10hqpm45"
datafile 2 switched to datafile copy "/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-UNDOTBS1_FNO-2_12hqpm7a"
datafile 3 switched to datafile copy "/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSAUX_FNO-3_11hqpm5s"
datafile 4 switched to datafile copy "/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-EXAMPLE_FNO-4_13hqpm83"
datafile 5 switched to datafile copy "/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-USERS_FNO-5_0vhqpltd"
datafile 6 switched to datafile copy "/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-APEX22_FNO-6_14hqpm8s"
datafile 7 switched to datafile copy "/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-FLOW_1_FNO-7_15hqpm9c"
From a SQL*Plus session, perform incomplete recovery and open the database using the RESETLOGS option:
SQL> RECOVER DATABASE USING BACKUP CONTROLFILE UNTIL CANCEL;

ORA-00279: change 7970332 generated at 08/15/2006 10:12:34 needed for thread 1
ORA-00289: suggestion :
/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_5_%u_.arc
ORA-00280: change 7970332 for thread 1 is in sequence #5


Specify log: {=suggested | filename | AUTO | CANCEL}
CANCEL
Media recovery cancelled.

SQL> ALTER DATABASE OPEN RESETLOGS;

Database altered.
From a SQL*Plus session, re-create any tempfiles that are still currently using ASM to the local file system. This is done by simply dropping the tempfiles from ASM and re-creating them in the local file system. This example relies on the initialization parameter db_create_file_dest=/u02/oradata:
SQL> select tablespace_name, file_name, bytes from dba_temp_files;

TABLESPACE_NAME FILE_NAME                                                 BYTES
--------------- ----------------------------------------------------- ---------
TEMP            +TESTDB_DATA1/testdb/tempfile/temp.261.598485663      536870912

SQL> alter database tempfile
  2  '+TESTDB_DATA1/testdb/tempfile/temp.261.598485663'
  3  drop including datafiles;

Database altered.

SQL> alter tablespace temp add tempfile size 512m
  2  autoextend on next 250m maxsize unlimited;

Tablespace altered.

SQL> select tablespace_name, file_name, bytes from dba_temp_files;

TABLESPACE_NAME FILE_NAME                                                 BYTES
--------------- ----------------------------------------------------- ---------
TEMP            /u02/oradata/TESTDB/datafile/o1_mf_temp_2g3spvq5_.tmp 536870912
  If users are currently accessing the tempfile(s) you are attempting to drop, you may receive the following error:
SQL> alter database tempfile
  2  '+TESTDB_DATA1/testdb/tempfile/temp.261.598485663'
  3  drop including datafiles;

ERROR at line 1:
ORA-25152: TEMPFILE cannot be dropped at this time
As for the poor users who were using the tempfile, their transaction will end and will be greeted with the following error message:
SQL> @testTemp.sql
       join dba_extents  c on (b.segment_name = c.segment_name)
            *
ERROR at line 4:
ORA-00372: file 601 cannot be modified at this time
ORA-01110: data file 601: '+TESTDB_DATA1/testdb/tempfile/temp.261.598485663'
ORA-00372: file 601 cannot be modified at this time
ORA-01110: data file 601: '+TESTDB_DATA1/testdb/tempfile/temp.261.598485663'
If this happens, you should attempt to drop the tempfile again so the operation is successful:
SQL> alter database tempfile
  2  '+TESTDB_DATA1/testdb/tempfile/temp.261.598485663'
  3  drop including datafiles;

Database altered.
From a SQL*Plus session, re-create any online redo logfiles that are still currently using ASM to the local file system. This is done by simply dropping the logfiles from ASM and re-creating them on the local file system. This example relies on the initialization parametersdb_create_file_dest=/u02/oradata and db_recovery_file_dest=/u02/flash_recovery_area:
Determine the current online redo logfiles to move to the local file system by examining the file names (and sizes) from V$LOGFILE:
SQL> select a.group#, a.member, b.bytes
  2  from v$logfile a, v$log b where a.group# = b.group#;

GROUP# MEMBER                                                           BYTES
------ ----------------------------------------------------------- ----------
     1 +TESTDB_DATA1/testdb/onlinelog/group_1.259.598486831         262144000
     2 +TESTDB_DATA1/testdb/onlinelog/group_2.260.598487179         262144000
     3 +TESTDB_DATA1/testdb/onlinelog/group_3.258.598487365         262144000
     1 +FLASH_RECOVERY_AREA/testdb/onlinelog/group_1.259.598486879  262144000
     2 +FLASH_RECOVERY_AREA/testdb/onlinelog/group_2.257.598487225  262144000
     3 +FLASH_RECOVERY_AREA/testdb/onlinelog/group_3.260.598487411  262144000

6 rows selected.
Force a log switch until the last redo log is marked "CURRENT" by issuing the following command:
SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 CURRENT
         2 INACTIVE
         3 INACTIVE

SQL> alter system switch logfile;

SQL> alter system switch logfile;

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 INACTIVE
         2 INACTIVE
         3 CURRENT
After making the last online redo log file the CURRENT one, drop the first online redo log:
SQL> alter database drop logfile group 1;

Database altered.
  As a DBA, you should already be aware that if you are going to drop a logfile group, it cannot be the current logfile group. I have run into instances; however, where attempting to drop the logfile group resulted in the following error as a result of the logfile group having an activestatus:
SQL> ALTER DATABASE DROP LOGFILE GROUP 1;
ALTER DATABASE DROP LOGFILE GROUP 1
*
ERROR at line 1:
ORA-01624: log 1 needed for crash recovery of instance TESTDB (thread 1)
ORA-00312: online log 1 thread 1: '<file_name>'
Easy problem to resolve. Simply perform a checkpoint on the database:
SQL> ALTER SYSTEM CHECKPOINT GLOBAL;

System altered.

SQL> ALTER DATABASE DROP LOGFILE GROUP 1;

Database altered.
Re-create the dropped redo log group in the local file system (and a different size if desired):
SQL> alter database add logfile group 1 size 250m;

Database altered.
After re-creating the online redo log group, force a log switch. The online redo log group just created should become the CURRENT one:
SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 UNUSED
         2 INACTIVE
         3 CURRENT

SQL> alter system switch logfile;

SQL> select group#, status from v$log;

    GROUP# STATUS
---------- ----------------
         1 CURRENT
         2 INACTIVE
         3 ACTIVE
After re-creating the first online redo log group, loop back to drop / re-create the next online redo logfile until all logs are rebuilt in the local file system.
Verify all online redo logfiles have been created in the local file system:
SQL> select a.group#, a.member, b.bytes
  2  from v$logfile a, v$log b where a.group# = b.group#;

GROUP# MEMBER                                                                     BYTES
------ --------------------------------------------------------------------- ----------
     1 /u02/oradata/TESTDB/onlinelog/o1_mf_1_2g3tc008_.log                    262144000
     2 /u02/oradata/TESTDB/onlinelog/o1_mf_2_2g3tkbwn_.log                    262144000
     3 /u02/oradata/TESTDB/onlinelog/o1_mf_3_2g3tmwno_.log                    262144000
     1 /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_1_2g3tc763_.log        262144000
     2 /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_2_2g3tkmr6_.log        262144000
     3 /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_3_2g3tn2g5_.log        262144000

6 rows selected.
Verify that all database files have been created in the local file system:
$ sqlplus "/ as sysdba"

SQL> @dba_files_all

Tablespace Name /
File Class           Filename                                                                        File Size Auto        Next             Max
-------------------- ------------------------------------------------------------------------- --------------- ---- ----------- ---------------
APEX22               /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-APEX22_FNO-6_14hqpm8s       104,857,600 NO             0               0
EXAMPLE              /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-EXAMPLE_FNO-4_13hqpm83      157,286,400 YES      655,360  34,359,721,984
FLOW_1               /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-FLOW_1_FNO-7_15hqpm9c        52,494,336 NO             0               0
SYSAUX               /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSAUX_FNO-3_11hqpm5s       419,430,400 YES   10,485,760  34,359,721,984
SYSTEM               /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSTEM_FNO-1_10hqpm45       608,174,080 YES   10,485,760  34,359,721,984
TEMP                 /u02/oradata/TESTDB/datafile/o1_mf_temp_2g3spvq5_.tmp                         536,870,912 YES  262,144,000  34,359,721,984
UNDOTBS1             /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-UNDOTBS1_FNO-2_12hqpm7a     209,715,200 YES    5,242,880  34,359,721,984
USERS                /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-USERS_FNO-5_0vhqpltd      2,382,888,960 YES    1,310,720  34,359,721,984
[ CONTROL FILE    ]  /u02/oradata/TESTDB/control01.ctl
[ ONLINE REDO LOG ]  /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_1_2g3tc763_.log               262,144,000
[ ONLINE REDO LOG ]  /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_2_2g3tkmr6_.log               262,144,000
[ ONLINE REDO LOG ]  /u02/flash_recovery_area/TESTDB/onlinelog/o1_mf_3_2g3tn2g5_.log               262,144,000
[ ONLINE REDO LOG ]  /u02/oradata/TESTDB/onlinelog/o1_mf_1_2g3tc008_.log                           262,144,000
[ ONLINE REDO LOG ]  /u02/oradata/TESTDB/onlinelog/o1_mf_2_2g3tkbwn_.log                           262,144,000
[ ONLINE REDO LOG ]  /u02/oradata/TESTDB/onlinelog/o1_mf_3_2g3tmwno_.log                           262,144,000
                                                                                               ---------------
sum                                                                                              6,044,581,888

15 rows selected.
At this point, the target database is open with all of its datafiles, controlfiles, online redo logfiles, tempfiles, and SPFILE stored in the local file system. If we wanted to remove the database files that were stored using ASM (which are actually now RMAN copies), this could be done from an RMAN session. You could also then remove the old version of the controfile(s) and SPFILE that were stored using ASM using a SQL*Plus session logged in to the ASM instance:
  If this is a production database, it would be best practice to first backup the database files on the local disk before removing the copies stored using ASM!
RMAN> DELETE NOPROMPT FORCE COPY;

using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=155 devtype=DISK

List of Datafile Copies
Key     File S Completion Time Ckp SCN    Ckp Time        Name
------- ---- - --------------- ---------- --------------- ----
59      1    A 15-AUG-06       7970332    15-AUG-06       +TESTDB_DATA1/testdb/datafile/system.269.598482099
60      2    A 15-AUG-06       7970332    15-AUG-06       +TESTDB_DATA1/testdb/datafile/undotbs1.256.598482299
61      3    A 15-AUG-06       7970332    15-AUG-06       +TESTDB_DATA1/testdb/datafile/sysaux.267.598482213
62      4    A 15-AUG-06       7970332    15-AUG-06       +TESTDB_DATA1/testdb/datafile/example.264.598482345
63      5    A 15-AUG-06       7970332    15-AUG-06       +TESTDB_DATA1/testdb/datafile/users.270.598481673
64      6    A 15-AUG-06       7970332    15-AUG-06       +TESTDB_DATA1/testdb/datafile/apex22.263.598482381
65      7    A 15-AUG-06       7970332    15-AUG-06       +TESTDB_DATA1/testdb/datafile/flow_1.262.598482405

List of Control File Copies
Key     S Completion Time Ckp SCN    Ckp Time        Name
------- - --------------- ---------- --------------- ----
58      A 15-AUG-06       7970332    15-AUG-06       /u02/oradata/TESTDB/cf_D-TESTDB_id-2370649665_16hqpm9j

List of Archived Log Copies
Key     Thrd Seq     S Low Time  Name
------- ---- ------- - --------- ----
54      1    4       A 14-AUG-06 /u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_4_2g3qxnxt_.arc
55      1    5       A 14-AUG-06 /u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_5_2g3qxo2c_.arc
56      1    1       A 15-AUG-06 /u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_1_2g3t3v8b_.arc
57      1    2       A 15-AUG-06 /u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_2_2g3t4q1g_.arc
58      1    3       A 15-AUG-06 /u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_3_2g3tdm2s_.arc
59      1    4       A 15-AUG-06 /u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_4_2g3tlkfk_.arc
60      1    5       A 15-AUG-06 /u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_5_2g3tqb1h_.arc
deleted datafile copy
datafile copy filename=+TESTDB_DATA1/testdb/datafile/system.269.598482099 recid=59 stamp=598531780
deleted datafile copy
datafile copy filename=+TESTDB_DATA1/testdb/datafile/undotbs1.256.598482299 recid=60 stamp=598531780
deleted datafile copy
datafile copy filename=+TESTDB_DATA1/testdb/datafile/sysaux.267.598482213 recid=61 stamp=598531780
deleted datafile copy
datafile copy filename=+TESTDB_DATA1/testdb/datafile/example.264.598482345 recid=62 stamp=598531780
deleted datafile copy
datafile copy filename=+TESTDB_DATA1/testdb/datafile/users.270.598481673 recid=63 stamp=598531780
deleted datafile copy
datafile copy filename=+TESTDB_DATA1/testdb/datafile/apex22.263.598482381 recid=64 stamp=598531780
deleted datafile copy
datafile copy filename=+TESTDB_DATA1/testdb/datafile/flow_1.262.598482405 recid=65 stamp=598531780
deleted control file copy
control file copy filename=/u02/oradata/TESTDB/cf_D-TESTDB_id-2370649665_16hqpm9j recid=58 stamp=598530356
deleted archive log
archive log filename=/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_4_2g3qxnxt_.arc recid=54 stamp=598531956
deleted archive log
archive log filename=/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_5_2g3qxo2c_.arc recid=55 stamp=598531962
deleted archive log
archive log filename=/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_1_2g3t3v8b_.arc recid=56 stamp=598534203
deleted archive log
archive log filename=/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_2_2g3t4q1g_.arc recid=57 stamp=598534231
deleted archive log
archive log filename=/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_3_2g3tdm2s_.arc recid=58 stamp=598534483
deleted archive log
archive log filename=/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_4_2g3tlkfk_.arc recid=59 stamp=598534673
deleted archive log
archive log filename=/u02/flash_recovery_area/TESTDB/archivelog/2006_08_15/o1_mf_1_5_2g3tqb1h_.arc recid=60 stamp=598534826
Deleted 15 objects

RMAN> exit

$ ORACLE_SID=+ASM; export ORACLE_SID
$ sqlplus "/ as sysdba"

SQL> ALTER DISKGROUP TESTDB_DATA1 DROP FILE '+TESTDB_DATA1/TESTDB/CONTROLFILE/backup.268.598481391';

Diskgroup altered.

SQL> ALTER DISKGROUP TESTDB_DATA1 DROP FILE '+TESTDB_DATA1/TESTDB/spfileTESTDB.ora';

Diskgroup altered.
One final note. Throughout this article, you will have noticed that I relied on using Oracle Managed Files (OMF) whenever possible. However, you can see that after relocating the database files from ASM to the local file system that our datafiles and controlfile(s) are not OMF. In this final task, I will convert the current datafiles and controlfile(s) to OMF:
First, determine the non-OMF controlfiles (to be renamed) currently in use:
SQL> select name from v$controlfile;

NAME
---------------------------------
/u02/oradata/TESTDB/control01.ctl
Next, determine the non-OMF datafiles (to be renamed) by examining the view DBA_DATA_FILES:
SQL> SELECT tablespace_name, file_name
  2  FROM dba_data_files;

TABLESPACE_NAME FILE_NAME
--------------- -------------------------------------------------------------------------
SYSTEM          /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSTEM_FNO-1_10hqpm45
UNDOTBS1        /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-UNDOTBS1_FNO-2_12hqpm7a
SYSAUX          /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSAUX_FNO-3_11hqpm5s
EXAMPLE         /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-EXAMPLE_FNO-4_13hqpm83
USERS           /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-USERS_FNO-5_0vhqpltd
APEX22          /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-APEX22_FNO-6_14hqpm8s
FLOW_1          /u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-FLOW_1_FNO-7_15hqpm9c

7 rows selected.
Shutdown the database:
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
Rename the non-OMF controlfile(s) in the file system to the newest OMF file name format:
$ cd /u02/oradata/TESTDB
$ mkdir -p controlfile
$ cp control01.ctl controlfile/o1_mf_8du3s3er_.ctl
$ cp control01.ctl controlfile/o1_mf_y2is93je_.ctl
$ rm control01.ctl
Modify the control_files initialization parameter in your init.ora or SPFILE to reference the new name(s):
SQL> startup nomount
ORACLE instance started.

Total System Global Area  285212672 bytes
Fixed Size                  1260420 bytes
Variable Size             150996092 bytes
Database Buffers          130023424 bytes
Redo Buffers                2932736 bytes

SQL> alter system set
  2  control_files='/u02/oradata/TESTDB/controlfile/o1_mf_8du3s3er_.ctl',
  3                '/u02/oradata/TESTDB/controlfile/o1_mf_y2is93je_.ctl'
  4  scope=spfile;

System altered.

SQL> shutdown immediate
ORA-01507: database not mounted


ORACLE instance shut down.
Rename the non-OMF datafiles in the file system to the newest OMF file name format:
$ cd /u02/oradata/TESTDB
$ mkdir -p datafile
$ mv data_D-TESTDB_I-2370649665_TS-SYSTEM_FNO-1_10hqpm45    datafile/o1_mf_system_2fb4b8s2_.dbf
$ mv data_D-TESTDB_I-2370649665_TS-UNDOTBS1_FNO-2_12hqpm7a  datafile/o1_mf_undotbs1_2fb4c2wf_.dbf
$ mv data_D-TESTDB_I-2370649665_TS-SYSAUX_FNO-3_11hqpm5s    datafile/o1_mf_sysaux_2fb4cb7z_.dbf
$ mv data_D-TESTDB_I-2370649665_TS-EXAMPLE_FNO-4_13hqpm83   datafile/o1_mf_example_2fb4ccw2_.dbf
$ mv data_D-TESTDB_I-2370649665_TS-USERS_FNO-5_0vhqpltd     datafile/o1_mf_users_2fb4cqf4_.dbf
$ mv data_D-TESTDB_I-2370649665_TS-APEX22_FNO-6_14hqpm8s    datafile/o1_mf_apex22_2ft4eswu_.dbf
$ mv data_D-TESTDB_I-2370649665_TS-FLOW_1_FNO-7_15hqpm9c    datafile/o1_mf_flow_1_2fb4cegw_.dbf
Rename the files in the controlfile:
SQL> startup mount
ORACLE instance started.

Total System Global Area  285212672 bytes
Fixed Size                  1260420 bytes
Variable Size             150996092 bytes
Database Buffers          130023424 bytes
Redo Buffers                2932736 bytes
Database mounted.

SQL> alter database rename file
  2  '/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSTEM_FNO-1_10hqpm45'
  3  to '/u02/oradata/TESTDB/datafile/o1_mf_system_2fb4b8s2_.dbf';

Database altered.

SQL> alter database rename file
  2  '/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-UNDOTBS1_FNO-2_12hqpm7a'
  3  to '/u02/oradata/TESTDB/datafile/o1_mf_undotbs1_2fb4c2wf_.dbf';

Database altered.

SQL> alter database rename file
  2  '/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-SYSAUX_FNO-3_11hqpm5s'
  3  to '/u02/oradata/TESTDB/datafile/o1_mf_sysaux_2fb4cb7z_.dbf';

Database altered.

SQL> alter database rename file
  2  '/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-EXAMPLE_FNO-4_13hqpm83'
  3  to '/u02/oradata/TESTDB/datafile/o1_mf_example_2fb4ccw2_.dbf';

Database altered.

SQL> alter database rename file
  2  '/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-USERS_FNO-5_0vhqpltd'
  3  to '/u02/oradata/TESTDB/datafile/o1_mf_users_2fb4cqf4_.dbf';

Database altered.

SQL> alter database rename file
  2  '/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-APEX22_FNO-6_14hqpm8s'
  3  to '/u02/oradata/TESTDB/datafile/o1_mf_apex22_2ft4eswu_.dbf';

Database altered.

SQL> alter database rename file
  2  '/u02/oradata/TESTDB/data_D-TESTDB_I-2370649665_TS-FLOW_1_FNO-7_15hqpm9c'
  3  to '/u02/oradata/TESTDB/datafile/o1_mf_flow_1_2fb4cegw_.dbf';

Database altered.
Open database and verify the new OMF files:
SQL> alter database open;

Database altered.

SQL> SELECT tablespace_name, file_name
  2  FROM dba_data_files;

TABLESPACE_NAME FILE_NAME
--------------- ---------------------------------------------------------
SYSTEM          /u02/oradata/TESTDB/datafile/o1_mf_system_2fb4b8s2_.dbf
UNDOTBS1        /u02/oradata/TESTDB/datafile/o1_mf_undotbs1_2fb4c2wf_.dbf
SYSAUX          /u02/oradata/TESTDB/datafile/o1_mf_sysaux_2fb4cb7z_.dbf
EXAMPLE         /u02/oradata/TESTDB/datafile/o1_mf_example_2fb4ccw2_.dbf
USERS           /u02/oradata/TESTDB/datafile/o1_mf_users_2fb4cqf4_.dbf
APEX22          /u02/oradata/TESTDB/datafile/o1_mf_apex22_2ft4eswu_.dbf
FLOW_1          /u02/oradata/TESTDB/datafile/o1_mf_flow_1_2fb4cegw_.dbf

7 rows selected.


Page Count: 3763

http://www.idevelopment.info/

  Backup and Recovery    
  LOBs    
  Locks    
  Security    
  Session Management    
  Tuning    



Best Way to save Time as DBA Script
UNIX Basics for the DBA
Basic UNIX Command
The following is a list of commonly used Unix command:
    • ps - Show process
    • grep - Search files for text patterns
    • mailx - Read or send mail
    • cat - Join files or display them
    • cut - Select columns for display
    • awk - Pattern-matching language
    • df - Show free disk space
Here are some examples of how the DBA uses these commands:

    • List available instances on a server:
$ ps -ef | grep smon
  oracle 21832     1  0   Feb 24 ?       19:05 ora_smon_oradb1
  oracle   898     1  0   Feb 15 ?        0:00 ora_smon_oradb2
    dliu 25199 19038  0 10:48:57 pts/6    0:00 grep smon
  oracle 27798     1  0 05:43:54 ?        0:00 ora_smon_oradb3
  oracle 28781     1  0   Mar 03 ?        0:01 ora_smon_oradb4

    • List available listeners on a server:
$ ps -ef | grep listener | grep -v grep
  oracle 23879    1  0   Feb 24 ?  33:36 /8.1.7/bin/tnslsnr listener_db1 -inherit
  oracle 27939    1  0 05:44:02 ?  0:00  /8.1.7/bin/tnslsnr listener_db2 -inherit
  oracle 23536    1  0   Feb 12 ?  4:19  /8.1.7/bin/tnslsnr listener_db3 -inherit
  oracle 28891    1  0   Mar 03 ?  0:01  /8.1.7/bin/tnslsnr listener_db4 -inherit

    • Find out file system usage for Oracle archive  destination:
$ df -k | grep oraarch
  /dev/vx/dsk/proddg/oraarch 71123968 4754872 65850768  7%  /u09/oraarch

    • List number of lines in the alert.log file:
$ cat alert.log | wc -l
   2984

    • List all Oracle error messages from the alert.log file:
$ grep ORA- alert.log
  ORA-00600: internal error code, arguments: [kcrrrfswda.1], [], [], [], [], []
  ORA-00600: internal error code, arguments: [1881], [25860496], [25857716], []
CRONTAB Basics
A crontab file is comprised of six fields:
       Minute0-59
       Hour0-23
       Day of month1-31
       Month1 - 12
       Day of Week0 - 6, with 0 = Sunday
       Unix Command or Shell Scripts
    • To edit a crontab file, type:
   Crontab -e

    • To view a crontab file, type:
                 Crontab -l
     0  4 * * 5       /dba/admin/analyze_table.ksh
     30 3  * * 3,6    /dba/admin/hotbackup.ksh /dev/null 2>&1

In the example above, the first entry shows that a script to analyze a table  runs every Friday at 4:00 a.m. The second entry shows that a script to perform a  hot backup runs every Wednesday and Saturday at 3:00 a.m.
Top DBA Shell Scripts for Monitoring the Database
The eight shell scripts provided below cover 90 percent of a DBA's daily  monitoring activities. You will need to modify the UNIX environment variables as  appropriate.
Check Oracle Instance Availability
The oratab file lists all the databases on a server:
$ cat /var/opt/oracle/oratab
###################################################################
## /var/opt/oracle/oratab                                        ##
###################################################################
oradb1:/u01/app/oracle/product/8.1.7:Y
oradb2:/u01/app/oracle/product/8.1.7:Y
oradb3:/u01/app/oracle/product/8.1.7:N
oradb4:/u01/app/oracle/product/8.1.7:Y

The following script checks all the databases listed in the oratab file, and  finds out the status (up or down) of databases:
################################################################### 
## ckinstance.ksh ## 
###################################################################
ORATAB=/var/opt/oracle/oratab
echo "`date`   "
echo  "Oracle Database(s) Status `hostname` :\n"
db=`egrep -i ":Y|:N" $ORATAB | cut -d":" -f1 | grep -v "\#" | grep -v "\*"`
pslist="`ps -ef | grep pmon`"
for i in $db ; do
  echo  "$pslist" | grep  "ora_pmon_$i"  > /dev/null 2>$1
  if (( $? )); then
        echo "Oracle Instance - $i:       Down"
  else
        echo "Oracle Instance - $i:       Up"
  fi
done     

Use the following to make sure the script is executable:
$ chmod 744 ckinstance.ksh
$ ls -l ckinstance.ksh
-rwxr--r--   1 oracle     dba     657 Mar  5 22:59 ckinstance.ksh*
Here is an instance availability report:
$ ckinstance.ksh
Mon Mar  4 10:44:12 PST 2002  
Oracle Database(s) Status for DBHOST server:
Oracle Instance - oradb1:   Up
Oracle Instance - oradb2:   Up
Oracle Instance - oradb3:   Down
Oracle Instance - oradb4:   Up        
Check Oracle Listener's Availability
A similar script checks for the Oracle listener. If the listener is down, the  script will restart the listener:
#######################################################################
## cklsnr.sh                                                         ##
#######################################################################
#!/bin/ksh
DBALIST="primary.dba@company.com,another.dba@company.com";export DBALIST
cd /var/opt/oracle
rm -f lsnr.exist 
ps -ef | grep mylsnr | grep -v grep  > lsnr.exist
if [ -s lsnr.exist ]
then
    echo 
else
echo "Alert" | mailx -s "Listener 'mylsnr' on `hostname` is down" $DBALIST 
    TNS_ADMIN=/var/opt/oracle; export TNS_ADMIN
    ORACLE_SID=db1; export ORACLE_SID   
    ORAENV_ASK=NO; export ORAENV_ASK
    PATH=$PATH:/bin:/usr/local/bin; export PATH
    . oraenv
    LD_LIBRARY_PATH=${ORACLE_HOME}/lib;export LD_LIBRARY_PATH
    lsnrctl start mylsnr
fi
Check Alert Logs (ORA-XXXXX)
Some of the environment variables used by each script can be put into one  profile:
#######################################################################
## oracle.profile ##
#######################################################################
EDITOR=vi;export EDITOR ORACLE_BASE=/u01/app/oracle; export
ORACLE_BASE ORACLE_HOME=$ORACLE_BASE/product/8.1.7; export
ORACLE_HOME LD_LIBRARY_PATH=$ORACLE_HOME/lib; export
LD_LIBRARY_PATH TNS_ADMIN=/var/opt/oracle;export
TNS_ADMIN NLS_LANG=american; export
NLS_LANG NLS_DATE_FORMAT='Mon DD YYYY HH24:MI:SS'; export
NLS_DATE_FORMAT ORATAB=/var/opt/oracle/oratab;export
ORATAB PATH=$PATH:$ORACLE_HOME:$ORACLE_HOME/bin:/usr/ccs/bin:/bin:/usr/bin:/usr/sbin:/
sbin:/usr/openwin/bin:/opt/bin:.; export
PATH DBALIST="primary.dba@company.com,another.dba@company.com";export
DBALIST
The following script first calls oracle.profile to set up all the environment  variables. The script also sends the DBA a warning e-mail if it finds any Oracle  errors:
####################################################################
## ckalertlog.sh                                                  ##
####################################################################
#!/bin/ksh
. /etc/oracle.profile
for SID in `cat $ORACLE_HOME/sidlist`
do
    cd $ORACLE_BASE/admin/$SID/bdump
    if [ -f alert_${SID}.log ]
    then
        mv alert_${SID}.log alert_work.log
        touch alert_${SID}.log
        cat alert_work.log >> alert_${SID}.hist
        grep ORA- alert_work.log > alert.err
    fi
    if [ `cat alert.err|wc -l` -gt 0 ]
    then
        mailx -s "${SID} ORACLE ALERT ERRORS" $DBALIST < alert.err
    fi
    rm -f alert.err
    rm -f alert_work.log
done
Clean Up Old Archived Logs
The following script cleans up old archive logs if the log file system  reaches 90-percent capacity:
$ df -k | grep arch
Filesystem                kbytes   used     avail    capacity  Mounted on
/dev/vx/dsk/proddg/archive 71123968 30210248 40594232   43%  /u08/archive
#######################################################################
## clean_arch.ksh                                                    ##
#######################################################################
#!/bin/ksh
df -k | grep arch > dfk.result
archive_filesystem=`awk  -F" "  '{ print $6 }' dfk.result`
archive_capacity=`awk  -F" "  '{ print $5 }' dfk.result`


if [[ $archive_capacity > 90% ] ]
then
    echo "Filesystem ${archive_filesystem} is ${archive_capacity} filled"
    # try one of the following option depend on your need
    find $archive_filesystem -type f -mtime +2 -exec rm -r {} \;    
    tar 
    rman
fi
Analyze Tables and Indexes (for Better Performance)
Below, I have shown an example on how to pass parameters to a script:
####################################################################
## analyze_table.sh ##
#################################################################### 
#!/bin/ksh #
input parameter: 1: password # 2: SID if (($#<1)) then echo "Please enter 
'oracle'
user password as the first parameter !" exit 0 fi if (($#<2)) then echo 
"Please enter
instance name as the second parameter!" exit 0 fi
To execute the script with parameters, type:
$ analyze_table.sh manager oradb1

The first part of script generates a file analyze.sql, which contains the  syntax for analyzing table. The second part of script analyzes all the  tables:
#####################################################################
## analyze_table.sh ##
#####################################################################
sqlplus -s <<!
oracle/$1@$2
set heading off
set feed off
set pagesize 200
set linesize 100
spool analyze_table.sql
select 'ANALYZE TABLE ' || owner || '.' || segment_name || 
       ' ESTIMATE STATISTICS SAMPLE 10 PERCENT;'
from dba_segments
where segment_type = 'TABLE'
and owner not in ('SYS', 'SYSTEM');
spool off
exit
!
sqlplus -s <<!
oracle/$1@$2
@./analyze_table.sql
exit
!
  

Here is an example of analyze.sql:
$ cat analyze.sql
ANALYZE TABLE HIRWIN.JANUSAGE_SUMMARY ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE HIRWIN.JANUSER_PROFILE ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE APPSSYS.HIST_SYSTEM_ACTIVITY ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE HTOMEH.QUEST_IM_VERSION ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE JSTENZEL.HIST_SYS_ACT_0615 ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE JSTENZEL.HISTORY_SYSTEM_0614 ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE JSTENZEL.CALC_SUMMARY3 ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE IMON.QUEST_IM_LOCK_TREE ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE APPSSYS.HIST_USAGE_SUMMARY ESTIMATE STATISTICS SAMPLE 10 PERCENT;
ANALYZE TABLE PATROL.P$LOCKCONFLICTTX ESTIMATE STATISTICS SAMPLE 10 PERCENT;
Check Tablespace Usage
This scripts checks for tablespace usage. If tablespace is 10 percent free,  it will send an alert e-mail.
#####################################################################
## ck_tbsp.sh ##
#####################################################################
#!/bin/ksh
sqlplus -s <<!
oracle/$1@$2
set feed off
set linesize 100
set pagesize 200
spool tablespace.alert
SELECT F.TABLESPACE_NAME,
       TO_CHAR ((T.TOTAL_SPACE - F.FREE_SPACE),'999,999') "USED (MB)",
       TO_CHAR (F.FREE_SPACE, '999,999') "FREE (MB)",
       TO_CHAR (T.TOTAL_SPACE, '999,999') "TOTAL (MB)",
       TO_CHAR ((ROUND ((F.FREE_SPACE/T.TOTAL_SPACE)*100)),'999')||' %' PER_FREE
FROM   (
       SELECT       TABLESPACE_NAME, 
                    ROUND (SUM (BLOCKS*(SELECT VALUE/1024
                                        FROM V\$PARAMETER 
                                        WHERE NAME = 'db_block_size')/1024)
                           ) FREE_SPACE
       FROM DBA_FREE_SPACE
       GROUP BY TABLESPACE_NAME
       ) F,
       (
       SELECT TABLESPACE_NAME,
       ROUND (SUM (BYTES/1048576)) TOTAL_SPACE
       FROM DBA_DATA_FILES
       GROUP BY TABLESPACE_NAME
       ) T
WHERE F.TABLESPACE_NAME = T.TABLESPACE_NAME
AND (ROUND ((F.FREE_SPACE/T.TOTAL_SPACE)*100)) < 10;
spool off
exit
!
if [ `cat tablespace.alert|wc -l` -gt 0 ]
then
          cat tablespace.alert -l tablespace.alert > tablespace.tmp
          mailx -s "TABLESPACE ALERT for ${2}" $DBALIST < tablespace.tmp
fi

An example of the alert mail output is as follows:
TABLESPACE_NAME     USED (MB)   FREE (MB)         TOTAL (MB)            PER_FREE 
------------------- --------- ----------- ------------------- ------------------
SYSTEM              2,047             203               2,250                9 %
STBS01                302              25                327                 8 %          
STBS02                241              11                252                 4 % 
STBS03                233              19                252                 8 %
Find Out Invalid Database Objects
The following finds out invalid database objects:
#####################################################################          
## invalid_object_alert.sh ## 
#####################################################################          
#!/bin/ksh 
. /etc/oracle.profile 
sqlplus -s <<! 
oracle/$1@$2 
set          feed off 
set heading off 
column object_name format a30 
spool invalid_object.alert          
SELECT  OWNER, OBJECT_NAME, OBJECT_TYPE, STATUS 
FROM    DBA_OBJECTS 
WHERE   STATUS = 'INVALID' 
ORDER BY OWNER, OBJECT_TYPE, OBJECT_NAME; 
spool off          
exit 

if [ `cat invalid_object.alert|wc -l` -gt 0 ] 
then 
    mailx -s "INVALID OBJECTS for ${2}" $DBALIST < invalid_object.alert 
fi
$ cat invalid_object.alert
OWNER        OBJECT_NAME           OBJECT_TYPE          STATUS
----------------------------------------------------------------------
HTOMEH       DBMS_SHARED_POOL            PACKAGE BODY          INVALID
HTOMEH       X_$KCBFWAIT                 VIEW                  INVALID
IMON         IW_MON                      PACKAGE               INVALID
IMON         IW_MON                      PACKAGE BODY          INVALID
IMON         IW_ARCHIVED_LOG             VIEW                  INVALID
IMON         IW_FILESTAT                 VIEW                  INVALID
IMON         IW_SQL_FULL_TEXT            VIEW                  INVALID
IMON         IW_SYSTEM_EVENT1            VIEW                  INVALID
IMON         IW_SYSTEM_EVENT_CAT         VIEW                  INVALID
LBAILEY      CHECK_TABLESPACE_USAGE      PROCEDURE             INVALID
PATROL       P$AUTO_EXTEND_TBSP          VIEW                  INVALID
SYS          DBMS_CRYPTO_TOOLKIT         PACKAGE               INVALID
SYS          DBMS_CRYPTO_TOOLKIT         PACKAGE BODY          INVALID
SYS          UPGRADE_SYSTEM_TYPES_TO_816 PROCEDURE             INVALID
SYS          AQ$_DEQUEUE_HISTORY_T       TYPE                  INVALID
SYS          HS_CLASS_CAPS               VIEW                  INVALID 
SYS          HS_CLASS_DD                 VIEW                  INVALID
Monitor Users and Transactions (Dead Locks, et al)
This script sends out an alert e-mail if dead lock occurs:
###################################################################
## deadlock_alert.sh ##
###################################################################
#!/bin/ksh
. /etc/oracle.profile
sqlplus -s <<!
oracle/$1@$2
set feed off
set heading off
spool deadlock.alert
SELECT   SID, DECODE(BLOCK, 0, 'NO', 'YES' ) BLOCKER,
              DECODE(REQUEST, 0, 'NO','YES' ) WAITER
FROM     V$LOCK 
WHERE    REQUEST > 0 OR BLOCK > 0 
ORDER BY block DESC; 
spool off
exit
!
if [ `cat deadlock.alert|wc -l` -gt 0 ]
then
    mailx -s "DEADLOCK ALERT for ${2}" $DBALIST < deadlock.alert
fi
Conclusion
0,20,40 7-17 * * 1-5 /dba/scripts/ckinstance.sh > /dev/null 2>&1
0,20,40 7-17 * * 1-5 /dba/scripts/cklsnr.sh > /dev/null 2>&1
0,20,40 7-17 * * 1-5 /dba/scripts/ckalertlog.sh > /dev/null 2>&1
30         * * * 0-6 /dba/scripts/clean_arch.sh > /dev/null 2>&1
*          5 * * 1,3 /dba/scripts/analyze_table.sh > /dev/null 2>&1
*          5 * * 0-6 /dba/scripts/ck_tbsp.sh > /dev/null 2>&1
*          5 * * 0-6 /dba/scripts/invalid_object_alert.sh > /dev/null 2>&1
0,20,40 7-17 * * 1-5 /dba/scripts/deadlock_alert.sh > /dev/null 2>&1