Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 32.8Mb
PDF (A4) - 32.8Mb
PDF (RPM) - 30.8Mb
HTML Download (TGZ) - 7.8Mb
HTML Download (Zip) - 7.9Mb
HTML Download (RPM) - 6.7Mb
Man Pages (TGZ) - 143.5Kb
Man Pages (Zip) - 203.6Kb
Info (Gzip) - 3.0Mb
Info (Zip) - 3.0Mb


MySQL 8.0 Reference Manual  /  ...  /  Internal Temporary Table Use in MySQL

Pre-General Availability Draft: 2017-07-24

8.4.4 Internal Temporary Table Use in MySQL

In some cases, the server creates internal temporary tables while processing statements. Users have no direct control over when this occurs.

The server creates temporary tables under conditions such as these:

  • Evaluation of UNION statements, with some exceptions described later.

  • Evaluation of some views, such those that use the TEMPTABLE algorithm, UNION, or aggregation.

  • Evaluation of derived tables (subqueries in the FROM clause).

  • Evaluation of common table expressions (see Section 13.2.11.9, “WITH Syntax (Common Table Expressions)”).

  • Tables created for subquery or semi-join materialization (see Section 8.2.2, “Optimizing Subqueries, Derived Tables, View References, and Common Table Expressions”).

  • Evaluation of statements that contain an ORDER BY clause and a different GROUP BY clause, or for which the ORDER BY or GROUP BY contains columns from tables other than the first table in the join queue.

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

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

  • Evaluation of multiple-table UPDATE statements.

  • Evaluation of GROUP_CONCAT() or COUNT(DISTINCT) expressions.

To determine whether a statement 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.

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 query 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 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 DESCRIBE statements use BLOB as the type for some columns, thus the temporary table used for the results is an on-disk table.

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. 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 reflects this execution strategy: The UNION RESULT query block is not present because that block corresponds to the part that reads from the temporary table.

These conditions qualify a UNION for evaluation without a temporary table:

  • 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.

Storage Engines Used for Temporary Tables

An internal temporary table can be held in memory and processed by the TempTable or MEMORY storage engine, or stored on disk by the InnoDB or MyISAM storage engine.

The internal_tmp_mem_storage_engine session variable defines the storage engine for in-memory internal temporary tables. Permitted values are TempTable (the default) and MEMORY.

The TempTable storage engine replaces the MEMORY storage engine as the default engine for in-memory internal temporary tables. The TempTable storage engine provides efficient storage for VARCHAR and VARBINARY columns.

The temptable_max_ram configuration option defines the maximum amount of memory that the TempTable storage engine can use before data is stored to disk. The default value is 1GiB.

The memory/temptable/physical_ram and memory/temptable/physical_disk Performance Schema instruments may be used to monitor TempTable memory allocation and disk storage. memory/temptable/physical_ram reports the amount of allocated RAM. memory/temptable/physical_disk reports the amount of allocated disk. If this instrument reports a value other than 0, the temptable_max_ram threshold was reached at some point. Data can be queried in Performance Schema memory summary tables such as memory_summary_global_by_event_name. See Section 25.11.15.10, “Memory Summary Tables”.

When using the MEMORY storage engine for in-memory temporary tables, MySQL automatically converts an in-memory temporary table to an on-disk table if it becomes too large. The maximum size for in-memory temporary tables is determined from whichever of the values of tmp_table_size and max_heap_table_size is smaller. 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.

The tmp_table_size and max_heap_table_size configuration options do not apply to the TempTable storage engine.

The internal_tmp_disk_storage_engine system variable determines which storage engine the server uses to manage on-disk internal temporary tables. Permitted values are INNODB (the default) and MYISAM.

For common table expressions (CTEs), the storage engine used for on-disk internal temporary tables cannot be MyISAM. If internal_tmp_disk_storage_engine=MYISAM, an error occurs for any attempt to materialize a CTE using an on-disk temporary table.

Note

Using internal_tmp_disk_storage_engine=INNODB, queries that generate temporary tables exceeding InnoDB row or column limits return Row size too large or Too many columns errors. The workaround is to set internal_tmp_disk_storage_engine to MYISAM.

Temporary Table Storage Format

When in-memory temporary tables are managed by the TempTable storage engine, rows that include VARCHAR and VARBINARY columns are represented in memory by an array of cells, with each cell containing a NULL flag, the data length, and a data pointer. Column values are placed in consecutive order after the array, in a single region of memory, without padding. Each cell in the array uses 16B of storage.

When in-memory temporary tables are managed by the MEMORY storage engine, fixed-length row format is used. VARCHAR and VARBINARY column values are padded to the maximum column length, in effect storing them as CHAR and BINARY columns.

On-disk temporary tables are managed by the InnoDB or MyISAM storage engine (depending on the internal_tmp_disk_storage_engine setting). Both engines store temporary tables using dynamic-width row format. Columns take only as much storage as needed, which reduces disk I/O and space requirements, and processing time compared to on-disk tables that use fixed-length rows.

When using the MEMORY storage engine, statements that initially create an internal temporary table in memory, and then convert it to an on-disk table, better performance might be achieved by skipping the conversion step and creating the table on disk to begin with.

The big_tables system variable can be used to force disk storage of internal temporary tables.


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.