Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 38.2Mb
PDF (A4) - 38.3Mb
PDF (RPM) - 33.1Mb
HTML Download (TGZ) - 8.1Mb
HTML Download (Zip) - 8.1Mb
HTML Download (RPM) - 7.0Mb
Man Pages (TGZ) - 133.2Kb
Man Pages (Zip) - 189.2Kb
Info (Gzip) - 3.4Mb
Info (Zip) - 3.4Mb
Excerpts from this Manual

B.5.6.2 TEMPORARY Table Problems

Temporary tables created with CREATE TEMPORARY TABLE have the following limitations:

  • TEMPORARY tables are supported only by the InnoDB, MEMORY, MyISAM, and MERGE storage engines.

  • The SHOW TABLES statement does not list TEMPORARY tables.

  • To rename TEMPORARY tables, RENAME TABLE does not work. Use ALTER TABLE instead:

    ALTER TABLE old_name RENAME new_name;
  • You cannot refer to a TEMPORARY table more than once in the same query. For example, the following does not work:

    SELECT * FROM temp_table JOIN temp_table AS t2;

    The statement produces this error:

    ERROR 1137: Can't reopen table: 'temp_table'

    You can work around this issue if your query permits use of a common table expression (CTE) rather than a TEMPORARY table. For example, this fails with the Can't reopen table error:

    CREATE TEMPORARY TABLE t SELECT 1 AS col_a, 2 AS col_b;
    SELECT * FROM t AS t1 JOIN t AS t2;

    To avoid the error, use a WITH clause that defines a CTE, rather than the TEMPORARY table:

    WITH cte AS (SELECT 1 AS col_a, 2 AS col_b)
    SELECT * FROM cte AS t1 JOIN cte AS t2;
  • The Can't reopen table error also occurs if you refer to a temporary table multiple times in a stored function under different aliases, even if the references occur in different statements within the function. It may occur for temporary tables created outside stored functions and referred to across multiple calling and callee functions.

  • There are known issues in using temporary tables with replication. See Section 17.4.1.31, “Replication and Temporary Tables”, for more information.


User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
  Posted by Devang Modi on August 30, 2011
Combine queries for Insert and Select always obeys Innodb locking rules
if one of the source table is based on Innodb engine.
It is also possible that the INSERT activity applicable to TEMPORARY
table which is not InnoDB engine. It is also possible that in SELECT
section with INNODB, some other TEMPORARY Tables are used.
Devang Modi
Sign Up Login You must be logged in to post a comment.