10.4.4 Internal Temporary Table Use in MySQL (original) (raw)

10.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:

To determine whether a statement requires a temporary table, useEXPLAIN and check theExtra column to see whether it saysUsing temporary (seeSection 10.8.1, “Optimizing Queries with EXPLAIN”). EXPLAIN does not necessarily say Using temporary for derived or materialized temporary tables. For statements that use window functions, EXPLAIN with FORMAT=JSON always provides information about the windowing steps. If the windowing functions use temporary tables, it is indicated for each step.

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

The server does not use a temporary table forUNION 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: TheUNION 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:

Internal Temporary Table Storage Engine

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

Storage Engine for In-Memory Internal Temporary Tables

Theinternal_tmp_mem_storage_engine variable defines the storage engine used for in-memory internal temporary tables. Permitted values areTempTable (the default) andMEMORY.

The TempTable storage engine provides efficient storage for VARCHAR and VARBINARY columns, and other binary large object types.

The following variables control TempTable storage engine limits and behavior:

Use of memory-mapped files by the TempTable storage engine is governed by these rules:

When using the MEMORY storage engine for in-memory temporary tables (internal_tmp_mem_storage_engine=MEMORY), MySQL automatically converts an in-memory temporary table to an on-disk table if it becomes too large. The maximum size of an in-memory temporary table is defined by thetmp_table_size ormax_heap_table_size value, whichever is smaller. This differs fromMEMORY tables explicitly created withCREATE TABLE. For such tables, only the max_heap_table_size variable determines how large a table can grow, and there is no conversion to on-disk format.

Storage Engine for On-Disk Internal Temporary Tables

MySQL 8.4 uses only theInnoDB storage engine for on-disk internal temporary tables. (TheMYISAM storage engine is no longer supported for this purpose.)

InnoDB on-disk internal temporary tables are created in session temporary tablespaces that reside in the data directory by default. For more information, seeSection 17.6.3.5, “Temporary Tablespaces”.

Internal Temporary Table Storage Format

When in-memory internal temporary tables are managed by theTempTable storage engine, rows that includeVARCHAR columns,VARBINARY columns, and other binary large object type 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 16 bytes of storage. The same storage format applies when theTempTable storage engine allocates space from memory-mapped files.

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

Internal temporary tables on disk are always managed byInnoDB.

When using the MEMORY storage engine, statements can initially create an in-memory internal temporary table and then convert it to an on-disk table if the table becomes too large. In such cases, better performance might be achieved by skipping the conversion and creating the internal temporary table on disk to begin with. Thebig_tables variable can be used to force disk storage of internal temporary tables.

Monitoring Internal Temporary Table Creation

When an internal temporary table is created in memory or on disk, the server increments theCreated_tmp_tables value. When an internal temporary table is created on disk, the server increments theCreated_tmp_disk_tables value. If too many internal temporary tables are created on disk, consider adjusting the engine-specific limits described in Internal Temporary Table Storage Engine.

The memory/temptable/physical_ram andmemory/temptable/physical_disk Performance Schema instruments can be used to monitorTempTable space allocation from memory and disk. memory/temptable/physical_ram reports the amount of allocated RAM.memory/temptable/physical_disk reports the amount of space allocated from disk when memory-mapped files are used as the TempTable overflow mechanism. If thephysical_disk instrument reports a value other than 0 and memory-mapped files are used as the TempTable overflow mechanism, a TempTable memory limit was reached at some point. Data can be queried in Performance Schema memory summary tables such asmemory_summary_global_by_event_name. SeeSection 29.12.20.10, “Memory Summary Tables”.