Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual Excerpts from this Manual

MySQL 5.7 Reference Manual  /  ...  /  How MySQL Uses Internal Temporary Tables

8.4.4 How MySQL Uses Internal Temporary Tables

In some cases, the server creates internal temporary tables while processing queries. Users have no direct control over when the server does this. An internal temporary table can be held in memory and processed by the MEMORY storage engine, or stored on disk. The server may create an internal temporary table initially as an in-memory table, then convert it to an on-disk table if it becomes too large. As of MySQL 5.7.5, the internal_tmp_disk_storage_engine system variable determines which storage engine the server uses to manage on-disk internal temporary tables. The value can be MYISAM or INNODB. The default in MySQL 5.7.5 is MYISAM. As of MySQL 5.7.6, the default is INNODB. Before MySQL 5.7.5, the server always uses MyISAM.

Temporary tables can be created under conditions such as these:

  • UNION queries use temporary tables, with some exceptions described later.

  • Some views require temporary tables, such those evaluated using the TEMPTABLE algorithm, or that use UNION or aggregation.

  • If there is an ORDER BY clause and a different GROUP BY clause, or if the ORDER BY or GROUP BY contains columns from tables other than the first table in the join queue, a temporary table is created.

  • DISTINCT combined with ORDER BY may require a temporary table.

  • If you use the SQL_SMALL_RESULT option, MySQL uses an in-memory temporary table, unless the query also contains elements (described later) that require on-disk storage.

  • Multiple-table UPDATE statements.

  • GROUP_CONCAT() or COUNT(DISTINCT) evaluation.

  • Derived tables (subqueries in the FROM clause).

  • Tables created for subquery or semi-join materialization.

To determine whether a query requires a temporary table, use EXPLAIN and check the Extra column to see whether it says Using temporary (see Section 8.8.1, “Optimizing Queries with EXPLAIN”). EXPLAIN will not necessarily say Using temporary for derived or materialized temporary tables.

If an internal temporary table is created initially as an in-memory table but becomes too large, MySQL automatically converts it to an on-disk table. The maximum size for in-memory temporary tables is the minimum of the tmp_table_size and max_heap_table_size values. This differs from MEMORY tables explicitly created with CREATE TABLE: For such tables, only the max_heap_table_size system variable determines how large the table is permitted to grow and there is no conversion to on-disk format.

As of MySQL 5.7.5, it is possible to specify the storage engine the server uses for on-disk internal temporary tables, by setting the internal_tmp_disk_storage_engine system variable. Permitted values are MYISAM (the default in MySQL 5.7.5) and INNODB (the default as of MySQL 5.7.6).

When the server creates an internal temporary table (either in memory or on disk), it increments the Created_tmp_tables status variable. If the server creates the table on disk (either initially or by converting an in-memory table) it increments the Created_tmp_disk_tables status variable.

Some conditions prevent the use of an in-memory temporary table, in which case the server uses an on-disk table instead:

  • Presence of a BLOB or TEXT column in the table

  • Presence of any string column in a GROUP BY or DISTINCT clause larger than 512 bytes for binary strings or 512 characters for nonbinary strings. (Before MySQL 5.7.3, the limit is 512 bytes regardless of string type.)

  • Presence of any string column with a maximum length larger than 512 (bytes for binary strings, characters for nonbinary strings) in the SELECT list, if UNION or UNION ALL is used

  • The SHOW COLUMNS and the DESCRIBE statements use BLOB as the type for some columns, thus the temporary table used for the results is an on-disk table.

As of MySQL 5.7.3, the server does not use a temporary table for UNION statements that meet certain qualifications. Instead, it retains from temporary table creation only the data structures necessary to perform result column typecasting. The table is not fully instantiated and no rows are written to or read from it; rows are sent directly to the client. As a result, The result is reduced memory and disk requirements, and smaller delay before the first row is sent to the client because the server need not wait until the last query block is executed. EXPLAIN and optimizer trace output will change: The UNION RESULT query block will not be present because that block is the part that reads from the temporary table.

The conditions that qualify a UNION for evaluation without a temporary table are:

  • The union is UNION ALL, not UNION or UNION DISTINCT.

  • There is no global ORDER BY clause.

  • The union is not the top-level query block of an {INSERT | REPLACE} ... SELECT ... statement.

Download this Manual
User Comments
  Posted by Baron Schwartz on August 14, 2007
MySQL also uses temporary tables when processing subqueries in the FROM clause (derived tables), some UNION queries, and some VIEW queries.
Sign Up Login You must be logged in to post a comment.