MySQL :: MySQL 8.0 Reference Manual :: 15.1.33 DROP TABLESPACE Statement (original) (raw)
15.1.33 DROP TABLESPACE Statement
DROP [UNDO] TABLESPACE tablespace_name
[ENGINE [=] engine_name]
This statement drops a tablespace that was previously created using CREATE TABLESPACE. It is supported by the NDB
andInnoDB
storage engines.
The UNDO
keyword, introduced in MySQL 8.0.14, must be specified to drop an undo tablespace. Only undo tablespaces created usingCREATE UNDO TABLESPACE syntax can be dropped. An undo tablespace must be in an empty
state before it can be dropped. For more information, seeSection 17.6.3.4, “Undo Tablespaces”.
ENGINE
sets the storage engine that uses the tablespace, where enginename
is the name of the storage engine. Currently, the valuesInnoDB
and NDB
are supported. If not set, the value ofdefault_storage_engine is used. If it is not the same as the storage engine used to create the tablespace, the DROP TABLESPACE
statement fails.
_`tablespacename`_
is a case-sensitive identifier in MySQL.
For an InnoDB
general tablespace, all tables must be dropped from the tablespace prior to a DROP TABLESPACE
operation. If the tablespace is not empty,DROP TABLESPACE
returns an error.
An NDB
tablespace to be dropped must not contain any data files; in other words, before you can drop anNDB
tablespace, you must first drop each of its data files usingALTER TABLESPACE ... DROP DATAFILE.
Notes
- A general
InnoDB
tablespace is not deleted automatically when the last table in the tablespace is dropped. The tablespace must be dropped explicitly usingDROP TABLESPACE_`tablespacename`_
. - A DROP DATABASE operation can drop tables that belong to a general tablespace but it cannot drop the tablespace, even if the operation drops all tables that belong to the tablespace. The tablespace must be dropped explicitly using
DROP TABLESPACE_`tablespacename`_
. - Similar to the system tablespace, truncating or dropping tables stored in a general tablespace creates free space internally in the general tablespace.ibd data file which can only be used for new
InnoDB
data. Space is not released back to the operating system as it is for file-per-table tablespaces.
InnoDB Examples
This example demonstrates how to drop an InnoDB
general tablespace. The general tablespace ts1
is created with a single table. Before dropping the tablespace, the table must be dropped.
mysql> CREATE TABLESPACE `ts1` ADD DATAFILE 'ts1.ibd' Engine=InnoDB;
mysql> CREATE TABLE t1 (c1 INT PRIMARY KEY) TABLESPACE ts1 Engine=InnoDB;
mysql> DROP TABLE t1;
mysql> DROP TABLESPACE ts1;
This example demonstrates dropping an undo tablespace. An undo tablespace must be in an empty
state before it can be dropped. For more information, seeSection 17.6.3.4, “Undo Tablespaces”.
mysql> DROP UNDO TABLESPACE undo_003;
NDB Example
This example shows how to drop an NDB
tablespace myts
having a data file namedmydata-1.dat
after first creating the tablespace, and assumes the existence of a log file group namedmylg
(seeSection 15.1.16, “CREATE LOGFILE GROUP Statement”).
mysql> CREATE TABLESPACE myts
-> ADD DATAFILE 'mydata-1.dat'
-> USE LOGFILE GROUP mylg
-> ENGINE=NDB;
You must remove all data files from the tablespace usingALTER TABLESPACE, as shown here, before it can be dropped:
mysql> ALTER TABLESPACE myts
-> DROP DATAFILE 'mydata-1.dat'
-> ENGINE=NDB;
mysql> DROP TABLESPACE myts;