Tip

Scripts for hot backup and restore

This procedure generates two scripts that do a hot backup and restore of the database. It is a full backup of the database datafiles, redolog, init, and control files. You can run this script at database open and it will generate 2 files:

  1. The first file "_hot_bkup_$1.sql" gets information about the physical structure of the DB and has operating system copy commands. In this case is the UNIX cp.
  2. The second file "_hot_restore_$1.sql" is used in case of recovery of the whole DB. It puts every copied file back to where it was.
It was first written by

    Requires Free Membership to View

Thomas B.Cox for the Windows NT platform and I changed it to work on UNIX. It has been tested on Oracle 8.1.7.3.0 on Unix Tru64 5.1a.

#!/bin/csh -f

# Filename: hot_bkp_restore.sh
# Purpose: creates a hot backup script and a hot recovery script
# Author: Robert Hanrahan , 
# Hewlett Packard Italiana S.p.a.
# based on an NT script by Thomas B. Cox
# Version: 1.2
# Last Mod: 05-Sep-2002
# 
# Added in 1.1: check for ARCHIVELOG mode
# Added in 1.2: rewritten for Unix (from v1.1 the NT version) + backup of
# the redo_log_files
# 
# Known bugs: does not back up INIT.ORA file - fixed :)
# 
# TEST THIS FIRST - NEVER RUN SCRIPTS YOU DON'T UNDERSTAND!
#
# Note: the names of generated files begin with an underscore '_'.
# 
# Important: the paths (/app/oracle/database/$1/Backup must exist!

setenv ORACLE_SID $1

if ($1 == "") then

clear

echo ""
echo "*********************************************"
echo "correct usage: $0 ORACLE_SID"
echo "*********************************************"
echo ""

else

sqlplus -s internal <
/app/oracle/database/$1/Backup/init$1.ora' );

   -- the two lines below have been decommented....
   dbms_output.put_line( 'startup ' ) ;
   dbms_output.put_line( 'exit ' ) ;

END ;
/
spool off
spool _hot_restore_$1.sql

DECLARE

   vc_host_copy_cmd CONSTANT VARCHAR2(2000) := 'host cp -rf ' ;

   vc_bkup_dest CONSTANT VARCHAR2(2000) := '/app/oracle/database/$1/Backup'
;

   vc_dir_sep CONSTANT VARCHAR2(1) := '/' ;

   CURSOR ts_cur
      IS
      SELECT ts.tablespace_name AS ts_nm
        FROM dba_tablespaces ts ; -- WHERE ts.contents != 'TEMPORARY' ;


   CURSOR ts_df_cur ( ts_nm_in IN VARCHAR2 , sep_in IN VARCHAR2 )
      IS
      SELECT df.file_name as ts_df_nm
           , substr ( file_name
                    , instr ( file_name , sep_in, -1, 1 ) + 1 
                    , ( length ( file_name )
                      + - instr ( file_name , sep_in, -1, 1 ) ) 
                    ) as just_df_nm
        FROM dba_data_files df
       WHERE df.tablespace_name = ts_nm_in ;
 
   CURSOR cf_cur ( sep_in IN VARCHAR2 )
      IS
      SELECT cf.name as cf_nm
           , substr ( name
                    , instr ( name , sep_in, -1, 1 ) + 1 
                    , ( length ( name )
                      + - instr ( name , sep_in, -1, 1 ) ) 
                    ) as just_cf_nm
        FROM v$controlfile cf ;
   CURSOR redo_cur (sep_in IN VARCHAR2 )
      IS
      SELECT rd.MEMBER as redo_nm
                    , substr ( MEMBER
                    , instr ( MEMBER , sep_in, -1, 1 ) + 1
                    , ( length ( MEMBER )
                      + - instr ( MEMBER , sep_in, -1, 1 ) )
                    ) as just_redo_nm
        FROM v$logfile rd ;

BEGIN

   FOR cf_rec IN cf_cur ( vc_dir_sep ) LOOP
      dbms_output.put_line ( vc_host_copy_cmd || ' ' || vc_bkup_dest
         || vc_dir_sep || cf_rec.just_cf_nm || ' ' || cf_rec.cf_nm );
   END LOOP ;

   -- new body for redo_logs

   FOR redo_rec IN redo_cur ( vc_dir_sep ) LOOP

   dbms_output.put_line( vc_host_copy_cmd || ' ' || vc_bkup_dest ||
vc_dir_sep || redo_rec.just_redo_nm || ' ' || redo_rec.redo_nm );

   END LOOP ;
   --

   FOR ts_rec IN ts_cur LOOP

   dbms_output.put_line( 'host echo Start restoring tablespace ' ||
ts_rec.ts_nm || '.' );

   FOR df_rec IN ts_df_cur ( ts_rec.ts_nm , vc_dir_sep ) LOOP

   dbms_output.put_line ( vc_host_copy_cmd || ' ' || vc_bkup_dest
            || vc_dir_sep || df_rec.just_df_nm || ' ' || df_rec.ts_df_nm );

   END LOOP ;

   dbms_output.put_line( 'host echo Finished restoring tablespace ' ||
ts_rec.ts_nm || '.' );

   END LOOP ;

   dbms_output.put_line( 'host echo End of restore. You may now start your
database. ' ) ;

   dbms_output.put_line( 'host cp -rf
/app/oracle/database/$1/Backup/init$1.ora $ORACLE_HOME/dbs/init$1.ora' );

END ;
/
spool off

exit

EOF

endif

For More Information

  • Feedback: E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in October 2002

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

Disclaimer: Our Tips Exchange is a forum for you to share technical advice and expertise with your peers and to learn from other enterprise IT professionals. TechTarget provides the infrastructure to facilitate this sharing of information. However, we cannot guarantee the accuracy or validity of the material submitted. You agree that your use of the Ask The Expert services and your reliance on any questions, answers, information or other materials received through this Web site is at your own risk.