Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-02 |
|
|
View PDF |
Use the DROP
TABLESPACE
statement to remove a tablespace from the database.
See Also:
|
You must have the DROP
TABLESPACE
system privilege. You cannot drop a tablespace if it contains any rollback segments holding active transactions.
drop_tablespace::=
Specify the name of the tablespace to be dropped.
You can drop a tablespace regardless of whether it is online or offline. Oracle recommends that you take the tablespace offline before dropping it to ensure that no SQL statements in currently running transactions access any of the objects in the tablespace.
You may want to alert any users who have been assigned the tablespace as either a default or temporary tablespace. After the tablespace has been dropped, these users cannot allocate space for objects or sort areas in the tablespace. You can reassign users new default and temporary tablespaces with the ALTER
USER
statement.
Oracle removes from the data dictionary all metadata about the tablespace and all datafiles and tempfiles in the tablespace. Oracle also automatically drops from the operating system any Oracle-managed datafiles and tempfiles in the tablespace. Other datafiles and tempfiles are not removed from the operating system unless you specify INCLUDING
CONTENTS
AND
DATAFILES
.
SYSTEM
tablespace.See Also:
Oracle9i Data Cartridge Developer's Guide and Oracle9i Database Concepts for more information on domain indexes |
Specify INCLUDING
CONTENTS
to drop all the contents of the tablespace. You must specify this clause to drop a tablespace that contains any database objects. If you omit this clause, and the tablespace is not empty, then Oracle returns an error and does not drop the tablespace.
For partitioned tables, DROP
TABLESPACE
will fail even if you specify INCLUDING
CONTENTS
, if the tablespace contains some, but not all:
For a partitioned index-organized table, if all the primary key index segments are in this tablespace, then this clause will also drop any overflow segments that exist in other tablespaces, as well as any associated mapping table in other tablespaces. If some of the primary key index segments are not in this tablespace, then the statement will fail. In that case, before you can drop the tablespace, you must use ALTER
TABLE
... MOVE
PARTITION
to move those primary key index segments into this tablespace, drop the partitions whose overflow data segments are not in this tablespace, and drop the partitioned index-organized table.
If the tablespace contains a master table of a materialized view, then Oracle invalidates the materialized view.
If the tablespace contains a materialized view log, then Oracle drops this log and any other direct-path INSERT
refresh information associated with the table.
When you specify INCLUDING
CONTENTS
, the AND
DATAFILES
clause lets you instruct Oracle to delete the associated operating system files as well. Oracle writes a message to the alert log for each operating system file deleted. This clause is not needed for Oracle-managed files.
Specify CASCADE
CONSTRAINTS
to drop all referential integrity constraints from tables outside tablespace
that refer to primary and unique keys of tables inside tablespace
. If you omit this clause and such referential integrity constraints exist, then Oracle returns an error and does not drop the tablespace.
The following statement drops the tbs_01
tablespace and drops all referential integrity constraints that refer to primary and unique keys inside tbs_01
:
DROP TABLESPACE tbs_01 INCLUDING CONTENTS CASCADE CONSTRAINTS;
The following example drops the tbs_02
tablespace and deletes all associated operating system datafiles:
DROP TABLESPACE tbs_02 INCLUDING CONTENTS AND DATAFILES;