RENAME TABLE

Syntax

RENAME TABLE[S] [IF EXISTS] tbl_name 
  [WAIT n | NOWAIT]
  TO new_tbl_name
    [, tbl_name2 TO new_tbl_name2] ...

Description

This statement renames one or more tables or views, but not the privileges associated with them. For InnoDB tables, it also triggers a reload of InnoDB statistics.

IF EXISTS

If this clause is used, you don't get an error if the table to be renamed doesn't exist.

The rename operation is done atomically, which means that no other session can access any of the tables while the rename is running. For example, if you have an existing table old_table, you can create another table new_table that has the same structure but is empty, and then replace the existing table with the empty one as follows (assuming that backup_table does not already exist):

CREATE TABLE new_table (...);
RENAME TABLE old_table TO backup_table, new_table TO old_table;

Moving Tables to Another Database

tbl_name can optionally be specified as db_name.tbl_name. See Identifier Qualifiers. This allows to use RENAME to move a table from a database to another (as long as they are on the same filesystem):

RENAME TABLE db1.t TO db2.t;

Limitations of Moving Tables to Another Database

Trying to do so produces the following error:

ERROR 1435 (HY000): Trigger in wrong schema

Trying to do so produces the following error:

ERROR 1450 (HY000): Changing schema from 'old_db' to 'new_db' is not allowed.

Renaming Multiple Tables at Once

Multiple tables can be renamed in a single statement. The presence or absence of the optional S (RENAME TABLE or RENAME TABLES) has no impact, whether a single or multiple tables are being renamed.

Renames are always executed in the specified order. Knowing this, it is also possible to swap two tables' names:

RENAME TABLE t1 TO tmp_table,
    t2 TO t1,
    tmp_table TO t2;

WAIT/NOWAIT

Set the lock wait timeout. See WAIT and NOWAIT.

Privileges

Executing the RENAME TABLE statement requires the DROP, CREATE and INSERT privileges for the table or the database.

Atomic RENAME TABLE

RENAME TABLE is atomic for most storage engines, including InnoDB, MyRocks, MyISAM and Aria (MDEV-23842).

This means that if there is a crash (server down or power outage) during RENAME TABLE, all tables revert to their original names and any changes to trigger files are reverted. See Atomic DDL for more information.

This page is licensed: GPLv2, originally from fill_help_tables.sql

Last updated

Was this helpful?