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.
DROP TABLE
causes an implicit
commit, except when used with the TEMPORARY
keyword. See Section 13.3.3, “Statements That Cause an Implicit Commit”.
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.6, “GRANT Syntax”.
If any tables named in the argument list do not exist, the statement fails with an error indicating by name which nonexisting tables it was unable to drop, and no changes are made.
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.6.40, “SHOW WARNINGS Syntax”.
IF EXISTS
can also be useful for dropping
tables in unusual circumstances under which there is an entry in
the data dictionary 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 removal of the data
dictionary entry.)
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 15.20.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.