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. All table data and the table definition
are removed, so be
careful with this statement! If any of the tables named
in the argument list do not exist, MySQL returns an error
indicating by name which nonexisting tables it was unable to drop,
but it also drops all of the tables in the list that do exist.
When a table is dropped, user privileges on the table are not automatically dropped. See Section 14.7.1.4, “GRANT Syntax”.
For a partitioned table, DROP TABLE
permanently removes the table definition, all of its partitions,
and all of the data which was stored in those partitions. It also
removes partition definitions associated with the dropped table.
Prior to MySQL 5.7.6, DROP TABLE
removes partition definitions (.par) files
associated with the dropped table. As of MySQL 5.7.6, partition
definition (.par) files are no longer
created. Instead, partition definitions are stored in the
internal data dictionary.
Use IF EXISTS to prevent an error from
occurring for tables that do not exist. A NOTE
is generated for each nonexistent table when using IF
EXISTS. See Section 14.7.5.40, “SHOW WARNINGS Syntax”.
IF EXISTS can 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.)
RESTRICT and CASCADE are
permitted to make porting easier. In MySQL 5.7, they
do nothing.
DROP TABLE automatically commits
the current active transaction, unless you use the
TEMPORARY keyword.
The TEMPORARY keyword has the following
effects:
The statement drops only
TEMPORARYtables.The statement does not end an ongoing transaction.
No access rights are checked. (A
TEMPORARYtable is visible only to 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.
DROP TABLE is not supported with
all innodb_force_recovery
settings. See Section 15.21.2, “Forcing InnoDB Recovery”.
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).
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
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 ;
Example:
mk-find --dblike "dbname" --tbllike "tableprefix%" --exec_plus "DROP TABLE %s"
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)?
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 :)
linux example for removing all the archive tables in a database called piwik to simulate the "drop table like 'piwik_archive_%'" example above
> 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.