Skip to content

Insight and analysis of technology and business strategy

How and why tmp_table_size and max_heap_table_size are bounded.

Overview

In some cases, MySQL creates internal temporary tables while processing queries. On the base of the dimensions of the resultset MySQL will use the MEMORY engine AND/OR the MyISAM engine. The difference is that MEMORY engine will handle the table in memory, while MyISAM will write it on disk. A table created using the MEMORY engine can be automatically converted by the MySQL server if it exceed the defined threshold. And there are others circumstances which could create temporary tables using MEMORY but that can go to MyISAM (so disk) if too large:
  • 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;
  • DISTINCT combined with ORDER BY may require a temporary table;
  • In the case of 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.
There are some conditions which will force the temporary table to use MyISAM :
  • Presence of a BLOB or TEXT column in the table;
  • Presence of any column in a GROUP BY or DISTINCT clause larger than 512 bytes;
  • Presence of any column larger than 512 bytes in the SELECT list, if UNION or UNION ALL;
The tables explicitly created with CREATE TABLE ENGINE MEMORY use ONLY the max_heap_table_size system variable to determines how large the table is permitted to grow and there is no conversion to on-disk format.

Why am I still doing a post on this?

Because I still see MySQL configurations that DBAs seem to use as separate assignments without taking into account the consequences of over-allocation and what impact it has on MySQL server memory usage. Let us take this from the start, the manual. In the manual section we can find the tmp_table_size definition: [code] Command-Line Format --tmp_table_size=# Config-File Format tmp_table_size Option Sets Variable Yes,tmp_table_size Variable Name tmp_table_size Variable Scope Both Dynamic Variable Yes Permitted Values Type numeric Default system dependent Range 1024-4294967295 [/code] What we need to take in account, and in mind, are these two elements: [code] Default system dependent Range 1024-4294967295 [/code] [code] Command-Line Format --max_heap_table_size=# Config-File Format max_heap_table_size Option Sets Variable Yes, max_heap_table_size Variable Name max_heap_table_size Variable Scope Both Dynamic Variable Yes Permitted Values Type numeric Default 16777216 Range 16384-4294967295 [/code] We can easily identify that both can be dynamically modified (Dynamic Variable Yes), that both the variable could be assign at global scope or per session (Variable Scope Both). Finally that max_heap_size is by default 16M while tmp_table_size is system dependent. Let us to try to clarify this digging in the code doing: [code] <mysql_source_dir>/sql ->; [root@xxx sql]# grep tmp_table_size *.* [/code] and we found this file: [code] set_var.cc:static sys_var_thd_ulonglong sys_tmp_table_size(&vars, "tmp_table_size",set_var.cc: &SV::tmp_table_size); [/code] From that my understanding is that both starts with a value of 16MB full-stop. In set_var.cc the statement is: [code] static sys_var_thd_ulonglong sys_tmp_table_size(&vars, "tmp_table_size",&SV::tmp_table_size); [/code] We have no explicit reference to allocation. The place were we have it is in mysqld.cc: [code] {"tmp_table_size", OPT_TMP_TABLE_SIZE, "If an internal in-memory temporary table exceeds this size, MySQL will" " automatically convert it to an on-disk MyISAM table.", &global_system_variables.tmp_table_size, &max_system_variables.tmp_table_size, 0, GET_ULL, REQUIRED_ARG, 16*1024*1024L, 1024, MAX_MEM_TABLE_SIZE, 0, 1, 0}, ... ... {"max_heap_table_size", OPT_MAX_HEP_TABLE_SIZE, "Don't allow creation of heap tables bigger than this.", &global_system_variables.max_heap_table_size, &max_system_variables.max_heap_table_size, 0, GET_ULL, REQUIRED_ARG, 16*1024*1024L, 16384, MAX_MEM_TABLE_SIZE, MALLOC_OVERHEAD, 1024, 0}, [/code] In the MySQL 5.5 and above, we have a clearer place and assignment in sys_vars.cc:: [code] static Sys_var_ulonglong Sys_tmp_table_size( "tmp_table_size", "If an internal in-memory temporary table exceeds this size, MySQL " "will automatically convert it to an on-disk MyISAM table", SESSION_VAR(tmp_table_size), CMD_LINE(REQUIRED_ARG), VALID_RANGE(1024, (ulonglong)~(intptr)0), DEFAULT(16*1024*1024), BLOCK_SIZE(1)); ... ... static Sys_var_ulonglong Sys_max_heap_table_size( "max_heap_table_size", "Don't allow creation of heap tables bigger than this", SESSION_VAR(max_heap_table_size), CMD_LINE(REQUIRED_ARG), VALID_RANGE(16384, (ulonglong)~(intptr)0), DEFAULT(16*1024*1024), BLOCK_SIZE(1024)); [/code] But the result is the same, MySQL start from 16MB, no matter what system you have, or if it does, is very well hide from search. Now let see what the manual say about how this two variables and their relation:
The maximum size of internal in-memory temporary tables. (The actual limit is determined as the minimum of tmp_table_size and max_heap_table_size.) If an in-memory temporary table exceeds the limit, MySQL automatically converts it to an on-disk MyISAM table. Increase the value of tmp_table_size (and max_heap_table_size if necessary) if you do many advanced GROUP BY queries and you have lots of memory. This variable does not apply to user-created MEMORY tables.
Well this one seems clear enough for everyone but to avoid confusion, check the code. So again: [code] [root@xxx sql]# grep tmp_table_size *.* [/code] but this time we open the file sql_select.cc [code] if (thd->variables.tmp_table_size == ~ (ulonglong) 0) // No limit share->max_rows= ~(ha_rows) 0; else share->max_rows= (ha_rows) (((share->db_type() == heap_hton) ? min(thd->variables.tmp_table_size, thd->variables.max_heap_table_size) : thd->variables.tmp_table_size) / share->reclength); [/code] Here is were we find the min() functions used from MySQL. [code] min(thd->variables.tmp_table_size,thd->variables.max_heap_table_size) [/code] So as the manual state MySQL will take the LOWER value assign to the two variables, as the good value for tmp_table_size (only). To be more clear, if we have in the my.cnf: [code] tmp_table_size = 32M max_heap_table_size = 16M [/code] MySQL will assign to tmp_table_size the value of 16M and to max_heap_table_size 16M. if we have: [code] tmp_table_size = 16M max_heap_table_size = 32M [/code] MySQL will assign to tmp_table_size the value of 16M and to max_heap_table_size 32M. This needs to take in account because I still see at client site a lot of : [code] tmp_table_size = 32M max_heap_table_size = 16M [/code] Which makes no sense. Finally, this variable has huge possible impact on memory consumption. Just consider that having: [code] max_connctions = 600 tmp_table_size = 32M max_heap_table_size = 32M [/code] These settings could potentially generate a memory usage on the server of (600 x 16MB) = 9.3 GB. Given that the variables are dynamic, and that could be assign at session level, it is good practics to increase the value of tmp_table_size only when is really needed, in the session before performing the operation which will require it. Seems all to me but If I have miss something here, corrections are welcome.

Pythian Blogs

  • There are no suggestions because the search field is empty.

Tell us how we can help!

dba-cloud-services
Upcoming-Events-banner