In some cases, the server creates internal temporary tables
while processing queries. Such a table can be held in memory and
processed by the MEMORY
storage engine, or
stored on disk and processed by the MyISAM
storage engine. A temporary table created initially as an
in-memory table may be converted to an on-disk table if it
becomes too large.
Temporary tables can be created under conditions such as these:
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.
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 7.2.1, “Optimizing Queries with EXPLAIN
”.
Some conditions prevent the use of an in-memory temporary table, in which case the server uses an on-disk table instead:
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
: The
max_heap_table_size
system
variable determines how large the table is allowed to grow and
there is no conversion to on-disk format.
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.
User Comments
MySQL also uses temporary tables when processing subqueries in the FROM clause (derived tables), some UNION queries, and some VIEW queries.
"Presence of a BLOB or TEXT column in the table" alone does not prevent the use of an in-memory temporary table unless the BLOB or TEXT column is in the select list and the query uses a group by or distinct clause.
Add your own comment.