In some cases, the server creates internal temporary tables while processing queries. Users have no direct control over when the server does this.
Temporary tables can be created under conditions such as these:
UNIONqueries use temporary tables.Some views require temporary tables, such those evaluated using the
TEMPTABLEalgorithm, or that useUNIONor aggregation.If there is an
ORDER BYclause and a differentGROUP BYclause, or if theORDER BYorGROUP BYcontains columns from tables other than the first table in the join queue, a temporary table is created.DISTINCTcombined withORDER BYmay require a temporary table.If you use the
SQL_SMALL_RESULToption, MySQL uses an in-memory temporary table, unless the query also contains elements (described later) that require on-disk storage.Multiple-table
UPDATEstatements.Evaluation of
GROUP_CONCAT()orCOUNT(DISTINCT)expressions.
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”).
An internal temporary table can be held in memory and
processed by the MEMORY storage engine, or
stored on disk and processed by the MyISAM
storage engine.
If an internal temporary table is created 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.
Some conditions prevent the use of an in-memory temporary table, in which case the server uses an on-disk table instead:
Presence of any string column in a
GROUP BYorDISTINCTclause larger than 512 bytesPresence of any string column with a maximum length larger than 512 (bytes for binary strings, characters for nonbinary strings) in the
SELECTlist, ifUNIONorUNION ALLis usedThe
SHOW COLUMNSand theDESCRIBEstatements useBLOBas the type for some columns, thus the temporary table used for the results is an on-disk table.
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.