Oracle® Database Administrator's Guide 10g Release 2 (10.2) Part Number B14231-02 |
|
|
View PDF |
This chapter describes the procedures for starting up and shutting down an Oracle Database instance and contains the following topics:
Suspending and Resuming a Database
See Also:
Oracle Database Oracle Clusterware and Oracle Real Application Clusters Administration and Deployment Guide for additional information specific to an Oracle Real Application Clusters environmentWhen you start up a database, you create an instance of that database and you determine the state of the database. Normally, you start up an instance by mounting and opening the database. Doing so makes the database available for any valid user to connect to and perform typical data access operations. Other options exist, and these are also discussed in this section.
This section contains the following topics relating to starting up an instance of a database:
You can start up a database instance with SQL*Plus, Recovery Manager, or Enterprise Manager.
You can start a SQL*Plus session, connect to Oracle Database with administrator privileges, and then issue the STARTUP
command. Using SQL*Plus in this way is the only method described in detail in this book.
You can also use Recovery Manager (RMAN) to execute STARTUP
and SHUTDOWN
commands. You may prefer to do this if your are within the RMAN environment and do not want to invoke SQL*Plus.
See Also:
Oracle Database Backup and Recovery Basics for information on starting up the database using RMANYou can use Oracle Enterprise Manager (EM) to administer your database, including starting it up and shutting it down. EM combines a GUI console, agents, common services, and tools to provide an integrated and comprehensive systems management platform for managing Oracle products. EM Database Control, which is the portion of EM that is dedicated to administering an Oracle database, enables you to perform the functions discussed in this book using a GUI interface, rather than command line operations.
See Also:
The remainder of this section describes using SQL*Plus to start up a database instance.
To start an instance, the database must read instance configuration parameters (the initialization parameters) from either a server parameter file (SPFILE
) or a text initialization parameter file.
When you issue the SQL*Plus STARTUP
command, the database attempts to read the initialization parameters from an SPFILE
in a platform-specific default location. If it finds no SPFILE
, it searches for a text initialization parameter file.
Note:
For UNIX or Linux, the platform-specific default location (directory) for theSPFILE
and text initialization parameter file is:
$ORACLE_HOME/dbs
For Windows NT and Windows 2000 the location is:
%ORACLE_HOME%\database
In the platform-specific default location, Oracle Database locates your initialization parameter file by examining filenames in the following order:
spfile
$ORACLE_SID
.ora
spfile.ora
init
$ORACLE_SID
.ora
The first two filenames represent SPFILE
s and the third represents a text initialization parameter file.
Note:
Thespfile.ora
file is included in this search path because in a Real Application Clusters environment one server parameter file is used to store the initialization parameter settings for all instances. There is no instance-specific location for storing a server parameter file.
For more information about the server parameter file for a Real Application Clusters environment, see Oracle Database Oracle Clusterware and Oracle Real Application Clusters Administration and Deployment Guide.
If you (or the Database Configuration Assistant) created a server parameter file, but you want to override it with a text initialization parameter file, you can specify the PFILE
clause of the STARTUP
command to identify the initialization parameter file.
STARTUP PFILE = /u01/oracle/dbs/init.ora
Starting Up with a Non-Default Server Parameter File
A non-default server parameter file (SPFILE
) is an SPFILE
that is in a location other than the default location. It is not usually necessary to start an instance with a non-default SPFILE
. However, should such a need arise, you can use the PFILE
clause to start an instance with a non-default server parameter file as follows:
Create a one-line text initialization parameter file that contains only the SPFILE
parameter. The value of the parameter is the non-default server parameter file location.
For example, create a text initialization parameter file /u01/oracle/dbs/spf_init.ora
that contains only the following parameter:
SPFILE = /u01/oracle/dbs/test_spfile.ora
Note:
You cannot use theIFILE
initialization parameter within a text initialization parameter file to point to a server parameter file. In this context, you must use the SPFILE
initialization parameter.Start up the instance pointing to this initialization parameter file.
STARTUP PFILE = /u01/oracle/dbs/spf_init.ora
The SPFILE
must reside on the machine running the database server. Therefore, the preceding method also provides a means for a client machine to start a database that uses an SPFILE
. It also eliminates the need for a client machine to maintain a client-side initialization parameter file. When the client machine reads the initialization parameter file containing the SPFILE
parameter, it passes the value to the server where the specified SPFILE
is read.
Initialization Files and Automatic Storage Management
A database that uses Automatic Storage Management (ASM) usually has a non-default SPFILE
. If you use the Database Configuration Assistant (DBCA) to configure a database to use ASM, DBCA creates an SPFILE
for the database instance in an ASM disk group, and then creates a text initialization parameter file in the default location in the local file system to point to the SPFILE
.
See Also:
Chapter 2, "Creating an Oracle Database", for more information about initialization parameters, initialization parameter files, and server parameter filesYou must perform some preliminary steps before attempting to start an instance of your database using SQL*Plus.
Ensure that environment variables are set so that you connect to the desired Oracle instance. For details, see "Selecting an Instance with Environment Variables".
Start SQL*Plus without connecting to the database:
SQLPLUS /NOLOG
Connect to Oracle Database as SYSDBA
:
CONNECT username/password AS SYSDBA
Now you are connected to the database and ready to start up an instance of your database.
See Also:
SQL*Plus User's Guide and Reference for descriptions and syntax for theCONNECT
, STARTUP
, and SHUTDOWN
commands.You use the SQL*Plus STARTUP
command to start up an Oracle Database instance. You can start an instance in various modes:
Start the instance without mounting a database. This does not allow access to the database and usually would be done only for database creation or the re-creation of control files.
Start the instance and mount the database, but leave it closed. This state allows for certain DBA activities, but does not allow general access to the database.
Start the instance, and mount and open the database. This can be done in unrestricted mode, allowing access to all users, or in restricted mode, allowing access for database administrators only.
Force the instance to start after a startup or shutdown problem, or start the instance and have complete media recovery begin immediately.
Note:
You cannot start a database instance if you are connected to the database through a shared server process.The following scenarios describe and illustrate the various states in which you can start up an instance. Some restrictions apply when combining clauses of the STARTUP
command.
Note:
It is possible to encounter problems starting up an instance if control files, database files, or redo log files are not available. If one or more of the files specified by theCONTROL_FILES
initialization parameter does not exist or cannot be opened when you attempt to mount a database, Oracle Database returns a warning message and does not mount the database. If one or more of the datafiles or redo log files is not available or cannot be opened when attempting to open a database, the database returns a warning message and does not open the database.See Also:
SQL*Plus User's Guide and Reference for information about the restrictions that apply when combining clauses of theSTARTUP
commandNormal database operation means that an instance is started and the database is mounted and open. This mode allows any valid user to connect to the database and perform data access operations.
The following command starts an instance, reads the initialization parameters from the default location, and then mounts and opens the database. (You can optionally specify a PFILE
clause.)
STARTUP
You can start an instance without mounting a database. Typically, you do so only during database creation. Use the STARTUP
command with the NOMOUNT
clause:
STARTUP NOMOUNT
You can start an instance and mount a database without opening it, allowing you to perform specific maintenance operations. For example, the database must be mounted but not open during the following tasks:
Enabling and disabling redo log archiving options. For more information, please refer to Chapter 7, "Managing Archived Redo Logs".
Performing full database recovery. For more information, please refer to Oracle Database Backup and Recovery Basics
The following command starts an instance and mounts the database, but leaves the database closed:
STARTUP MOUNT
You can start an instance, and optionally mount and open a database, in restricted mode so that the instance is available only to administrative personnel (not general database users). Use this mode of instance startup when you need to accomplish one of the following tasks:
Perform an export or import of data
Perform a data load (with SQL*Loader)
Temporarily prevent typical users from using data
Perform certain migration or upgrade operations
Typically, all users with the CREATE SESSION
system privilege can connect to an open database. Opening a database in restricted mode allows database access only to users with both the CREATE SESSION
and RESTRICTED SESSION
system privilege. Only database administrators should have the RESTRICTED SESSION
system privilege. Further, when the instance is in restricted mode, a database administrator cannot access the instance remotely through an Oracle Net listener, but can only access the instance locally from the machine that the instance is running on.
The following command starts an instance (and mounts and opens the database) in restricted mode:
STARTUP RESTRICT
You can use the RESTRICT
clause in combination with the MOUNT
, NOMOUNT
, and OPEN
clauses.
Later, use the ALTER SYSTEM
statement to disable the RESTRICTED SESSION
feature:
ALTER SYSTEM DISABLE RESTRICTED SESSION;
If you open the database in nonrestricted mode and later find that you need to restrict access, you can use the ALTER SYSTEM
statement to do so, as described in "Restricting Access to an Open Database".
In unusual circumstances, you might experience problems when attempting to start a database instance. You should not force a database to start unless you are faced with the following:
You cannot shut down the current instance with the SHUTDOWN NORMAL
, SHUTDOWN IMMEDIATE
, or SHUTDOWN TRANSACTIONAL
commands.
You experience problems when starting an instance.
If one of these situations arises, you can usually solve the problem by starting a new instance (and optionally mounting and opening the database) using the STARTUP
command with the FORCE
clause:
STARTUP FORCE
If an instance is running, STARTUP FORCE
shuts it down with mode ABORT
before restarting it. In this case, beginning with Oracle Database 10g Release 2, the alert log shows the message "Shutting down instance (abort)
" followed by "Starting ORACLE instance (normal)
." (Earlier versions of the database showed only "Starting ORACLE instance (force)
" in the alert log.)
See Also:
"Shutting Down with the ABORT Clause" to understand the side effects of aborting the current instanceIf you know that media recovery is required, you can start an instance, mount a database to the instance, and have the recovery process automatically start by using the STARTUP
command with the RECOVER
clause:
STARTUP OPEN RECOVER
If you attempt to perform recovery when no recovery is required, Oracle Database issues an error message.
Many sites use procedures to enable automatic startup of one or more Oracle Database instances and databases immediately following a system start. The procedures for performing this task are specific to each operating system. For information about automatic startup, see your operating system specific Oracle documentation.
You can alter the availability of a database. You may want to do this in order to restrict access for maintenance reasons or to make the database read only. The following sections explain how to alter the availability of a database:
When you need to perform specific administrative operations, the database must be started and mounted to an instance, but closed. You can achieve this scenario by starting the instance and mounting the database.
To mount a database to a previously started, but not opened instance, use the SQL statement ALTER DATABASE
with the MOUNT
clause as follows:
ALTER DATABASE MOUNT;
See Also:
"Starting an Instance and Mounting a Database" for a list of operations that require the database to be mounted and closed (and procedures to start an instance and mount a database in one step)You can make a mounted but closed database available for general use by opening the database. To open a mounted database, use the ALTER DATABASE
statement with the OPEN
clause:
ALTER DATABASE OPEN;
After executing this statement, any valid Oracle Database user with the CREATE SESSION
system privilege can connect to the database.
Opening a database in read-only mode enables you to query an open database while eliminating any potential for online data content changes. While opening a database in read-only mode guarantees that datafile and redo log files are not written to, it does not restrict database recovery or operations that change the state of the database without generating redo. For example, you can take datafiles offline or bring them online since these operations do not affect data content.
If a query against a database in read-only mode uses temporary tablespace, for example to do disk sorts, then the issuer of the query must have a locally managed tablespace assigned as the default temporary tablespace. Otherwise, the query will fail. This is explained in "Creating a Locally Managed Temporary Tablespace".
Ideally, you open a database in read-only mode when you alternate a standby database between read-only and recovery mode. Be aware that these are mutually exclusive modes.
The following statement opens a database in read-only mode:
ALTER DATABASE OPEN READ ONLY;
You can also open a database in read/write mode as follows:
ALTER DATABASE OPEN READ WRITE;
However, read/write is the default mode.
Note:
You cannot use theRESETLOGS
clause with a READ ONLY
clause.To place an instance in restricted mode, where only users with administrative privileges can access it, use the SQL statement ALTER SYSTEM
with the ENABLE RESTRICTED SESSION
clause. After placing an instance in restricted mode, you should consider killing all current user sessions before performing any administrative tasks.
To lift an instance from restricted mode, use ALTER SYSTEM
with the DISABLE RESTRICTED SESSION
clause.
See Also:
"Terminating Sessions" for directions for killing user sessions
"Restricting Access to an Instance at Startup" to learn some reasons for placing an instance in restricted mode
To initiate database shutdown, use the SQL*Plus SHUTDOWN
command. Control is not returned to the session that initiates a database shutdown until shutdown is complete. Users who attempt connections while a shutdown is in progress receive a message like the following:
ORA-01090: shutdown in progress - connection is not permitted
Note:
You cannot shut down a database if you are connected to the database through a shared server process.To shut down a database and instance, you must first connect as SYSOPER
or SYSDBA
. There are several modes for shutting down a database. These are discussed in the following sections:
Some shutdown modes wait for certain events to occur (such as transactions completing or users disconnecting) before actually bringing down the database. There is a one-hour timeout period for these events. This timeout behavior is discussed in this additional section:
To shut down a database in normal situations, use the SHUTDOWN
command with the NORMAL
clause:
SHUTDOWN NORMAL
The NORMAL
clause is optional, because this is the default shutdown method if no clause is provided.
Normal database shutdown proceeds with the following conditions:
No new connections are allowed after the statement is issued.
Before the database is shut down, the database waits for all currently connected users to disconnect from the database.
The next startup of the database will not require any instance recovery procedures.
Use immediate database shutdown only in the following situations:
To initiate an automated and unattended backup
When a power shutdown is going to occur soon
When the database or one of its applications is functioning irregularly and you cannot contact users to ask them to log off or they are unable to log off
To shut down a database immediately, use the SHUTDOWN
command with the IMMEDIATE
clause:
SHUTDOWN IMMEDIATE
Immediate database shutdown proceeds with the following conditions:
No new connections are allowed, nor are new transactions allowed to be started, after the statement is issued.
Any uncommitted transactions are rolled back. (If long uncommitted transactions exist, this method of shutdown might not complete quickly, despite its name.)
Oracle Database does not wait for users currently connected to the database to disconnect. The database implicitly rolls back active transactions and disconnects all connected users.
The next startup of the database will not require any instance recovery procedures.
When you want to perform a planned shutdown of an instance while allowing active transactions to complete first, use the SHUTDOWN
command with the TRANSACTIONAL
clause:
SHUTDOWN TRANSACTIONAL
Transactional database shutdown proceeds with the following conditions:
No new connections are allowed, nor are new transactions allowed to be started, after the statement is issued.
After all transactions have completed, any client still connected to the instance is disconnected.
At this point, the instance shuts down just as it would when a SHUTDOWN IMMEDIATE
statement is submitted.
The next startup of the database will not require any instance recovery procedures.
A transactional shutdown prevents clients from losing work, and at the same time, does not require all users to log off.
You can shut down a database instantaneously by aborting the database instance. If possible, perform this type of shutdown only in the following situations:
The database or one of its applications is functioning irregularly and none of the other types of shutdown works.
You need to shut down the database instantaneously (for example, if you know a power shutdown is going to occur in one minute).
You experience problems when starting a database instance.
When you must do a database shutdown by aborting transactions and user connections, issue the SHUTDOWN
command with the ABORT
clause:
SHUTDOWN ABORT
An aborted database shutdown proceeds with the following conditions:
No new connections are allowed, nor are new transactions allowed to be started, after the statement is issued.
Current client SQL statements being processed by Oracle Database are immediately terminated.
Uncommitted transactions are not rolled back.
Oracle Database does not wait for users currently connected to the database to disconnect. The database implicitly disconnects all connected users.
The next startup of the database will require instance recovery procedures.
Shutdown modes that wait for users to disconnect or for transactions to complete have a limit on the amount of time that they wait. If all events blocking the shutdown do not occur within one hour, the shutdown command cancels with the following message: ORA-01013: user requested cancel of current operation
.
Occasionally you might want to put a database in a state that allows only DBA transactions, queries, fetches, or PL/SQL statements. Such a state is referred to as a quiesced state, in the sense that no ongoing non-DBA transactions, queries, fetches, or PL/SQL statements are running in the system.
Note:
In this discussion of quiesce database, a DBA is defined as userSYS
or SYSTEM
. Other users, including those with the DBA
role, are not allowed to issue the ALTER SYSTEM QUIESCE DATABASE
statement or proceed after the database is quiesced.The quiesced state lets administrators perform actions that cannot safely be done otherwise. These actions include:
Actions that fail if concurrent user transactions access the same object--for example, changing the schema of a database table or adding a column to an existing table where a no-wait lock is required.
Actions whose undesirable intermediate effect can be seen by concurrent user transactions--for example, a multistep procedure for reorganizing a table when the table is first exported, then dropped, and finally imported. A concurrent user who attempts to access the table after it was dropped, but before import, would not have an accurate view of the situation.
Without the ability to quiesce the database, you would need to shut down the database and reopen it in restricted mode. This is a serious restriction, especially for systems requiring 24 x 7 availability. Quiescing a database is much a smaller restriction, because it eliminates the disruption to users and the downtime associated with shutting down and restarting the database.
When the database is in the quiesced state, it is through the facilities of the Database Resource Manager that non-DBA sessions are prevented from becoming active. Therefore, while this statement is in effect, any attempt to change the current resource plan will be queued until after the system is unquiesced. See Chapter 24, "Using the Database Resource Manager" for more information about the Database Resource Manager.
To place a database into a quiesced state, issue the following statement:
ALTER SYSTEM QUIESCE RESTRICTED;
Non-DBA active sessions will continue until they become inactive. An active session is one that is currently inside of a transaction, a query, a fetch, or a PL/SQL statement; or a session that is currently holding any shared resources (for example, enqueues). No inactive sessions are allowed to become active. For example, If a user issues a SQL query in an attempt to force an inactive session to become active, the query will appear to be hung. When the database is later unquiesced, the session is resumed, and the blocked action is processed.
Once all non-DBA sessions become inactive, the ALTER SYSTEM QUIESCE RESTRICTED
statement completes, and the database is in a quiesced state. In an Oracle Real Application Clusters environment, this statement affects all instances, not just the one that issues the statement.
The ALTER SYSTEM QUIESCE RESTRICTED
statement may wait a long time for active sessions to become inactive. You can determine the sessions that are blocking the quiesce operation by querying the V$BLOCKING_QUIESCE
view. This view returns only a single column: SID
(Session ID). You can join it with V$SESSION
to get more information about the session, as shown in the following example:
select bl.sid, user, osuser, type, program from v$blocking_quiesce bl, v$session se where bl.sid = se.sid;
See Oracle Database Reference for details on these view.
If you interrupt the request to quiesce the database, or if your session terminates abnormally before all active sessions are quiesced, then Oracle Database automatically reverses any partial effects of the statement.
For queries that are carried out by successive multiple Oracle Call Interface (OCI) fetches, the ALTER SYSTEM QUIESCE RESTRICTED
statement does not wait for all fetches to finish. It only waits for the current fetch to finish.
For both dedicated and shared server connections, all non-DBA logins after this statement is issued are queued by the Database Resource Manager, and are not allowed to proceed. To the user, it appears as if the login is hung. The login will resume when the database is unquiesced.
The database remains in the quiesced state even if the session that issued the statement exits. A DBA must log in to the database to issue the statement that specifically unquiesces the database.
Note:
You cannot perform a cold backup when the database is in the quiesced state, because Oracle Database background processes may still perform updates for internal purposes even while the database is quiesced. In addition, the file headers of online datafiles continue to appear to be accessible. They do not look the same as if a clean shutdown had been performed. However, you can still take online backups while the database is in a quiesced state.The following statement restores the database to normal operation:
ALTER SYSTEM UNQUIESCE;
All non-DBA activity is allowed to proceed. In an Oracle Real Application Clusters environment, this statement is not required to be issued from the same session, or even the same instance, as that which quiesced the database. If the session issuing the ALTER SYSTEM UNQUIESCE
statement terminates abnormally, then the Oracle Database server ensures that the unquiesce operation completes.
You can query the ACTIVE_STATE
column of the V$INSTANCE
view to see the current state of an instance. The column values has one of these values:
NORMAL
: Normal unquiesced state.
QUIESCING
: Being quiesced, but some non-DBA sessions are still active.
QUIESCED
: Quiesced; no non-DBA sessions are active or allowed.
The ALTER SYSTEM SUSPEND
statement halts all input and output (I/O) to datafiles (file header and file data) and control files. The suspended state lets you back up a database without I/O interference. When the database is suspended all preexisting I/O operations are allowed to complete and any new database accesses are placed in a queued state.
The suspend command is not specific to an instance. In an Oracle Real Application Clusters environment, when you issue the suspend command on one system, internal locking mechanisms propagate the halt request across instances, thereby quiescing all active instances in a given cluster. However, if someone starts a new instance another instance is being suspended, the new instance will not be suspended.
Use the ALTER SYSTEM RESUME
statement to resume normal database operations. The SUSPEND
and RESUME
commands can be issued from different instances. For example, if instances 1, 2, and 3 are running, and you issue an ALTER SYSTEM SUSPEND
statement from instance 1, then you can issue a RESUME
statement from instance 1, 2, or 3 with the same effect.
The suspend/resume feature is useful in systems that allow you to mirror a disk or file and then split the mirror, providing an alternative backup and restore solution. If you use a system that is unable to split a mirrored disk from an existing database while writes are occurring, then you can use the suspend/resume feature to facilitate the split.
The suspend/resume feature is not a suitable substitute for normal shutdown operations, because copies of a suspended database can contain uncommitted updates.
Caution:
Do not use theALTER SYSTEM SUSPEND
statement as a substitute for placing a tablespace in hot backup mode. Precede any database suspend operation by an ALTER TABLESPACE BEGIN BACKUP
statement.The following statements illustrate ALTER SYSTEM SUSPEND/RESUME
usage. The V$INSTANCE
view is queried to confirm database status.
SQL> ALTER SYSTEM SUSPEND; System altered SQL> SELECT DATABASE_STATUS FROM V$INSTANCE; DATABASE_STATUS --------- SUSPENDED SQL> ALTER SYSTEM RESUME; System altered SQL> SELECT DATABASE_STATUS FROM V$INSTANCE; DATABASE_STATUS --------- ACTIVE
See Also:
Oracle Database Backup and Recovery Advanced User's Guide for details about backing up a database using the database suspend/resume feature