Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 38.0Mb
PDF (A4) - 38.1Mb
PDF (RPM) - 37.3Mb
HTML Download (TGZ) - 10.2Mb
HTML Download (Zip) - 10.3Mb
HTML Download (RPM) - 8.9Mb
Man Pages (TGZ) - 217.0Kb
Man Pages (Zip) - 329.8Kb
Info (Gzip) - 3.5Mb
Info (Zip) - 3.5Mb
Excerpts from this Manual

13.1.29 DROP TABLE Syntax

DROP [TEMPORARY] TABLE [IF EXISTS]
    tbl_name [, tbl_name] ...
    [RESTRICT | CASCADE]

DROP TABLE removes one or more tables. You must have the DROP privilege for each table.

Be careful with this statement! It removes the table definition and all table data. For a partitioned table, it permanently removes the table definition, all its partitions, and all data stored in those partitions. It also removes partition definitions associated with the dropped table.

Note

As of MySQL 5.7.6, partition definition (.par) files are no longer created for partitioned InnoDB tables. Instead, partition definitions are stored in the InnoDB internal data dictionary. Partition definition (.par) files continue to be used for partitioned MyISAM tables.

DROP TABLE causes an implicit commit, except when used with the TEMPORARY keyword. See Section 13.3.3, “Statements That Cause an Implicit Commit”.

Important

When a table is dropped, privileges granted specifically for the table are not automatically dropped. They must be dropped manually. See Section 13.7.1.4, “GRANT Syntax”.

If any tables named in the argument list do not exist, the statement returns an error indicating by name which nonexisting tables it was unable to drop, but also drops all tables in the list that do exist.

Use IF EXISTS to prevent an error from occurring for tables that do not exist. Instead of an error, a NOTE is generated for each nonexistent table; these notes can be displayed with SHOW WARNINGS. See Section 13.7.5.40, “SHOW WARNINGS Syntax”.

IF EXISTS can also be useful for dropping tables in unusual circumstances under which there is an .frm file but no table managed by the storage engine. (For example, if an abnormal server exit occurs after removal of the table from the storage engine but before .frm file removal.)

The TEMPORARY keyword has the following effects:

  • The statement drops only TEMPORARY tables.

  • The statement does not cause an implicit commit.

  • No access rights are checked. A TEMPORARY table is visible only with the session that created it, so no check is necessary.

Using TEMPORARY is a good way to ensure that you do not accidentally drop a non-TEMPORARY table.

The RESTRICT and CASCADE keywords do nothing. They are permitted to make porting easier from other database systems.

DROP TABLE is not supported with all innodb_force_recovery settings. See Section 14.21.2, “Forcing InnoDB Recovery”.


User Comments
  Posted by Pankaj Khanna on March 26, 2006
An example to drop tables having parent-child relationship is to drop the child tables first and then the parent tables. This can be very helpful when we drop tables and then recreate them in a script.

Example:
Let's say table A has two children B and C. Then we can use the following syntax to drop all tables.

DROP TABLE IF EXISTS B,C,A;

This can be placed in the beginning of the script instead
of individually dropping each table (somewhat but not exactly similar to CASCADE CONSTRAINTS option in Oracle).
  Posted by David Andersen on August 31, 2007
Just found an excellent library, which allows dropping multiple tables using syntax similar to "drop table like 'sales%'". The library can also do some multi-purpose Dynamic SQL.

You can read about the specific syntax at: http://datacharmer.blogspot.com/2005/12/mysql-5-general-purpose-routine.html

It can be downloaded from https://sourceforge.net/project/showfiles.php?group_id=166288
  Posted by Malcolm Ke (kexianbin@diyism.com) on September 23, 2008
Guy, "drop tables like" could be realized thus:
delimiter $$
create procedure drop_tables_like(pattern varchar(255), db varchar(255))
begin
select @str_sql:=concat('drop table ', group_concat(table_name))
from information_schema.tables
where table_schema=db and table_name like pattern;

prepare stmt from @str_sql;
execute stmt;
drop prepare stmt;
end$$

call drop_tables_like('kw_%', 'db_1')$$

drop procedure if exists drop_tables_like$$
delimiter ;
  Posted by Morgan Christiansson on November 22, 2008
It's also possible to do DROP TABLE LIKE 'tableprefix%' using the free software maatkit tool from http://www.maatkit.org/

Example:
mk-find --dblike "dbname" --tbllike "tableprefix%" --exec_plus "DROP TABLE %s"
  Posted by Jonathan Watt on May 28, 2009
To drop ALL tables in your database (fill out the first line as appropriate):

MYSQL="mysql -h HOST -u USERNAME -pPASSWORD -D DB_NAME"
$MYSQL -BNe "show tables" | awk '{print "set foreign_key_checks=0; drop table `" $1 "`;"}' | $MYSQL
unset MYSQL

This can be useful if you need to empty a database in order to restore a backup made by mysqldump, but you couldn't use --add-drop-database because you don't have CREATE DATABASE privileges on the command line (e.g. you're on shared hosting). mysqldump adds DROP TABLE by default, but if tables may have been added or renamed since the time of your backup (e.g. by some sort of update process that you're trying to revert from), failing to drop those tables will likely cause serious headaches later on.

Of course this raises the question of why MySQL doesn't support "DROP TABLE *;" (in which case mysqldump could just insert that)?
  Posted by Oliver Frick on August 22, 2011
You can use "show tables from mysqldb1 like 'name%' "
And then copy paste into a text editor and build a comma separated list to feed "drop table "... For me this is faster than write the procedure :)
  Posted by Peter Hine on May 7, 2012
for table in `echo show tables in piwik\; | mysql | grep piwik_archive_`;do echo drop table $table\; | mysql -D piwik; done

linux example for removing all the archive tables in a database called piwik to simulate the "drop table like 'piwik_archive_%'" example above
  Posted by Brendan Byrd on July 22, 2015
It should be noted that the TEMPORARY keyword is also allowed on slave servers, especially non-existent temporary tables. For example, if 'tempo' is an existing temp table for a non-admin user on a slave:

> DROP TABLE IF EXISTS tempo;
Query OK, 0 rows affected (0.00 sec)

> DROP TABLE IF EXISTS tempo;
ERROR 1290 (HY000): The MySQL server is running with the --read-only option so it cannot execute this statement

> DROP TEMPORARY TABLE IF EXISTS tempo;
Query OK, 0 rows affected, 1 warning (0.00 sec)

MySQL knows that the DROP is for a temp table if the table exists, but assumes that the DROP is for a non-temp table if the table doesn't exist, unless the TEMPORARY keyword is used.

Sign Up Login You must be logged in to post a comment.