Home > Articles

Backup and Recovery Scripts

This chapter is from the book

This chapter is from the book

Having the right backup and recovery procedures is the lifeblood of any database. Companies live on data, and, if that data is not available, the whole company collapses. As a result, it is the responsibility of the database administrator to protect the database from system faults, crashes, and natural calamities resulting from a variety of circumstances.

The choice of a backup and recovery mechanism depends mainly on the following factors:

  • Database mode (ARCHIVELOG, NOARCHIVELOG)

  • Size of the database

  • Backup and recovery time

  • uptime

  • Type of data (OLTP, DSS, Data Warehouse).

The types of backup are

  • Offline backup (Cold or closed database backup)

  • Online backup (Hot or open database backup)

  • Logical export

Logical exports create an export file that contains a list of SQL statements to recreate the database. Export is performed when the database is open and does not affect users work. Offline backups can only be performed when the database is shut down cleanly, and the database will be unavailable to users while the offline backup is being performed. Online backups are performed when the database is open, and it does not affect users work. The database needs to run in ARCHIVELOG mode to perform online backups.

The database can run in either ARCHIVELOG mode or NOARCHIVELOG mode. In ARCHIVELOG mode, the archiver (ARCH) process archives the redo log files to the archive destination directory. These archive files can be used to recover the database in the case of a failure. In NOARCHIVELOG mode, the redo log files are not archived.

When the database is running in ARCHIVELOG mode, the choice can be one or more of the following:

  • Export

  • Hot backup

  • Cold backup

When the database is running in NOARCHIVELOG mode, the choice of backup is as follows:

  • Export

  • Cold backup

Cold Backup

Offline or cold backups are performed when the database is completely shutdown. The disadvantage of an offline backup is that it cannot be done if the database needs to be run 24/7. Additionally, you can only recover the database up to the point when the last backup was made unless the database is running in ARCHIVELOG mode.

The general steps involved in performing a cold backup are shown in Figure 3.1. These general steps are used in writing cold backup scripts for Unix and Windows NT.

Figure 3.1 Steps for cold backup.

The steps in Figure 3.1 are explained as follows.

Step 1—Generating File List

An offline backup consists of physically copying the following files:

  • Data files

  • Control files

  • Init.ora and config.ora files

CAUTION

Backing up online redo log files is not advised in all cases, except when performing cold backup with the database running in NOARCHIVELOG mode. If you make a cold backup in ARCHIVELOG mode do not backup redo log files. There is a chance that you may accidentally overwrite your real online redo logs, preventing you from doing a complete recovery.

If your database is running in ARCHIVELOG mode, when you perform cold backup you should also backup archive logs that exist.

Before performing a cold backup, you need to know the location of the files that need to be backed up. Because the database structure changes day to day as more files get added or moved between directories, it is always better to query the database to get the physical structure of database before making a cold backup.

To get the structure of the database, query the following dynamic data dictionary tables:

  • V$datafile Lists all the data files used in the database
    SQL>select name from v$datafile;
  • Backup the control file and perform a trace of the control file using
    SQL>alter database backup controlfile to '/u10/backup/control.ctl';
    SQL>alter database backup controlfile to trace;
  • Init.ora and config.ora Located under $ORACLE_HOME/dbs directory

Step 2—Shut down the database

You can shut down a database with the following commands:

$su – oracle
$sqlplus "/ as sysdba"
SQL>shutdown

Step 3—Perform a backup

In the first step, you generated a list of files to be backed up. To back up the files, you can use the Unix copy command (cp) to copy it to a backup location, as shown in the following code. You have to copy all files that you generated in Step 1.

$cp /u01/oracle/users01.dbf /u10/backup

You can perform the backup of the Init.ora and config.ora files as follows:

 $cp $ORACLE_HOME/dbs/init.ora /u10/backup
 $cp $ORACLE_HOME/dbs/config.ora /u10/backup

Step 4—Start the database

After the backup is complete, you can start the database as follows:

$su – oracle
$sqlplus "/ as sysdba"
SQL> startup

Hot Backup

An online backup or hot backup is also referred to as ARCHIVE LOG backup. An online backup can only be done when the database is running in ARCHIVELOG mode and the database is open. When the database is running in ARCHIVELOG mode, the archiver (ARCH) background process will make a copy of the online redo log file to archive backup location.

An online backup consists of backing up the following files. But, because the database is open while performing a backup, you have to follow the procedure shown in Figure 3.2 to backup the files:

  • Data files of each tablespace

  • Archived redo log files

  • Control file

  • Init.ora and config.ora files

Figure 3.2 Steps for hot backup.

The general steps involved in performing hot backup are shown in Figure 3.2. These general steps are used in writing hot backup scripts for Unix and Windows NT.

The steps in Figure 3.2 are explained as follows.

Step 1—Put the tablespace in the Backup mode and copy the data files.

Assume that your database has two tablespaces, USERS and TOOLS. To back up the files for these two tablespaces, first put the tablespace in backup mode by using the ALTER statement as follows:

SQL>alter tablespace USERS begin backup;

After the tablespace is in Backup mode, you can use the SELECT statement to list the data files for the USERS tablespace, and the copy (cp) command to copy the files to the backup location. Assume that the USERS tablespace has two data files—users01.dbf and users02.dbf.

SQL>select file_name from dba_data_files 
  where tablespace_name='USERS';
$cp /u01/oracle/users01.dbf /u10/backup
$cp /u01/oracle/users01.dbf /u10/backup

The following command ends the backup process and puts the tablespace back in normal mode.

SQL>alter tablespace USERS end backup;

You have to repeat this process for all tablespaces. You can get the list of tablespaces by using the following SQL statement:

SQL>select tablespace_name from dba_tablespaces;

Step 2—Back up the control and Init.ora files.

To backup the control file,

SQL>alter database backup controlfile to '/u10/backup/control.ctl';

You can copy the Init.ora file to a backup location using

$cp $ORACLE_HOME/dbs/initorcl.ora /u10/backup

Step 3—Stop archiving.

Archiving is a continuous process and, without stopping archiver, you might unintentionally copy the file that the archiver is currently writing. To avoid this, first stop the archiver and then copy the archive files to backup location. You can stop the archiver as follows:

SQL>alter system switch logfile;
SQL>alter system archive log stop;

The first command switches redo log file and the second command stops the archiver process.

Step 4—Back up the archive files.

To avoid backing up the archive file that is currently being written, we find the least sequence number that is to be archived from the V$LOG view, and then backup all the archive files before that sequence number. The archive file location is defined by the LOG_ARCHIVE_DEST_n parameter in the Init.ora file.

select min(sequence#) from v$log
where archived='NO';

Step 5—Restart the archive process.

The following command restarts the archiver process:

SQL>alter system archive log start;

Now you have completed the hot backup of database.

An online backup of a database will keep the database open and functional for 24/7 operations. It is advised to schedule online backups when there is the least user activity on the database, because backing up the database is very I/O intensive and users can see slow response during the backup period. Additionally, if the user activity is very high, the archive destination might fill up very fast.

Database Crashes During Hot Backup

There can be many reasons for the database to crash during a hot backup—a power outage or rebooting of the server, for example. If these were to happen during a hot backup, chances are that tablespace would be left in backup mode. In that case you must manually recover the files involved, and the recovery operation would end the backup of tablespace. It's important to check the status of the files as soon as you restart the instance and end the backup for the tablespace if it's in backup mode.

select a.name,b.status from v$datafile a, v$backup b
where a.file#=b.file# and b.status='ACTIVE';

or

select a.tablespace_name,a.file_name,b.status from dba_data_files a, 
v$backup b
where a.file_id=b.file# and b.status='ACTIVE';

This statement lists files with ACTIVE status. If the file is in ACTIVE state, the corresponding tablespace is in backup mode. The second statement gives the tablespace name also, but this can't be used unless the database is open. You need to end the backup mode of the tablespace with the following command:

   alter tablespace tablespace_name end backup;

Logical Export

Export is the single most versatile utility available to perform a backup of the database, de-fragment the database, and port the database or individual objects from one operating system to another operating system.

Export backup detects block corruption

Though you perform other types of backup regularly, it is good to perform full export of database at regular intervals, because export detects any data or block corruptions in the database. By using export file, it is also possible to recover individual objects, whereas other backup methods do not support individual object recovery.

Export can be used to export the database at different levels of functionality:

  • Full export (full database export) (FULL=Y)

  • User-level export (exports objects of specified users) (OWNER=userlist)

  • Table-level export (exports specified tables and partitions) (TABLES=tablelist)

  • Transportable tablespaces (TABLESPACES=tools, TRANSPORT_TABLESPACE=y)

There are two methods of Export:

  • Conventional Path (default)—Uses SQL layer to create the export file. The fact is that the SQL layer introduces CPU overhead due to character set, converting numbers, dates and so on. This is time consuming.

  • Direct path (DIRECT=YES)—Skips the SQL layer and reads directly from database buffers or private buffers. Therefore it is much faster than conventional path.

We will discuss scripts to perform the full, user-level, and table-level export of database. The scripts also show you how to compress and split the export file while performing the export. This is especially useful if the underlying operating system has a limitation of 2GB maximum file limit.

Understand scripting

This chapter requires understanding of basic Unix shell and DOS batch programming techniques that are described in Chapter 2 "Building Blocks." That chapter explained some of the common routines that will be used across most of the scripts presented here.

This book could have provided much more simple scripts. But, considering standardization across all scripts and the reusability of individual sections for your own writing of scripts, I am focusing on providing a comprehensive script, rather than a temporary fix. After you understand one script, it is easy to follow the flow for the rest of the scripts.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020