Skip Headers

Oracle9i SQL Reference
Release 2 (9.2)

Part Number A96540-02
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Feedback

Go to previous page Go to next page
View PDF

ALTER TABLESPACE

Purpose

Use the ALTER TABLESPACE statement to alter an existing tablespace or one or more of its datafiles or tempfiles.

You cannot use this statement to convert a dictionary-managed tablespace to a locally managed tablespace. For that purpose, use the DBMS_SPACE_ADMIN package, which is documented in Oracle9i Supplied PL/SQL Packages and Types Reference.

See Also:

Oracle9i Database Administrator's Guide and CREATE TABLESPACE for information on creating a tablespace

Prerequisites

If you have ALTER TABLESPACE system privilege, then you can perform any of this statement's operations. If you have MANAGE TABLESPACE system privilege, then you can only perform the following operations:

Before you can make a tablespace read only, the following conditions must be met:

Performing this function in restricted mode may help you meet these restrictions, because only users with RESTRICTED SESSION system privilege can be logged on.

Syntax

alter_tablespace::=

Text description of statements_333.gif follows
Text description of alter_tablespace


(datafile_tempfile_clauses::=, data_segment_compression::=--part of ALTER TABLE syntax, storage_clause::=, logging_clause::=)

datafile_tempfile_clauses::=

Text description of statements_337.gif follows
Text description of datafile_tempfile_clauses


(datafile_tempfile_spec::=--part of file_specification).

Semantics

tablespace

Specify the name of the tablespace to be altered.

Restrictions on Altering Tablespaces

datafile_tempfile_clauses

The tablespace file clauses let you add or modify a datafile or tempfile.

ADD DATAFILE | TEMPFILE Clause

Specify ADD to add to the tablespace a datafile or tempfile specified by datafile_tempfile_spec.

For locally managed temporary tablespaces, this is the only clause you can specify at any time.

If you omit datafile_tempfile_spec, then Oracle creates an Oracle-managed file of 100M with AUTOEXTEND enabled.

You can add a datafile or tempfile to a locally managed tablespace that is online or to a dictionary managed tablespace that is online or offline. Be sure the file is not in use by another database.


Note:

On some operating systems, Oracle does not allocate space for the tempfile until the tempfile blocks are actually accessed. This delay in space allocation results in faster creation and resizing of tempfiles, but it requires that sufficient disk space is available when the tempfiles are later used. To avoid potential problems, before you create or resize a tempfile, ensure that the available disk space exceeds the size of the new tempfile or the increased size of a resized tempfile. The excess space should allow for anticipated increases in disk space use by unrelated operations as well. Then proceed with the creation or resizing operation.


See Also:

file_specification, "Adding a Datafile: Example", and "Adding an Oracle-managed Datafile: Example"

RENAME DATAFILE Clause

Specify RENAME DATAFILE to rename one or more of the tablespace's datafiles. The database must be open, and you must take the tablespace offline before renaming it. Each 'filename' must fully specify a datafile using the conventions for filenames on your operating system.

This clause merely associates the tablespace with the new file rather than the old one. This clause does not actually change the name of the operating system file. You must change the name of the file through your operating system.

See Also:

"Moving and Renaming Tablespaces: Example"

DATAFILE | TEMPFILE ONLINE | OFFLINE

Use this clause to take all datafiles or tempfiles in the tablespace offline or put them online. This clause has no effect on the ONLINE/OFFLINE status of the tablespace.

The database must be mounted. If tablespace is SYSTEM, or an undo tablespace, or the default temporary tablespace, then the database must not be open.

DEFAULT storage_clause

DEFAULT storage_clause lets you specify the new default storage parameters for objects subsequently created in the tablespace. For a dictionary-managed temporary table, Oracle considers only the NEXT parameter of the storage_clause.

Restriction on Default Tablespace Storage

You cannot specify this clause for a locally managed tablespace.

See Also:

storage_clause

MINIMUM EXTENT

The MINIMUM EXTENT clause lets you control free space fragmentation in the tablespace by ensuring that every used or free extent in a tablespace is at least as large as, and is a multiple of, integer. This clause is not relevant for a dictionary-managed temporary tablespace.

Restriction on MINIMUM EXTENT

You cannot specify this clause for a locally managed tablespace.

See Also:

Oracle9i Database Administrator's Guide for more information about using MINIMUM EXTENT to control space fragmentation and "Changing Tablespace Extent Allocation: Example"

ONLINE

Specify ONLINE to bring the tablespace online.

OFFLINE

Specify OFFLINE to take the tablespace offline and prevent further access to its segments. When you take a tablespace offline, all of its datafiles are also offline.


Suggestion: Before taking a tablespace offline for a long time, you may want to alter the tablespace allocation of any users who have been assigned the tablespace as either a default or temporary tablespace. When the tablespace is offline, these users cannot allocate space for objects or sort areas in the tablespace. See ALTER USER for more information on allocating tablespace quota to users.


Restriction on Taking Tablespaces Offline

You cannot take a temporary tablespace offline.

NORMAL

Specify NORMAL to flush all blocks in all datafiles in the tablespace out of the SGA. You need not perform media recovery on this tablespace before bringing it back online. This is the default.

TEMPORARY

If you specify TEMPORARY, then Oracle performs a checkpoint for all online datafiles in the tablespace but does not ensure that all files can be written. Any offline files may require media recovery before you bring the tablespace back online.

IMMEDIATE

If you specify IMMEDIATE, then Oracle does not ensure that tablespace files are available and does not perform a checkpoint. You must perform media recovery on the tablespace before bringing it back online.


Note:

The FOR RECOVER setting for ALTER TABLESPACE ... OFFLINE has been deprecated. The syntax is supported for backward compatibility. However, users are encouraged to use the transportable tablespaces feature for tablespace recovery.


See Also:

Oracle9i User-Managed Backup and Recovery Guide for information on using transportable tablespaces to perform media recovery

BEGIN BACKUP

Specify BEGIN BACKUP to indicate that an open backup is to be performed on the datafiles that make up this tablespace. This clause does not prevent users from accessing the tablespace. You must use this clause before beginning an open backup.

Restrictions on Beginning Tablespace Backup

You cannot specify this clause for a read-only tablespace or for a temporary locally managed tablespace.


Note:

While the backup is in progress, you cannot take the tablespace offline normally, shut down the instance, or begin another backup of the tablespace.


See Also:

"Backing Up Tablespaces: Examples"

END BACKUP

Specify END BACKUP to indicate that an online backup of the tablespace is complete. Use this clause as soon as possible after completing an online backup. Otherwise, if an instance failure or SHUTDOWN ABORT occurs, then Oracle assumes that media recovery (possibly requiring archived redo log) is necessary at the next instance start up.

Restriction on Ending Tablespace Backup

You cannot use this clause on a read-only tablespace.

See Also:

READ ONLY | READ WRITE

Specify READ ONLY to place the tablespace in transition read-only mode. In this state, existing transactions can complete (commit or roll back), but no further write operations (DML) are allowed to the tablespace except for rollback of existing transactions that previously modified blocks in the tablespace.

Once a tablespace is read only, you can copy its files to read-only media. You must then rename the datafiles in the control file to point to the new location by using the SQL statement ALTER DATABASE ... RENAME.

See Also:

Specify READ WRITE to indicate that write operations are allowed on a previously read-only tablespace.

PERMANENT | TEMPORARY

Specify PERMANENT to indicate that the tablespace is to be converted from a temporary to a permanent one. A permanent tablespace is one in which permanent database objects can be stored. This is the default when a tablespace is created.

Specify TEMPORARY to indicate specifies that the tablespace is to be converted from a permanent to a temporary one. A temporary tablespace is one in which no permanent database objects can be stored. Objects in a temporary tablespace persist only for the duration of the session.

Restrictions on Temporary Tablespaces

COALESCE

For each datafile in the tablespace, this clause combines all contiguous free extents into larger contiguous extents.

logging_clause

Specify LOGGING if you want logging of all tables, indexes, and partitions within the tablespace. The tablespace-level logging attribute can be overridden by logging specifications at the table, index, and partition levels.

When an existing tablespace logging attribute is changed by an ALTER TABLESPACE statement, all tables, indexes, and partitions created after the statement will have the new default logging attribute (which you can still subsequently override). The logging attributes of existing objects are not changed.

If the tablespace is in FORCE LOGGING mode, then you can specify NOLOGGING in this statement to set the default logging mode of the tablespace to NOLOGGING, but this will not take the tablespace out of FORCE LOGGING mode.

[NO] FORCE LOGGING

Use this clause to put the tablespace in force logging mode or take it out of force logging mode. The database must be open and in READ WRITE mode. Neither of these settings changes the default LOGGING or NOLOGGING mode of the tablespace.

Restriction on Force Logging Mode

You cannot specify FORCE LOGGING for an undo or a temporary tablespace.

See Also:

Oracle9i Database Administrator's Guide for information on when to use FORCE LOGGING mode and "Changing Tablespace Logging Attributes: Example"

Examples

Backing Up Tablespaces: Examples

The following statement signals to the database that a backup is about to begin:

ALTER TABLESPACE tbs_01 
    BEGIN BACKUP; 

The following statement signals to the database that the backup is finished:

ALTER TABLESPACE tbs_01 
   END BACKUP; 
Moving and Renaming Tablespaces: Example

This example moves and renames a datafile associated with the tbs_01 tablespace from 'diskb:tbs_f5.dat' to 'diska:tbs_f5.dat':

  1. Take the tablespace offline using an ALTER TABLESPACE statement with the OFFLINE clause:
    ALTER TABLESPACE tbs_01 OFFLINE NORMAL; 
    
    
  2. Copy the file from 'diskb:tbs_f5.dat' to 'diska:tbs_f5.dat' using your operating system's commands.
  3. Rename the datafile using the ALTER TABLESPACE statement with the RENAME DATAFILE clause:
    ALTER TABLESPACE tbs_01
      RENAME DATAFILE 'diskb:tbs_f5.dat'
      TO              'diska:tbs_f5.dat'; 
    
    
  4. Bring the tablespace back online using an ALTER TABLESPACE statement with the ONLINE clause:
    ALTER TABLESPACE tbs_01 ONLINE; 
    
Adding a Datafile: Example

The following statement adds a datafile to the tablespace. When more space is needed, new extents of size 10 kilobytes will be added up to a maximum of 100 kilobytes:

ALTER TABLESPACE tbs_03 
    ADD DATAFILE 'tbs_f04.dbf'
    SIZE 50K
    AUTOEXTEND ON
    NEXT 10K
    MAXSIZE 100K;
Adding an Oracle-managed Datafile: Example

The following example adds an Oracle-managed datafile to the omf_ts1 tablespace (see "Creating Oracle-managed Files: Examples" for the creation of this tablespace). The new datafile is 100M and is autoextensible with unlimited maximum size:

ALTER TABLESPACE omf_ts1 ADD DATAFILE; 
Changing Tablespace Logging Attributes: Example

The following example changes the default logging attribute of a tablespace to NOLOGGING:

ALTER TABLESPACE tbs_03 NOLOGGING;

Altering a tablespace logging attribute has no affect on the logging attributes of the existing schema objects within the tablespace. The tablespace-level logging attribute can be overridden by logging specifications at the table, index, and partition levels.

Changing Tablespace Extent Allocation: Example

The following statement changes the allocation of every extent of tbs_03 to a multiple of 128K:

ALTER TABLESPACE tbs_03 MINIMUM EXTENT 128K;